From f4f339d18a1dd0ea3edef27972f50179ca9629b5 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Lu=C3=ADs=20Duarte?= Date: Mon, 16 Dec 2024 19:39:15 +0000 Subject: [PATCH] feat: add whereIn for SelectBuilder This API abbreviates the usage of `(field, test) IN (VALUES (?, ?), (?, ?))` in where conditions by dynamically constructing this query dynamically depending on the number of fields given and the length of values given. This makes it really easy to build dynamic queries that filter by multiple status: `db.select('employee').whereIn('role', ["eng", "hr", "sales"])` It will generate something like this sql: `SELECT * FROM employee WHERE (role) IN (VALUES ('eng'), ('hr'), ('sales));` This is SQL syntax supported by both postgres and SQLite (therefore D1 and DOs too) Or we can use this for multiple fields at the same time: `db.select('employee').whereIn(['role', 'team'], [["eng", "workers"], ["eng", "workflows"]])` Also, we make the arguments to `whereIn` typesafe: - whereIn fields only support a string or a array of strings - whereIn values are checked against the fields type (if the field type is a string, means that we can only pass a Primitive list, otherwise, if the field type is an array of strings, means that we must pass a list of a list of primitives) --- src/modularBuilder.ts | 65 ++++++++++++++++++++++++++++++++++++ tests/unit/select.test.ts | 69 +++++++++++++++++++++++++++++++++++++++ 2 files changed, 134 insertions(+) diff --git a/src/modularBuilder.ts b/src/modularBuilder.ts index 69f75c0..cd294db 100644 --- a/src/modularBuilder.ts +++ b/src/modularBuilder.ts @@ -78,6 +78,71 @@ export class SelectBuilder, P extends T extends Array ? Primitive[][] : Primitive[]>( + fields: T, + values: P + ): SelectBuilder { + let whereInCondition: string + let whereInParams: Primitive[] + + const seperateWithComma = (prev: string, next: string) => prev + ', ' + next + + // if we have no values, we no-op + if (values.length === 0) { + return new SelectBuilder( + { + ...this._options, + }, + this._fetchAll, + this._fetchOne + ) + } + + if (!Array.isArray(fields)) { + // at this point, we know that it's a string + whereInCondition = `(${fields}) IN (VALUES ` + + whereInCondition += values.map(() => '(?)').reduce(seperateWithComma) + whereInCondition += ')' + // if it's not an array, we can assume that values is whereInParams[] + whereInParams = values as Primitive[] + } else { + // NOTE(lduarte): we assume that this is const throughout the values list, if it's not, oh well garbage in, garbage out + const fieldLength = fields.length + + whereInCondition = `(${fields.map((val) => val).reduce(seperateWithComma)}) IN (VALUES ` + + const valuesString = `(${[...new Array(fieldLength).keys()].map(() => '?').reduce(seperateWithComma)})` + + whereInCondition += [...new Array(fieldLength).keys()].map(() => valuesString).reduce(seperateWithComma) + whereInCondition += ')' + // finally, flatten the list since the whereInParams are in a single list + whereInParams = values.flat() + } + + let conditions: string | Array = [whereInCondition] + let params: Primitive[] = whereInParams + if ((this._options.where as any)?.conditions) { + conditions = (this._options.where as any)?.conditions.concat(conditions) + } + + if ((this._options.where as any)?.params) { + params = (this._options.where as any)?.params.concat(params) + } + + return new SelectBuilder( + { + ...this._options, + where: { + conditions: conditions, + params: params, + }, + }, + this._fetchAll, + this._fetchOne + ) + } + join(join: SelectAll['join']): SelectBuilder { return this._parseArray('join', this._options.join, join) } diff --git a/tests/unit/select.test.ts b/tests/unit/select.test.ts index 9dcfbdf..5a23761 100644 --- a/tests/unit/select.test.ts +++ b/tests/unit/select.test.ts @@ -790,4 +790,73 @@ describe('Select Builder', () => { expect(result.fetchType).toEqual('ALL') } }) + + it('select whereIn single field', async () => { + const result = new QuerybuilderTest().select('testTable').whereIn('field', [1, 2, 3, 4]).getQueryAll() + + expect(result.query).toEqual('SELECT * FROM testTable WHERE (field) IN (VALUES (?), (?), (?), (?))') + expect(result.arguments).toEqual([1, 2, 3, 4]) + expect(result.fetchType).toEqual('ALL') + }) + + it('select whereIn multiple fields', async () => { + const result = new QuerybuilderTest() + .select('testTable') + .whereIn( + ['field', 'test'], + [ + ['somebody', 1], + ['once', 2], + ['told', 3], + ['me', 4], + ] + ) + .getQueryAll() + + expect(result.query).toEqual('SELECT * FROM testTable WHERE (field, test) IN (VALUES (?, ?), (?, ?))') + expect(result.arguments).toEqual(['somebody', 1, 'once', 2, 'told', 3, 'me', 4]) + expect(result.fetchType).toEqual('ALL') + }) + + it('select whereIn multiple fields with another where', async () => { + const result = new QuerybuilderTest() + .select('testTable') + .where('commited = ?', 1) + .whereIn( + ['field', 'test'], + [ + ['somebody', 1], + ['once', 2], + ['told', 3], + ['me', 4], + ] + ) + .getQueryAll() + + expect(result.query).toEqual( + 'SELECT * FROM testTable WHERE (commited = ?) AND ((field, test) IN (VALUES (?, ?), (?, ?)))' + ) + expect(result.arguments).toEqual([1, 'somebody', 1, 'once', 2, 'told', 3, 'me', 4]) + expect(result.fetchType).toEqual('ALL') + + const result2 = new QuerybuilderTest() + .select('testTable') + .whereIn( + ['field', 'test'], + [ + ['somebody', 1], + ['once', 2], + ['told', 3], + ['me', 4], + ] + ) + .where('commited = ?', 1) + .getQueryAll() + + expect(result2.query).toEqual( + 'SELECT * FROM testTable WHERE ((field, test) IN (VALUES (?, ?), (?, ?))) AND (commited = ?)' + ) + expect(result2.arguments).toEqual(['somebody', 1, 'once', 2, 'told', 3, 'me', 4, 1]) + expect(result2.fetchType).toEqual('ALL') + }) })