diff --git a/docs/database/query-builder.mdx b/docs/database/query-builder.mdx index 37c815fbf..dca22cf47 100644 --- a/docs/database/query-builder.mdx +++ b/docs/database/query-builder.mdx @@ -16,6 +16,7 @@ keywords: [c++ orm, sql, c++ sql, c++ query builder, database, query builder, ti - [Basic Where Clauses](#basic-where-clauses) - [Where Clauses](#where-clauses) - [Or Where Clauses](#or-where-clauses) + - [Where Not Clauses](#where-not-clauses) - [Additional Where Clauses](#additional-where-clauses) - [Condition Operator Overriding](#condition-operator-overriding) - [Logical Grouping](#logical-grouping) @@ -405,6 +406,17 @@ select * from users where (first_name = "John" or last_name = "Smith" and votes Still, it is a better idea to use [Logical Grouping](#logical-grouping) described few lines below, which allows better control of the parentheses. ::: +### Where Not Clauses + +The `whereNot` and `orWhereNot` methods may be used to negate a given group of query constraints. For example, the following query excludes products that are on clearance or which have a price that is less than ten: + + auto products = DB::table("products") + ->whereNot([](auto &query) { + query.whereEq("clearance", true) + .orWhere("price", "<", 10); + }) + .get(); + ### Additional Where Clauses **whereIn / whereNotIn / orWhereIn / orWhereNotIn** diff --git a/docs/supported-compilers.mdx b/docs/supported-compilers.mdx index 55dfc389e..f1c72b464 100644 --- a/docs/supported-compilers.mdx +++ b/docs/supported-compilers.mdx @@ -8,7 +8,7 @@ keywords: [c++ orm, supported compilers, supported build systems, tinyorm] # Supported Compilers -Following compilers are backed up by the GitHub Action [workflows](https://github.com/silverqx/TinyORM/tree/main/.github/workflows) (CI pipelines), these workflows also include more then __1027 unit tests__ 😮💥. +Following compilers are backed up by the GitHub Action [workflows](https://github.com/silverqx/TinyORM/tree/main/.github/workflows) (CI pipelines), these workflows also include more then __1058 unit tests__ 😮💥.
diff --git a/include/orm/query/querybuilder.hpp b/include/orm/query/querybuilder.hpp index a0090a0dd..144858ae3 100644 --- a/include/orm/query/querybuilder.hpp +++ b/include/orm/query/querybuilder.hpp @@ -275,6 +275,7 @@ namespace Orm::Query rightJoinSub(T &&query, const QString &as, const std::function &callback); + /* General where */ /*! Add a basic where clause to the query. */ template Builder &where(const Column &column, const QString &comparison, @@ -290,18 +291,51 @@ namespace Orm::Query template Builder &orWhereEq(const Column &column, T &&value); + /* General where not */ + /*! Add a basic "where not" clause to the query. */ + template + Builder &whereNot(const Column &column, const QString &comparison, + T &&value, const QString &condition = AND); + /*! Add an "or where not" clause to the query. */ + template + Builder &orWhereNot(const Column &column, const QString &comparison, T &&value); + /*! Add a basic equal "where not" clause to the query. */ + template + Builder &whereNotEq(const Column &column, T &&value, + const QString &condition = AND); + /*! Add an equal "or where not" clause to the query. */ + template + Builder &orWhereNotEq(const Column &column, T &&value); + + /* Nested where */ /*! Add a nested where clause to the query. */ Builder &where(const std::function &callback, const QString &condition = AND); /*! Add a nested "or where" clause to the query. */ Builder &orWhere(const std::function &callback); + /*! Add a nested "where not" clause to the query. */ + Builder &whereNot(const std::function &callback, + const QString &condition = AND); + /*! Add a nested "or where not" clause to the query. */ + Builder &orWhereNot(const std::function &callback); + /* Array where */ /*! Add a vector of basic where clauses to the query. */ Builder &where(const QVector &values, - const QString &condition = AND); + const QString &condition = AND, + const QString &defaultCondition = ""); /*! Add a vector of basic "or where" clauses to the query. */ - Builder &orWhere(const QVector &values); - + Builder &orWhere(const QVector &values, + const QString &defaultCondition = ""); + /*! Add a vector of basic "where not" clauses to the query. */ + Builder &whereNot(const QVector &values, + const QString &condition = AND, + const QString &defaultCondition = ""); + /*! Add a vector of basic "or where not" clauses to the query. */ + Builder &orWhereNot(const QVector &values, + const QString &defaultCondition = ""); + + /* where column */ /*! Add a vector of where clauses comparing two columns to the query. */ Builder &whereColumn(const QVector &values, const QString &condition = AND); @@ -320,6 +354,7 @@ namespace Orm::Query /*! Add an equal "or where" clause comparing two columns to the query. */ Builder &orWhereColumnEq(const Column &first, const Column &second); + /* where IN */ /*! Add a "where in" clause to the query. */ Builder &whereIn(const Column &column, const QVector &values, const QString &condition = AND, bool nope = false); @@ -331,6 +366,7 @@ namespace Orm::Query /*! Add an "or where not in" clause to the query. */ Builder &orWhereNotIn(const Column &column, const QVector &values); + /* where null */ /*! Add a "where null" clause to the query. */ Builder &whereNull(const QVector &columns = {ASTERISK}, const QString &condition = AND, bool nope = false); @@ -352,6 +388,7 @@ namespace Orm::Query /*! Add an "or where not null" clause to the query. */ Builder &orWhereNotNull(const Column &column); + /* where sub-queries */ /*! Add a basic where clause to the query with a full sub-select column. */ template Builder &where(C &&column, const QString &comparison, V &&value, @@ -366,11 +403,29 @@ namespace Orm::Query template inline Builder &orWhereEq(C &&column, V &&value); + /* where not sub-queries */ + /*! Add a basic "where not" clause to the query with a full sub-select column. */ + template + Builder &whereNot(C &&column, const QString &comparison, V &&value, + const QString &condition = AND); + /*! Add an "or where not" clause to the query with a full sub-select column. */ + template + inline Builder &orWhereNot(C &&column, const QString &comparison, V &&value); + /*! Add a basic equal "where not" clause to the query with a full sub-select + column. */ + template + inline Builder &whereNotEq(C &&column, V &&value, const QString &condition = AND); + /*! Add an equal "or where not" clause to the query with a full sub-select + column. */ + template + inline Builder &orWhereNotEq(C &&column, V &&value); + /*! Add a full sub-select to the "where" clause. */ template Builder &whereSub(const Column &column, const QString &comparison, T &&query, const QString &condition = AND); + /* where raw */ /*! Add a raw "where" clause to the query. */ Builder &whereRaw(const QString &sql, const QVector &bindings = {}, const QString &condition = AND); @@ -565,7 +620,8 @@ namespace Orm::Query /*! Add a vector of basic where clauses to the query. */ Builder & addArrayOfWheres(const QVector &values, - const QString &condition = AND); + const QString &condition = AND, + const QString &defaultCondition = ""); /*! Add a vector of where clauses comparing two columns to the query. */ Builder & addArrayOfWheres(const QVector &values, @@ -993,6 +1049,8 @@ namespace Orm::Query return joinSub(std::forward(query), as, callback, RIGHT); } + /* Basic where */ + template Builder & Builder::where(const Column &column, const QString &comparison, T &&value, @@ -1027,6 +1085,40 @@ namespace Orm::Query return where(column, EQ, std::forward(value), OR); } + /* Genral where not */ + + template + Builder & + Builder::whereNot(const Column &column, const QString &comparison, T &&value, + const QString &condition) + { + return where(column, comparison, std::forward(value), + SPACE_IN.arg(condition, NOT)); + } + + template + Builder & + Builder::orWhereNot(const Column &column, const QString &comparison, T &&value) + { + return where(column, comparison, std::forward(value), + SPACE_IN.arg(OR, NOT)); + } + + template + Builder & + Builder::whereNotEq(const Column &column, T &&value, const QString &condition) + { + return where(column, EQ, std::forward(value), SPACE_IN.arg(condition, NOT)); + } + + template + Builder &Builder::orWhereNotEq(const Column &column, T &&value) + { + return where(column, EQ, std::forward(value), SPACE_IN.arg(OR, NOT)); + } + + /* where sub-queries */ + template Builder & Builder::where(C &&column, const QString &comparison, V &&value, @@ -1064,6 +1156,38 @@ namespace Orm::Query return where(std::forward(column), EQ, std::forward(value), OR); } + /* where not sub-queries */ + + template + Builder & + Builder::whereNot(C &&column, const QString &comparison, V &&value, + const QString &condition) + { + return where(std::forward(column), comparison, std::forward(value), + SPACE_IN.arg(condition, NOT)); + } + + template + Builder &Builder::orWhereNot(C &&column, const QString &comparison, V &&value) + { + return where(std::forward(column), comparison, std::forward(value), + SPACE_IN.arg(OR, NOT)); + } + + template + Builder &Builder::whereNotEq(C &&column, V &&value, const QString &condition) + { + return where(std::forward(column), EQ, std::forward(value), + SPACE_IN.arg(condition, NOT)); + } + + template + Builder &Builder::orWhereNotEq(C &&column, V &&value) + { + return where(std::forward(column), EQ, std::forward(value), + SPACE_IN.arg(OR, NOT)); + } + template Builder & Builder::whereSub(const Column &column, const QString &comparison, diff --git a/src/orm/query/querybuilder.cpp b/src/orm/query/querybuilder.cpp index a216a2d14..5cbc08434 100644 --- a/src/orm/query/querybuilder.cpp +++ b/src/orm/query/querybuilder.cpp @@ -325,6 +325,8 @@ Builder &Builder::fromRaw(const QString &expression, const QVector &bi return *this; } +/* Nested where */ + Builder &Builder::where(const std::function &callback, const QString &condition) { @@ -341,20 +343,53 @@ Builder &Builder::orWhere(const std::function &callback) return where(callback, OR); } -Builder &Builder::where(const QVector &values, const QString &condition) +Builder &Builder::whereNot(const std::function &callback, + const QString &condition) +{ + return where(callback, SPACE_IN.arg(condition, NOT)); +} + +Builder &Builder::orWhereNot(const std::function &callback) +{ + return where(callback, SPACE_IN.arg(OR, NOT)); +} + +/* Array where */ + +Builder &Builder::where(const QVector &values, const QString &condition, + const QString &defaultCondition) { /* We will maintain the boolean we received when the method was called and pass it into the nested where. The parentheses in this query are ok: select * from xyz where (id = ?) */ - return addArrayOfWheres(values, condition); + return addArrayOfWheres(values, condition, defaultCondition); } -Builder &Builder::orWhere(const QVector &values) +Builder &Builder::orWhere(const QVector &values, + const QString &defaultCondition) { - return where(values, OR); + return where(values, OR, defaultCondition); } +Builder &Builder::whereNot(const QVector &values, const QString &condition, + const QString &defaultCondition) +{ + return where(values, SPACE_IN.arg(condition, NOT), + // Avoid "and/... not" between all WhereItem-s + defaultCondition.isEmpty() ? condition : defaultCondition); +} + +Builder &Builder::orWhereNot(const QVector &values, + const QString &defaultCondition) +{ + return where(values, SPACE_IN.arg(OR, NOT), + // Avoid "or not" between all WhereItem-s + defaultCondition.isEmpty() ? OR : defaultCondition); +} + +/* where column */ + Builder &Builder::whereColumn(const QVector &values, const QString &condition) { @@ -395,6 +430,8 @@ Builder &Builder::orWhereColumnEq(const Column &first, const Column &second) return whereColumn(first, EQ, second, OR); } +/* where IN */ + Builder &Builder::whereIn(const Column &column, const QVector &values, const QString &condition, const bool nope) { @@ -427,6 +464,8 @@ Builder &Builder::orWhereNotIn(const Column &column, const QVector &va return whereNotIn(column, values, OR); } +/* where null */ + Builder &Builder::whereNull(const QVector &columns, const QString &condition, const bool nope) { @@ -474,6 +513,8 @@ Builder &Builder::orWhereNotNull(const Column &column) return orWhereNotNull(QVector {column}); } +/* where raw */ + Builder &Builder::whereRaw(const QString &sql, const QVector &bindings, const QString &condition) { @@ -893,13 +934,17 @@ QVector Builder::cleanBindings(QVector &&bindings) const } Builder & -Builder::addArrayOfWheres(const QVector &values, const QString &condition) +Builder::addArrayOfWheres(const QVector &values, const QString &condition, + const QString &defaultCondition) { - return where([&values, &condition](Builder &query) + return where([&values, &condition, &defaultCondition](Builder &query) { for (const auto &where : values) query.where(where.column, where.comparison, where.value, - where.condition.isEmpty() ? condition : where.condition); + where.condition.isEmpty() + // Allow to pass a default condition for the QVector + ? (defaultCondition.isEmpty() ? condition : defaultCondition) + : where.condition); }, condition); } diff --git a/tests/auto/unit/orm/query/mysql_querybuilder/tst_mysql_querybuilder.cpp b/tests/auto/unit/orm/query/mysql_querybuilder/tst_mysql_querybuilder.cpp index 192f030be..6094f0d0c 100644 --- a/tests/auto/unit/orm/query/mysql_querybuilder/tst_mysql_querybuilder.cpp +++ b/tests/auto/unit/orm/query/mysql_querybuilder/tst_mysql_querybuilder.cpp @@ -6,12 +6,14 @@ #include "databases.hpp" +using Orm::Constants::AND; using Orm::Constants::ASC; using Orm::Constants::DESC; using Orm::Constants::ID; using Orm::Constants::LEFT; using Orm::Constants::LIKE; using Orm::Constants::NAME; +using Orm::Constants::OR; using Orm::Constants::SIZE; using Orm::DB; @@ -101,17 +103,34 @@ private Q_SLOTS: void where() const; void where_WithVectorValue() const; + void where_WithVectorValue_DefaultCondition() const; void where_QueryableValue() const; void where_QueryableColumn() const; + void whereNot() const; + void whereNot_WithVectorValue() const; + void whereNot_WithVectorValue_DefaultCondition() const; + void whereNot_QueryableValue() const; + void whereNot_QueryableColumn() const; + void orWhere() const; void orWhere_ColumnExpression() const; void orWhere_WithVectorValue() const; + void orWhere_WithVectorValue_DefaultCondition() const; void orWhere_WithVectorValue_ColumnExpression() const; void orWhereEq_QueryableValue() const; void orWhereEq_QueryableColumn() const; void orWhereEq_QueryableColumnAndValue() const; + void orWhereNot() const; + void orWhereNot_ColumnExpression() const; + void orWhereNot_WithVectorValue() const; + void orWhereNot_WithVectorValue_DefaultCondition() const; + void orWhereNot_WithVectorValue_ColumnExpression() const; + void orWhereNotEq_QueryableValue() const; + void orWhereNotEq_QueryableColumn() const; + void orWhereNotEq_QueryableColumnAndValue() const; + void whereColumn() const; void orWhereColumn() const; void orWhereColumn_ColumnExpression() const; @@ -1134,6 +1153,20 @@ void tst_MySql_QueryBuilder::where_WithVectorValue() const } } +void tst_MySql_QueryBuilder::where_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents") + .where({{"progress", 100, ">="}}) + .where({{ID, 3}, {SIZE, 10, ">"}}, AND, OR); + QCOMPARE(builder->toSql(), + "select * from `torrents` where (`progress` >= ?) and " + "(`id` = ? or `size` > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + void tst_MySql_QueryBuilder::where_QueryableValue() const { // With lambda expression @@ -1196,6 +1229,192 @@ void tst_MySql_QueryBuilder::where_QueryableColumn() const } } +void tst_MySql_QueryBuilder::whereNot() const +{ + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "=", 3); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` = ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNotEq(ID, 3); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` = ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNotEq(ID, 3) + .whereEq(NAME, "test3"); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` = ? and `name` = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant("test3")})); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "!=", 3); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` != ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "<>", 3); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` <> ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 3); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` > ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 3) + .whereNot(NAME, LIKE, "test%"); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` > ? and not `name` like ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant("test%")})); + } +} + +void tst_MySql_QueryBuilder::whereNot_WithVectorValue() const +{ + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{ID, 3}}); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not (`id` = ?)"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{ID, 3}, {SIZE, 10, ">"}}); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not (`id` = ? and `size` > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant(10)})); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{ID, 3}, {SIZE, 10, ">"}}) + .whereNot({{"progress", 100, ">="}}); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not (`id` = ? and `size` > ?) " + "and not (`progress` >= ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant(10), QVariant(100)})); + } +} + +void tst_MySql_QueryBuilder::whereNot_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents") + .whereNot({{"progress", 100, ">="}}) + .whereNot({{ID, 3}, {SIZE, 10, ">"}}, AND, OR); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not (`progress` >= ?) and " + "not (`id` = ? or `size` > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + +void tst_MySql_QueryBuilder::whereNot_QueryableValue() const +{ + // With lambda expression + { + auto builder = createQuery(); + + builder->from("torrents").whereNot(ID, ">", [](auto &query) + { + query.from("torrents", "t").selectRaw("avg(t.size)"); + }); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not `id` > (select avg(t.size) from `torrents` as `t`)"); + QVERIFY(builder->getBindings().isEmpty()); + } + // With QueryBuilder + { + auto builder = createQuery(); + + builder->from("torrents") + .whereNot(ID, ">", + createQuery()->from("torrents", "t") + .selectRaw("avg(t.size)")); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not `id` > (select avg(t.size) from `torrents` as `t`)"); + QVERIFY(builder->getBindings().isEmpty()); + } +} + +void tst_MySql_QueryBuilder::whereNot_QueryableColumn() const +{ + // With lambda expression + { + auto builder = createQuery(); + + builder->from("torrents").whereNot([](auto &query) + { + query.from("torrents", "t").selectRaw("avg(t.size)"); + }, ">", 13); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not (select avg(t.size) from `torrents` as `t`) > ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(13)})); + } + // With QueryBuilder + { + auto builder = createQuery(); + + builder->from("torrents") + .whereNot(createQuery()->from("torrents", "t") + .selectRaw("avg(t.size)"), + ">", 13); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not (select avg(t.size) from `torrents` as `t`) > ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(13)})); + } +} + void tst_MySql_QueryBuilder::orWhere() const { { @@ -1246,6 +1465,19 @@ void tst_MySql_QueryBuilder::orWhere_WithVectorValue() const QVector({QVariant(3), QVariant(10), QVariant(100)})); } +void tst_MySql_QueryBuilder::orWhere_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").where({{"progress", 100, ">="}}) + .orWhere({{ID, 3}, {SIZE, 10, ">"}}, AND); + QCOMPARE(builder->toSql(), + "select * from `torrents` where (`progress` >= ?) or " + "(`id` = ? and `size` > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + void tst_MySql_QueryBuilder::orWhere_WithVectorValue_ColumnExpression() const { auto builder = createQuery(); @@ -1368,6 +1600,197 @@ void tst_MySql_QueryBuilder::orWhereEq_QueryableColumnAndValue() const } } +void tst_MySql_QueryBuilder::orWhereNot() const +{ + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 4) + .orWhereNot("progress", ">=", 300); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` > ? or not `progress` >= ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant(300)})); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 4) + .orWhereNotEq(NAME, "test3"); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not `id` > ? or not `name` = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant("test3")})); + } +} + +void tst_MySql_QueryBuilder::orWhereNot_ColumnExpression() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(Raw(ID), ">", 4) + .orWhereNotEq(Raw("`name`"), "test3"); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not id > ? or not `name` = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant("test3")})); +} + +void tst_MySql_QueryBuilder::orWhereNot_WithVectorValue() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{ID, 3}, {SIZE, 10, ">"}}) + .orWhereNot({{"progress", 100, ">="}}); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not (`id` = ? and `size` > ?) or " + "not (`progress` >= ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant(10), QVariant(100)})); +} + +void tst_MySql_QueryBuilder::orWhereNot_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{"progress", 100, ">="}}) + .orWhereNot({{ID, 3}, {SIZE, 10, ">"}}, AND); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not (`progress` >= ?) or " + "not (`id` = ? and `size` > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + +void tst_MySql_QueryBuilder::orWhereNot_WithVectorValue_ColumnExpression() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents") + .whereNot({{Raw(ID), 3}, {Raw("`size`"), 10, ">"}}) + .orWhereNot({{Raw("progress"), 100, ">="}}); + QCOMPARE(builder->toSql(), + "select * from `torrents` where not (id = ? and `size` > ?) or " + "not (progress >= ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant(10), QVariant(100)})); +} + +void tst_MySql_QueryBuilder::orWhereNotEq_QueryableValue() const +{ + // With lambda expression + { + auto builder = createQuery(); + + builder->from("torrents") + .whereNotEq(ID, 2) + .orWhereNotEq(ID, [](auto &query) + { + query.from("torrents", "t").selectRaw("avg(t.size)"); + }); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not `id` = ? or " + "not `id` = (select avg(t.size) from `torrents` as `t`)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(2)})); + } + // With QueryBuilder + { + auto builder = createQuery(); + + builder->from("torrents") + .whereNotEq(ID, 2) + .orWhereNotEq(ID, + createQuery()->from("torrents", "t") + .selectRaw("avg(t.size)")); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not `id` = ? or " + "not `id` = (select avg(t.size) from `torrents` as `t`)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(2)})); + } +} + +void tst_MySql_QueryBuilder::orWhereNotEq_QueryableColumn() const +{ + // With lambda expression + { + auto builder = createQuery(); + + builder->from("torrents") + .whereNotEq(ID, 2) + .orWhereNotEq([](auto &query) + { + query.from("torrents", "t").selectRaw("avg(t.size)"); + }, 13); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not `id` = ? or " + "not (select avg(t.size) from `torrents` as `t`) = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(2), QVariant(13)})); + } + // With QueryBuilder + { + auto builder = createQuery(); + + builder->from("torrents") + .whereNotEq(ID, 2) + .orWhereNotEq(createQuery()->from("torrents", "t") + .selectRaw("avg(t.size)"), 13); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not `id` = ? or " + "not (select avg(t.size) from `torrents` as `t`) = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(2), QVariant(13)})); + } +} + +void tst_MySql_QueryBuilder::orWhereNotEq_QueryableColumnAndValue() const +{ + // Following is extreme case, but it should work + { + auto builder = createQuery(); + + builder->from("torrents") + .whereNotEq(ID, 2) + .orWhereNotEq([](auto &query) + { + query.from("torrents", "t").selectRaw("avg(t.size)"); + }, createQuery()->from("torrents", "t") + .selectRaw("avg(t.size)")); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not `id` = ? or " + "not (select avg(t.size) from `torrents` as `t`) = " + "(select avg(t.size) from `torrents` as `t`)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(2)})); + } + { + auto builder = createQuery(); + + builder->from("torrents") + .whereNotEq(ID, 2) + .orWhereNotEq(createQuery()->from("torrents", "t") + .selectRaw("avg(t.size)"), [](auto &query) + { + query.from("torrents", "t").selectRaw("avg(t.size)"); + }); + QCOMPARE(builder->toSql(), + "select * from `torrents` " + "where not `id` = ? or " + "not (select avg(t.size) from `torrents` as `t`) = " + "(select avg(t.size) from `torrents` as `t`)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(2)})); + } +} + void tst_MySql_QueryBuilder::whereColumn() const { auto builder = createQuery(); diff --git a/tests/auto/unit/orm/query/postgresql_querybuilder/tst_postgresql_querybuilder.cpp b/tests/auto/unit/orm/query/postgresql_querybuilder/tst_postgresql_querybuilder.cpp index 66597d3f2..c6df5a37d 100644 --- a/tests/auto/unit/orm/query/postgresql_querybuilder/tst_postgresql_querybuilder.cpp +++ b/tests/auto/unit/orm/query/postgresql_querybuilder/tst_postgresql_querybuilder.cpp @@ -6,12 +6,14 @@ #include "databases.hpp" +using Orm::Constants::AND; using Orm::Constants::ASC; using Orm::Constants::DESC; using Orm::Constants::ID; using Orm::Constants::LEFT; using Orm::Constants::LIKE; using Orm::Constants::NAME; +using Orm::Constants::OR; using Orm::Constants::SIZE; using Orm::DB; @@ -68,12 +70,22 @@ private Q_SLOTS: void where() const; void where_WithVectorValue() const; + void where_WithVectorValue_DefaultCondition() const; + + void whereNot() const; + void whereNot_WithVectorValue_DefaultCondition() const; void orWhere() const; void orWhere_ColumnExpression() const; void orWhere_WithVectorValue() const; + void orWhere_WithVectorValue_DefaultCondition() const; void orWhere_WithVectorValue_ColumnExpression() const; + void orWhereNot() const; + void orWhereNot_WithVectorValue() const; + void orWhereNot_WithVectorValue_DefaultCondition() const; + void orWhereNot_ColumnExpression() const; + void whereColumn() const; void orWhereColumn() const; void orWhereColumn_ColumnExpression() const; @@ -876,6 +888,108 @@ void tst_PostgreSQL_QueryBuilder::where_WithVectorValue() const } } +void tst_PostgreSQL_QueryBuilder::where_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").where({{"progress", 100, ">="}}) + .where({{ID, 3}, {SIZE, 10, ">"}}, AND, OR); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where (\"progress\" >= ?) and " + "(\"id\" = ? or \"size\" > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + +void tst_PostgreSQL_QueryBuilder::whereNot() const +{ + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "=", 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" = ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNotEq(ID, 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" = ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNotEq(ID, 3) + .whereNotEq(NAME, "test3"); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" = ? and not \"name\" = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant("test3")})); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "!=", 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" != ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "<>", 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" <> ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" > ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 3) + .whereNot(NAME, LIKE, "test%"); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" " + "where not \"id\" > ? and not \"name\"::text like ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant("test%")})); + } +} + +void tst_PostgreSQL_QueryBuilder::whereNot_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{"progress", 100, ">="}}) + .whereNot({{ID, 3}, {SIZE, 10, ">"}}, AND, OR); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not (\"progress\" >= ?) and " + "not (\"id\" = ? or \"size\" > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + void tst_PostgreSQL_QueryBuilder::orWhere() const { { @@ -926,6 +1040,19 @@ void tst_PostgreSQL_QueryBuilder::orWhere_WithVectorValue() const QVector({QVariant(3), QVariant(10), QVariant(100)})); } +void tst_PostgreSQL_QueryBuilder::orWhere_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").where({{"progress", 100, ">="}}) + .orWhere({{ID, 3}, {SIZE, 10, ">"}}, AND); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where (\"progress\" >= ?) or " + "(\"id\" = ? and \"size\" > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + void tst_PostgreSQL_QueryBuilder::orWhere_WithVectorValue_ColumnExpression() const { auto builder = createQuery(); @@ -940,6 +1067,70 @@ void tst_PostgreSQL_QueryBuilder::orWhere_WithVectorValue_ColumnExpression() con QVector({QVariant(3), QVariant(10), QVariant(100)})); } +void tst_PostgreSQL_QueryBuilder::orWhereNot() const +{ + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 4) + .orWhereNot("progress", ">=", 300); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" > ? or " + "not \"progress\" >= ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant(300)})); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 4) + .orWhereNotEq(NAME, "test3"); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" > ? or not \"name\" = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant("test3")})); + } +} + +void tst_PostgreSQL_QueryBuilder::orWhereNot_WithVectorValue() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{ID, 3}, {SIZE, 10, ">"}}) + .orWhereNot({{"progress", 100, ">="}}); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not (\"id\" = ? and \"size\" > ?) or " + "not (\"progress\" >= ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant(10), QVariant(100)})); +} + +void tst_PostgreSQL_QueryBuilder::orWhereNot_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{"progress", 100, ">="}}) + .orWhereNot({{ID, 3}, {SIZE, 10, ">"}}, AND); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not (\"progress\" >= ?) or " + "not (\"id\" = ? and \"size\" > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + +void tst_PostgreSQL_QueryBuilder::orWhereNot_ColumnExpression() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(Raw(ID), ">", 4) + .orWhereNotEq(Raw("\"name\""), "test3"); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not id > ? or not \"name\" = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant("test3")})); +} + void tst_PostgreSQL_QueryBuilder::whereColumn() const { auto builder = createQuery(); diff --git a/tests/auto/unit/orm/query/sqlite_querybuilder/tst_sqlite_querybuilder.cpp b/tests/auto/unit/orm/query/sqlite_querybuilder/tst_sqlite_querybuilder.cpp index a882c46af..818ac5339 100644 --- a/tests/auto/unit/orm/query/sqlite_querybuilder/tst_sqlite_querybuilder.cpp +++ b/tests/auto/unit/orm/query/sqlite_querybuilder/tst_sqlite_querybuilder.cpp @@ -6,12 +6,14 @@ #include "databases.hpp" +using Orm::Constants::AND; using Orm::Constants::ASC; using Orm::Constants::DESC; using Orm::Constants::ID; using Orm::Constants::LEFT; using Orm::Constants::LIKE; using Orm::Constants::NAME; +using Orm::Constants::OR; using Orm::Constants::SIZE; using Orm::DB; @@ -67,12 +69,22 @@ private Q_SLOTS: void where() const; void where_WithVectorValue() const; + void where_WithVectorValue_DefaultCondition() const; + + void whereNot() const; + void whereNot_WithVectorValue_DefaultCondition() const; void orWhere() const; void orWhere_ColumnExpression() const; void orWhere_WithVectorValue() const; + void orWhere_WithVectorValue_DefaultCondition() const; void orWhere_WithVectorValue_ColumnExpression() const; + void orWhereNot() const; + void orWhereNot_WithVectorValue() const; + void orWhereNot_WithVectorValue_DefaultCondition() const; + void orWhereNot_ColumnExpression() const; + void whereColumn() const; void orWhereColumn() const; void orWhereColumn_ColumnExpression() const; @@ -84,7 +96,7 @@ private Q_SLOTS: void whereNotIn() const; void whereNotIn_ColumnExpression() const; void whereIn_Empty() const; - void WhereNotIn_Empty() const; + void whereNotIn_Empty() const; void whereIn_ValueExpression() const; void whereNull() const; @@ -834,6 +846,108 @@ void tst_SQLite_QueryBuilder::where_WithVectorValue() const } } +void tst_SQLite_QueryBuilder::where_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").where({{"progress", 100, ">="}}) + .where({{ID, 3}, {SIZE, 10, ">"}}, AND, OR); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where (\"progress\" >= ?) and " + "(\"id\" = ? or \"size\" > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + +void tst_SQLite_QueryBuilder::whereNot() const +{ + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "=", 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" = ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNotEq(ID, 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" = ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNotEq(ID, 3) + .whereNotEq(NAME, "test3"); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" = ? and not \"name\" = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant("test3")})); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "!=", 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" != ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, "<>", 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" <> ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 3); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" > ?"); + QCOMPARE(builder->getBindings(), + QVector {QVariant(3)}); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 3) + .whereNot(NAME, LIKE, "test%"); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" > ? and " + "not \"name\" like ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant("test%")})); + } +} + +void tst_SQLite_QueryBuilder::whereNot_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{"progress", 100, ">="}}) + .whereNot({{ID, 3}, {SIZE, 10, ">"}}, AND, OR); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not (\"progress\" >= ?) and " + "not (\"id\" = ? or \"size\" > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + void tst_SQLite_QueryBuilder::orWhere() const { { @@ -884,6 +998,19 @@ void tst_SQLite_QueryBuilder::orWhere_WithVectorValue() const QVector({QVariant(3), QVariant(10), QVariant(100)})); } +void tst_SQLite_QueryBuilder::orWhere_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").where({{"progress", 100, ">="}}) + .orWhere({{ID, 3}, {SIZE, 10, ">"}}, AND); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where (\"progress\" >= ?) or " + "(\"id\" = ? and \"size\" > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + void tst_SQLite_QueryBuilder::orWhere_WithVectorValue_ColumnExpression() const { auto builder = createQuery(); @@ -898,6 +1025,70 @@ void tst_SQLite_QueryBuilder::orWhere_WithVectorValue_ColumnExpression() const QVector({QVariant(3), QVariant(10), QVariant(100)})); } +void tst_SQLite_QueryBuilder::orWhereNot() const +{ + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 4) + .orWhereNot("progress", ">=", 300); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" > ? or " + "not \"progress\" >= ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant(300)})); + } + + { + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(ID, ">", 4) + .orWhereNotEq(NAME, "test3"); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not \"id\" > ? or not \"name\" = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant("test3")})); + } +} + +void tst_SQLite_QueryBuilder::orWhereNot_WithVectorValue() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{ID, 3}, {SIZE, 10, ">"}}) + .orWhereNot({{"progress", 100, ">="}}); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not (\"id\" = ? and \"size\" > ?) or " + "not (\"progress\" >= ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(3), QVariant(10), QVariant(100)})); +} + +void tst_SQLite_QueryBuilder::orWhereNot_WithVectorValue_DefaultCondition() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot({{"progress", 100, ">="}}) + .orWhereNot({{ID, 3}, {SIZE, 10, ">"}}, AND); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not (\"progress\" >= ?) or " + "not (\"id\" = ? and \"size\" > ?)"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(100), QVariant(3), QVariant(10)})); +} + +void tst_SQLite_QueryBuilder::orWhereNot_ColumnExpression() const +{ + auto builder = createQuery(); + + builder->select("*").from("torrents").whereNot(Raw(ID), ">", 4) + .orWhereNotEq(Raw("\"name\""), "test3"); + QCOMPARE(builder->toSql(), + "select * from \"torrents\" where not id > ? or not \"name\" = ?"); + QCOMPARE(builder->getBindings(), + QVector({QVariant(4), QVariant("test3")})); +} + void tst_SQLite_QueryBuilder::whereColumn() const { auto builder = createQuery(); @@ -1130,7 +1321,7 @@ void tst_SQLite_QueryBuilder::whereIn_Empty() const } } -void tst_SQLite_QueryBuilder::WhereNotIn_Empty() const +void tst_SQLite_QueryBuilder::whereNotIn_Empty() const { { auto builder = createQuery();