From 67212e5c5b57325ba56966b2052a848eec056737 Mon Sep 17 00:00:00 2001 From: mike12345567 Date: Thu, 23 Sep 2021 16:17:23 +0100 Subject: [PATCH 1/3] Fixes issue #2616 - this is a slightly complex fix and handles a few other issues with mysql (around returning on creation of a row and relationships) - a new mechanism is now used for pagination and limiting which makes sure the limits are applied to the outer table rather than the combination of the outer and the joined. --- .../integrations/postgres/docker-compose.yml | 2 +- .../api/controllers/row/ExternalRequest.ts | 3 ++ packages/server/src/definitions/datasource.ts | 5 ++ packages/server/src/integrations/base/sql.ts | 52 +++++++++---------- packages/server/src/integrations/mysql.ts | 21 +++++++- 5 files changed, 54 insertions(+), 29 deletions(-) diff --git a/packages/server/scripts/integrations/postgres/docker-compose.yml b/packages/server/scripts/integrations/postgres/docker-compose.yml index e2bba9f38e..4dfcb0e1ad 100644 --- a/packages/server/scripts/integrations/postgres/docker-compose.yml +++ b/packages/server/scripts/integrations/postgres/docker-compose.yml @@ -15,7 +15,7 @@ services: - ./init.sql:/docker-entrypoint-initdb.d/init.sql pgadmin: - container_name: pgadmin + container_name: pgadmin-pg image: dpage/pgadmin4 restart: always environment: diff --git a/packages/server/src/api/controllers/row/ExternalRequest.ts b/packages/server/src/api/controllers/row/ExternalRequest.ts index b809e597e4..12db55efdc 100644 --- a/packages/server/src/api/controllers/row/ExternalRequest.ts +++ b/packages/server/src/api/controllers/row/ExternalRequest.ts @@ -544,6 +544,9 @@ module External { extra: { idFilter: buildFilters(id || generateIdForRow(row, table), {}, table), }, + meta: { + table, + } } // can't really use response right now const response = await makeExternalQuery(appId, json) diff --git a/packages/server/src/definitions/datasource.ts b/packages/server/src/definitions/datasource.ts index 48fd24e1cf..d7d4e77961 100644 --- a/packages/server/src/definitions/datasource.ts +++ b/packages/server/src/definitions/datasource.ts @@ -1,3 +1,5 @@ +import {Table} from "./common"; + export enum Operation { CREATE = "CREATE", READ = "READ", @@ -136,6 +138,9 @@ export interface QueryJson { sort?: SortJson paginate?: PaginationJson body?: object + meta?: { + table?: Table, + } extra?: { idFilter?: SearchFilters } diff --git a/packages/server/src/integrations/base/sql.ts b/packages/server/src/integrations/base/sql.ts index b59bac5a5a..91af3e1a85 100644 --- a/packages/server/src/integrations/base/sql.ts +++ b/packages/server/src/integrations/base/sql.ts @@ -1,7 +1,5 @@ import { Knex, knex } from "knex" const BASE_LIMIT = 5000 -// if requesting a single row then need to up the limit for the sake of joins -const SINGLE_ROW_LIMIT = 100 import { QueryJson, SearchFilters, @@ -146,46 +144,48 @@ function buildCreate( function buildRead(knex: Knex, json: QueryJson, limit: number): KnexQuery { let { endpoint, resource, filters, sort, paginate, relationships } = json const tableName = endpoint.entityId - let query: KnexQuery = knex(tableName) // select all if not specified if (!resource) { resource = { fields: [] } } + let selectStatement: string|string[] = "*" // handle select if (resource.fields && resource.fields.length > 0) { // select the resources as the format "table.columnName" - this is what is provided // by the resource builder further up - query = query.select(resource.fields.map(field => `${field} as ${field}`)) - } else { - query = query.select("*") + selectStatement = resource.fields.map(field => `${field} as ${field}`) + } + let foundLimit = limit || BASE_LIMIT + // handle pagination + let foundOffset: number | null = null + if (paginate && paginate.page && paginate.limit) { + // @ts-ignore + const page = paginate.page <= 1 ? 0 : paginate.page - 1 + const offset = page * paginate.limit + foundLimit = paginate.limit + foundOffset = offset + } else if (paginate && paginate.limit) { + foundLimit = paginate.limit + } + // start building the query + let query: KnexQuery = knex(tableName).limit(foundLimit) + if (foundOffset) { + query = query.offset(foundOffset) } - // handle where - query = addFilters(tableName, query, filters) - // handle join - query = addRelationships(query, tableName, relationships) - // handle sorting if (sort) { for (let [key, value] of Object.entries(sort)) { const direction = value === SortDirection.ASCENDING ? "asc" : "desc" query = query.orderBy(key, direction) } } - let foundLimit = limit || BASE_LIMIT - // handle pagination - if (paginate && paginate.page && paginate.limit) { + query = addFilters(tableName, query, filters) + // @ts-ignore + let preQuery: KnexQuery = knex({ // @ts-ignore - const page = paginate.page <= 1 ? 0 : paginate.page - 1 - const offset = page * paginate.limit - foundLimit = paginate.limit - query = query.offset(offset) - } else if (paginate && paginate.limit) { - foundLimit = paginate.limit - } - if (foundLimit === 1) { - foundLimit = SINGLE_ROW_LIMIT - } - query = query.limit(foundLimit) - return query + [tableName]: query, + }).select(selectStatement) + // handle joins + return addRelationships(preQuery, tableName, relationships) } function buildUpdate( diff --git a/packages/server/src/integrations/mysql.ts b/packages/server/src/integrations/mysql.ts index c5db35ed2a..11220afb46 100644 --- a/packages/server/src/integrations/mysql.ts +++ b/packages/server/src/integrations/mysql.ts @@ -104,7 +104,7 @@ module MySQLModule { client: any, query: SqlQuery, connect: boolean = true - ): Promise { + ): Promise { // Node MySQL is callback based, so we must wrap our call in a promise return new Promise((resolve, reject) => { if (connect) { @@ -238,6 +238,23 @@ module MySQLModule { return internalQuery(this.client, input, false) } + // when creating if an ID has been inserted need to make sure + // the id filter is enriched with it before trying to retrieve the row + checkLookupKeys(results: any, json: QueryJson) { + if (!results?.insertId || !json.meta?.table || !json.meta.table.primary) { + return json + } + const primaryKey = json.meta.table.primary?.[0] + json.extra = { + idFilter: { + equal: { + [primaryKey]: results.insertId + }, + } + } + return json + } + async query(json: QueryJson) { const operation = this._operation(json) this.client.connect() @@ -250,7 +267,7 @@ module MySQLModule { const results = await internalQuery(this.client, input, false) // same as delete, manage returning if (operation === Operation.CREATE || operation === Operation.UPDATE) { - row = this.getReturningRow(json) + row = this.getReturningRow(this.checkLookupKeys(results, json)) } this.client.end() if (operation !== Operation.READ) { From 5d8f348fc21be01e723fae959f9773720879dc1c Mon Sep 17 00:00:00 2001 From: mike12345567 Date: Thu, 23 Sep 2021 16:56:13 +0100 Subject: [PATCH 2/3] Fixing SQL test cases. --- packages/server/src/integrations/tests/sql.spec.js | 14 +++++++------- 1 file changed, 7 insertions(+), 7 deletions(-) diff --git a/packages/server/src/integrations/tests/sql.spec.js b/packages/server/src/integrations/tests/sql.spec.js index fa8bcd1d86..64cdda215f 100644 --- a/packages/server/src/integrations/tests/sql.spec.js +++ b/packages/server/src/integrations/tests/sql.spec.js @@ -57,7 +57,7 @@ describe("SQL query builder", () => { const query = sql._query(generateReadJson()) expect(query).toEqual({ bindings: [limit], - sql: `select * from "${TABLE_NAME}" limit $1` + sql: `select * from (select * from "${TABLE_NAME}" limit $1) as "${TABLE_NAME}"` }) }) @@ -68,7 +68,7 @@ describe("SQL query builder", () => { })) expect(query).toEqual({ bindings: [limit], - sql: `select "${TABLE_NAME}"."name" as "${nameProp}", "${TABLE_NAME}"."age" as "${ageProp}" from "${TABLE_NAME}" limit $1` + sql: `select "${TABLE_NAME}"."name" as "${nameProp}", "${TABLE_NAME}"."age" as "${ageProp}" from (select * from "${TABLE_NAME}" limit $1) as "${TABLE_NAME}"` }) }) @@ -82,7 +82,7 @@ describe("SQL query builder", () => { })) expect(query).toEqual({ bindings: ["John%", limit], - sql: `select * from "${TABLE_NAME}" where "${TABLE_NAME}"."name" ilike $1 limit $2` + sql: `select * from (select * from "${TABLE_NAME}" where "${TABLE_NAME}"."name" ilike $1 limit $2) as "${TABLE_NAME}"` }) }) @@ -99,7 +99,7 @@ describe("SQL query builder", () => { })) expect(query).toEqual({ bindings: [2, 10, limit], - sql: `select * from "${TABLE_NAME}" where "${TABLE_NAME}"."age" between $1 and $2 limit $3` + sql: `select * from (select * from "${TABLE_NAME}" where "${TABLE_NAME}"."age" between $1 and $2 limit $3) as "${TABLE_NAME}"` }) }) @@ -115,7 +115,7 @@ describe("SQL query builder", () => { })) expect(query).toEqual({ bindings: [10, "John", limit], - sql: `select * from "${TABLE_NAME}" where ("${TABLE_NAME}"."age" = $1) or ("${TABLE_NAME}"."name" = $2) limit $3` + sql: `select * from (select * from "${TABLE_NAME}" where ("${TABLE_NAME}"."age" = $1) or ("${TABLE_NAME}"."name" = $2) limit $3) as "${TABLE_NAME}"` }) }) @@ -160,7 +160,7 @@ describe("SQL query builder", () => { const query = new Sql("mssql", 10)._query(generateReadJson()) expect(query).toEqual({ bindings: [10], - sql: `select top (@p0) * from [${TABLE_NAME}]` + sql: `select * from (select top (@p0) * from [${TABLE_NAME}]) as [${TABLE_NAME}]` }) }) @@ -168,7 +168,7 @@ describe("SQL query builder", () => { const query = new Sql("mysql", 10)._query(generateReadJson()) expect(query).toEqual({ bindings: [10], - sql: `select * from \`${TABLE_NAME}\` limit ?` + sql: `select * from (select * from \`${TABLE_NAME}\` limit ?) as \`${TABLE_NAME}\`` }) }) }) From 43db0abef8475a293932bce72d374541d74930d0 Mon Sep 17 00:00:00 2001 From: mike12345567 Date: Thu, 23 Sep 2021 17:43:06 +0100 Subject: [PATCH 3/3] Fixing postgres datasource test. --- packages/server/src/api/routes/tests/datasource.spec.js | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/packages/server/src/api/routes/tests/datasource.spec.js b/packages/server/src/api/routes/tests/datasource.spec.js index 98a99717fd..b6d94f714d 100644 --- a/packages/server/src/api/routes/tests/datasource.spec.js +++ b/packages/server/src/api/routes/tests/datasource.spec.js @@ -94,7 +94,8 @@ describe("/datasources", () => { .expect(200) // this is mock data, can't test it expect(res.body).toBeDefined() - expect(pg.queryMock).toHaveBeenCalledWith(`select "users"."name" as "users.name", "users"."age" as "users.age" from "users" where "users"."name" ilike $1 limit $2`, ["John%", 5000]) + const expSql = `select "users"."name" as "users.name", "users"."age" as "users.age" from (select * from "users" where "users"."name" ilike $1 limit $2) as "users"` + expect(pg.queryMock).toHaveBeenCalledWith(expSql, ["John%", 5000]) }) })