From 8e51b220c59d80fe7ce58b166cf3533ca1cc6cf1 Mon Sep 17 00:00:00 2001 From: Jonathan Fishner Date: Mon, 7 Oct 2024 14:10:44 +0300 Subject: [PATCH] add view definitions (#246) * add view definitions * fix query for new sql-server version * fix build * add views for sqlite * fix for mysql view defenition --------- Co-authored-by: Guy Ben-Aharon --- .eslintrc.cjs | 2 +- package-lock.json | 65 ++++++ package.json | 3 +- .../import-metadata/scripts/maria-script.ts | 2 +- .../import-metadata/scripts/mysql-script.ts | 6 +- .../scripts/postgres-script.ts | 5 +- .../import-metadata/scripts/sqlite-script.ts | 4 +- .../scripts/sqlserver-script.ts | 159 +++++++++----- src/lib/domain/db-dependency.ts | 203 +++++++++++++++--- 9 files changed, 363 insertions(+), 86 deletions(-) diff --git a/.eslintrc.cjs b/.eslintrc.cjs index 4af14dad..233b3302 100644 --- a/.eslintrc.cjs +++ b/.eslintrc.cjs @@ -6,9 +6,9 @@ module.exports = { 'plugin:react/recommended', 'plugin:@typescript-eslint/recommended', 'plugin:react-hooks/recommended', - 'plugin:prettier/recommended', 'plugin:css-modules/recommended', 'plugin:tailwindcss/recommended', + 'plugin:prettier/recommended', // 'plugin:jsx-a11y/recommended', ], ignorePatterns: ['dist', '.eslintrc.cjs'], diff --git a/package-lock.json b/package-lock.json index 92160ce0..a9477c27 100644 --- a/package-lock.json +++ b/package-lock.json @@ -36,6 +36,7 @@ "@xyflow/react": "^12.3.1", "ahooks": "^3.8.1", "ai": "^3.3.14", + "buffer": "^6.0.3", "class-variance-authority": "^0.7.0", "clsx": "^2.1.1", "cmdk": "^1.0.0", @@ -4198,6 +4199,26 @@ "integrity": "sha512-3oSeUO0TMV67hN1AmbXsK4yaqU7tjiHlbxRDZOpH0KW9+CeX4bRAaX0Anxt0tx2MrpRpWwQaPwIlISEJhYU5Pw==", "license": "MIT" }, + "node_modules/base64-js": { + "version": "1.5.1", + "resolved": "https://registry.npmjs.org/base64-js/-/base64-js-1.5.1.tgz", + "integrity": "sha512-AKpaYlHn8t4SVbOHCy+b5+KKgvR4vrsD8vbvrbiQJps7fKDTkjkDry6ji0rUJjC0kzbNePLwzxq8iypo41qeWA==", + "funding": [ + { + "type": "github", + "url": "https://github.com/sponsors/feross" + }, + { + "type": "patreon", + "url": "https://www.patreon.com/feross" + }, + { + "type": "consulting", + "url": "https://feross.org/support" + } + ], + "license": "MIT" + }, "node_modules/big-integer": { "version": "1.6.52", "resolved": "https://registry.npmjs.org/big-integer/-/big-integer-1.6.52.tgz", @@ -4273,6 +4294,30 @@ "node": "^6 || ^7 || ^8 || ^9 || ^10 || ^11 || ^12 || >=13.7" } }, + "node_modules/buffer": { + "version": "6.0.3", + "resolved": "https://registry.npmjs.org/buffer/-/buffer-6.0.3.tgz", + "integrity": "sha512-FTiCpNxtwiZZHEZbcbTIcZjERVICn9yq/pDFkTl95/AxzD1naBctN7YO68riM/gLSDY7sdrMby8hofADYuuqOA==", + "funding": [ + { + "type": "github", + "url": "https://github.com/sponsors/feross" + }, + { + "type": "patreon", + "url": "https://www.patreon.com/feross" + }, + { + "type": "consulting", + "url": "https://feross.org/support" + } + ], + "license": "MIT", + "dependencies": { + "base64-js": "^1.3.1", + "ieee754": "^1.2.1" + } + }, "node_modules/call-bind": { "version": "1.0.7", "resolved": "https://registry.npmjs.org/call-bind/-/call-bind-1.0.7.tgz", @@ -6781,6 +6826,26 @@ "@babel/runtime": "^7.23.2" } }, + "node_modules/ieee754": { + "version": "1.2.1", + "resolved": "https://registry.npmjs.org/ieee754/-/ieee754-1.2.1.tgz", + "integrity": "sha512-dcyqhDvX1C46lXZcVqCpK+FtMRQVdIMN6/Df5js2zouUsqG7I6sFxitIC+7KYK29KdXOLHdu9zL4sFnoVQnqaA==", + "funding": [ + { + "type": "github", + "url": "https://github.com/sponsors/feross" + }, + { + "type": "patreon", + "url": "https://www.patreon.com/feross" + }, + { + "type": "consulting", + "url": "https://feross.org/support" + } + ], + "license": "BSD-3-Clause" + }, "node_modules/ignore": { "version": "5.3.2", "resolved": "https://registry.npmjs.org/ignore/-/ignore-5.3.2.tgz", diff --git a/package.json b/package.json index 18d5eb3c..4b9177af 100644 --- a/package.json +++ b/package.json @@ -37,9 +37,10 @@ "@radix-ui/react-toggle-group": "^1.1.0", "@radix-ui/react-tooltip": "^1.1.2", "@uidotdev/usehooks": "^2.4.1", - "ahooks": "^3.8.1", "@xyflow/react": "^12.3.1", + "ahooks": "^3.8.1", "ai": "^3.3.14", + "buffer": "^6.0.3", "class-variance-authority": "^0.7.0", "clsx": "^2.1.1", "cmdk": "^1.0.0", diff --git a/src/lib/data/import-metadata/scripts/maria-script.ts b/src/lib/data/import-metadata/scripts/maria-script.ts index a7805dbc..3f4c0044 100644 --- a/src/lib/data/import-metadata/scripts/maria-script.ts +++ b/src/lib/data/import-metadata/scripts/maria-script.ts @@ -122,7 +122,7 @@ export const mariaDBQuery = `WITH fk_info as ( AND table_schema = DATABASE() AND (0x00) IN (@views:=CONCAT_WS(',', @views, CONCAT('{', '"schema":"', \`TABLE_SCHEMA\`, '",', '"view_name":"', \`TABLE_NAME\`, '",', - '"definition":"', REPLACE(REPLACE(TO_BASE64(VIEW_DEFINITION), ' ', ''), '\n', ''), '"}'))) ) ) + '"view_definition":"', REPLACE(REPLACE(TO_BASE64(VIEW_DEFINITION), ' ', ''), '\n', ''), '"}'))) ) ) ) (SELECT CAST(CONCAT('{"fk_info": [',IFNULL(@fk_info,''), '], "pk_info": [', IFNULL(@pk_info, ''), diff --git a/src/lib/data/import-metadata/scripts/mysql-script.ts b/src/lib/data/import-metadata/scripts/mysql-script.ts index a7017832..45204a85 100644 --- a/src/lib/data/import-metadata/scripts/mysql-script.ts +++ b/src/lib/data/import-metadata/scripts/mysql-script.ts @@ -133,7 +133,7 @@ export const getMySQLQuery = ( AND table_schema = DATABASE() AND (0x00) IN (@views:=CONCAT_WS(',', @views, CONCAT('{', '"schema":"', \`TABLE_SCHEMA\`, '",', '"view_name":"', \`TABLE_NAME\`, '",', - '"definition":"', REPLACE(REPLACE(TO_BASE64(VIEW_DEFINITION), ' ', ''), '\n', ''), '"}'))) ) ) + '"view_definition":"', REPLACE(REPLACE(TO_BASE64(VIEW_DEFINITION), ' ', ''), '\n', ''), '"}'))) ) ) ) (SELECT CAST(CONCAT('{"fk_info": [',IFNULL(@fk_info,''), '], "pk_info": [', IFNULL(@pk_info, ''), @@ -282,11 +282,11 @@ export const getMySQLQuery = ( IFNULL((SELECT GROUP_CONCAT( CONCAT('{"schema":"', cast(vws.TABLE_SCHEMA as CHAR), '","view_name":"', vws.view_name, - '","definition":"', definition, '"}') + '","view_definition":"', view_definition, '"}') ) FROM ( SELECT \`TABLE_SCHEMA\`, \`TABLE_NAME\` AS view_name, - '' AS definition + REPLACE(REPLACE(TO_BASE64(\`VIEW_DEFINITION\`), ' ', ''), '\n', '') AS view_definition FROM information_schema.views vws WHERE vws.table_schema = DATABASE() ) AS vws), ''), diff --git a/src/lib/data/import-metadata/scripts/postgres-script.ts b/src/lib/data/import-metadata/scripts/postgres-script.ts index bdda0825..a7c8dc1f 100644 --- a/src/lib/data/import-metadata/scripts/postgres-script.ts +++ b/src/lib/data/import-metadata/scripts/postgres-script.ts @@ -226,7 +226,10 @@ cols AS ( ',') AS config_metadata FROM pg_settings conf ), views AS ( - SELECT array_to_string(array_agg(CONCAT('{"schema":"', views.schemaname, '","view_name":"', viewname, '"}')), + SELECT array_to_string(array_agg(CONCAT('{"schema":"', views.schemaname, + '","view_name":"', viewname, + '","view_definition":"', encode(convert_to(REPLACE(definition, '"', '\\"'), 'UTF8'), 'base64'), + '"}')), ',') AS views_metadata FROM pg_views views WHERE views.schemaname NOT IN ('information_schema', 'pg_catalog') ${ diff --git a/src/lib/data/import-metadata/scripts/sqlite-script.ts b/src/lib/data/import-metadata/scripts/sqlite-script.ts index a542d76e..6b53f697 100644 --- a/src/lib/data/import-metadata/scripts/sqlite-script.ts +++ b/src/lib/data/import-metadata/scripts/sqlite-script.ts @@ -118,7 +118,7 @@ export const sqliteQuery = `WITH fk_info AS ( JOIN pragma_table_info(m.name) p ON - m.type = 'table' + m.type in ('table', 'view') ), tbls AS ( SELECT json_group_array( @@ -134,7 +134,7 @@ export const sqliteQuery = `WITH fk_info AS ( FROM sqlite_master m WHERE - m.type = 'table' + m.type in ('table', 'view') ), views AS ( SELECT json_group_array( diff --git a/src/lib/data/import-metadata/scripts/sqlserver-script.ts b/src/lib/data/import-metadata/scripts/sqlserver-script.ts index f2218a8b..c9de6ec5 100644 --- a/src/lib/data/import-metadata/scripts/sqlserver-script.ts +++ b/src/lib/data/import-metadata/scripts/sqlserver-script.ts @@ -139,6 +139,7 @@ tbls AS ( ) + N']' AS all_tables_json FROM ( + -- Select from tables SELECT COALESCE(REPLACE(s.name, '"', ''), '') AS schema_name, COALESCE(REPLACE(t.name, '"', ''), '') AS table_name, @@ -155,6 +156,22 @@ tbls AS ( s.name LIKE '%' GROUP BY s.name, t.name, t.type_desc, t.create_date + + UNION ALL + + -- Select from views + SELECT + COALESCE(REPLACE(s.name, '"', ''), '') AS table_name, + COALESCE(REPLACE(v.name, '"', ''), '') AS object_name, + 0 AS row_count, -- Views don't have row counts + 'VIEW' AS table_type, + v.create_date AS creation_date + FROM + sys.views v + JOIN + sys.schemas s ON v.schema_id = s.schema_id + WHERE + s.name LIKE '%' ) AS aggregated ), views AS ( @@ -162,8 +179,17 @@ views AS ( '[' + STRING_AGG( CONVERT(nvarchar(max), JSON_QUERY( - N'{"schema": "' + COALESCE(REPLACE(s.name, '"', ''), '') COLLATE SQL_Latin1_General_CP1_CI_AS + - '", "view_name": "' + COALESCE(REPLACE(v.name, '"', ''), '') COLLATE SQL_Latin1_General_CP1_CI_AS + '"}' + N'{"schema": "' + STRING_ESCAPE(COALESCE(s.name, ''), 'json') + + '", "view_name": "' + STRING_ESCAPE(COALESCE(v.name, ''), 'json') + + '", "view_definition": "' + + STRING_ESCAPE( + CAST( + '' AS XML + ).value( + 'xs:base64Binary(sql:column("DefinitionBinary"))', + 'VARCHAR(MAX)' + ), 'json') + + '"}' ) ), ',' ) + N']' AS all_views_json @@ -171,6 +197,10 @@ views AS ( sys.views v JOIN sys.schemas s ON v.schema_id = s.schema_id + JOIN + sys.sql_modules m ON v.object_id = m.object_id + CROSS APPLY + (SELECT CONVERT(VARBINARY(MAX), m.definition) AS DefinitionBinary) AS bin WHERE s.name LIKE '%' ) @@ -329,68 +359,91 @@ indexes AS ( ), tbls AS ( SELECT - '[' + ISNULL( - STUFF(( - SELECT ',' + - CONVERT(nvarchar(max), - JSON_QUERY( - N'{"schema": "' + COALESCE(REPLACE(aggregated.schema_name, '"', ''), '') COLLATE SQL_Latin1_General_CP1_CI_AS + - '", "table": "' + COALESCE(REPLACE(aggregated.table_name, '"', ''), '') COLLATE SQL_Latin1_General_CP1_CI_AS + - '", "row_count": "' + CAST(aggregated.row_count AS NVARCHAR(MAX)) + - '", "table_type": "' + aggregated.table_type COLLATE SQL_Latin1_General_CP1_CI_AS + - '", "creation_date": "' + CONVERT(NVARCHAR(MAX), aggregated.creation_date, 120) + '"}' - ) + '[' + ISNULL( + STUFF(( + SELECT ',' + + CONVERT(nvarchar(max), + JSON_QUERY( + N'{"schema": "' + COALESCE(REPLACE(aggregated.schema_name, '"', ''), '') COLLATE SQL_Latin1_General_CP1_CI_AS + + '", "table": "' + COALESCE(REPLACE(aggregated.object_name, '"', ''), '') COLLATE SQL_Latin1_General_CP1_CI_AS + + '", "row_count": "' + CAST(aggregated.row_count AS NVARCHAR(MAX)) + + '", "object_type": "' + aggregated.object_type COLLATE SQL_Latin1_General_CP1_CI_AS + + '", "creation_date": "' + CONVERT(NVARCHAR(MAX), aggregated.creation_date, 120) + '"}' ) - FROM - ( - SELECT - COALESCE(REPLACE(s.name, '"', ''), '') AS schema_name, - COALESCE(REPLACE(t.name, '"', ''), '') AS table_name, - SUM(p.rows) AS row_count, - t.type_desc AS table_type, - t.create_date AS creation_date - FROM - sys.tables t - JOIN - sys.schemas s ON t.schema_id = s.schema_id - JOIN - sys.partitions p ON t.object_id = p.object_id AND p.index_id IN (0, 1) - WHERE - s.name LIKE '%' - GROUP BY - s.name, t.name, t.type_desc, t.create_date - ) AS aggregated - FOR XML PATH('') - ), 1, 1, ''), '') - + N']' AS all_tables_json + ) + FROM + ( + -- Select from tables + SELECT + COALESCE(REPLACE(s.name, '"', ''), '') AS schema_name, + COALESCE(REPLACE(t.name, '"', ''), '') AS object_name, + SUM(p.rows) AS row_count, + t.type_desc AS object_type, + t.create_date AS creation_date + FROM + sys.tables t + JOIN + sys.schemas s ON t.schema_id = s.schema_id + JOIN + sys.partitions p ON t.object_id = p.object_id AND p.index_id IN (0, 1) + WHERE + s.name LIKE '%' + GROUP BY + s.name, t.name, t.type_desc, t.create_date + + UNION ALL + + -- Select from views + SELECT + COALESCE(REPLACE(s.name, '"', ''), '') AS schema_name, + COALESCE(REPLACE(v.name, '"', ''), '') AS object_name, + 0 AS row_count, -- Views don't have row counts + 'VIEW' AS object_type, + v.create_date AS creation_date + FROM + sys.views v + JOIN + sys.schemas s ON v.schema_id = s.schema_id + WHERE + s.name LIKE '%' + ) AS aggregated + FOR XML PATH('') + ), 1, 1, ''), '') + + N']' AS all_objects_json ), views AS ( SELECT - '[' + ISNULL( - STUFF(( - SELECT ',' + - CONVERT(nvarchar(max), - JSON_QUERY( - N'{"schema": "' + COALESCE(REPLACE(s.name, '"', ''), '') COLLATE SQL_Latin1_General_CP1_CI_AS + - '", "view_name": "' + COALESCE(REPLACE(v.name, '"', ''), '') COLLATE SQL_Latin1_General_CP1_CI_AS + '"}' + '[' + + ( + SELECT + STUFF(( + SELECT ',' + CONVERT(nvarchar(max), + JSON_QUERY( + N'{"schema": "' + COALESCE(REPLACE(s.name, '"', ''), '') + + '", "view_name": "' + COALESCE(REPLACE(v.name, '"', ''), '') + + '", "view_definition": "' + + CAST( + ( + SELECT CAST(OBJECT_DEFINITION(v.object_id) AS VARBINARY(MAX)) FOR XML PATH('') + ) AS NVARCHAR(MAX) + ) + '"}' + ) ) - ) - FROM - sys.views v - JOIN - sys.schemas s ON v.schema_id = s.schema_id - WHERE - s.name LIKE '%' - FOR XML PATH('') - ), 1, 1, ''), '') - + N']' AS all_views_json + FROM + sys.views v + JOIN + sys.schemas s ON v.schema_id = s.schema_id + WHERE + s.name LIKE '%' + FOR XML PATH(''), TYPE).value('.', 'NVARCHAR(MAX)'), 1, 1, '') + ) + ']' AS all_views_json ) SELECT JSON_QUERY( N'{"fk_info": ' + ISNULL((SELECT cast(all_fks_json as nvarchar(max)) FROM fk_info), N'[]') + ', "pk_info": ' + ISNULL((SELECT cast(all_pks_json as nvarchar(max)) FROM pk_info), N'[]') + ', "columns": ' + ISNULL((SELECT cast(all_columns_json as nvarchar(max)) FROM cols), N'[]') + ', "indexes": ' + ISNULL((SELECT cast(all_indexes_json as nvarchar(max)) FROM indexes), N'[]') + - ', "tables": ' + ISNULL((SELECT cast(all_tables_json as nvarchar(max)) FROM tbls), N'[]') + + ', "tables": ' + ISNULL((SELECT cast(all_objects_json as nvarchar(max)) FROM tbls), N'[]') + ', "views": ' + ISNULL((SELECT cast(all_views_json as nvarchar(max)) FROM views), N'[]') + ', "database_name": "' + DB_NAME() + '"' + ', "version": ""}' diff --git a/src/lib/domain/db-dependency.ts b/src/lib/domain/db-dependency.ts index fa02e4e2..afc9ca01 100644 --- a/src/lib/domain/db-dependency.ts +++ b/src/lib/domain/db-dependency.ts @@ -1,10 +1,14 @@ -/* eslint-disable */ import type { ViewInfo } from '../data/import-metadata/metadata-types/view-info'; import { DatabaseType } from './database-type'; -import { schemaNameToSchemaId } from './db-schema'; +import { + schemaNameToDomainSchemaName, + schemaNameToSchemaId, +} from './db-schema'; import type { DBTable } from './db-table'; import { generateId } from '@/lib/utils'; +import type { AST } from 'node-sql-parser'; import { Parser } from 'node-sql-parser'; +import { Buffer } from 'buffer'; export interface DBDependency { id: string; @@ -29,10 +33,10 @@ export const shouldShowDependencyBySchemaFilter = ( const astDatabaseTypes: Record = { [DatabaseType.POSTGRESQL]: 'postgresql', - [DatabaseType.MYSQL]: 'mysql', - [DatabaseType.MARIADB]: 'mariadb', + [DatabaseType.MYSQL]: 'postgresql', + [DatabaseType.MARIADB]: 'postgresql', [DatabaseType.GENERIC]: 'postgresql', - [DatabaseType.SQLITE]: 'sqlite', + [DatabaseType.SQLITE]: 'postgresql', [DatabaseType.SQL_SERVER]: 'postgresql', }; @@ -49,33 +53,65 @@ export const createDependenciesFromMetadata = ({ const dependencies = views .flatMap((view) => { + const viewSchema = schemaNameToDomainSchemaName(view.schema); const sourceTable = tables.find( (table) => - table.name === view.view_name && - table.schema === view.schema + table.name === view.view_name && viewSchema === table.schema ); if (!sourceTable) { console.warn( - `Source table for view ${view.schema}.${view.view_name} not found` + `Source table for view ${view.view_name} not found (schema: ${viewSchema})` ); return []; // Skip this view and proceed to the next } if (view.view_definition) { try { + let decodedViewDefinition: string; - // Pre-process the view_definition - const modifiedViewDefinition = preprocessViewDefinition( - view.view_definition - ); + // For other database types, decode the base64-encoded view definition + if (databaseType === DatabaseType.SQL_SERVER) { + decodedViewDefinition = Buffer.from( + view.view_definition, + 'base64' + ).toString('utf16le'); + } else { + decodedViewDefinition = Buffer.from( + view.view_definition, + 'base64' + ).toString('utf-8'); + } - // Parse using PostgreSQL dialect + let modifiedViewDefinition = ''; + if ( + databaseType === DatabaseType.MYSQL || + databaseType === DatabaseType.MARIADB + ) { + modifiedViewDefinition = preprocessViewDefinitionMySQL( + decodedViewDefinition + ); + } else if (databaseType === DatabaseType.SQL_SERVER) { + modifiedViewDefinition = + preprocessViewDefinitionSQLServer( + decodedViewDefinition + ); + } else { + modifiedViewDefinition = preprocessViewDefinition( + decodedViewDefinition + ); + } + + // Parse using the appropriate dialect const ast = parser.astify(modifiedViewDefinition, { database: astDatabaseTypes[databaseType], + type: 'select', // Parsing a SELECT statement }); - const dependentTables = extractTablesFromAST(ast, view.schema); + const dependentTables = extractTablesFromAST( + ast, + viewSchema + ); return dependentTables.map((depTable) => { const depSchema = depTable.schema ?? view.schema; // Use view's schema if depSchema is undefined @@ -84,7 +120,7 @@ export const createDependenciesFromMetadata = ({ const targetTable = tables.find( (table) => table.name === depTableName && - table.schema === depSchema + (table.schema || '') === depSchema ); if (targetTable) { @@ -129,12 +165,22 @@ function preprocessViewDefinition(viewDefinition: string): string { return ''; } + // Remove leading and trailing whitespace + viewDefinition = viewDefinition.replace(/\s+/g, ' ').trim(); + + // Replace escaped double quotes with regular ones + viewDefinition = viewDefinition.replace(/\\"/g, '"'); + // Replace 'CREATE MATERIALIZED VIEW' with 'CREATE VIEW' - viewDefinition = viewDefinition.replace(/CREATE\s+MATERIALIZED\s+VIEW/i, 'CREATE VIEW'); + viewDefinition = viewDefinition.replace( + /CREATE\s+MATERIALIZED\s+VIEW/i, + 'CREATE VIEW' + ); // Regular expression to match 'CREATE VIEW [schema.]view_name [ (column definitions) ] AS' // This regex captures the view name and skips any content between the view name and 'AS' - const regex = /CREATE\s+VIEW\s+(?:(?:`[^`]+`|"[^"]+"|\w+)\.)?(?:`([^`]+)`|"([^"]+)"|(\w+))[\s\S]*?\bAS\b\s+/i; + const regex = + /CREATE\s+VIEW\s+(?:(?:`[^`]+`|"[^"]+"|\w+)\.)?(?:`([^`]+)`|"([^"]+)"|(\w+))[\s\S]*?\bAS\b\s+/i; const match = viewDefinition.match(regex); let modifiedDefinition: string; @@ -142,13 +188,18 @@ function preprocessViewDefinition(viewDefinition: string): string { if (match) { const viewName = match[1] || match[2] || match[3]; // Extract the SQL after the 'AS' keyword - const restOfDefinition = viewDefinition.substring(match.index! + match[0].length); + const restOfDefinition = viewDefinition.substring( + match.index! + match[0].length + ); // Replace double-quoted identifiers with unquoted ones let modifiedSQL = restOfDefinition.replace(/"(\w+)"/g, '$1'); // Replace '::' type casts with 'CAST' expressions - modifiedSQL = modifiedSQL.replace(/\(([^()]+)\)::(\w+)/g, 'CAST($1 AS $2)'); + modifiedSQL = modifiedSQL.replace( + /\(([^()]+)\)::(\w+)/g, + 'CAST($1 AS $2)' + ); // Remove ClickHouse-specific syntax that may still be present // For example, remove SETTINGS clauses inside the SELECT statement @@ -163,13 +214,114 @@ function preprocessViewDefinition(viewDefinition: string): string { return modifiedDefinition; } +// Preprocess the view_definition for SQL Server +function preprocessViewDefinitionSQLServer(viewDefinition: string): string { + if (!viewDefinition) { + return ''; + } + + // Remove BOM if present + viewDefinition = viewDefinition.replace(/^\uFEFF/, ''); + + // Normalize whitespace + viewDefinition = viewDefinition.replace(/\s+/g, ' ').trim(); + + // Remove square brackets and replace with double quotes + viewDefinition = viewDefinition.replace(/\[([^\]]+)\]/g, '"$1"'); + + // Remove database names from fully qualified identifiers + viewDefinition = viewDefinition.replace( + /"([a-zA-Z0-9_]+)"\."([a-zA-Z0-9_]+)"\."([a-zA-Z0-9_]+)"/g, + '"$2"."$3"' + ); + + // Replace SQL Server functions with PostgreSQL equivalents + viewDefinition = viewDefinition.replace(/\bGETDATE\(\)/gi, 'NOW()'); + viewDefinition = viewDefinition.replace(/\bISNULL\(/gi, 'COALESCE('); + + // Replace 'TOP N' with 'LIMIT N' at the end of the query + const topMatch = viewDefinition.match(/SELECT\s+TOP\s+(\d+)/i); + if (topMatch) { + const topN = topMatch[1]; + viewDefinition = viewDefinition.replace( + /SELECT\s+TOP\s+\d+/i, + 'SELECT' + ); + viewDefinition = viewDefinition.replace(/;+\s*$/, ''); // Remove semicolons at the end + viewDefinition += ` LIMIT ${topN}`; + } + + viewDefinition = viewDefinition.replace(/\n/g, ''); // Remove newlines + + // Adjust CREATE VIEW syntax + const regex = + /CREATE\s+VIEW\s+(?:"?([^".\s]+)"?\.)?"?([^".\s]+)"?\s+AS\s+/i; + const match = viewDefinition.match(regex); + let modifiedDefinition: string; + + if (match) { + const viewName = match[2]; + const modifiedSQL = viewDefinition.substring( + match.index! + match[0].length + ); + + // Remove semicolons at the end + const finalSQL = modifiedSQL.replace(/;+\s*$/, ''); + + modifiedDefinition = `CREATE VIEW "${viewName}" AS ${finalSQL}`; + } else { + console.warn('Could not preprocess view definition:', viewDefinition); + modifiedDefinition = viewDefinition; + } + + return modifiedDefinition; +} + +// Preprocess the view_definition to remove schema from CREATE VIEW +function preprocessViewDefinitionMySQL(viewDefinition: string): string { + if (!viewDefinition) { + return ''; + } + + // Remove any trailing semicolons + viewDefinition = viewDefinition.replace(/;\s*$/, ''); + + // Remove backticks from identifiers + viewDefinition = viewDefinition.replace(/`/g, ''); + + // Remove unnecessary parentheses around joins and ON clauses + viewDefinition = removeRedundantParentheses(viewDefinition); + + return viewDefinition; +} + +function removeRedundantParentheses(sql: string): string { + // Regular expressions to match unnecessary parentheses + const patterns = [ + /\(\s*(JOIN\s+[^()]+?)\s*\)/gi, + /\(\s*(ON\s+[^()]+?)\s*\)/gi, + // Additional patterns if necessary + ]; + + let prevSql; + do { + prevSql = sql; + patterns.forEach((pattern) => { + sql = sql.replace(pattern, '$1'); + }); + } while (sql !== prevSql); + + return sql; +} + function extractTablesFromAST( - ast: any, - defaultSchema: string + ast: AST | AST[], + defaultSchema?: string ): { schema?: string; tableName: string }[] { const tablesMap = new Map(); const visitedNodes = new Set(); + // eslint-disable-next-line @typescript-eslint/no-explicit-any function traverse(node: any) { if (!node || visitedNodes.has(node)) return; visitedNodes.add(node); @@ -179,14 +331,17 @@ function extractTablesFromAST( } else if (typeof node === 'object') { // Check if node represents a table if ( - node.hasOwnProperty('table') && + Object.hasOwnProperty.call(node, 'table') && typeof node.table === 'string' ) { let schema = node.db || node.schema; const tableName = node.table; if (tableName) { // Assign default schema if undefined - schema = schema || defaultSchema; + schema = + schemaNameToDomainSchemaName(schema) || + defaultSchema || + ''; const key = `${schema}.${tableName}`; if (!tablesMap.has(key)) { tablesMap.set(key, { schema, tableName }); @@ -196,7 +351,7 @@ function extractTablesFromAST( // Recursively traverse all properties for (const key in node) { - if (node.hasOwnProperty(key)) { + if (Object.hasOwnProperty.call(node, key)) { traverse(node[key]); } }