diff --git a/src/query/compiler.js b/src/query/compiler.js index 5737afbe3f..2dc649d6e6 100644 --- a/src/query/compiler.js +++ b/src/query/compiler.js @@ -591,6 +591,16 @@ assign(QueryCompiler.prototype, { ); }, + onVal(clause) { + return ( + this.formatter.wrap(clause.column) + + ' ' + + this.formatter.operator(clause.operator) + + ' ' + + this.formatter.parameter(clause.value) + ); + }, + onRaw(clause) { return this.formatter.unwrapRaw(clause.value); }, diff --git a/src/query/joinclause.js b/src/query/joinclause.js index 4829abb92e..bf30b741cd 100644 --- a/src/query/joinclause.js +++ b/src/query/joinclause.js @@ -14,40 +14,24 @@ function JoinClause(table, type, schema) { this.clauses = []; } -assign(JoinClause.prototype, { - grouping: 'join', +function getClauseFromArguments(compilerType, bool, first, operator, second) { + let data = null; - // Adds an "on" clause to the current join object. - on(first, operator, second) { - if (typeof first === 'function') { - this.clauses.push({ - type: 'onWrapped', - value: first, - bool: this._bool(), - }); - return this; - } - - let data; - const bool = this._bool(); + if (typeof first === 'function') { + data = { + type: 'onWrapped', + value: first, + bool: bool, + }; + } else { switch (arguments.length) { - case 1: { - if (typeof first === 'object' && typeof first.toSQL !== 'function') { - const keys = Object.keys(first); - let i = -1; - const method = bool === 'or' ? 'orOn' : 'on'; - while (++i < keys.length) { - this[method](keys[i], first[keys[i]]); - } - return this; - } else { - data = { type: 'onRaw', value: first, bool }; - } + case 3: { + data = { type: 'onRaw', value: first, bool }; break; } - case 2: + case 4: data = { - type: 'onBasic', + type: compilerType, column: first, operator: '=', value: operator, @@ -56,14 +40,39 @@ assign(JoinClause.prototype, { break; default: data = { - type: 'onBasic', + type: compilerType, column: first, operator, value: second, bool, }; } - this.clauses.push(data); + } + + return data; +} + +assign(JoinClause.prototype, { + grouping: 'join', + + // Adds an "on" clause to the current join object. + on(first) { + if (typeof first === 'object' && typeof first.toSQL !== 'function') { + const keys = Object.keys(first); + let i = -1; + const method = this._bool() === 'or' ? 'orOn' : 'on'; + while (++i < keys.length) { + this[method](keys[i], first[keys[i]]); + } + return this; + } + + const data = getClauseFromArguments('onBasic', this._bool(), ...arguments); + + if (data) { + this.clauses.push(data); + } + return this; }, @@ -82,6 +91,34 @@ assign(JoinClause.prototype, { return this._bool('or').on.apply(this, arguments); }, + onVal(first) { + if (typeof first === 'object' && typeof first.toSQL !== 'function') { + const keys = Object.keys(first); + let i = -1; + const method = this._bool() === 'or' ? 'orOnVal' : 'onVal'; + while (++i < keys.length) { + this[method](keys[i], first[keys[i]]); + } + return this; + } + + const data = getClauseFromArguments('onVal', this._bool(), ...arguments); + + if (data) { + this.clauses.push(data); + } + + return this; + }, + + andOnVal() { + return this.onVal(...arguments); + }, + + orOnVal() { + return this._bool('or').onVal(...arguments); + }, + onBetween(column, values) { assert( Array.isArray(values), diff --git a/test/unit/query/builder.js b/test/unit/query/builder.js index 10eedd4c2e..9a2514753f 100644 --- a/test/unit/query/builder.js +++ b/test/unit/query/builder.js @@ -8267,4 +8267,109 @@ describe('QueryBuilder', function() { } ); }); + + it('join with onVal andOnVal orOnVal', () => { + testsql( + qb() + .select({ + id: 'p.ID', + status: 'p.post_status', + name: 'p.post_title', + // type: 'terms.name', + price: 'price.meta_value', + createdAt: 'p.post_date_gmt', + updatedAt: 'p.post_modified_gmt', + }) + .from({ p: 'wp_posts' }) + .leftJoin({ price: 'wp_postmeta' }, function() { + this.on('p.id', '=', 'price.post_id') + .onVal(function() { + this.onVal('price.meta_key', '_regular_price').andOnVal( + 'price_meta_key', + '_regular_price' + ); + }) + .orOnVal(function() { + this.onVal('price_meta.key', '_regular_price'); + }); + }), + { + pg: { + sql: + 'select "p"."ID" as "id", "p"."post_status" as "status", "p"."post_title" as "name", "price"."meta_value" as "price", "p"."post_date_gmt" as "createdAt", "p"."post_modified_gmt" as "updatedAt" from "wp_posts" as "p" left join "wp_postmeta" as "price" on "p"."id" = "price"."post_id" and ("price"."meta_key" = ? and "price_meta_key" = ?) or ("price_meta"."key" = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + mysql: { + sql: + 'select `p`.`ID` as `id`, `p`.`post_status` as `status`, `p`.`post_title` as `name`, `price`.`meta_value` as `price`, `p`.`post_date_gmt` as `createdAt`, `p`.`post_modified_gmt` as `updatedAt` from `wp_posts` as `p` left join `wp_postmeta` as `price` on `p`.`id` = `price`.`post_id` and (`price`.`meta_key` = ? and `price_meta_key` = ?) or (`price_meta`.`key` = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + mssql: { + sql: + 'select [p].[ID] as [id], [p].[post_status] as [status], [p].[post_title] as [name], [price].[meta_value] as [price], [p].[post_date_gmt] as [createdAt], [p].[post_modified_gmt] as [updatedAt] from [wp_posts] as [p] left join [wp_postmeta] as [price] on [p].[id] = [price].[post_id] and ([price].[meta_key] = ? and [price_meta_key] = ?) or ([price_meta].[key] = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + 'pg-redshift': { + sql: + 'select "p"."ID" as "id", "p"."post_status" as "status", "p"."post_title" as "name", "price"."meta_value" as "price", "p"."post_date_gmt" as "createdAt", "p"."post_modified_gmt" as "updatedAt" from "wp_posts" as "p" left join "wp_postmeta" as "price" on "p"."id" = "price"."post_id" and ("price"."meta_key" = ? and "price_meta_key" = ?) or ("price_meta"."key" = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + oracledb: { + sql: + 'select "p"."ID" "id", "p"."post_status" "status", "p"."post_title" "name", "price"."meta_value" "price", "p"."post_date_gmt" "createdAt", "p"."post_modified_gmt" "updatedAt" from "wp_posts" "p" left join "wp_postmeta" "price" on "p"."id" = "price"."post_id" and ("price"."meta_key" = ? and "price_meta_key" = ?) or ("price_meta"."key" = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + } + ); + + testsql( + qb() + .select({ + id: 'p.ID', + status: 'p.post_status', + name: 'p.post_title', + // type: 'terms.name', + price: 'price.meta_value', + createdAt: 'p.post_date_gmt', + updatedAt: 'p.post_modified_gmt', + }) + .from({ p: 'wp_posts' }) + .leftJoin({ price: 'wp_postmeta' }, (builder) => { + builder.onVal((q) => { + q.onVal('price.meta_key', '_regular_price').andOnVal( + 'price_meta_key', + '_regular_price' + ); + }) + .orOnVal((q) => { + q.onVal('price_meta.key', '_regular_price'); + }) + }), + { + pg: { + sql: + 'select "p"."ID" as "id", "p"."post_status" as "status", "p"."post_title" as "name", "price"."meta_value" as "price", "p"."post_date_gmt" as "createdAt", "p"."post_modified_gmt" as "updatedAt" from "wp_posts" as "p" left join "wp_postmeta" as "price" on ("price"."meta_key" = ? and "price_meta_key" = ?) or ("price_meta"."key" = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + mysql: { + sql: + 'select `p`.`ID` as `id`, `p`.`post_status` as `status`, `p`.`post_title` as `name`, `price`.`meta_value` as `price`, `p`.`post_date_gmt` as `createdAt`, `p`.`post_modified_gmt` as `updatedAt` from `wp_posts` as `p` left join `wp_postmeta` as `price` on (`price`.`meta_key` = ? and `price_meta_key` = ?) or (`price_meta`.`key` = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + mssql: { + sql: + 'select [p].[ID] as [id], [p].[post_status] as [status], [p].[post_title] as [name], [price].[meta_value] as [price], [p].[post_date_gmt] as [createdAt], [p].[post_modified_gmt] as [updatedAt] from [wp_posts] as [p] left join [wp_postmeta] as [price] on ([price].[meta_key] = ? and [price_meta_key] = ?) or ([price_meta].[key] = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + 'pg-redshift': { + sql: + 'select "p"."ID" as "id", "p"."post_status" as "status", "p"."post_title" as "name", "price"."meta_value" as "price", "p"."post_date_gmt" as "createdAt", "p"."post_modified_gmt" as "updatedAt" from "wp_posts" as "p" left join "wp_postmeta" as "price" on ("price"."meta_key" = ? and "price_meta_key" = ?) or ("price_meta"."key" = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + oracledb: { + sql: + 'select "p"."ID" "id", "p"."post_status" "status", "p"."post_title" "name", "price"."meta_value" "price", "p"."post_date_gmt" "createdAt", "p"."post_modified_gmt" "updatedAt" from "wp_posts" "p" left join "wp_postmeta" "price" on ("price"."meta_key" = ? and "price_meta_key" = ?) or ("price_meta"."key" = ?)', + bindings: ['_regular_price', '_regular_price', '_regular_price'], + }, + })}); });