From a9387d4f284421e459bf44df93b98dc6448a8cb5 Mon Sep 17 00:00:00 2001 From: Denys Otrishko Date: Fri, 29 Sep 2023 19:24:23 +0300 Subject: [PATCH 1/3] feat(select): add more join types --- lib/query-conditions-builder.js | 25 +++++ lib/select-builder.js | 131 +++++++++++++++++++++++- lib/utils.js | 3 +- types/lib/query-conditions-builder.d.ts | 10 ++ types/lib/select-builder.d.ts | 81 +++++++++++++++ 5 files changed, 244 insertions(+), 6 deletions(-) diff --git a/lib/query-conditions-builder.js b/lib/query-conditions-builder.js index 7b6a143..ba8d077 100644 --- a/lib/query-conditions-builder.js +++ b/lib/query-conditions-builder.js @@ -44,26 +44,51 @@ class QueryConditionsBuilder extends QueryBuilder { return this; } + orWhereEq(key, value) { + this.whereConditions.or(key, '=', this._whereValueMapper(value)); + return this; + } + whereMore(key, value) { this.whereConditions.and(key, '>', this._whereValueMapper(value)); return this; } + orWhereMore(key, value) { + this.whereConditions.or(key, '>', this._whereValueMapper(value)); + return this; + } + whereMoreEq(key, value) { this.whereConditions.and(key, '>=', this._whereValueMapper(value)); return this; } + orWhereMoreEq(key, value) { + this.whereConditions.or(key, '>=', this._whereValueMapper(value)); + return this; + } + whereLess(key, value) { this.whereConditions.and(key, '<', this._whereValueMapper(value)); return this; } + orWhereLess(key, value) { + this.whereConditions.or(key, '<', this._whereValueMapper(value)); + return this; + } + whereLessEq(key, value) { this.whereConditions.and(key, '<=', this._whereValueMapper(value)); return this; } + orWhereLessEq(key, value) { + this.whereConditions.or(key, '<=', this._whereValueMapper(value)); + return this; + } + whereNot(key, cond, value) { this.whereConditions.not(key, cond, this._whereValueMapper(value)); return this; diff --git a/lib/select-builder.js b/lib/select-builder.js index 293ceae..8269089 100644 --- a/lib/select-builder.js +++ b/lib/select-builder.js @@ -20,7 +20,7 @@ class SelectBuilder extends QueryConditionsBuilder { this.operations = { select: new Set(), selectDistinct: false, - innerJoin: [], + join: [], groupBy: new Set(), orderBy: [], from: [], @@ -59,14 +59,117 @@ class SelectBuilder extends QueryConditionsBuilder { } innerJoin(tableName, leftKey, rightKey) { - this.operations.innerJoin.push({ + return this.innerJoinAs(tableName, null, leftKey, rightKey); + } + + innerJoinAs(tableName, alias, leftKey, rightKey) { + this.join('INNER', tableName, alias, leftKey, rightKey); + return this; + } + + innerJoinCond(tableName, condition) { + return this.innerJoinCondAs(tableName, null, condition); + } + + innerJoinCondAs(tableName, alias, condition) { + this.joinCond('INNER', tableName, alias, condition); + return this; + } + + leftJoin(tableName, leftKey, rightKey) { + return this.leftJoinAs(tableName, null, leftKey, rightKey); + } + + leftJoinAs(tableName, alias, leftKey, rightKey) { + this.join('LEFT OUTER', tableName, alias, leftKey, rightKey); + return this; + } + + leftJoinCond(tableName, condition) { + return this.leftJoinCondAs(tableName, null, condition); + } + + leftJoinCondAs(tableName, alias, condition) { + this.joinCond('LEFT OUTER', tableName, alias, condition); + return this; + } + + rightJoin(tableName, leftKey, rightKey) { + return this.rightJoinAs(tableName, null, leftKey, rightKey); + } + + rightJoinAs(tableName, alias, leftKey, rightKey) { + this.join('RIGHT OUTER', tableName, alias, leftKey, rightKey); + return this; + } + + rightJoinCond(tableName, condition) { + return this.rightJoinCondAs(tableName, null, condition); + } + + rightJoinCondAs(tableName, alias, condition) { + this.joinCond('RIGHT OUTER', tableName, alias, condition); + return this; + } + + fullJoin(tableName, leftKey, rightKey) { + return this.fullJoinAs(tableName, null, leftKey, rightKey); + } + + fullJoinAs(tableName, alias, leftKey, rightKey) { + this.join('FULL OUTER', tableName, alias, leftKey, rightKey); + return this; + } + + fullJoinCond(tableName, condition) { + return this.fullJoinCondAs(tableName, null, condition); + } + + fullJoinCondAs(tableName, alias, condition) { + this.joinCond('FULL OUTER', tableName, alias, condition); + return this; + } + + naturalJoin(tableName) { + return this.naturalJoinAs(tableName, null, null, null); + } + + naturalJoinAs(tableName, alias) { + this.join('NATURAL', tableName, alias, null, null); + return this; + } + + crossJoin(tableName) { + return this.crossJoinAs(tableName, null, null, null); + } + + crossJoinAs(tableName, alias) { + this.join('CROSS', tableName, alias, null, null); + return this; + } + + join(kind, tableName, alias, leftKey, rightKey) { + this.operations.join.push({ + kind, table: this.escapeIdentifier(tableName), + alias: this.escapeIdentifier(alias), leftKey: this.escapeKey(leftKey), rightKey: this.escapeKey(rightKey), }); return this; } + joinCond(kind, tableName, alias, condition) { + checkTypeOrQuery(condition, 'condition', 'string'); + this.operations.join.push({ + kind, + table: this.escapeIdentifier(tableName), + alias: this.escapeIdentifier(alias), + condition, + }); + return this; + } + distinct() { this.operations.selectDistinct = true; return this; @@ -162,6 +265,26 @@ class SelectBuilder extends QueryConditionsBuilder { ); } + // #private + _processJoin(joins) { + let clauses = ''; + for (const join of joins) { + const alias = join.alias ? ` AS ${join.alias}` : ''; + if (join.kind === 'NATURAL' || join.kind === 'CROSS') { + clauses += ` ${join.kind} JOIN ${join.table}${alias}`; + } else if (join.condition) { + const condition = + join.condition instanceof QueryBuilder + ? join.condition.build() + : join.condition; + clauses += ` ${join.kind} JOIN ${join.table}${alias} ON ${condition}`; + } else { + clauses += ` ${join.kind} JOIN ${join.table}${alias} ON ${join.leftKey} = ${join.rightKey}`; + } + } + return clauses; + } + // #private _processOrder(clauses) { return mapJoinIterable(clauses, (o) => `${o.field} ${o.dir}`, ', '); @@ -179,9 +302,7 @@ class SelectBuilder extends QueryConditionsBuilder { } query += ` FROM ${this._processFrom(this.operations.from)}`; - for (const { table, leftKey, rightKey } of this.operations.innerJoin) { - query += ` INNER JOIN ${table} ON ${leftKey} = ${rightKey}`; - } + query += this._processJoin(this.operations.join); const whereClauses = this.whereConditions.build(); if (whereClauses.length > 0) { diff --git a/lib/utils.js b/lib/utils.js index 6d995dc..e05d9f9 100644 --- a/lib/utils.js +++ b/lib/utils.js @@ -1,8 +1,9 @@ 'use strict'; -const escapeIdentifier = (name) => `"${name}"`; +const escapeIdentifier = (name) => name && `"${name}"`; const escapeKey = (key, escapeIdentifier) => + key && key .split('.') .map((k) => (k === '*' ? '*' : escapeIdentifier(k))) diff --git a/types/lib/query-conditions-builder.d.ts b/types/lib/query-conditions-builder.d.ts index 75de897..36b434c 100644 --- a/types/lib/query-conditions-builder.d.ts +++ b/types/lib/query-conditions-builder.d.ts @@ -21,14 +21,24 @@ export class QueryConditionsBuilder< whereEq(key: string, value: CV): this; + orWhereEq(key: string, value: CV): this; + whereMore(key: string, value: CV): this; + orWhereMore(key: string, value: CV): this; + whereMoreEq(key: string, value: CV): this; + orWhereMoreEq(key: string, value: CV): this; + whereLess(key: string, value: CV): this; + orWhereMoreEq(key: string, value: CV): this; + whereLessEq(key: string, value: CV): this; + orWhereLessEq(key: string, value: CV): this; + orWhere(key: string, cond: string, value: CV): this; orWhereKey(leftKey: string, cond: string, rightKey: string): this; diff --git a/types/lib/select-builder.d.ts b/types/lib/select-builder.d.ts index 55c4dd9..fa589d4 100644 --- a/types/lib/select-builder.d.ts +++ b/types/lib/select-builder.d.ts @@ -10,6 +10,14 @@ export type SelectQueryValue = export type SelectConditionValue = any | SelectQueryValue; +export type JoinKind = + | 'INNER' + | 'LEFT OUTER' + | 'RIGHT OUTER' + | 'FULL OUTER' + | 'NATURAL' + | 'CROSS'; + export class SelectBuilder extends QueryConditionsBuilder< SelectBuilderOptions, SelectConditionValue @@ -28,6 +36,79 @@ export class SelectBuilder extends QueryConditionsBuilder< innerJoin(tableName: string, leftKey: string, rightKey: string): this; + innerJoinAs( + tableName: string, + alias: string, + leftKey: string, + rightKey: string + ): this; + + innerJoinCond(tableName: string, condition: string): this; + + innerJoinCondAs(tableName: string, alias: string, condition: string): this; + + leftJoin(tableName: string, leftKey: string, rightKey: string): this; + + leftJoinAs( + tableName: string, + alias: string, + leftKey: string, + rightKey: string + ): this; + + leftJoinCond(tableName: string, condition: string): this; + + leftJoinCondAs(tableName: string, alias: string, condition: string): this; + + rightJoin(tableName: string, leftKey: string, rightKey: string): this; + + rightJoinAs( + tableName: string, + alias: string, + leftKey: string, + rightKey: string + ): this; + + rightJoinCond(tableName: string, condition: string): this; + + rightJoinCondAs(tableName: string, alias: string, condition: string): this; + + fullJoin(tableName: string, leftKey: string, rightKey: string): this; + + fullJoinAs( + tableName: string, + alias: string, + leftKey: string, + rightKey: string + ): this; + + fullJoinCond(tableName: string, condition: string): this; + + fullJoinCondAs(tableName: string, alias: string, condition: string): this; + + naturalJoin(tableName: string): this; + + naturalJoinAs(tableName: string, alias: string): this; + + crossJoin(tableName: string): this; + + crossJoinAs(tableName: string, alias: string): this; + + join( + kind: JoinKind, + tableName: string, + alias: string, + leftKey: string, + rightKey: string + ): this; + + joinCond( + kind: JoinKind, + tableName: string, + alias: string, + condition: string + ): this; + distinct(): this; orderBy(field: string, dir?: 'ASC' | 'DESC'): this; From 47cbd941cbd7f2170dc8388490e2e7a6bea1679b Mon Sep 17 00:00:00 2001 From: Denys Otrishko Date: Fri, 29 Sep 2023 19:45:48 +0300 Subject: [PATCH 2/3] feat(select): add more join types --- doc/sql.md | 78 ++++++++++++ test/sqlgen.js | 323 +++++++++++++++++++++++++++++++++++++++++++++++++ 2 files changed, 401 insertions(+) diff --git a/doc/sql.md b/doc/sql.md index b21e7dd..e8cb214 100644 --- a/doc/sql.md +++ b/doc/sql.md @@ -14,11 +14,16 @@ - [QueryConditionsBuilder.prototype.orWhere](#queryconditionsbuilderprototypeorwherekey-cond-value) - [QueryConditionsBuilder.prototype.orWhereAny](#queryconditionsbuilderprototypeorwhereanykey-value) - [QueryConditionsBuilder.prototype.orWhereBetween](#queryconditionsbuilderprototypeorwherebetweenkey-from-to-symmetric) + - [QueryConditionsBuilder.prototype.orWhereEq](#queryconditionsbuilderprototypeorwhereeqkey-value) - [QueryConditionsBuilder.prototype.orWhereExists](#queryconditionsbuilderprototypeorwhereexistssubquery) - [QueryConditionsBuilder.prototype.orWhereILike](#queryconditionsbuilderprototypeorwhereilikekey-value) - [QueryConditionsBuilder.prototype.orWhereIn](#queryconditionsbuilderprototypeorwhereinkey-conds) - [QueryConditionsBuilder.prototype.orWhereKey](#queryconditionsbuilderprototypeorwherekeyleftkey-cond-rightkey) + - [QueryConditionsBuilder.prototype.orWhereLess](#queryconditionsbuilderprototypeorwherelesskey-value) + - [QueryConditionsBuilder.prototype.orWhereLessEq](#queryconditionsbuilderprototypeorwherelesseqkey-value) - [QueryConditionsBuilder.prototype.orWhereLike](#queryconditionsbuilderprototypeorwherelikekey-value) + - [QueryConditionsBuilder.prototype.orWhereMore](#queryconditionsbuilderprototypeorwheremorekey-value) + - [QueryConditionsBuilder.prototype.orWhereMoreEq](#queryconditionsbuilderprototypeorwheremoreeqkey-value) - [QueryConditionsBuilder.prototype.orWhereNot](#queryconditionsbuilderprototypeorwherenotkey-cond-value) - [QueryConditionsBuilder.prototype.orWhereNotBetween](#queryconditionsbuilderprototypeorwherenotbetweenkey-from-to-symmetric) - [QueryConditionsBuilder.prototype.orWhereNotILike](#queryconditionsbuilderprototypeorwherenotilikekey-value) @@ -59,15 +64,36 @@ - [SelectBuilder.prototype.avg](#selectbuilderprototypeavgfield-alias) - [SelectBuilder.prototype.build](#selectbuilderprototypebuild) - [SelectBuilder.prototype.count](#selectbuilderprototypecountfield---alias) + - [SelectBuilder.prototype.crossJoin](#selectbuilderprototypecrossjointablename) + - [SelectBuilder.prototype.crossJoinAs](#selectbuilderprototypecrossjoinastablename-alias) - [SelectBuilder.prototype.distinct](#selectbuilderprototypedistinct) - [SelectBuilder.prototype.from](#selectbuilderprototypefromtablename-alias) + - [SelectBuilder.prototype.fullJoin](#selectbuilderprototypefulljointablename-leftkey-rightkey) + - [SelectBuilder.prototype.fullJoinAs](#selectbuilderprototypefulljoinastablename-alias-leftkey-rightkey) + - [SelectBuilder.prototype.fullJoinCond](#selectbuilderprototypefulljoincondtablename-condition) + - [SelectBuilder.prototype.fullJoinCondAs](#selectbuilderprototypefulljoincondastablename-alias-condition) - [SelectBuilder.prototype.groupBy](#selectbuilderprototypegroupbyfields) - [SelectBuilder.prototype.innerJoin](#selectbuilderprototypeinnerjointablename-leftkey-rightkey) + - [SelectBuilder.prototype.innerJoinAs](#selectbuilderprototypeinnerjoinastablename-alias-leftkey-rightkey) + - [SelectBuilder.prototype.innerJoinCond](#selectbuilderprototypeinnerjoincondtablename-condition) + - [SelectBuilder.prototype.innerJoinCondAs](#selectbuilderprototypeinnerjoincondastablename-alias-condition) + - [SelectBuilder.prototype.join](#selectbuilderprototypejoinkind-tablename-alias-leftkey-rightkey) + - [SelectBuilder.prototype.joinCond](#selectbuilderprototypejoincondkind-tablename-alias-condition) + - [SelectBuilder.prototype.leftJoin](#selectbuilderprototypeleftjointablename-leftkey-rightkey) + - [SelectBuilder.prototype.leftJoinAs](#selectbuilderprototypeleftjoinastablename-alias-leftkey-rightkey) + - [SelectBuilder.prototype.leftJoinCond](#selectbuilderprototypeleftjoincondtablename-condition) + - [SelectBuilder.prototype.leftJoinCondAs](#selectbuilderprototypeleftjoincondastablename-alias-condition) - [SelectBuilder.prototype.limit](#selectbuilderprototypelimitlimit) - [SelectBuilder.prototype.max](#selectbuilderprototypemaxfield-alias) - [SelectBuilder.prototype.min](#selectbuilderprototypeminfield-alias) + - [SelectBuilder.prototype.naturalJoin](#selectbuilderprototypenaturaljointablename) + - [SelectBuilder.prototype.naturalJoinAs](#selectbuilderprototypenaturaljoinastablename-alias) - [SelectBuilder.prototype.offset](#selectbuilderprototypeoffsetoffset) - [SelectBuilder.prototype.orderBy](#selectbuilderprototypeorderbyfield-dir--asc) + - [SelectBuilder.prototype.rightJoin](#selectbuilderprototyperightjointablename-leftkey-rightkey) + - [SelectBuilder.prototype.rightJoinAs](#selectbuilderprototyperightjoinastablename-alias-leftkey-rightkey) + - [SelectBuilder.prototype.rightJoinCond](#selectbuilderprototyperightjoincondtablename-condition) + - [SelectBuilder.prototype.rightJoinCondAs](#selectbuilderprototyperightjoincondastablename-alias-condition) - [SelectBuilder.prototype.select](#selectbuilderprototypeselectfields) - [SelectBuilder.prototype.selectAs](#selectbuilderprototypeselectasfield-alias) - [SelectBuilder.prototype.selectFn](#selectbuilderprototypeselectfnfn-field-alias) @@ -204,6 +230,8 @@ Build params for this query #### QueryConditionsBuilder.prototype.orWhereBetween(key, from, to, symmetric) +#### QueryConditionsBuilder.prototype.orWhereEq(key, value) + #### QueryConditionsBuilder.prototype.orWhereExists(subquery) #### QueryConditionsBuilder.prototype.orWhereILike(key, value) @@ -212,8 +240,16 @@ Build params for this query #### QueryConditionsBuilder.prototype.orWhereKey(leftKey, cond, rightKey) +#### QueryConditionsBuilder.prototype.orWhereLess(key, value) + +#### QueryConditionsBuilder.prototype.orWhereLessEq(key, value) + #### QueryConditionsBuilder.prototype.orWhereLike(key, value) +#### QueryConditionsBuilder.prototype.orWhereMore(key, value) + +#### QueryConditionsBuilder.prototype.orWhereMoreEq(key, value) + #### QueryConditionsBuilder.prototype.orWhereNot(key, cond, value) #### QueryConditionsBuilder.prototype.orWhereNotBetween(key, from, to, symmetric) @@ -294,24 +330,66 @@ Build params for this query #### SelectBuilder.prototype.count(field = '\*', alias) +#### SelectBuilder.prototype.crossJoin(tableName) + +#### SelectBuilder.prototype.crossJoinAs(tableName, alias) + #### SelectBuilder.prototype.distinct() #### SelectBuilder.prototype.from(tableName, alias) +#### SelectBuilder.prototype.fullJoin(tableName, leftKey, rightKey) + +#### SelectBuilder.prototype.fullJoinAs(tableName, alias, leftKey, rightKey) + +#### SelectBuilder.prototype.fullJoinCond(tableName, condition) + +#### SelectBuilder.prototype.fullJoinCondAs(tableName, alias, condition) + #### SelectBuilder.prototype.groupBy(...fields) #### SelectBuilder.prototype.innerJoin(tableName, leftKey, rightKey) +#### SelectBuilder.prototype.innerJoinAs(tableName, alias, leftKey, rightKey) + +#### SelectBuilder.prototype.innerJoinCond(tableName, condition) + +#### SelectBuilder.prototype.innerJoinCondAs(tableName, alias, condition) + +#### SelectBuilder.prototype.join(kind, tableName, alias, leftKey, rightKey) + +#### SelectBuilder.prototype.joinCond(kind, tableName, alias, condition) + +#### SelectBuilder.prototype.leftJoin(tableName, leftKey, rightKey) + +#### SelectBuilder.prototype.leftJoinAs(tableName, alias, leftKey, rightKey) + +#### SelectBuilder.prototype.leftJoinCond(tableName, condition) + +#### SelectBuilder.prototype.leftJoinCondAs(tableName, alias, condition) + #### SelectBuilder.prototype.limit(limit) #### SelectBuilder.prototype.max(field, alias) #### SelectBuilder.prototype.min(field, alias) +#### SelectBuilder.prototype.naturalJoin(tableName) + +#### SelectBuilder.prototype.naturalJoinAs(tableName, alias) + #### SelectBuilder.prototype.offset(offset) #### SelectBuilder.prototype.orderBy(field, dir = 'ASC') +#### SelectBuilder.prototype.rightJoin(tableName, leftKey, rightKey) + +#### SelectBuilder.prototype.rightJoinAs(tableName, alias, leftKey, rightKey) + +#### SelectBuilder.prototype.rightJoinCond(tableName, condition) + +#### SelectBuilder.prototype.rightJoinCondAs(tableName, alias, condition) + #### SelectBuilder.prototype.select(...fields) #### SelectBuilder.prototype.selectAs(field, alias) diff --git a/test/sqlgen.js b/test/sqlgen.js index 07d609f..49dbf06 100644 --- a/test/sqlgen.js +++ b/test/sqlgen.js @@ -875,6 +875,64 @@ test.testSync('Select with inner join', (test, { builder, params }) => { test.strictSame(params.build(), ['abc']); }); +test.testSync('Select with inner join as', (test, { builder, params }) => { + builder + .from('table1') + .innerJoinAs('table2', 't2', 'table1.f', 't2.f') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'INNER JOIN "table2" AS "t2" ON "table1"."f" = "t2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync( + 'Select with inner join condition', + (test, { builder, params }) => { + builder + .from('table1') + .innerJoinCond( + 'table2', + builder.raw(() => `"table1"."f" = "table2"."f"`) + ) + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'INNER JOIN "table2" ON "table1"."f" = "table2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); + } +); + +test.testSync( + 'Select with inner join as condition', + (test, { builder, params }) => { + builder + .from('table1') + .innerJoinCondAs( + 'table2', + 't2', + builder.raw(() => `"table1"."f" = "t2"."f"`) + ) + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'INNER JOIN "table2" AS "t2" ON "table1"."f" = "t2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); + } +); + test.testSync( 'Select with inner join and where raw', (test, { builder, params }) => { @@ -955,6 +1013,271 @@ test.testSync( } ); +test.testSync('Select with left join', (test, { builder, params }) => { + builder + .from('table1') + .leftJoin('table2', 'table1.f', 'table2.f') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'LEFT OUTER JOIN "table2" ON "table1"."f" = "table2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync('Select with left join as', (test, { builder, params }) => { + builder + .from('table1') + .leftJoinAs('table2', 't2', 'table1.f', 't2.f') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'LEFT OUTER JOIN "table2" AS "t2" ON "table1"."f" = "t2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync( + 'Select with left join condition', + (test, { builder, params }) => { + builder + .from('table1') + .leftJoinCond( + 'table2', + builder.raw(() => `"table1"."f" = "table2"."f"`) + ) + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'LEFT OUTER JOIN "table2" ON "table1"."f" = "table2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); + } +); + +test.testSync( + 'Select with left join as condition', + (test, { builder, params }) => { + builder + .from('table1') + .leftJoinCondAs( + 'table2', + 't2', + builder.raw(() => `"table1"."f" = "t2"."f"`) + ) + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'LEFT OUTER JOIN "table2" AS "t2" ON "table1"."f" = "t2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); + } +); + +test.testSync('Select with right join', (test, { builder, params }) => { + builder + .from('table1') + .rightJoin('table2', 'table1.f', 'table2.f') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'RIGHT OUTER JOIN "table2" ON "table1"."f" = "table2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync('Select with right join as', (test, { builder, params }) => { + builder + .from('table1') + .rightJoinAs('table2', 't2', 'table1.f', 't2.f') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'RIGHT OUTER JOIN "table2" AS "t2" ON "table1"."f" = "t2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync( + 'Select with right join condition', + (test, { builder, params }) => { + builder + .from('table1') + .rightJoinCond( + 'table2', + builder.raw(() => `"table1"."f" = "table2"."f"`) + ) + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'RIGHT OUTER JOIN "table2" ON "table1"."f" = "table2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); + } +); + +test.testSync( + 'Select with right join as condition', + (test, { builder, params }) => { + builder + .from('table1') + .rightJoinCondAs( + 'table2', + 't2', + builder.raw(() => `"table1"."f" = "t2"."f"`) + ) + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'RIGHT OUTER JOIN "table2" AS "t2" ON "table1"."f" = "t2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); + } +); + +test.testSync('Select with full join', (test, { builder, params }) => { + builder + .from('table1') + .fullJoin('table2', 'table1.f', 'table2.f') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'FULL OUTER JOIN "table2" ON "table1"."f" = "table2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync('Select with full join as', (test, { builder, params }) => { + builder + .from('table1') + .fullJoinAs('table2', 't2', 'table1.f', 't2.f') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'FULL OUTER JOIN "table2" AS "t2" ON "table1"."f" = "t2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync( + 'Select with full join condition', + (test, { builder, params }) => { + builder + .from('table1') + .fullJoinCond( + 'table2', + builder.raw(() => `"table1"."f" = "table2"."f"`) + ) + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'FULL OUTER JOIN "table2" ON "table1"."f" = "table2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); + } +); + +test.testSync( + 'Select with full join as condition', + (test, { builder, params }) => { + builder + .from('table1') + .fullJoinCondAs( + 'table2', + 't2', + builder.raw(() => `"table1"."f" = "t2"."f"`) + ) + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" ' + + 'FULL OUTER JOIN "table2" AS "t2" ON "table1"."f" = "t2"."f" ' + + 'WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); + } +); + +test.testSync('Select with natural join', (test, { builder, params }) => { + builder.from('table1').naturalJoin('table2').where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" NATURAL JOIN "table2" WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync('Select with natural join as', (test, { builder, params }) => { + builder + .from('table1') + .naturalJoinAs('table2', 't2') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" NATURAL JOIN "table2" AS "t2" WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync('Select with cross join', (test, { builder, params }) => { + builder.from('table1').crossJoin('table2').where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" CROSS JOIN "table2" WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + +test.testSync('Select with cross join as', (test, { builder, params }) => { + builder + .from('table1') + .crossJoinAs('table2', 't2') + .where('table1.f', '=', 'abc'); + const query = builder.build(); + test.strictSame( + query, + 'SELECT * FROM "table1" CROSS JOIN "table2" AS "t2" WHERE "table1"."f" = $1' + ); + test.strictSame(params.build(), ['abc']); +}); + test.testSync('Select where nested', (test, { builder, params }) => { const nested = new SelectBuilder(builder.params) .from('table2') From 1205359cae801e6cbd1055456bd53fd3e23929fa Mon Sep 17 00:00:00 2001 From: Denys Otrishko Date: Fri, 29 Sep 2023 19:52:49 +0300 Subject: [PATCH 3/3] feat(select): add more join types --- types/lib/select-builder.d.ts | 34 +++++++++++++++++++++++++--------- 1 file changed, 25 insertions(+), 9 deletions(-) diff --git a/types/lib/select-builder.d.ts b/types/lib/select-builder.d.ts index fa589d4..ef261aa 100644 --- a/types/lib/select-builder.d.ts +++ b/types/lib/select-builder.d.ts @@ -43,9 +43,13 @@ export class SelectBuilder extends QueryConditionsBuilder< rightKey: string ): this; - innerJoinCond(tableName: string, condition: string): this; + innerJoinCond(tableName: string, condition: QueryBuilder | string): this; - innerJoinCondAs(tableName: string, alias: string, condition: string): this; + innerJoinCondAs( + tableName: string, + alias: string, + condition: QueryBuilder | string + ): this; leftJoin(tableName: string, leftKey: string, rightKey: string): this; @@ -56,9 +60,13 @@ export class SelectBuilder extends QueryConditionsBuilder< rightKey: string ): this; - leftJoinCond(tableName: string, condition: string): this; + leftJoinCond(tableName: string, condition: QueryBuilder | string): this; - leftJoinCondAs(tableName: string, alias: string, condition: string): this; + leftJoinCondAs( + tableName: string, + alias: string, + condition: QueryBuilder | string + ): this; rightJoin(tableName: string, leftKey: string, rightKey: string): this; @@ -69,9 +77,13 @@ export class SelectBuilder extends QueryConditionsBuilder< rightKey: string ): this; - rightJoinCond(tableName: string, condition: string): this; + rightJoinCond(tableName: string, condition: QueryBuilder | string): this; - rightJoinCondAs(tableName: string, alias: string, condition: string): this; + rightJoinCondAs( + tableName: string, + alias: string, + condition: QueryBuilder | string + ): this; fullJoin(tableName: string, leftKey: string, rightKey: string): this; @@ -82,9 +94,13 @@ export class SelectBuilder extends QueryConditionsBuilder< rightKey: string ): this; - fullJoinCond(tableName: string, condition: string): this; + fullJoinCond(tableName: string, condition: QueryBuilder | string): this; - fullJoinCondAs(tableName: string, alias: string, condition: string): this; + fullJoinCondAs( + tableName: string, + alias: string, + condition: QueryBuilder | string + ): this; naturalJoin(tableName: string): this; @@ -106,7 +122,7 @@ export class SelectBuilder extends QueryConditionsBuilder< kind: JoinKind, tableName: string, alias: string, - condition: string + condition: QueryBuilder | string ): this; distinct(): this;