]> Some of my projects - localmylist.git/commitdiff
DB update scratch
authorAPTX <marek321@gmail.com>
Sat, 23 Jan 2016 15:10:51 +0000 (16:10 +0100)
committerAPTX <marek321@gmail.com>
Sat, 23 Jan 2016 15:10:51 +0000 (16:10 +0100)
db-update/db-update-resources.qrc [new file with mode: 0644]
db-update/db-update.pro [new file with mode: 0644]
db-update/main.cpp [new file with mode: 0644]
localmylist.pro
localmylist/localmylist.pro
localmylist/mylist.cpp
localmylist/mylist.h
localmylist/share/schema/schema.sql

diff --git a/db-update/db-update-resources.qrc b/db-update/db-update-resources.qrc
new file mode 100644 (file)
index 0000000..807350d
--- /dev/null
@@ -0,0 +1,2 @@
+<RCC/>
+
diff --git a/db-update/db-update.pro b/db-update/db-update.pro
new file mode 100644 (file)
index 0000000..a22f025
--- /dev/null
@@ -0,0 +1,18 @@
+QT += core
+QT -= gui
+
+include(../config.pri)
+
+TARGET = lml-db-update
+DESTDIR = ../build
+CONFIG += console
+CONFIG -= app_bundle
+
+TEMPLATE = app
+
+SOURCES += main.cpp
+
+include(../localmylist.pri)
+
+target.path = $${PREFIX}/bin
+INSTALLS += target
diff --git a/db-update/main.cpp b/db-update/main.cpp
new file mode 100644 (file)
index 0000000..fd05f96
--- /dev/null
@@ -0,0 +1,476 @@
+#include <iterator>
+#include <utility>
+
+#include <QtCore/QCoreApplication>
+#include <QStringList>
+#include <QTextStream>
+#include <QUrl>
+#include <QSqlQuery>
+#include <QSqlError>
+#include "mylist.h"
+#include "settings.h"
+
+#include <QDebug>
+
+class SqlQueryResultIterator : public std::iterator<std::forward_iterator_tag, int>
+{
+       QSqlQuery *query;
+       bool sentinel;
+public:
+       SqlQueryResultIterator(QSqlQuery &query, bool sentinel) : query{&query}, sentinel{sentinel} {}
+       SqlQueryResultIterator(const SqlQueryResultIterator &it) : query{it.query}, sentinel{it.sentinel} {}
+       SqlQueryResultIterator &operator++() { query->next(); return *this; }
+       SqlQueryResultIterator operator++(int) = delete;
+       bool operator==(const SqlQueryResultIterator &rhs)
+       {
+               qDebug() << "it operator==" << sentinel << rhs.sentinel;
+               if (sentinel == rhs.sentinel)
+               {
+                       if (sentinel)
+                               return true;
+                       return query->at() == rhs.query->at();
+               }
+               return query->at() == QSql::AfterLastRow;
+       }
+       bool operator!=(const SqlQueryResultIterator &rhs) { return !operator==(rhs); }
+       const QSqlQuery &operator*() { return *query; }
+};
+
+namespace std
+{
+       SqlQueryResultIterator begin(QSqlQuery &q)
+       {
+               if (!q.isActive())
+                       throw std::logic_error{"Trying to iterate over the results of a "
+                                                                  "query that has not been executed"};
+               if (!q.isSelect() || q.at() == QSql::AfterLastRow)
+                       return {q, true};
+               if (q.at() == QSql::BeforeFirstRow && !q.next())
+                       return {q, true};
+               return {q, false};
+       }
+       SqlQueryResultIterator end(QSqlQuery &q)
+       {
+               return SqlQueryResultIterator{q, true};
+       }
+}
+
+namespace {
+
+class SqlException : public std::runtime_error
+{
+       static std::string makeErrorMessage(const QString &msg, const QSqlQuery &query)
+       {
+               QSqlError e = query.lastError();
+               QString what{"SQL Error: %1\n"
+                               "Database: %2\n"
+                               "Driver: %3\n"
+                               "Query: %4\n"};
+               what = what.arg(msg, e.databaseText(), e.driverText(), query.lastQuery());
+               return qPrintable(what);
+       }
+
+public:
+       SqlException(const QSqlQuery &q, const QString &msg = "")
+               : std::runtime_error{makeErrorMessage(msg, q)} {}
+};
+
+template <typename T>
+class VariantCastException : public std::runtime_error
+{
+public:
+       VariantCastException(const QVariant &v)
+               : std::runtime_error{qPrintable(
+                               QString{"Cannot convert QVariant<%1> to type %2"}
+                                               .arg(v.typeName())
+                                               .arg(QVariant::typeToName(qMetaTypeId<T>())))}
+       {}
+};
+
+template<typename T>
+std::vector<T> getValuesFromQuery(QSqlQuery &query)
+{
+       std::vector<T> ret;
+       for (auto &result : query)
+               ret.push_back(result.value(0).value<T>());
+       return ret;
+}
+
+namespace detail {
+template<typename T, int FIRST_RESULT_COLUMN, int N, typename Result>
+auto forEachResult_TypeCastHelper(Result &result)
+{
+       constexpr int column = FIRST_RESULT_COLUMN + N;
+       if (result.record().count() <= column)
+               throw std::range_error{qPrintable(
+                               QString{"Column %1 is out of range for query:\n%2"}
+                                       .arg(column))};
+       QVariant &variant = result.value(column);
+       if (!variant.canConvert<T>())
+               throw VariantCastException<T>{variant};
+       return variant.value<T>();
+}
+template<int FIRST_RESULT_COLUMN, typename... T, typename Result, typename F, std::size_t... I>
+void forEachResult_callHelper(Result &result, F func, std::index_sequence<I...>)
+{
+       func(forEachResult_TypeCastHelper<T, FIRST_RESULT_COLUMN, I>(result)...);
+}
+
+} // namespace detail
+
+template<typename... T, int FIRST_RESULT_COLUMN = 0, typename C, typename F>
+void forEachResult(C &container, F func)
+{
+       for (const auto &result : container)
+               detail::forEachResult_callHelper<FIRST_RESULT_COLUMN, T...>(
+                               result, func, std::index_sequence_for<T...>{});
+}
+
+QStringList executedQueries;
+
+void saveQuery(const QString &query)
+{
+       QString savedQuery = query;
+       savedQuery.truncate(1000);
+       if (query.length() > 1000)
+               savedQuery += " [...]";
+       executedQueries << savedQuery;
+}
+
+void execQuery(QSqlQuery &query)
+{
+       if (!query.exec())
+               throw SqlException{query};
+       saveQuery(query.lastQuery());
+}
+
+QSqlQuery prepareQuery(const QString &query)
+{
+       QSqlQuery q{LocalMyList::instance()->database()->connection()};
+       if (!q.prepare(query))
+               throw SqlException{q};
+       return q;
+}
+
+QSqlQuery execQuery(const QString &query)
+{
+       QSqlQuery q{LocalMyList::instance()->database()->connection()};
+       if (!q.exec(query))
+               throw SqlException{q};
+       saveQuery(query);
+       return q;
+}
+
+const char UPDATE_SCHEMA[] = "update";
+const char PUBLIC_SCHEMA[] = "public";
+
+
+void switchToSchema(const QString &schemaName)
+{
+       execQuery(QString{"SET search_path = %1"}.arg(schemaName));
+}
+
+void dropSchema(const QString &schemaName)
+{
+       execQuery(QString{"DROP SCHEMA IF EXISTS %1 CASCADE"}.arg(schemaName));
+}
+
+void createSchema(const QString &schemaName)
+{
+       execQuery(QString{"CREATE SCHEMA %1"}.arg(schemaName));
+}
+
+void initializeSchemaFromFile(const QString &schemaPath)
+{
+       QFile schemaFile{schemaPath};
+       schemaFile.open(QIODevice::ReadOnly);
+       QString schema = QString::fromUtf8(schemaFile.readAll());
+       execQuery(schema);
+}
+
+QSqlQuery getAllViews(const QString &schemaName)
+{
+       QString query(R"(
+SELECT viewname, definition
+       FROM pg_views
+       WHERE schemaname = :schemaName
+       )");
+       QSqlQuery q = prepareQuery(query);
+       q.bindValue(":schemaName", schemaName);
+       execQuery(q);
+       return q;
+}
+
+QSqlQuery getAllRules(const QString &schemaName)
+{
+       QString query(R"(
+SELECT rulename, tablename, definition
+       FROM pg_rules
+       WHERE schemaname = :schemaName
+       )");
+       QSqlQuery q = prepareQuery(query);
+       q.bindValue(":schemaName", schemaName);
+       execQuery(q);
+       return q;
+}
+
+void dropAllViews(const QString &schemaName)
+{
+       forEachResult<QString>(getAllViews(schemaName), [&](const QString &viewName)
+       {
+               execQuery(QString{"DROP VIEW %2.%1"}.arg(viewName, schemaName));
+       });
+}
+
+void dropAllRules(const QString &schemaName)
+{
+       forEachResult<QString>(getAllRules(schemaName), [&](const QString &ruleName)
+       {
+               execQuery(QString{"DROP RULE %2.%1"}.arg(ruleName, schemaName));
+       });
+}
+
+void copyAllViews(const QString &sourceSchemaName, const QString &targetSchemaName)
+{
+       forEachResult<QString, QString>(getAllViews(sourceSchemaName),
+               [&](const auto &viewName, const auto &viewDefinition)
+               {
+                       execQuery(QString{"CREATE VIEW %2.%1 AS %3"}
+                                         .arg(viewName, targetSchemaName, viewDefinition));
+               });
+}
+
+void copyAllRules(const QString &sourceSchemaName/*, const QString &targetSchemaName*/)
+{
+       forEachResult<QString, QString, QString>(getAllRules(sourceSchemaName),
+               [&](const auto &, const auto &, const auto &viewDefinition)
+               {
+                       execQuery(viewDefinition);
+               });
+}
+
+QSqlQuery makeSchemaDiffQuery(const QString &oldSchema, const QString &newSchema)
+{
+       QString query(R"(
+SELECT table_name
+       FROM information_schema.tables
+       WHERE table_type = 'BASE TABLE'
+               AND table_schema = :newSchema
+EXCEPT
+SELECT table_name
+       FROM information_schema.tables
+       WHERE table_type = 'BASE TABLE'
+               AND table_schema = :oldSchema
+       )");
+       QSqlQuery q = prepareQuery(query);
+       q.bindValue(":oldSchema", oldSchema);
+       q.bindValue(":newSchema", newSchema);
+       return q;
+}
+
+QSqlQuery makeEnumDiffQuery(const QString &oldSchema, const QString &newSchema)
+{
+       QString query(R"(
+SELECT t.typname FROM pg_type t
+       JOIN pg_namespace n ON n.oid = t.typnamespace
+       WHERE typtype = 'e'
+       AND n.nspname = :newSchema
+EXCEPT
+SELECT t.typname FROM pg_type t
+       JOIN pg_namespace n ON n.oid = t.typnamespace
+       WHERE typtype = 'e'
+       AND n.nspname = :oldSchema
+       )");
+       QSqlQuery q = prepareQuery(query);
+       q.bindValue(":oldSchema", oldSchema);
+       q.bindValue(":newSchema", newSchema);
+       return q;
+}
+
+QSqlQuery getNewTables()
+{
+       QSqlQuery q = makeSchemaDiffQuery(PUBLIC_SCHEMA, UPDATE_SCHEMA);
+       execQuery(q);
+       return q;
+}
+
+QSqlQuery getNewEnums()
+{
+       QSqlQuery q = makeEnumDiffQuery(PUBLIC_SCHEMA, UPDATE_SCHEMA);
+       execQuery(q);
+       return q;
+}
+
+QString getEnumValues(const QString &enumName, const QString &schemaName)
+{
+       QString query(R"(
+SELECT string_agg('''' || enumlabel || '''', ', ') AS enum_labels FROM (
+       SELECT enumlabel FROM pg_enum e
+               JOIN pg_type t ON t.oid = e.enumtypid
+               JOIN pg_namespace n ON n.oid = t.typnamespace
+               WHERE t.typname = :enumName
+                       AND n.nspname = :schemaName
+               ORDER BY e.enumsortorder) sq
+               )");
+       QSqlQuery q = prepareQuery(query);
+       q.bindValue(":enumName", enumName);
+       q.bindValue(":schemaName", schemaName);
+       execQuery(q);
+       q.next();
+       return q.value(0).toString();
+}
+
+void copyTableSchema(const QString tableName, const QString &sourceSchema,
+                               const QString &destinationSchema)
+{
+       QString query(R"(
+CREATE TABLE %3.%1
+       (LIKE %2.%1 INCLUDING ALL)
+       )");
+       query = query.arg(tableName, sourceSchema, destinationSchema);
+       execQuery(query);
+}
+
+void copyEnum(const QString enumName, const QString &sourceSchema,
+                               const QString &destinationSchema)
+{
+       QString createEnumQuery{"CREATE TYPE %2.%1 AS ENUM (%3)"};
+       execQuery(createEnumQuery
+                         .arg(enumName)
+                         .arg(destinationSchema)
+                         .arg(getEnumValues(enumName, sourceSchema)));
+}
+
+void printExecutedQueries(QTextStream &s)
+{
+       for (auto &query : executedQueries)
+               s << query << ";" << endl;
+}
+
+} // namespace anonymous
+
+using namespace LocalMyList;
+/**
+ * Database update algorithm
+ * - Create update schema (drop any existing update schema)
+ * - Import current schema from file to update schema
+ * - Drop ALL views.
+ *     Views hold no data, but reference tables making it hard to update some
+ *     tables. Best way to update them is to replace them.
+ * - Find deleted tables
+ * - - Currently ignore these instead of dropping them.
+ * - Find new tables
+ * - - New tables can just be added (TODO: table relations eforced by the DB. LML has none.)
+ * - Find Changed tables (non empty EXCEPT query)
+ * - For each changed table:
+ * - - Find deleted columns (old EXCEPT new)
+ * - - - Currently ignore them
+ * - - Find new columns(new EXCEPT old)
+ * - - - ALTER TABLE or copy via temp table?
+ * - - For each changed columns (inverse INTERSECT query withname, type, nullable, type size)
+ * - - - ALTER TABLE or copy via temp table?
+ * - - TODO table constraints (should be the same as
+ */
+
+/*
+ * --set search_path=update;
+SELECT c.relname, quote_ident(a.attname) AS column_name, format_type(a.atttypid, a.atttypmod) AS data_type, a.attnotnull
+       FROM pg_attribute a
+       JOIN pg_class c ON a.attrelid = c.oid
+               AND c.relname = 'anime'
+       JOIN pg_namespace n ON c.relnamespace = n.oid
+               AND n.nspname = 'public'
+       JOIN pg_type t ON a.atttypid = t.oid
+               AND t.typisdefined = true
+       WHERE a.attnum > 0
+               AND a.attisdropped = false
+EXCEPT
+(SELECT c.relname, quote_ident(a.attname) AS column_name, format_type(a.atttypid, a.atttypmod) AS data_type, a.attnotnull
+       FROM pg_attribute a
+       JOIN pg_class c ON a.attrelid = c.oid
+               AND c.relname = 'anime'
+       JOIN pg_namespace n ON c.relnamespace = n.oid
+               AND n.nspname = 'public'
+       JOIN pg_type t ON a.atttypid = t.oid
+               AND t.typisdefined = true
+       WHERE a.attnum > 0
+               AND a.attisdropped = false
+INTERSECT
+SELECT c.relname, quote_ident(a.attname) AS column_name, format_type(a.atttypid, a.atttypmod) AS data_type, a.attnotnull
+       FROM pg_attribute a
+       JOIN pg_class c ON a.attrelid = c.oid
+               AND c.relname = 'anime'
+       JOIN pg_namespace n ON c.relnamespace = n.oid
+               AND n.nspname = 'update'
+       JOIN pg_type t ON a.atttypid = t.oid
+               AND t.typisdefined = true
+       WHERE a.attnum > 0
+               AND a.attisdropped = false)
+*/
+
+int main(int argc, char *argv[])
+{
+       QCoreApplication a(argc, argv);
+       QTextStream cout(stdout);
+
+       QSettings updateTestSettings(QSettings::IniFormat, QSettings::UserScope,
+                                                                "APTX", "localmylist-update-test");
+       LocalMyList::instance()->loadLocalSettings(updateTestSettings);
+       if (!LocalMyList::instance()->database()->connect())
+       {
+               cout << "Could not connect to database.";
+               return 1;
+       }
+       try
+       {
+               RaiiTransaction t{LocalMyList::instance()->database()};
+               dropSchema(PUBLIC_SCHEMA);
+               createSchema(PUBLIC_SCHEMA);
+               dropSchema(UPDATE_SCHEMA);
+               createSchema(UPDATE_SCHEMA);
+               switchToSchema(UPDATE_SCHEMA);
+               initializeSchemaFromFile(":/localmylist/schema.sql");
+               //switchToSchema(PUBLIC_SCHEMA);
+
+               dropAllViews(PUBLIC_SCHEMA);
+               dropAllRules(PUBLIC_SCHEMA);
+
+               // Handle new types
+               auto newEnums = getNewEnums();
+               cout << "Found " << newEnums.size() << " new enums." << endl;
+               forEachResult<QString>(newEnums, [](const QString &enumName)
+               {
+                       copyEnum(enumName, UPDATE_SCHEMA, PUBLIC_SCHEMA);
+               });
+
+               // Add new tables.
+               auto newTables = getNewTables();
+               forEachResult<QString>(newTables, [](const QString &tableName)
+               {
+                       copyTableSchema(tableName, UPDATE_SCHEMA, PUBLIC_SCHEMA);
+               });
+
+
+
+               copyAllViews(UPDATE_SCHEMA, PUBLIC_SCHEMA);
+               //copyAllRules(UPDATE_SCHEMA);
+               t.commit();
+
+//             auto newTables = getValuesFromQuery<QString>(getNewTables());
+
+//             cout << "Found " << newTables.size() << " new tables:" << endl;
+//             for (auto &table : newTables)
+//                     copyTableSchema(table, UPDATE_SCHEMA, PUBLIC_SCHEMA);
+
+//             t.commit();
+       }
+       catch (std::exception &e)
+       {
+               cout << e.what() << endl;
+               //printExecutedQueries(cout);
+               return 1;
+       }
+       printExecutedQueries(cout);
+       return 0;
+       return a.exec();
+}
index 7c4ca3657a6c3860b553a2ecb3fa8ec6924b39d2..80e39edaeda94c9d8b9064b381785c87271ef82d 100644 (file)
@@ -3,7 +3,8 @@ CONFIG += ordered
 
 include(config.pri)
 
-SUBDIRS += localmylist
+SUBDIRS += localmylist \
+    db-update
 
 !nodaemon {
        SUBDIRS += anioni
index b59e41bc1159e49d75621d7364f4f9958734e2d6..7f95cd6433f1fc3fc8837086c5f6d9ee96cfd997 100644 (file)
@@ -107,6 +107,9 @@ CONV_HEADERS += \
        include/LocalMyList/DirectoryWatcher \
        include/LocalMyList/RaiiMyList
 
+RESOURCES += \
+       localmylist_resources.qrc
+
 !noscript {
        QT *= script
        HEADERS += scriptable.h
index 64a6e2df328b16e3a11ae2181f23a6d8138aa22f..450bec850182f14ac239aa24b77f3f95e2962e24 100644 (file)
 #ifndef LOCALMYLIST_NO_ANIDBUDPCLIENT
 #      include <AniDBUdpClient/Client>
 #endif
+
+inline void initResources()
+{
+       Q_INIT_RESOURCE(localmylist_resources);
+}
+
 namespace LocalMyList {
 
 MyList::MyList()
@@ -511,6 +517,7 @@ void MyList::init()
 {
        static bool init = false;
        if (init) return;
+       initResources();
 
        if (!MANUAL_CLEANUP)
                qAddPostRoutine(MyList::destroy);
index 9fa1a54b8d3a01173c735ce4241d2999b4fd64ba..173db03c6c3c1fe42a6b25fa3a82e6300ebd7704 100644 (file)
@@ -33,8 +33,8 @@ class LOCALMYLISTSHARED_EXPORT MyList : public QObject
        Q_PROPERTY(int runningTaskCount READ runningTaskCount)
        Q_PROPERTY(int udpClientId READ udpClientId)
 
-public:
        MyList();
+public:
        ~MyList();
 
        LocalMyList::Database *database() const;
index 873c2a52771b9495aebb7ab2952179513b51a1e3..97502f17cfdde9e79b7caf04b19573e5ed16098b 100644 (file)
@@ -1,3 +1,4 @@
+-- ALTER EXTENSION pg_trgm SET SCHEMA pg_catalog;
 DROP TYPE IF EXISTS episode_type_enum;
 CREATE TYPE episode_type_enum AS ENUM ('', 'S', 'C', 'T', 'P', 'O');
 DROP TYPE IF EXISTS quality_enum;