mirror of
https://github.com/chartdb/chartdb.git
synced 2025-11-09 08:25:57 +00:00
fix(import-mssql): fix import/export scripts to handle data correctly (#598)
* fix(import-mssql): fix import/export scripts to handle data correctly * fix --------- Co-authored-by: Guy Ben-Aharon <baguy3@gmail.com>
This commit is contained in:
82
src/lib/data/export-metadata/export-per-type/common.ts
Normal file
82
src/lib/data/export-metadata/export-per-type/common.ts
Normal file
@@ -0,0 +1,82 @@
|
|||||||
|
import type { Diagram } from '@/lib/domain/diagram';
|
||||||
|
import type { DBTable } from '@/lib/domain/db-table';
|
||||||
|
|
||||||
|
export function isFunction(value: string): boolean {
|
||||||
|
// Common SQL functions
|
||||||
|
const functionPatterns = [
|
||||||
|
/^CURRENT_TIMESTAMP$/i,
|
||||||
|
/^NOW\(\)$/i,
|
||||||
|
/^GETDATE\(\)$/i,
|
||||||
|
/^CURRENT_DATE$/i,
|
||||||
|
/^CURRENT_TIME$/i,
|
||||||
|
/^UUID\(\)$/i,
|
||||||
|
/^NEWID\(\)$/i,
|
||||||
|
/^NEXT VALUE FOR/i,
|
||||||
|
/^IDENTITY\s*\(\d+,\s*\d+\)$/i,
|
||||||
|
];
|
||||||
|
return functionPatterns.some((pattern) => pattern.test(value.trim()));
|
||||||
|
}
|
||||||
|
|
||||||
|
export function isKeyword(value: string): boolean {
|
||||||
|
// Common SQL keywords that can be used as default values
|
||||||
|
const keywords = [
|
||||||
|
'NULL',
|
||||||
|
'TRUE',
|
||||||
|
'FALSE',
|
||||||
|
'CURRENT_TIMESTAMP',
|
||||||
|
'CURRENT_DATE',
|
||||||
|
'CURRENT_TIME',
|
||||||
|
'CURRENT_USER',
|
||||||
|
'SESSION_USER',
|
||||||
|
'SYSTEM_USER',
|
||||||
|
];
|
||||||
|
return keywords.includes(value.trim().toUpperCase());
|
||||||
|
}
|
||||||
|
|
||||||
|
export function strHasQuotes(value: string): boolean {
|
||||||
|
return /^['"].*['"]$/.test(value.trim());
|
||||||
|
}
|
||||||
|
|
||||||
|
export function exportFieldComment(comment: string): string {
|
||||||
|
if (!comment) {
|
||||||
|
return '';
|
||||||
|
}
|
||||||
|
|
||||||
|
return comment
|
||||||
|
.split('\n')
|
||||||
|
.map((commentLine) => ` -- ${commentLine}\n`)
|
||||||
|
.join('');
|
||||||
|
}
|
||||||
|
|
||||||
|
export function getInlineFK(table: DBTable, diagram: Diagram): string {
|
||||||
|
if (!diagram.relationships) {
|
||||||
|
return '';
|
||||||
|
}
|
||||||
|
|
||||||
|
const fks = diagram.relationships
|
||||||
|
.filter((r) => r.sourceTableId === table.id)
|
||||||
|
.map((r) => {
|
||||||
|
const targetTable = diagram.tables?.find(
|
||||||
|
(t) => t.id === r.targetTableId
|
||||||
|
);
|
||||||
|
const sourceField = table.fields.find(
|
||||||
|
(f) => f.id === r.sourceFieldId
|
||||||
|
);
|
||||||
|
const targetField = targetTable?.fields.find(
|
||||||
|
(f) => f.id === r.targetFieldId
|
||||||
|
);
|
||||||
|
|
||||||
|
if (!targetTable || !sourceField || !targetField) {
|
||||||
|
return '';
|
||||||
|
}
|
||||||
|
|
||||||
|
const targetTableName = targetTable.schema
|
||||||
|
? `"${targetTable.schema}"."${targetTable.name}"`
|
||||||
|
: `"${targetTable.name}"`;
|
||||||
|
|
||||||
|
return ` FOREIGN KEY ("${sourceField.name}") REFERENCES ${targetTableName}("${targetField.name}")`;
|
||||||
|
})
|
||||||
|
.filter(Boolean);
|
||||||
|
|
||||||
|
return fks.join(',\n');
|
||||||
|
}
|
||||||
247
src/lib/data/export-metadata/export-per-type/mssql.ts
Normal file
247
src/lib/data/export-metadata/export-per-type/mssql.ts
Normal file
@@ -0,0 +1,247 @@
|
|||||||
|
import {
|
||||||
|
exportFieldComment,
|
||||||
|
isFunction,
|
||||||
|
isKeyword,
|
||||||
|
strHasQuotes,
|
||||||
|
} from './common';
|
||||||
|
import type { Diagram } from '@/lib/domain/diagram';
|
||||||
|
import type { DBTable } from '@/lib/domain/db-table';
|
||||||
|
import type { DBField } from '@/lib/domain/db-field';
|
||||||
|
import type { DBRelationship } from '@/lib/domain/db-relationship';
|
||||||
|
|
||||||
|
function parseMSSQLDefault(field: DBField): string {
|
||||||
|
if (!field.default) {
|
||||||
|
return '';
|
||||||
|
}
|
||||||
|
|
||||||
|
let defaultValue = field.default.trim();
|
||||||
|
|
||||||
|
// Remove type casting for SQL Server
|
||||||
|
defaultValue = defaultValue.split('::')[0];
|
||||||
|
|
||||||
|
// Handle nextval sequences for SQL Server
|
||||||
|
if (defaultValue.includes('nextval')) {
|
||||||
|
return 'IDENTITY(1,1)';
|
||||||
|
}
|
||||||
|
|
||||||
|
// Special handling for SQL Server DEFAULT values
|
||||||
|
if (defaultValue.match(/^\(\(.*\)\)$/)) {
|
||||||
|
// Handle ((0)), ((0.00)) style defaults
|
||||||
|
return defaultValue.replace(/^\(\(|\)\)$/g, '');
|
||||||
|
} else if (defaultValue.match(/^\(N'.*'\)$/)) {
|
||||||
|
// Handle (N'value') style defaults
|
||||||
|
const innerValue = defaultValue.replace(/^\(N'|'\)$/g, '');
|
||||||
|
return `N'${innerValue}'`;
|
||||||
|
} else if (defaultValue.match(/^\(NULL\)$/i)) {
|
||||||
|
// Handle (NULL) defaults
|
||||||
|
return 'NULL';
|
||||||
|
} else if (defaultValue.match(/^\(getdate\(\)\)$/i)) {
|
||||||
|
// Handle (getdate()) defaults
|
||||||
|
return 'getdate()';
|
||||||
|
} else if (defaultValue.match(/^\('?\*'?\)$/i) || defaultValue === '*') {
|
||||||
|
// Handle ('*') or (*) or * defaults - common for "all" values
|
||||||
|
return "N'*'";
|
||||||
|
} else if (defaultValue.match(/^\((['"])(.*)\1\)$/)) {
|
||||||
|
// Handle ('value') or ("value") style defaults
|
||||||
|
const matches = defaultValue.match(/^\((['"])(.*)\1\)$/);
|
||||||
|
return matches ? `N'${matches[2]}'` : defaultValue;
|
||||||
|
}
|
||||||
|
|
||||||
|
// Handle special characters that could be interpreted as operators
|
||||||
|
const sqlServerSpecialChars = /[*+\-/%&|^!=<>~]/;
|
||||||
|
if (sqlServerSpecialChars.test(defaultValue)) {
|
||||||
|
// If the value contains special characters and isn't already properly quoted
|
||||||
|
if (
|
||||||
|
!strHasQuotes(defaultValue) &&
|
||||||
|
!isFunction(defaultValue) &&
|
||||||
|
!isKeyword(defaultValue)
|
||||||
|
) {
|
||||||
|
return `N'${defaultValue.replace(/'/g, "''")}'`;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
if (
|
||||||
|
strHasQuotes(defaultValue) ||
|
||||||
|
isFunction(defaultValue) ||
|
||||||
|
isKeyword(defaultValue) ||
|
||||||
|
/^-?\d+(\.\d+)?$/.test(defaultValue)
|
||||||
|
) {
|
||||||
|
return defaultValue;
|
||||||
|
}
|
||||||
|
|
||||||
|
return `'${defaultValue}'`;
|
||||||
|
}
|
||||||
|
|
||||||
|
export function exportMSSQL(diagram: Diagram): string {
|
||||||
|
if (!diagram.tables || !diagram.relationships) {
|
||||||
|
return '';
|
||||||
|
}
|
||||||
|
|
||||||
|
const tables = diagram.tables;
|
||||||
|
const relationships = diagram.relationships;
|
||||||
|
|
||||||
|
// Create CREATE SCHEMA statements for all schemas
|
||||||
|
let sqlScript = '';
|
||||||
|
const schemas = new Set<string>();
|
||||||
|
|
||||||
|
tables.forEach((table) => {
|
||||||
|
if (table.schema) {
|
||||||
|
schemas.add(table.schema);
|
||||||
|
}
|
||||||
|
});
|
||||||
|
|
||||||
|
// Add schema creation statements
|
||||||
|
schemas.forEach((schema) => {
|
||||||
|
sqlScript += `IF NOT EXISTS (SELECT * FROM sys.schemas WHERE name = '${schema}')\nBEGIN\n EXEC('CREATE SCHEMA [${schema}]');\nEND;\n\n`;
|
||||||
|
});
|
||||||
|
|
||||||
|
// Generate table creation SQL
|
||||||
|
sqlScript += tables
|
||||||
|
.map((table: DBTable) => {
|
||||||
|
// Skip views
|
||||||
|
if (table.isView) {
|
||||||
|
return '';
|
||||||
|
}
|
||||||
|
|
||||||
|
const tableName = table.schema
|
||||||
|
? `[${table.schema}].[${table.name}]`
|
||||||
|
: `[${table.name}]`;
|
||||||
|
|
||||||
|
return `${
|
||||||
|
table.comments ? `/**\n${table.comments}\n*/\n` : ''
|
||||||
|
}CREATE TABLE ${tableName} (\n${table.fields
|
||||||
|
.map((field: DBField) => {
|
||||||
|
const fieldName = `[${field.name}]`;
|
||||||
|
const typeName = field.type.name;
|
||||||
|
|
||||||
|
// Handle SQL Server specific type formatting
|
||||||
|
let typeWithSize = typeName;
|
||||||
|
if (field.characterMaximumLength) {
|
||||||
|
if (
|
||||||
|
typeName.toLowerCase() === 'varchar' ||
|
||||||
|
typeName.toLowerCase() === 'nvarchar' ||
|
||||||
|
typeName.toLowerCase() === 'char' ||
|
||||||
|
typeName.toLowerCase() === 'nchar'
|
||||||
|
) {
|
||||||
|
typeWithSize = `${typeName}(${field.characterMaximumLength})`;
|
||||||
|
}
|
||||||
|
} else if (field.precision && field.scale) {
|
||||||
|
if (
|
||||||
|
typeName.toLowerCase() === 'decimal' ||
|
||||||
|
typeName.toLowerCase() === 'numeric'
|
||||||
|
) {
|
||||||
|
typeWithSize = `${typeName}(${field.precision}, ${field.scale})`;
|
||||||
|
}
|
||||||
|
} else if (field.precision) {
|
||||||
|
if (
|
||||||
|
typeName.toLowerCase() === 'decimal' ||
|
||||||
|
typeName.toLowerCase() === 'numeric'
|
||||||
|
) {
|
||||||
|
typeWithSize = `${typeName}(${field.precision})`;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
const notNull = field.nullable ? '' : ' NOT NULL';
|
||||||
|
|
||||||
|
// Check if identity column
|
||||||
|
const identity = field.default
|
||||||
|
?.toLowerCase()
|
||||||
|
.includes('identity')
|
||||||
|
? ' IDENTITY(1,1)'
|
||||||
|
: '';
|
||||||
|
|
||||||
|
const unique =
|
||||||
|
!field.primaryKey && field.unique ? ' UNIQUE' : '';
|
||||||
|
|
||||||
|
// Handle default value using SQL Server specific parser
|
||||||
|
const defaultValue =
|
||||||
|
field.default &&
|
||||||
|
!field.default.toLowerCase().includes('identity')
|
||||||
|
? ` DEFAULT ${parseMSSQLDefault(field)}`
|
||||||
|
: '';
|
||||||
|
|
||||||
|
// Do not add PRIMARY KEY as a column constraint - will add as table constraint
|
||||||
|
return `${exportFieldComment(field.comments ?? '')} ${fieldName} ${typeWithSize}${notNull}${identity}${unique}${defaultValue}`;
|
||||||
|
})
|
||||||
|
.join(',\n')}${
|
||||||
|
table.fields.filter((f) => f.primaryKey).length > 0
|
||||||
|
? `,\n PRIMARY KEY (${table.fields
|
||||||
|
.filter((f) => f.primaryKey)
|
||||||
|
.map((f) => `[${f.name}]`)
|
||||||
|
.join(', ')})`
|
||||||
|
: ''
|
||||||
|
}\n);\n\n${table.indexes
|
||||||
|
.map((index) => {
|
||||||
|
const indexName = table.schema
|
||||||
|
? `[${table.schema}_${index.name}]`
|
||||||
|
: `[${index.name}]`;
|
||||||
|
const indexFields = index.fieldIds
|
||||||
|
.map((fieldId) => {
|
||||||
|
const field = table.fields.find(
|
||||||
|
(f) => f.id === fieldId
|
||||||
|
);
|
||||||
|
return field ? `[${field.name}]` : '';
|
||||||
|
})
|
||||||
|
.filter(Boolean);
|
||||||
|
|
||||||
|
// SQL Server has a limit of 32 columns in an index
|
||||||
|
if (indexFields.length > 32) {
|
||||||
|
const warningComment = `/* WARNING: This index originally had ${indexFields.length} columns. It has been truncated to 32 columns due to SQL Server's index column limit. */\n`;
|
||||||
|
console.warn(
|
||||||
|
`Warning: Index ${indexName} on table ${tableName} has ${indexFields.length} columns. SQL Server limits indexes to 32 columns. The index will be truncated.`
|
||||||
|
);
|
||||||
|
indexFields.length = 32;
|
||||||
|
return indexFields.length > 0
|
||||||
|
? `${warningComment}CREATE ${index.unique ? 'UNIQUE ' : ''}INDEX ${indexName}\nON ${tableName} (${indexFields.join(', ')});\n\n`
|
||||||
|
: '';
|
||||||
|
}
|
||||||
|
|
||||||
|
return indexFields.length > 0
|
||||||
|
? `CREATE ${index.unique ? 'UNIQUE ' : ''}INDEX ${indexName}\nON ${tableName} (${indexFields.join(', ')});\n\n`
|
||||||
|
: '';
|
||||||
|
})
|
||||||
|
.join('')}`;
|
||||||
|
})
|
||||||
|
.filter(Boolean) // Remove empty strings (views)
|
||||||
|
.join('\n');
|
||||||
|
|
||||||
|
// Generate foreign keys
|
||||||
|
sqlScript += `\n${relationships
|
||||||
|
.map((r: DBRelationship) => {
|
||||||
|
const sourceTable = tables.find((t) => t.id === r.sourceTableId);
|
||||||
|
const targetTable = tables.find((t) => t.id === r.targetTableId);
|
||||||
|
|
||||||
|
if (
|
||||||
|
!sourceTable ||
|
||||||
|
!targetTable ||
|
||||||
|
sourceTable.isView ||
|
||||||
|
targetTable.isView
|
||||||
|
) {
|
||||||
|
return '';
|
||||||
|
}
|
||||||
|
|
||||||
|
const sourceField = sourceTable.fields.find(
|
||||||
|
(f) => f.id === r.sourceFieldId
|
||||||
|
);
|
||||||
|
const targetField = targetTable.fields.find(
|
||||||
|
(f) => f.id === r.targetFieldId
|
||||||
|
);
|
||||||
|
|
||||||
|
if (!sourceField || !targetField) {
|
||||||
|
return '';
|
||||||
|
}
|
||||||
|
|
||||||
|
const sourceTableName = sourceTable.schema
|
||||||
|
? `[${sourceTable.schema}].[${sourceTable.name}]`
|
||||||
|
: `[${sourceTable.name}]`;
|
||||||
|
const targetTableName = targetTable.schema
|
||||||
|
? `[${targetTable.schema}].[${targetTable.name}]`
|
||||||
|
: `[${targetTable.name}]`;
|
||||||
|
|
||||||
|
return `ALTER TABLE ${sourceTableName}\nADD CONSTRAINT [${r.name}] FOREIGN KEY([${sourceField.name}]) REFERENCES ${targetTableName}([${targetField.name}]);\n`;
|
||||||
|
})
|
||||||
|
.filter(Boolean) // Remove empty strings
|
||||||
|
.join('\n')}`;
|
||||||
|
|
||||||
|
return sqlScript;
|
||||||
|
}
|
||||||
@@ -1,9 +1,10 @@
|
|||||||
import type { Diagram } from '../../domain/diagram';
|
import type { Diagram } from '../../domain/diagram';
|
||||||
import { OPENAI_API_KEY, OPENAI_API_ENDPOINT, LLM_MODEL_NAME } from '@/lib/env';
|
import { OPENAI_API_KEY, OPENAI_API_ENDPOINT, LLM_MODEL_NAME } from '@/lib/env';
|
||||||
import type { DatabaseType } from '@/lib/domain/database-type';
|
import { DatabaseType } from '@/lib/domain/database-type';
|
||||||
import type { DBTable } from '@/lib/domain/db-table';
|
import type { DBTable } from '@/lib/domain/db-table';
|
||||||
import type { DataType } from '../data-types/data-types';
|
import type { DataType } from '../data-types/data-types';
|
||||||
import { generateCacheKey, getFromCache, setInCache } from './export-sql-cache';
|
import { generateCacheKey, getFromCache, setInCache } from './export-sql-cache';
|
||||||
|
import { exportMSSQL } from './export-per-type/mssql';
|
||||||
|
|
||||||
export const exportBaseSQL = (diagram: Diagram): string => {
|
export const exportBaseSQL = (diagram: Diagram): string => {
|
||||||
const { tables, relationships } = diagram;
|
const { tables, relationships } = diagram;
|
||||||
@@ -12,6 +13,10 @@ export const exportBaseSQL = (diagram: Diagram): string => {
|
|||||||
return '';
|
return '';
|
||||||
}
|
}
|
||||||
|
|
||||||
|
if (diagram.databaseType === DatabaseType.SQL_SERVER) {
|
||||||
|
return exportMSSQL(diagram);
|
||||||
|
}
|
||||||
|
|
||||||
// Filter out the tables that are views
|
// Filter out the tables that are views
|
||||||
const nonViewTables = tables.filter((table) => !table.isView);
|
const nonViewTables = tables.filter((table) => !table.isView);
|
||||||
|
|
||||||
@@ -226,6 +231,13 @@ export const exportSQL = async (
|
|||||||
}
|
}
|
||||||
): Promise<string> => {
|
): Promise<string> => {
|
||||||
const sqlScript = exportBaseSQL(diagram);
|
const sqlScript = exportBaseSQL(diagram);
|
||||||
|
if (
|
||||||
|
databaseType === DatabaseType.SQL_SERVER &&
|
||||||
|
diagram.databaseType === DatabaseType.SQL_SERVER
|
||||||
|
) {
|
||||||
|
return sqlScript;
|
||||||
|
}
|
||||||
|
|
||||||
const cacheKey = await generateCacheKey(databaseType, sqlScript);
|
const cacheKey = await generateCacheKey(databaseType, sqlScript);
|
||||||
|
|
||||||
const cachedResult = getFromCache(cacheKey);
|
const cachedResult = getFromCache(cacheKey);
|
||||||
|
|||||||
@@ -117,7 +117,7 @@ indexes AS (
|
|||||||
JOIN sys.schemas s ON t.schema_id = s.schema_id
|
JOIN sys.schemas s ON t.schema_id = s.schema_id
|
||||||
JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
|
JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
|
||||||
JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
|
JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
|
||||||
WHERE s.name LIKE '%' AND i.name IS NOT NULL
|
WHERE s.name LIKE '%' AND i.name IS NOT NULL AND ic.is_included_column = 0
|
||||||
),
|
),
|
||||||
tbls AS (
|
tbls AS (
|
||||||
SELECT
|
SELECT
|
||||||
@@ -324,6 +324,7 @@ indexes AS (
|
|||||||
JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
|
JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
|
||||||
WHERE s.name LIKE '%'
|
WHERE s.name LIKE '%'
|
||||||
AND i.name IS NOT NULL
|
AND i.name IS NOT NULL
|
||||||
|
AND ic.is_included_column = 0
|
||||||
FOR XML PATH('')
|
FOR XML PATH('')
|
||||||
), 1, 1, ''), '')
|
), 1, 1, ''), '')
|
||||||
+ N']' AS all_indexes_json
|
+ N']' AS all_indexes_json
|
||||||
|
|||||||
Reference in New Issue
Block a user