diff --git a/api/src/api_models/index.ts b/api/src/api_models/index.ts index b83aadfaa..2ddb28443 100644 --- a/api/src/api_models/index.ts +++ b/api/src/api_models/index.ts @@ -45,7 +45,7 @@ import { ApiKeyIDRequest, } from './api'; import { Role, RolePermission, RoleCreateOrUpdateRequest, RoleIDRequest } from './role'; -import { QueryParams, QueryRequest, HttpParams } from './query'; +import { QueryParams, QueryRequest, HttpParams, QueryStructureRequest } from './query'; import { Job, JobFilterObject, JobListRequest, JobPaginationResponse, JobSortObject, JobRunRequest } from './job'; import { Config, ConfigDescription, ConfigGetRequest, ConfigUpdateRequest } from './config'; import { @@ -157,6 +157,7 @@ export default { QueryParams, QueryRequest, HttpParams, + QueryStructureRequest, Job, JobFilterObject, diff --git a/api/src/api_models/query.ts b/api/src/api_models/query.ts index a609d75a7..bf0a62f44 100644 --- a/api/src/api_models/query.ts +++ b/api/src/api_models/query.ts @@ -1,5 +1,5 @@ import { Type } from 'class-transformer'; -import { IsBoolean, IsIn, IsObject, IsOptional, IsString, ValidateNested } from 'class-validator'; +import { IsBoolean, IsIn, IsNumber, IsObject, IsOptional, IsString, ValidateNested } from 'class-validator'; import { ApiModel, ApiModelProperty, SwaggerDefinitionConstant } from 'swagger-express-ts'; import { Authentication } from './base'; @@ -155,3 +155,67 @@ export class HttpParams { }) url: string; } + +@ApiModel({ + description: 'Query Structure object', + name: 'QueryStructureRequest', +}) +export class QueryStructureRequest { + @IsIn(['TABLES', 'COLUMNS', 'DATA', 'INDEXES', 'COUNT']) + @ApiModelProperty({ + description: `type of query. + TABLES = get all tables in database + COLUMNS = get column structure of table + DATA = get data of table + INDEXES = get indexes of table + COUNT = get total number of rows in table`, + required: true, + enum: ['TABLES', 'COLUMNS', 'DATA', 'INDEXES', 'COUNT'], + }) + query_type: 'TABLES' | 'COLUMNS' | 'DATA' | 'INDEXES' | 'COUNT'; + + @IsIn(['postgresql', 'mysql']) + @ApiModelProperty({ + description: 'datasource type of query', + required: true, + enum: ['postgresql', 'mysql'], + }) + type: 'postgresql' | 'mysql'; + + @IsString() + @ApiModelProperty({ + description: 'datasource key', + required: true, + }) + key: string; + + @IsString() + @ApiModelProperty({ + description: 'table schema', + required: true, + }) + table_schema: string; + + @IsString() + @ApiModelProperty({ + description: 'table schema', + required: true, + }) + table_name: string; + + @IsNumber() + @IsOptional() + @ApiModelProperty({ + description: 'Limit of query results. Default = 20', + required: false, + }) + limit?: number; + + @IsNumber() + @IsOptional() + @ApiModelProperty({ + description: 'Offset of query results, Default = 0', + required: false, + }) + offset?: number; +} diff --git a/api/src/controller/query.controller.ts b/api/src/controller/query.controller.ts index cf27cb873..468235834 100644 --- a/api/src/controller/query.controller.ts +++ b/api/src/controller/query.controller.ts @@ -4,7 +4,7 @@ import { controller, httpPost, interfaces } from 'inversify-express-utils'; import { ApiOperationPost, ApiPath } from 'swagger-express-ts'; import { QueryService } from '../services/query.service'; import { validate } from '../middleware/validation'; -import { QueryRequest } from '../api_models/query'; +import { QueryRequest, QueryStructureRequest } from '../api_models/query'; import permission from '../middleware/permission'; import { PERMISSIONS } from '../services/role.service'; import { ApiKey } from '../api_models/api'; @@ -54,4 +54,38 @@ export class QueryController implements interfaces.Controller { next(error); } } + + @ApiOperationPost({ + path: '/structure', + description: 'query structure of selected datasource', + parameters: { + body: { description: 'Query Structure object', required: true, model: 'QueryStructureRequest' }, + }, + responses: { + 200: { description: 'Query result' }, + 500: { description: 'ApiError', model: 'ApiError' }, + }, + }) + @httpPost( + '/structure', + permission({ match: 'all', permissions: [PERMISSIONS.DASHBOARD_MANAGE] }), + validate(QueryStructureRequest), + ) + public async queryStructure(req: express.Request, res: express.Response, next: express.NextFunction): Promise { + try { + const { query_type, type, key, table_schema, table_name, limit, offset } = req.body as QueryStructureRequest; + const result = await this.queryService.queryStructure( + query_type, + type, + key, + table_schema, + table_name, + limit, + offset, + ); + res.json(result); + } catch (error) { + next(error); + } + } } diff --git a/api/src/services/query.service.ts b/api/src/services/query.service.ts index 55c6c661a..ced1f2092 100644 --- a/api/src/services/query.service.ts +++ b/api/src/services/query.service.ts @@ -70,6 +70,148 @@ export class QueryService { } } + private getDBStructureSql(): string { + return 'SELECT table_schema, table_name, table_type FROM information_schema.tables ORDER BY table_schema, table_name'; + } + + private getColumnStructureSql(type: string, table_schema: string, table_name: string): string { + if (type === 'postgresql') { + const attrelid = `'${table_schema}.${table_name}'::regclass`; + return ` + SELECT + ordinal_position, + UPPER(pc.contype) AS column_key, + pg_get_constraintdef(pc.oid) AS column_key_text, + column_name, + format_type(atttypid, atttypmod) AS column_type, + is_nullable, + column_default, + pg_catalog.col_description(${attrelid}, ordinal_position) AS column_comment + FROM + information_schema.columns + JOIN pg_attribute pa ON pa.attrelid = ${attrelid} + AND attname = column_name + LEFT JOIN pg_constraint pc ON pc.conrelid = ${attrelid} AND ordinal_position = any(pc.conkey) + WHERE + table_name = '${table_name}' AND table_schema = '${table_schema}'; + `; + } + if (type === 'mysql') { + return ` + SELECT ordinal_position, column_key, column_name, column_type, is_nullable, column_default, column_comment + FROM information_schema.columns + WHERE table_name = '${table_name}' AND table_schema = '${table_schema}' + `; + } + return ''; + } + + private getDataSql(table_schema: string, table_name: string, limit: number, offset: number): string { + return ` + SELECT * + FROM ${table_schema}.${table_name} + LIMIT ${limit} OFFSET ${offset}`; + } + + private getIndexesSql(type: string, table_schema: string, table_name: string): string { + if (type === 'postgresql') { + return ` + SELECT + ix.relname AS index_name, + upper(am.amname) AS index_algorithm, + indisunique AS is_unique, + pg_get_indexdef(indexrelid) AS index_definition, + CASE WHEN position(' WHERE ' IN pg_get_indexdef(indexrelid)) > 0 THEN + regexp_replace(pg_get_indexdef(indexrelid), '.+WHERE ', '') + WHEN position(' WITH ' IN pg_get_indexdef(indexrelid)) > 0 THEN + regexp_replace(pg_get_indexdef(indexrelid), '.+WITH ', '') + ELSE + '' + END AS condition, + pg_catalog.obj_description(i.indexrelid, 'pg_class') AS comment + FROM + pg_index i + JOIN pg_class t ON t.oid = i.indrelid + JOIN pg_class ix ON ix.oid = i.indexrelid + JOIN pg_namespace n ON t.relnamespace = n.oid + JOIN pg_am AS am ON ix.relam = am.oid + WHERE + t.relname = '${table_name}' AND n.nspname = '${table_schema}'; + `; + } + if (type === 'mysql') { + return ` + SELECT + sub_part AS index_length, + index_name AS index_name, + index_type AS index_algorithm, + CASE non_unique WHEN 0 THEN 'TRUE' ELSE 'FALSE' END AS is_unique, + column_name AS column_name + FROM + information_schema.statistics + WHERE + table_name = '${table_name}' AND table_schema = '${table_schema}' + ORDER BY + seq_in_index ASC; + `; + } + return ''; + } + + private getCountSql(table_schema: string, table_name: string): string { + return ` + SELECT count(*) AS total + FROM ${table_schema}.${table_name} + `; + } + + async queryStructure( + query_type: string, + type: string, + key: string, + table_schema: string, + table_name: string, + limit = 20, + offset = 0, + ): Promise { + let sql: string; + switch (query_type) { + case 'TABLES': + sql = this.getDBStructureSql(); + break; + case 'COLUMNS': + sql = this.getColumnStructureSql(type, table_schema, table_name); + break; + case 'DATA': + sql = this.getDataSql(table_schema, table_name, limit, offset); + break; + case 'INDEXES': + sql = this.getIndexesSql(type, table_schema, table_name); + break; + case 'COUNT': + sql = this.getCountSql(table_schema, table_name); + break; + + default: + return null; + } + + let result; + switch (type) { + case 'postgresql': + result = await this.postgresqlQuery(key, sql); + break; + + case 'mysql': + result = await this.mysqlQuery(key, sql); + break; + + default: + return null; + } + return result; + } + async query( type: string, key: string, diff --git a/api/tests/e2e/06_query.test.ts b/api/tests/e2e/06_query.test.ts index 92a701a0d..0ba66caeb 100644 --- a/api/tests/e2e/06_query.test.ts +++ b/api/tests/e2e/06_query.test.ts @@ -1,5 +1,5 @@ import { connectionHook } from './jest.util'; -import { QueryRequest } from '~/api_models/query'; +import { QueryRequest, QueryStructureRequest } from '~/api_models/query'; import { app } from '~/server'; import request from 'supertest'; import { AccountLoginRequest, AccountLoginResponse } from '~/api_models/account'; @@ -220,4 +220,195 @@ describe('QueryController', () => { expect(response.body).toMatchObject({}); }); }); + + describe('queryStructure', () => { + it('query_type = TABLES', async () => { + const query: QueryStructureRequest = { + query_type: 'TABLES', + type: 'postgresql', + key: 'preset', + table_schema: '', + table_name: '', + }; + + const response = await server + .post('/query/structure') + .set('Authorization', `Bearer ${superadminLogin.token}`) + .send(query); + + expect(response.body.length).toEqual(222); + expect(response.body[212]).toMatchObject({ + table_schema: 'public', + table_name: 'dashboard', + table_type: 'BASE TABLE', + }); + }); + + it('query_type = COLUMNS', async () => { + const query: QueryStructureRequest = { + query_type: 'COLUMNS', + type: 'postgresql', + key: 'preset', + table_schema: 'public', + table_name: 'dashboard', + }; + + const response = await server + .post('/query/structure') + .set('Authorization', `Bearer ${superadminLogin.token}`) + .send(query); + + expect(response.body).toMatchObject([ + { + ordinal_position: 1, + column_key: 'P', + column_key_text: 'PRIMARY KEY (id)', + column_name: 'id', + column_type: 'uuid', + is_nullable: 'NO', + column_default: 'gen_random_uuid()', + column_comment: null, + }, + { + ordinal_position: 2, + column_key: null, + column_key_text: null, + column_name: 'name', + column_type: 'character varying', + is_nullable: 'NO', + column_default: null, + column_comment: null, + }, + { + ordinal_position: 4, + column_key: null, + column_key_text: null, + column_name: 'create_time', + column_type: 'timestamp with time zone', + is_nullable: 'NO', + column_default: 'CURRENT_TIMESTAMP', + column_comment: null, + }, + { + ordinal_position: 5, + column_key: null, + column_key_text: null, + column_name: 'update_time', + column_type: 'timestamp with time zone', + is_nullable: 'NO', + column_default: 'CURRENT_TIMESTAMP', + column_comment: null, + }, + { + ordinal_position: 6, + column_key: null, + column_key_text: null, + column_name: 'is_removed', + column_type: 'boolean', + is_nullable: 'NO', + column_default: 'false', + column_comment: null, + }, + { + ordinal_position: 7, + column_key: null, + column_key_text: null, + column_name: 'is_preset', + column_type: 'boolean', + is_nullable: 'NO', + column_default: 'false', + column_comment: null, + }, + { + ordinal_position: 8, + column_key: null, + column_key_text: null, + column_name: 'group', + column_type: 'character varying', + is_nullable: 'NO', + column_default: "''::character varying", + column_comment: null, + }, + { + ordinal_position: 9, + column_key: 'F', + column_key_text: 'FOREIGN KEY (content_id) REFERENCES dashboard_content(id) ON DELETE SET NULL', + column_name: 'content_id', + column_type: 'uuid', + is_nullable: 'YES', + column_default: null, + column_comment: null, + }, + ]); + }); + + it('query_type = DATA', async () => { + const query: QueryStructureRequest = { + query_type: 'DATA', + type: 'postgresql', + key: 'preset', + table_schema: 'public', + table_name: 'dashboard', + }; + + const response = await server + .post('/query/structure') + .set('Authorization', `Bearer ${superadminLogin.token}`) + .send(query); + + expect(response.body.length).toEqual(4); + }); + + it('query_type = COUNT', async () => { + const query: QueryStructureRequest = { + query_type: 'COUNT', + type: 'postgresql', + key: 'preset', + table_schema: 'public', + table_name: 'dashboard', + }; + + const response = await server + .post('/query/structure') + .set('Authorization', `Bearer ${superadminLogin.token}`) + .send(query); + + expect(response.body).toMatchObject([{ total: '4' }]); + }); + + it('query_type = INDEXES', async () => { + const query: QueryStructureRequest = { + query_type: 'INDEXES', + type: 'postgresql', + key: 'preset', + table_schema: 'public', + table_name: 'dashboard', + }; + + const response = await server + .post('/query/structure') + .set('Authorization', `Bearer ${superadminLogin.token}`) + .send(query); + + expect(response.body).toMatchObject([ + { + index_name: 'dashboard_pkey', + index_algorithm: 'BTREE', + is_unique: true, + index_definition: 'CREATE UNIQUE INDEX dashboard_pkey ON public.dashboard USING btree (id)', + condition: '', + comment: null, + }, + { + index_name: 'dashboard_name_preset_idx', + index_algorithm: 'BTREE', + is_unique: true, + index_definition: + 'CREATE UNIQUE INDEX dashboard_name_preset_idx ON public.dashboard USING btree (name, is_preset) WHERE (is_removed = false)', + condition: '(is_removed = false)', + comment: null, + }, + ]); + }); + }); }); diff --git a/api/tests/integration/06_query.test.ts b/api/tests/integration/06_query.test.ts index 3b72e28b3..e4806fac3 100644 --- a/api/tests/integration/06_query.test.ts +++ b/api/tests/integration/06_query.test.ts @@ -123,4 +123,135 @@ describe('QueryService', () => { expect(results).toMatchObject({}); }); }); + + describe('queryStructure', () => { + it('TABLES', async () => { + const results = await queryService.queryStructure('TABLES', 'postgresql', 'pg', '', ''); + expect(results.length).toEqual(222); + expect(results[212]).toMatchObject({ + table_schema: 'public', + table_name: 'dashboard', + table_type: 'BASE TABLE', + }); + }); + + it('COLUMNS', async () => { + const results = await queryService.queryStructure('COLUMNS', 'postgresql', 'pg', 'public', 'dashboard'); + expect(results).toMatchObject([ + { + ordinal_position: 1, + column_key: 'P', + column_key_text: 'PRIMARY KEY (id)', + column_name: 'id', + column_type: 'uuid', + is_nullable: 'NO', + column_default: 'gen_random_uuid()', + column_comment: null, + }, + { + ordinal_position: 2, + column_key: null, + column_key_text: null, + column_name: 'name', + column_type: 'character varying', + is_nullable: 'NO', + column_default: null, + column_comment: null, + }, + { + ordinal_position: 4, + column_key: null, + column_key_text: null, + column_name: 'create_time', + column_type: 'timestamp with time zone', + is_nullable: 'NO', + column_default: 'CURRENT_TIMESTAMP', + column_comment: null, + }, + { + ordinal_position: 5, + column_key: null, + column_key_text: null, + column_name: 'update_time', + column_type: 'timestamp with time zone', + is_nullable: 'NO', + column_default: 'CURRENT_TIMESTAMP', + column_comment: null, + }, + { + ordinal_position: 6, + column_key: null, + column_key_text: null, + column_name: 'is_removed', + column_type: 'boolean', + is_nullable: 'NO', + column_default: 'false', + column_comment: null, + }, + { + ordinal_position: 7, + column_key: null, + column_key_text: null, + column_name: 'is_preset', + column_type: 'boolean', + is_nullable: 'NO', + column_default: 'false', + column_comment: null, + }, + { + ordinal_position: 8, + column_key: null, + column_key_text: null, + column_name: 'group', + column_type: 'character varying', + is_nullable: 'NO', + column_default: "''::character varying", + column_comment: null, + }, + { + ordinal_position: 9, + column_key: 'F', + column_key_text: 'FOREIGN KEY (content_id) REFERENCES dashboard_content(id) ON DELETE SET NULL', + column_name: 'content_id', + column_type: 'uuid', + is_nullable: 'YES', + column_default: null, + column_comment: null, + }, + ]); + }); + + it('DATA', async () => { + const results = await queryService.queryStructure('DATA', 'postgresql', 'pg', 'public', 'dashboard'); + expect(results.length).toEqual(3); + }); + + it('COUNT', async () => { + const results = await queryService.queryStructure('COUNT', 'postgresql', 'pg', 'public', 'dashboard'); + expect(results).toMatchObject([{ total: '3' }]); + }); + + it('INDEXES', async () => { + const results = await queryService.queryStructure('INDEXES', 'postgresql', 'pg', 'public', 'dashboard'); + expect(results).toMatchObject([ + { + index_name: 'dashboard_pkey', + index_algorithm: 'BTREE', + is_unique: true, + index_definition: 'CREATE UNIQUE INDEX dashboard_pkey ON public.dashboard USING btree (id)', + condition: '', + comment: null, + }, + { + index_name: 'dashboard_name_preset_idx', + index_algorithm: 'BTREE', + is_unique: true, + index_definition: + 'CREATE UNIQUE INDEX dashboard_name_preset_idx ON public.dashboard USING btree (name, is_preset) WHERE (is_removed = false)', + condition: '(is_removed = false)', + comment: null, + }, + ]); + }); + }); }); diff --git a/api/tests/unit/validation.test.ts b/api/tests/unit/validation.test.ts index cb952add7..5dab681a9 100644 --- a/api/tests/unit/validation.test.ts +++ b/api/tests/unit/validation.test.ts @@ -23,7 +23,7 @@ import { DataSourceUpdateRequest, } from '~/api_models/datasource'; import { JobListRequest, JobRunRequest } from '~/api_models/job'; -import { QueryRequest } from '~/api_models/query'; +import { QueryRequest, QueryStructureRequest } from '~/api_models/query'; import { ConfigGetRequest, ConfigUpdateRequest } from '~/api_models/config'; import { DashboardChangelogListRequest } from '~/api_models/dashboard_changelog'; import { @@ -1880,6 +1880,73 @@ describe('QueryRequest', () => { }); }); +describe('QueryStructureRequest', () => { + it('Should have no validation errors', () => { + const data: QueryStructureRequest = { + query_type: 'TABLES', + type: 'postgresql', + key: '', + table_schema: '', + table_name: '', + limit: 20, + offset: 0, + }; + + const result = validateClass(QueryStructureRequest, data); + expect(result).toMatchObject(data); + }); + + it('Should have validation errors', () => { + const data = {}; + expect(() => validateClass(QueryStructureRequest, data)).toThrow( + new ApiError(VALIDATION_FAILED, { message: `request body is incorrect` }), + ); + try { + validateClass(QueryStructureRequest, data); + } catch (error) { + expect(error.detail.errors).toMatchObject([ + { + target: {}, + value: undefined, + property: 'query_type', + children: [], + constraints: { + isIn: 'query_type must be one of the following values: TABLES, COLUMNS, DATA, INDEXES, COUNT', + }, + }, + { + target: {}, + value: undefined, + property: 'type', + children: [], + constraints: { isIn: 'type must be one of the following values: postgresql, mysql' }, + }, + { + target: {}, + value: undefined, + property: 'key', + children: [], + constraints: { isString: 'key must be a string' }, + }, + { + target: {}, + value: undefined, + property: 'table_schema', + children: [], + constraints: { isString: 'table_schema must be a string' }, + }, + { + target: {}, + value: undefined, + property: 'table_name', + children: [], + constraints: { isString: 'table_name must be a string' }, + }, + ]); + } + }); +}); + describe('RoleCreateOrUpdateRequest', () => { it('Should have no validation errors', () => { const data: RoleCreateOrUpdateRequest = {