mirror of
https://github.com/chartdb/chartdb.git
synced 2026-02-10 21:49:56 -06:00
fix: improve SQL default value parsing for PostgreSQL, MySQL, and SQL Server with proper type handling and casting support (#900)
This commit is contained in:
@@ -86,7 +86,7 @@ export interface SQLBinaryExpr extends SQLASTNode {
|
||||
|
||||
export interface SQLFunctionNode extends SQLASTNode {
|
||||
type: 'function';
|
||||
name: string;
|
||||
name: string | { name: Array<{ value: string }> };
|
||||
args?: {
|
||||
value: SQLASTArg[];
|
||||
};
|
||||
@@ -108,6 +108,31 @@ export interface SQLStringLiteral extends SQLASTNode {
|
||||
value: string;
|
||||
}
|
||||
|
||||
export interface SQLDefaultNode extends SQLASTNode {
|
||||
type: 'default';
|
||||
value: SQLASTNode;
|
||||
}
|
||||
|
||||
export interface SQLCastNode extends SQLASTNode {
|
||||
type: 'cast';
|
||||
expr: SQLASTNode;
|
||||
target: Array<{ dataType: string }>;
|
||||
}
|
||||
|
||||
export interface SQLBooleanNode extends SQLASTNode {
|
||||
type: 'bool';
|
||||
value: boolean;
|
||||
}
|
||||
|
||||
export interface SQLNullNode extends SQLASTNode {
|
||||
type: 'null';
|
||||
}
|
||||
|
||||
export interface SQLNumberNode extends SQLASTNode {
|
||||
type: 'number';
|
||||
value: number;
|
||||
}
|
||||
|
||||
export type SQLASTArg =
|
||||
| SQLColumnRef
|
||||
| SQLStringLiteral
|
||||
@@ -146,6 +171,22 @@ export function buildSQLFromAST(
|
||||
): string {
|
||||
if (!ast) return '';
|
||||
|
||||
// Handle default value wrapper
|
||||
if (ast.type === 'default' && 'value' in ast) {
|
||||
const defaultNode = ast as SQLDefaultNode;
|
||||
return buildSQLFromAST(defaultNode.value, dbType);
|
||||
}
|
||||
|
||||
// Handle PostgreSQL cast expressions (e.g., 'value'::type)
|
||||
if (ast.type === 'cast' && 'expr' in ast && 'target' in ast) {
|
||||
const castNode = ast as SQLCastNode;
|
||||
const expr = buildSQLFromAST(castNode.expr, dbType);
|
||||
if (castNode.target.length > 0 && castNode.target[0].dataType) {
|
||||
return `${expr}::${castNode.target[0].dataType.toLowerCase()}`;
|
||||
}
|
||||
return expr;
|
||||
}
|
||||
|
||||
if (ast.type === 'binary_expr') {
|
||||
const expr = ast as SQLBinaryExpr;
|
||||
const leftSQL = buildSQLFromAST(expr.left, dbType);
|
||||
@@ -155,7 +196,59 @@ export function buildSQLFromAST(
|
||||
|
||||
if (ast.type === 'function') {
|
||||
const func = ast as SQLFunctionNode;
|
||||
let expr = func.name;
|
||||
let funcName = '';
|
||||
|
||||
// Handle nested function name structure
|
||||
if (typeof func.name === 'object' && func.name && 'name' in func.name) {
|
||||
const nameObj = func.name as { name: Array<{ value: string }> };
|
||||
if (nameObj.name.length > 0) {
|
||||
funcName = nameObj.name[0].value || '';
|
||||
}
|
||||
} else if (typeof func.name === 'string') {
|
||||
funcName = func.name;
|
||||
}
|
||||
|
||||
if (!funcName) return '';
|
||||
|
||||
// Normalize PostgreSQL function names to uppercase for consistency
|
||||
if (dbType === DatabaseType.POSTGRESQL) {
|
||||
const pgFunctions = [
|
||||
'now',
|
||||
'current_timestamp',
|
||||
'current_date',
|
||||
'current_time',
|
||||
'gen_random_uuid',
|
||||
'random',
|
||||
'nextval',
|
||||
'currval',
|
||||
];
|
||||
if (pgFunctions.includes(funcName.toLowerCase())) {
|
||||
funcName = funcName.toUpperCase();
|
||||
}
|
||||
}
|
||||
|
||||
// Some PostgreSQL functions don't have parentheses (like CURRENT_TIMESTAMP)
|
||||
if (funcName === 'CURRENT_TIMESTAMP' && !func.args) {
|
||||
return funcName;
|
||||
}
|
||||
|
||||
// Handle SQL Server function defaults that were preprocessed as strings
|
||||
// The preprocessor converts NEWID() to 'newid', GETDATE() to 'getdate', etc.
|
||||
if (dbType === DatabaseType.SQL_SERVER) {
|
||||
const sqlServerFunctions: Record<string, string> = {
|
||||
newid: 'NEWID()',
|
||||
newsequentialid: 'NEWSEQUENTIALID()',
|
||||
getdate: 'GETDATE()',
|
||||
sysdatetime: 'SYSDATETIME()',
|
||||
};
|
||||
|
||||
const lowerFuncName = funcName.toLowerCase();
|
||||
if (sqlServerFunctions[lowerFuncName]) {
|
||||
return sqlServerFunctions[lowerFuncName];
|
||||
}
|
||||
}
|
||||
|
||||
let expr = funcName;
|
||||
if (func.args) {
|
||||
expr +=
|
||||
'(' +
|
||||
@@ -175,12 +268,31 @@ export function buildSQLFromAST(
|
||||
})
|
||||
.join(', ') +
|
||||
')';
|
||||
} else {
|
||||
expr += '()';
|
||||
}
|
||||
return expr;
|
||||
} else if (ast.type === 'column_ref') {
|
||||
return quoteIdentifier((ast as SQLColumnRef).column, dbType);
|
||||
} else if (ast.type === 'expr_list') {
|
||||
return (ast as SQLExprList).value.map((v) => v.value).join(' AND ');
|
||||
} else if (ast.type === 'single_quote_string') {
|
||||
// String literal with single quotes
|
||||
const strNode = ast as SQLStringLiteral;
|
||||
return `'${strNode.value}'`;
|
||||
} else if (ast.type === 'double_quote_string') {
|
||||
// String literal with double quotes
|
||||
const strNode = ast as SQLStringLiteral;
|
||||
return `"${strNode.value}"`;
|
||||
} else if (ast.type === 'bool') {
|
||||
// Boolean value
|
||||
const boolNode = ast as SQLBooleanNode;
|
||||
return boolNode.value ? 'TRUE' : 'FALSE';
|
||||
} else if (ast.type === 'null') {
|
||||
return 'NULL';
|
||||
} else if (ast.type === 'number') {
|
||||
const numNode = ast as SQLNumberNode;
|
||||
return String(numNode.value);
|
||||
} else {
|
||||
const valueNode = ast as { type: string; value: string | number };
|
||||
return typeof valueNode.value === 'string'
|
||||
|
||||
@@ -0,0 +1,228 @@
|
||||
import { describe, it, expect } from 'vitest';
|
||||
import { fromMySQL } from '../mysql';
|
||||
|
||||
describe('MySQL Default Value Import', () => {
|
||||
describe('String Default Values', () => {
|
||||
it('should parse simple string defaults with single quotes', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE tavern_patrons (
|
||||
patron_id INT NOT NULL,
|
||||
membership_status VARCHAR(50) DEFAULT 'regular',
|
||||
PRIMARY KEY (patron_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromMySQL(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const statusColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'membership_status'
|
||||
);
|
||||
expect(statusColumn?.default).toBe("'regular'");
|
||||
});
|
||||
|
||||
it('should parse string defaults with escaped quotes', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE wizard_spellbooks (
|
||||
spellbook_id INT NOT NULL,
|
||||
incantation VARCHAR(255) DEFAULT 'Dragon\\'s flame',
|
||||
spell_metadata TEXT DEFAULT '{"type": "fire"}',
|
||||
PRIMARY KEY (spellbook_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromMySQL(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const incantationColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'incantation'
|
||||
);
|
||||
expect(incantationColumn?.default).toBeTruthy();
|
||||
const metadataColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'spell_metadata'
|
||||
);
|
||||
expect(metadataColumn?.default).toBeTruthy();
|
||||
});
|
||||
});
|
||||
|
||||
describe('Numeric Default Values', () => {
|
||||
it('should parse integer defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE dungeon_levels (
|
||||
level_id INT NOT NULL,
|
||||
monster_count INT DEFAULT 0,
|
||||
max_treasure INT DEFAULT 1000,
|
||||
PRIMARY KEY (level_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromMySQL(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const monsterColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'monster_count'
|
||||
);
|
||||
expect(monsterColumn?.default).toBe('0');
|
||||
const treasureColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'max_treasure'
|
||||
);
|
||||
expect(treasureColumn?.default).toBe('1000');
|
||||
});
|
||||
|
||||
it('should parse decimal defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE merchant_inventory (
|
||||
item_id INT NOT NULL,
|
||||
base_price DECIMAL(10, 2) DEFAULT 99.99,
|
||||
loyalty_discount FLOAT DEFAULT 0.15,
|
||||
PRIMARY KEY (item_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromMySQL(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const priceColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'base_price'
|
||||
);
|
||||
expect(priceColumn?.default).toBe('99.99');
|
||||
const discountColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'loyalty_discount'
|
||||
);
|
||||
expect(discountColumn?.default).toBe('0.15');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Boolean Default Values', () => {
|
||||
it('should parse boolean defaults in MySQL (using TINYINT)', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE character_status (
|
||||
character_id INT NOT NULL,
|
||||
is_alive TINYINT(1) DEFAULT 1,
|
||||
is_cursed TINYINT(1) DEFAULT 0,
|
||||
has_magic BOOLEAN DEFAULT TRUE,
|
||||
PRIMARY KEY (character_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromMySQL(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const aliveColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_alive'
|
||||
);
|
||||
expect(aliveColumn?.default).toBe('1');
|
||||
const cursedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_cursed'
|
||||
);
|
||||
expect(cursedColumn?.default).toBe('0');
|
||||
});
|
||||
});
|
||||
|
||||
describe('NULL Default Values', () => {
|
||||
it('should parse NULL defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE companion_animals (
|
||||
companion_id INT NOT NULL,
|
||||
special_trait VARCHAR(255) DEFAULT NULL,
|
||||
PRIMARY KEY (companion_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromMySQL(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const traitColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'special_trait'
|
||||
);
|
||||
expect(traitColumn?.default).toBe('NULL');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Function Default Values', () => {
|
||||
it('should parse function defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE quest_entries (
|
||||
entry_id INT NOT NULL AUTO_INCREMENT,
|
||||
quest_accepted TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
last_updated TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
quest_uuid VARCHAR(36) DEFAULT (UUID()),
|
||||
PRIMARY KEY (entry_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromMySQL(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const acceptedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'quest_accepted'
|
||||
);
|
||||
expect(acceptedColumn?.default).toBe('CURRENT_TIMESTAMP');
|
||||
const updatedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'last_updated'
|
||||
);
|
||||
expect(updatedColumn?.default).toBe('CURRENT_TIMESTAMP');
|
||||
});
|
||||
});
|
||||
|
||||
describe('AUTO_INCREMENT', () => {
|
||||
it('should handle AUTO_INCREMENT columns correctly', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE hero_registry (
|
||||
hero_id INT NOT NULL AUTO_INCREMENT,
|
||||
hero_name VARCHAR(100),
|
||||
PRIMARY KEY (hero_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromMySQL(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const idColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'hero_id'
|
||||
);
|
||||
expect(idColumn?.increment).toBe(true);
|
||||
// AUTO_INCREMENT columns typically don't have a default value
|
||||
expect(idColumn?.default).toBeUndefined();
|
||||
});
|
||||
});
|
||||
|
||||
describe('Complex Real-World Example', () => {
|
||||
it('should handle complex table with multiple default types', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE adventurer_profiles (
|
||||
adventurer_id BIGINT NOT NULL AUTO_INCREMENT,
|
||||
character_name VARCHAR(50) NOT NULL,
|
||||
guild_email VARCHAR(255) NOT NULL,
|
||||
rank VARCHAR(20) DEFAULT 'novice',
|
||||
is_guild_verified TINYINT(1) DEFAULT 0,
|
||||
gold_coins INT DEFAULT 100,
|
||||
account_balance DECIMAL(10, 2) DEFAULT 0.00,
|
||||
joined_realm TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
last_quest TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
inventory_data JSON DEFAULT NULL,
|
||||
PRIMARY KEY (adventurer_id),
|
||||
UNIQUE KEY uk_guild_email (guild_email),
|
||||
INDEX idx_rank (rank)
|
||||
);
|
||||
`;
|
||||
|
||||
const result = await fromMySQL(sql);
|
||||
const table = result.tables[0];
|
||||
expect(table).toBeDefined();
|
||||
|
||||
// Check various default values
|
||||
const rankColumn = table.columns.find((c) => c.name === 'rank');
|
||||
expect(rankColumn?.default).toBe("'novice'");
|
||||
|
||||
const verifiedColumn = table.columns.find(
|
||||
(c) => c.name === 'is_guild_verified'
|
||||
);
|
||||
expect(verifiedColumn?.default).toBe('0');
|
||||
|
||||
const goldColumn = table.columns.find(
|
||||
(c) => c.name === 'gold_coins'
|
||||
);
|
||||
expect(goldColumn?.default).toBe('100');
|
||||
|
||||
const balanceColumn = table.columns.find(
|
||||
(c) => c.name === 'account_balance'
|
||||
);
|
||||
expect(balanceColumn?.default).toBe('0.00');
|
||||
|
||||
const joinedColumn = table.columns.find(
|
||||
(c) => c.name === 'joined_realm'
|
||||
);
|
||||
expect(joinedColumn?.default).toBe('CURRENT_TIMESTAMP');
|
||||
|
||||
const inventoryColumn = table.columns.find(
|
||||
(c) => c.name === 'inventory_data'
|
||||
);
|
||||
expect(inventoryColumn?.default).toBe('NULL');
|
||||
});
|
||||
});
|
||||
});
|
||||
@@ -101,12 +101,28 @@ function extractColumnsFromCreateTable(statement: string): SQLColumn[] {
|
||||
const typeMatch = definition.match(/^([^\s(]+)(?:\(([^)]+)\))?/);
|
||||
const dataType = typeMatch ? typeMatch[1] : '';
|
||||
|
||||
// Extract default value
|
||||
let defaultValue: string | undefined;
|
||||
const defaultMatch = definition.match(
|
||||
/DEFAULT\s+('[^']*'|"[^"]*"|NULL|CURRENT_TIMESTAMP|\S+)/i
|
||||
);
|
||||
if (defaultMatch) {
|
||||
defaultValue = defaultMatch[1];
|
||||
}
|
||||
|
||||
// Check for AUTO_INCREMENT
|
||||
const increment = definition
|
||||
.toUpperCase()
|
||||
.includes('AUTO_INCREMENT');
|
||||
|
||||
columns.push({
|
||||
name: columnName,
|
||||
type: dataType,
|
||||
nullable,
|
||||
primaryKey,
|
||||
unique: definition.toUpperCase().includes('UNIQUE'),
|
||||
default: defaultValue,
|
||||
increment,
|
||||
});
|
||||
}
|
||||
}
|
||||
@@ -721,7 +737,28 @@ export async function fromMySQL(sqlContent: string): Promise<SQLParserResult> {
|
||||
parseError
|
||||
);
|
||||
|
||||
// Error handling without logging
|
||||
// Try fallback parser when main parser fails
|
||||
const tableMatch = trimmedStmt.match(
|
||||
/CREATE\s+TABLE\s+(?:IF\s+NOT\s+EXISTS\s+)?`?([^`\s(]+)`?\s*\(/i
|
||||
);
|
||||
if (tableMatch) {
|
||||
const tableName = tableMatch[1];
|
||||
const tableId = generateId();
|
||||
tableMap[tableName] = tableId;
|
||||
|
||||
const extractedColumns =
|
||||
extractColumnsFromCreateTable(trimmedStmt);
|
||||
if (extractedColumns.length > 0) {
|
||||
tables.push({
|
||||
id: tableId,
|
||||
name: tableName,
|
||||
schema: undefined,
|
||||
columns: extractedColumns,
|
||||
indexes: [],
|
||||
order: tables.length,
|
||||
});
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
@@ -130,7 +130,7 @@ describe('PostgreSQL ALTER TABLE ADD COLUMN Tests', () => {
|
||||
(col) => col.name === 'price'
|
||||
);
|
||||
expect(priceColumn).toBeDefined();
|
||||
expect(priceColumn?.default).toBe('has default');
|
||||
expect(priceColumn?.default).toBe('0');
|
||||
});
|
||||
|
||||
it('should not add duplicate columns', async () => {
|
||||
|
||||
@@ -0,0 +1,395 @@
|
||||
import { describe, it, expect } from 'vitest';
|
||||
import { fromPostgres } from '../postgresql';
|
||||
|
||||
describe('PostgreSQL Default Value Import', () => {
|
||||
describe('String Default Values', () => {
|
||||
it('should parse simple string defaults with single quotes', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE heroes (
|
||||
hero_id INTEGER NOT NULL,
|
||||
hero_status CHARACTER VARYING DEFAULT 'questing',
|
||||
PRIMARY KEY (hero_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const statusColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'hero_status'
|
||||
);
|
||||
expect(statusColumn?.default).toBe("'questing'");
|
||||
});
|
||||
|
||||
it('should parse string defaults with special characters that need escaping', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE spell_scrolls (
|
||||
scroll_id INTEGER NOT NULL,
|
||||
incantation CHARACTER VARYING DEFAULT 'Dragon''s breath',
|
||||
rune_inscription TEXT DEFAULT 'Ancient rune
|
||||
Sacred symbol',
|
||||
PRIMARY KEY (scroll_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const incantationColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'incantation'
|
||||
);
|
||||
expect(incantationColumn?.default).toBe("'Dragon''s breath'");
|
||||
});
|
||||
|
||||
it('should parse elvish text default values', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE elven_greetings (
|
||||
greeting_id INTEGER NOT NULL,
|
||||
elvish_welcome CHARACTER VARYING DEFAULT 'Mae govannen',
|
||||
PRIMARY KEY (greeting_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const greetingColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'elvish_welcome'
|
||||
);
|
||||
expect(greetingColumn?.default).toBe("'Mae govannen'");
|
||||
});
|
||||
});
|
||||
|
||||
describe('Numeric Default Values', () => {
|
||||
it('should parse integer defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE dragon_hoards (
|
||||
hoard_id INTEGER NOT NULL,
|
||||
gold_pieces INTEGER DEFAULT 0,
|
||||
max_treasure_value INTEGER DEFAULT 10000,
|
||||
PRIMARY KEY (hoard_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const goldColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'gold_pieces'
|
||||
);
|
||||
expect(goldColumn?.default).toBe('0');
|
||||
const treasureColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'max_treasure_value'
|
||||
);
|
||||
expect(treasureColumn?.default).toBe('10000');
|
||||
});
|
||||
|
||||
it('should parse decimal defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE enchanted_items (
|
||||
item_id INTEGER NOT NULL,
|
||||
market_price DECIMAL(10, 2) DEFAULT 99.99,
|
||||
magic_power_rating NUMERIC DEFAULT 0.85,
|
||||
PRIMARY KEY (item_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const priceColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'market_price'
|
||||
);
|
||||
expect(priceColumn?.default).toBe('99.99');
|
||||
const powerColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'magic_power_rating'
|
||||
);
|
||||
expect(powerColumn?.default).toBe('0.85');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Boolean Default Values', () => {
|
||||
it('should parse boolean defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE magical_artifacts (
|
||||
artifact_id INTEGER NOT NULL,
|
||||
is_cursed BOOLEAN DEFAULT TRUE,
|
||||
is_destroyed BOOLEAN DEFAULT FALSE,
|
||||
is_legendary BOOLEAN DEFAULT '1',
|
||||
is_identified BOOLEAN DEFAULT '0',
|
||||
PRIMARY KEY (artifact_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const cursedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_cursed'
|
||||
);
|
||||
expect(cursedColumn?.default).toBe('TRUE');
|
||||
const destroyedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_destroyed'
|
||||
);
|
||||
expect(destroyedColumn?.default).toBe('FALSE');
|
||||
const legendaryColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_legendary'
|
||||
);
|
||||
expect(legendaryColumn?.default).toBe("'1'");
|
||||
const identifiedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_identified'
|
||||
);
|
||||
expect(identifiedColumn?.default).toBe("'0'");
|
||||
});
|
||||
});
|
||||
|
||||
describe('NULL Default Values', () => {
|
||||
it('should parse NULL defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE wizard_familiars (
|
||||
familiar_id INTEGER NOT NULL,
|
||||
special_ability CHARACTER VARYING DEFAULT NULL,
|
||||
PRIMARY KEY (familiar_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const abilityColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'special_ability'
|
||||
);
|
||||
expect(abilityColumn?.default).toBe('NULL');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Function Default Values', () => {
|
||||
it('should parse function defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE quest_logs (
|
||||
quest_id UUID DEFAULT gen_random_uuid(),
|
||||
quest_started TIMESTAMP DEFAULT NOW(),
|
||||
last_updated TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
difficulty_roll INTEGER DEFAULT random()
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const questIdColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'quest_id'
|
||||
);
|
||||
expect(questIdColumn?.default).toBe('GEN_RANDOM_UUID()');
|
||||
const startedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'quest_started'
|
||||
);
|
||||
expect(startedColumn?.default).toBe('NOW()');
|
||||
const updatedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'last_updated'
|
||||
);
|
||||
expect(updatedColumn?.default).toBe('CURRENT_TIMESTAMP');
|
||||
const difficultyColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'difficulty_roll'
|
||||
);
|
||||
expect(difficultyColumn?.default).toBe('RANDOM()');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Complex Real-World Example', () => {
|
||||
it('should handle a complex guild management table correctly', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE "realm"(
|
||||
"realm_id" integer NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE "guild"(
|
||||
"guild_id" CHARACTER VARYING NOT NULL UNIQUE,
|
||||
PRIMARY KEY ("guild_id")
|
||||
);
|
||||
|
||||
CREATE TABLE "guild_schedule"(
|
||||
"schedule_id" CHARACTER VARYING NOT NULL UNIQUE,
|
||||
PRIMARY KEY ("schedule_id")
|
||||
);
|
||||
|
||||
CREATE TABLE "guild_quests"(
|
||||
"is_active" CHARACTER VARYING NOT NULL DEFAULT 'active',
|
||||
"quest_description" CHARACTER VARYING,
|
||||
"quest_type" CHARACTER VARYING,
|
||||
"quest_status" CHARACTER VARYING DEFAULT 'pending',
|
||||
"quest_id" CHARACTER VARYING NOT NULL UNIQUE,
|
||||
"reward_gold" CHARACTER VARYING,
|
||||
"quest_giver" CHARACTER VARYING,
|
||||
"party_size" CHARACTER VARYING,
|
||||
"difficulty_level" CHARACTER VARYING,
|
||||
"monster_type" CHARACTER VARYING,
|
||||
"dungeon_location" CHARACTER VARYING,
|
||||
"main_guild_ref" CHARACTER VARYING NOT NULL,
|
||||
"schedule_ref" CHARACTER VARYING,
|
||||
"last_attempt" CHARACTER VARYING,
|
||||
"max_attempts" INTEGER,
|
||||
"failed_attempts" INTEGER,
|
||||
"party_members" INTEGER,
|
||||
"loot_distributor" CHARACTER VARYING,
|
||||
"quest_validator" CHARACTER VARYING,
|
||||
"scout_report" CHARACTER VARYING,
|
||||
"completion_xp" INTEGER,
|
||||
"bonus_xp" INTEGER,
|
||||
"map_coordinates" CHARACTER VARYING,
|
||||
"quest_correlation" CHARACTER VARYING,
|
||||
"is_completed" BOOLEAN NOT NULL DEFAULT '0',
|
||||
"reward_items" CHARACTER VARYING,
|
||||
"quest_priority" INTEGER,
|
||||
"started_at" CHARACTER VARYING,
|
||||
"status" CHARACTER VARYING,
|
||||
"completed_at" CHARACTER VARYING,
|
||||
"party_level" INTEGER,
|
||||
"quest_master" CHARACTER VARYING,
|
||||
PRIMARY KEY ("quest_id"),
|
||||
FOREIGN KEY ("main_guild_ref") REFERENCES "guild"("guild_id"),
|
||||
FOREIGN KEY ("schedule_ref") REFERENCES "guild_schedule"("schedule_id")
|
||||
);
|
||||
`;
|
||||
|
||||
const result = await fromPostgres(sql);
|
||||
|
||||
// Find the guild_quests table
|
||||
const questTable = result.tables.find(
|
||||
(t) => t.name === 'guild_quests'
|
||||
);
|
||||
expect(questTable).toBeDefined();
|
||||
|
||||
// Check specific default values
|
||||
const activeColumn = questTable?.columns.find(
|
||||
(c) => c.name === 'is_active'
|
||||
);
|
||||
expect(activeColumn?.default).toBe("'active'");
|
||||
|
||||
const statusColumn = questTable?.columns.find(
|
||||
(c) => c.name === 'quest_status'
|
||||
);
|
||||
expect(statusColumn?.default).toBe("'pending'");
|
||||
|
||||
const completedColumn = questTable?.columns.find(
|
||||
(c) => c.name === 'is_completed'
|
||||
);
|
||||
expect(completedColumn?.default).toBe("'0'");
|
||||
});
|
||||
});
|
||||
|
||||
describe('ALTER TABLE ADD COLUMN with defaults', () => {
|
||||
it('should handle ALTER TABLE ADD COLUMN with default values', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE adventurers (
|
||||
adventurer_id INTEGER NOT NULL,
|
||||
PRIMARY KEY (adventurer_id)
|
||||
);
|
||||
|
||||
ALTER TABLE adventurers ADD COLUMN class_type VARCHAR(50) DEFAULT 'warrior';
|
||||
ALTER TABLE adventurers ADD COLUMN experience_points INTEGER DEFAULT 0;
|
||||
ALTER TABLE adventurers ADD COLUMN is_guild_member BOOLEAN DEFAULT TRUE;
|
||||
ALTER TABLE adventurers ADD COLUMN joined_at TIMESTAMP DEFAULT NOW();
|
||||
`;
|
||||
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
|
||||
const classColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'class_type'
|
||||
);
|
||||
expect(classColumn?.default).toBe("'warrior'");
|
||||
|
||||
const xpColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'experience_points'
|
||||
);
|
||||
expect(xpColumn?.default).toBe('0');
|
||||
|
||||
const guildColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_guild_member'
|
||||
);
|
||||
expect(guildColumn?.default).toBe('TRUE');
|
||||
|
||||
const joinedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'joined_at'
|
||||
);
|
||||
expect(joinedColumn?.default).toBe('NOW()');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Edge Cases and Special Characters', () => {
|
||||
it('should handle defaults with parentheses in strings', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE spell_formulas (
|
||||
formula_id INTEGER NOT NULL,
|
||||
damage_calculation VARCHAR DEFAULT '(strength + magic) * 2',
|
||||
mana_cost TEXT DEFAULT 'cast(level * 10 - wisdom)',
|
||||
PRIMARY KEY (formula_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const damageColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'damage_calculation'
|
||||
);
|
||||
expect(damageColumn?.default).toBe("'(strength + magic) * 2'");
|
||||
const manaColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'mana_cost'
|
||||
);
|
||||
expect(manaColumn?.default).toBe("'cast(level * 10 - wisdom)'");
|
||||
});
|
||||
|
||||
it('should handle defaults with JSON strings', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE item_enchantments (
|
||||
enchantment_id INTEGER NOT NULL,
|
||||
properties JSON DEFAULT '{"element": "fire"}',
|
||||
modifiers JSONB DEFAULT '[]',
|
||||
PRIMARY KEY (enchantment_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const propertiesColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'properties'
|
||||
);
|
||||
expect(propertiesColumn?.default).toBe(`'{"element": "fire"}'`);
|
||||
const modifiersColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'modifiers'
|
||||
);
|
||||
expect(modifiersColumn?.default).toBe("'[]'");
|
||||
});
|
||||
|
||||
it('should handle casting in defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE ancient_runes (
|
||||
rune_id INTEGER NOT NULL,
|
||||
rune_type VARCHAR DEFAULT 'healing'::text,
|
||||
PRIMARY KEY (rune_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const runeColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'rune_type'
|
||||
);
|
||||
expect(runeColumn?.default).toBe("'healing'::text");
|
||||
});
|
||||
});
|
||||
|
||||
describe('Serial Types', () => {
|
||||
it('should not set default for SERIAL types as they auto-increment', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE monster_spawns (
|
||||
spawn_id SERIAL PRIMARY KEY,
|
||||
minion_id SMALLSERIAL,
|
||||
boss_id BIGSERIAL
|
||||
);
|
||||
`;
|
||||
const result = await fromPostgres(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
|
||||
const spawnColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'spawn_id'
|
||||
);
|
||||
expect(spawnColumn?.default).toBeUndefined();
|
||||
expect(spawnColumn?.increment).toBe(true);
|
||||
|
||||
const minionColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'minion_id'
|
||||
);
|
||||
expect(minionColumn?.default).toBeUndefined();
|
||||
expect(minionColumn?.increment).toBe(true);
|
||||
|
||||
const bossColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'boss_id'
|
||||
);
|
||||
expect(bossColumn?.default).toBeUndefined();
|
||||
expect(bossColumn?.increment).toBe(true);
|
||||
});
|
||||
});
|
||||
});
|
||||
@@ -7,6 +7,8 @@ import type {
|
||||
SQLForeignKey,
|
||||
SQLEnumType,
|
||||
} from '../../common';
|
||||
import { buildSQLFromAST } from '../../common';
|
||||
import { DatabaseType } from '@/lib/domain/database-type';
|
||||
import type {
|
||||
TableReference,
|
||||
ColumnReference,
|
||||
@@ -347,13 +349,20 @@ function extractColumnsFromSQL(sql: string): SQLColumn[] {
|
||||
|
||||
// Try to extract column definition
|
||||
// Match: column_name TYPE[(params)][array]
|
||||
// Updated regex to handle complex types like GEOGRAPHY(POINT, 4326) and custom types like subscription_status
|
||||
const columnMatch = trimmedLine.match(
|
||||
/^\s*["']?(\w+)["']?\s+([\w_]+(?:\([^)]+\))?(?:\[\])?)/i
|
||||
);
|
||||
// First extract column name and everything after it
|
||||
const columnMatch = trimmedLine.match(/^\s*["']?(\w+)["']?\s+(.+)/i);
|
||||
if (columnMatch) {
|
||||
const columnName = columnMatch[1];
|
||||
let columnType = columnMatch[2];
|
||||
const restOfLine = columnMatch[2];
|
||||
|
||||
// Now extract the type from the rest of the line
|
||||
// Match type which could be multi-word (like CHARACTER VARYING) with optional params
|
||||
const typeMatch = restOfLine.match(
|
||||
/^((?:CHARACTER\s+VARYING|DOUBLE\s+PRECISION|[\w]+)(?:\([^)]+\))?(?:\[\])?)/i
|
||||
);
|
||||
|
||||
if (!typeMatch) continue;
|
||||
let columnType = typeMatch[1].trim();
|
||||
|
||||
// Normalize PostGIS types
|
||||
if (columnType.toUpperCase().startsWith('GEOGRAPHY')) {
|
||||
@@ -380,7 +389,65 @@ function extractColumnsFromSQL(sql: string): SQLColumn[] {
|
||||
const isPrimary = trimmedLine.match(/PRIMARY\s+KEY/i) !== null;
|
||||
const isNotNull = trimmedLine.match(/NOT\s+NULL/i) !== null;
|
||||
const isUnique = trimmedLine.match(/\bUNIQUE\b/i) !== null;
|
||||
const hasDefault = trimmedLine.match(/DEFAULT\s+/i) !== null;
|
||||
|
||||
// Extract default value
|
||||
let defaultValue: string | undefined;
|
||||
// Updated regex to handle casting with :: operator
|
||||
const defaultMatch = trimmedLine.match(
|
||||
/DEFAULT\s+((?:'[^']*'|"[^"]*"|\S+)(?:::\w+)?)/i
|
||||
);
|
||||
if (defaultMatch) {
|
||||
let defVal = defaultMatch[1].trim();
|
||||
// Remove trailing comma if present
|
||||
defVal = defVal.replace(/,$/, '').trim();
|
||||
// Handle string literals
|
||||
if (defVal.startsWith("'") && defVal.endsWith("'")) {
|
||||
// Keep the quotes for string literals
|
||||
defaultValue = defVal;
|
||||
} else if (defVal.match(/^\d+(\.\d+)?$/)) {
|
||||
// Numeric value
|
||||
defaultValue = defVal;
|
||||
} else if (
|
||||
defVal.toUpperCase() === 'TRUE' ||
|
||||
defVal.toUpperCase() === 'FALSE'
|
||||
) {
|
||||
// Boolean value
|
||||
defaultValue = defVal.toUpperCase();
|
||||
} else if (defVal.toUpperCase() === 'NULL') {
|
||||
// NULL value
|
||||
defaultValue = 'NULL';
|
||||
} else if (defVal.includes('(') && defVal.includes(')')) {
|
||||
// Function call (like gen_random_uuid())
|
||||
// Normalize PostgreSQL function names to uppercase
|
||||
const funcMatch = defVal.match(/^(\w+)\(/);
|
||||
if (funcMatch) {
|
||||
const funcName = funcMatch[1];
|
||||
const pgFunctions = [
|
||||
'now',
|
||||
'current_timestamp',
|
||||
'current_date',
|
||||
'current_time',
|
||||
'gen_random_uuid',
|
||||
'random',
|
||||
'nextval',
|
||||
'currval',
|
||||
];
|
||||
if (pgFunctions.includes(funcName.toLowerCase())) {
|
||||
defaultValue = defVal.replace(
|
||||
funcName,
|
||||
funcName.toUpperCase()
|
||||
);
|
||||
} else {
|
||||
defaultValue = defVal;
|
||||
}
|
||||
} else {
|
||||
defaultValue = defVal;
|
||||
}
|
||||
} else {
|
||||
// Other expressions
|
||||
defaultValue = defVal;
|
||||
}
|
||||
}
|
||||
|
||||
columns.push({
|
||||
name: columnName,
|
||||
@@ -388,7 +455,7 @@ function extractColumnsFromSQL(sql: string): SQLColumn[] {
|
||||
nullable: !isNotNull && !isPrimary,
|
||||
primaryKey: isPrimary,
|
||||
unique: isUnique || isPrimary,
|
||||
default: hasDefault ? 'has default' : undefined,
|
||||
default: defaultValue,
|
||||
increment:
|
||||
isSerialType ||
|
||||
trimmedLine.includes('gen_random_uuid()') ||
|
||||
@@ -1266,8 +1333,17 @@ export async function fromPostgres(
|
||||
definition?.unique === 'unique';
|
||||
|
||||
// Check for default value
|
||||
const hasDefault =
|
||||
let defaultValue: string | undefined;
|
||||
const defaultVal =
|
||||
expr.default_val || definition?.default_val;
|
||||
if (defaultVal && !isSerialType) {
|
||||
// Create a temporary columnDef to use the getDefaultValueString function
|
||||
const tempColumnDef = {
|
||||
default_val: defaultVal,
|
||||
} as ColumnDefinition;
|
||||
defaultValue =
|
||||
getDefaultValueString(tempColumnDef);
|
||||
}
|
||||
|
||||
// Create the new column object
|
||||
const newColumn: SQLColumn = {
|
||||
@@ -1279,11 +1355,7 @@ export async function fromPostgres(
|
||||
definition?.constraint === 'primary key' ||
|
||||
isSerialType,
|
||||
unique: isUnique,
|
||||
default: isSerialType
|
||||
? undefined
|
||||
: hasDefault
|
||||
? 'has default'
|
||||
: undefined,
|
||||
default: defaultValue,
|
||||
increment:
|
||||
isSerialType ||
|
||||
definition?.auto_increment ===
|
||||
@@ -1648,8 +1720,74 @@ export async function fromPostgres(
|
||||
columnDefPart.match(/NOT\s+NULL/i) !== null;
|
||||
const isUnique =
|
||||
columnDefPart.match(/\bUNIQUE\b/i) !== null;
|
||||
const hasDefault =
|
||||
columnDefPart.match(/DEFAULT\s+/i) !== null;
|
||||
// Extract default value
|
||||
let defaultValue: string | undefined;
|
||||
// Updated regex to handle casting with :: operator
|
||||
const defaultMatch = columnDefPart.match(
|
||||
/DEFAULT\s+((?:'[^']*'|"[^"]*"|\S+)(?:::\w+)?)/i
|
||||
);
|
||||
if (defaultMatch) {
|
||||
let defVal = defaultMatch[1].trim();
|
||||
// Remove trailing comma or semicolon if present
|
||||
defVal = defVal.replace(/[,;]$/, '').trim();
|
||||
// Handle string literals
|
||||
if (
|
||||
defVal.startsWith("'") &&
|
||||
defVal.endsWith("'")
|
||||
) {
|
||||
// Keep the quotes for string literals
|
||||
defaultValue = defVal;
|
||||
} else if (defVal.match(/^\d+(\.\d+)?$/)) {
|
||||
// Numeric value
|
||||
defaultValue = defVal;
|
||||
} else if (
|
||||
defVal.toUpperCase() === 'TRUE' ||
|
||||
defVal.toUpperCase() === 'FALSE'
|
||||
) {
|
||||
// Boolean value
|
||||
defaultValue = defVal.toUpperCase();
|
||||
} else if (defVal.toUpperCase() === 'NULL') {
|
||||
// NULL value
|
||||
defaultValue = 'NULL';
|
||||
} else if (
|
||||
defVal.includes('(') &&
|
||||
defVal.includes(')')
|
||||
) {
|
||||
// Function call
|
||||
// Normalize PostgreSQL function names to uppercase
|
||||
const funcMatch = defVal.match(/^(\w+)\(/);
|
||||
if (funcMatch) {
|
||||
const funcName = funcMatch[1];
|
||||
const pgFunctions = [
|
||||
'now',
|
||||
'current_timestamp',
|
||||
'current_date',
|
||||
'current_time',
|
||||
'gen_random_uuid',
|
||||
'random',
|
||||
'nextval',
|
||||
'currval',
|
||||
];
|
||||
if (
|
||||
pgFunctions.includes(
|
||||
funcName.toLowerCase()
|
||||
)
|
||||
) {
|
||||
defaultValue = defVal.replace(
|
||||
funcName,
|
||||
funcName.toUpperCase()
|
||||
);
|
||||
} else {
|
||||
defaultValue = defVal;
|
||||
}
|
||||
} else {
|
||||
defaultValue = defVal;
|
||||
}
|
||||
} else {
|
||||
// Other expressions
|
||||
defaultValue = defVal;
|
||||
}
|
||||
}
|
||||
|
||||
tableColumns.push({
|
||||
name: columnName,
|
||||
@@ -1657,7 +1795,7 @@ export async function fromPostgres(
|
||||
nullable: !isNotNull && !isPrimary,
|
||||
primaryKey: isPrimary,
|
||||
unique: isUnique || isPrimary,
|
||||
default: hasDefault ? 'has default' : undefined,
|
||||
default: defaultValue,
|
||||
increment: false,
|
||||
});
|
||||
}
|
||||
@@ -1814,58 +1952,10 @@ export async function fromPostgres(
|
||||
function getDefaultValueString(
|
||||
columnDef: ColumnDefinition
|
||||
): string | undefined {
|
||||
let defVal = columnDef.default_val;
|
||||
|
||||
if (
|
||||
defVal &&
|
||||
typeof defVal === 'object' &&
|
||||
defVal.type === 'default' &&
|
||||
'value' in defVal
|
||||
) {
|
||||
defVal = defVal.value;
|
||||
}
|
||||
const defVal = columnDef.default_val;
|
||||
|
||||
if (defVal === undefined || defVal === null) return undefined;
|
||||
|
||||
let value: string | undefined;
|
||||
|
||||
switch (typeof defVal) {
|
||||
case 'string':
|
||||
value = defVal;
|
||||
break;
|
||||
case 'number':
|
||||
value = String(defVal);
|
||||
break;
|
||||
case 'boolean':
|
||||
value = defVal ? 'TRUE' : 'FALSE';
|
||||
break;
|
||||
case 'object':
|
||||
if ('value' in defVal && typeof defVal.value === 'string') {
|
||||
value = defVal.value;
|
||||
} else if ('raw' in defVal && typeof defVal.raw === 'string') {
|
||||
value = defVal.raw;
|
||||
} else if (defVal.type === 'bool') {
|
||||
value = defVal.value ? 'TRUE' : 'FALSE';
|
||||
} else if (defVal.type === 'function' && defVal.name) {
|
||||
const fnName = defVal.name;
|
||||
if (
|
||||
fnName &&
|
||||
typeof fnName === 'object' &&
|
||||
Array.isArray(fnName.name) &&
|
||||
fnName.name.length > 0 &&
|
||||
fnName.name[0].value
|
||||
) {
|
||||
value = fnName.name[0].value.toUpperCase();
|
||||
} else if (typeof fnName === 'string') {
|
||||
value = fnName.toUpperCase();
|
||||
} else {
|
||||
value = 'UNKNOWN_FUNCTION';
|
||||
}
|
||||
}
|
||||
break;
|
||||
default:
|
||||
value = undefined;
|
||||
}
|
||||
|
||||
return value;
|
||||
// Use buildSQLFromAST to reconstruct the default value
|
||||
return buildSQLFromAST(defVal, DatabaseType.POSTGRESQL);
|
||||
}
|
||||
|
||||
@@ -0,0 +1,252 @@
|
||||
import { describe, it, expect } from 'vitest';
|
||||
import { fromSQLServer } from '../sqlserver';
|
||||
|
||||
describe('SQL Server Default Value Import', () => {
|
||||
describe('String Default Values', () => {
|
||||
it('should parse simple string defaults with single quotes', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE kingdom_citizens (
|
||||
citizen_id INT NOT NULL,
|
||||
allegiance NVARCHAR(50) DEFAULT 'neutral',
|
||||
PRIMARY KEY (citizen_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromSQLServer(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const allegianceColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'allegiance'
|
||||
);
|
||||
expect(allegianceColumn?.default).toBe("'neutral'");
|
||||
});
|
||||
|
||||
it('should parse string defaults with Unicode prefix', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE ancient_scrolls (
|
||||
scroll_id INT NOT NULL,
|
||||
runic_inscription NVARCHAR(255) DEFAULT N'Ancient wisdom',
|
||||
prophecy NVARCHAR(MAX) DEFAULT N'The chosen one shall rise',
|
||||
PRIMARY KEY (scroll_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromSQLServer(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const runicColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'runic_inscription'
|
||||
);
|
||||
expect(runicColumn?.default).toBe("N'Ancient wisdom'");
|
||||
const prophecyColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'prophecy'
|
||||
);
|
||||
expect(prophecyColumn?.default).toBe(
|
||||
"N'The chosen one shall rise'"
|
||||
);
|
||||
});
|
||||
});
|
||||
|
||||
describe('Numeric Default Values', () => {
|
||||
it('should parse integer defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE castle_treasury (
|
||||
treasury_id INT NOT NULL,
|
||||
gold_count INT DEFAULT 0,
|
||||
max_capacity BIGINT DEFAULT 100000,
|
||||
guard_posts SMALLINT DEFAULT 5,
|
||||
PRIMARY KEY (treasury_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromSQLServer(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const goldColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'gold_count'
|
||||
);
|
||||
expect(goldColumn?.default).toBe('0');
|
||||
const capacityColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'max_capacity'
|
||||
);
|
||||
expect(capacityColumn?.default).toBe('100000');
|
||||
const guardColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'guard_posts'
|
||||
);
|
||||
expect(guardColumn?.default).toBe('5');
|
||||
});
|
||||
|
||||
it('should parse decimal defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE blacksmith_shop (
|
||||
item_id INT NOT NULL,
|
||||
weapon_price DECIMAL(10, 2) DEFAULT 99.99,
|
||||
guild_discount FLOAT DEFAULT 0.15,
|
||||
enchantment_tax NUMERIC(5, 4) DEFAULT 0.0825,
|
||||
PRIMARY KEY (item_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromSQLServer(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const priceColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'weapon_price'
|
||||
);
|
||||
expect(priceColumn?.default).toBe('99.99');
|
||||
const discountColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'guild_discount'
|
||||
);
|
||||
expect(discountColumn?.default).toBe('0.15');
|
||||
const taxColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'enchantment_tax'
|
||||
);
|
||||
expect(taxColumn?.default).toBe('0.0825');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Boolean Default Values', () => {
|
||||
it('should parse BIT defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE magic_barriers (
|
||||
barrier_id INT NOT NULL,
|
||||
is_active BIT DEFAULT 1,
|
||||
is_breached BIT DEFAULT 0,
|
||||
PRIMARY KEY (barrier_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromSQLServer(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const activeColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_active'
|
||||
);
|
||||
expect(activeColumn?.default).toBe('1');
|
||||
const breachedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'is_breached'
|
||||
);
|
||||
expect(breachedColumn?.default).toBe('0');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Date and Time Default Values', () => {
|
||||
it('should parse date/time function defaults', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE battle_logs (
|
||||
battle_id INT NOT NULL,
|
||||
battle_started DATETIME DEFAULT GETDATE(),
|
||||
last_action DATETIME2 DEFAULT SYSDATETIME(),
|
||||
battle_date DATE DEFAULT GETDATE(),
|
||||
PRIMARY KEY (battle_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromSQLServer(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const startedColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'battle_started'
|
||||
);
|
||||
expect(startedColumn?.default).toBe('GETDATE()');
|
||||
const actionColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'last_action'
|
||||
);
|
||||
expect(actionColumn?.default).toBe('SYSDATETIME()');
|
||||
const dateColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'battle_date'
|
||||
);
|
||||
expect(dateColumn?.default).toBe('GETDATE()');
|
||||
});
|
||||
});
|
||||
|
||||
describe('IDENTITY columns', () => {
|
||||
it('should handle IDENTITY columns correctly', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE legendary_weapons (
|
||||
weapon_id INT IDENTITY(1,1) NOT NULL,
|
||||
legacy_id BIGINT IDENTITY(100,10) NOT NULL,
|
||||
weapon_name NVARCHAR(100),
|
||||
PRIMARY KEY (weapon_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromSQLServer(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const weaponColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'weapon_id'
|
||||
);
|
||||
expect(weaponColumn?.increment).toBe(true);
|
||||
const legacyColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'legacy_id'
|
||||
);
|
||||
expect(legacyColumn?.increment).toBe(true);
|
||||
});
|
||||
});
|
||||
|
||||
describe('Complex Real-World Example with Schema', () => {
|
||||
it('should handle complex table with schema and multiple default types', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE [dbo].[QuestContracts] (
|
||||
[ContractID] INT IDENTITY(1,1) NOT NULL,
|
||||
[AdventurerID] INT NOT NULL,
|
||||
[QuestDate] DATETIME DEFAULT GETDATE(),
|
||||
[QuestStatus] NVARCHAR(20) DEFAULT N'Available',
|
||||
[RewardAmount] DECIMAL(10, 2) DEFAULT 0.00,
|
||||
[IsCompleted] BIT DEFAULT 0,
|
||||
[CompletedDate] DATETIME NULL,
|
||||
[QuestNotes] NVARCHAR(MAX) DEFAULT NULL,
|
||||
[DifficultyLevel] INT DEFAULT 5,
|
||||
[QuestGuid] UNIQUEIDENTIFIER DEFAULT NEWID(),
|
||||
PRIMARY KEY ([ContractID])
|
||||
);
|
||||
`;
|
||||
|
||||
const result = await fromSQLServer(sql);
|
||||
const table = result.tables[0];
|
||||
expect(table).toBeDefined();
|
||||
expect(table.schema).toBe('dbo');
|
||||
|
||||
// Check various default values
|
||||
const questDateColumn = table.columns.find(
|
||||
(c) => c.name === 'QuestDate'
|
||||
);
|
||||
expect(questDateColumn?.default).toBe('GETDATE()');
|
||||
|
||||
const statusColumn = table.columns.find(
|
||||
(c) => c.name === 'QuestStatus'
|
||||
);
|
||||
expect(statusColumn?.default).toBe("N'Available'");
|
||||
|
||||
const rewardColumn = table.columns.find(
|
||||
(c) => c.name === 'RewardAmount'
|
||||
);
|
||||
expect(rewardColumn?.default).toBe('0.00');
|
||||
|
||||
const completedColumn = table.columns.find(
|
||||
(c) => c.name === 'IsCompleted'
|
||||
);
|
||||
expect(completedColumn?.default).toBe('0');
|
||||
|
||||
const difficultyColumn = table.columns.find(
|
||||
(c) => c.name === 'DifficultyLevel'
|
||||
);
|
||||
expect(difficultyColumn?.default).toBe('5');
|
||||
|
||||
const guidColumn = table.columns.find(
|
||||
(c) => c.name === 'QuestGuid'
|
||||
);
|
||||
expect(guidColumn?.default).toBe('NEWID()');
|
||||
});
|
||||
});
|
||||
|
||||
describe('Expressions in defaults', () => {
|
||||
it('should handle parentheses in default expressions', async () => {
|
||||
const sql = `
|
||||
CREATE TABLE spell_calculations (
|
||||
calculation_id INT NOT NULL,
|
||||
base_damage INT DEFAULT (10 + 5),
|
||||
total_power DECIMAL(10,2) DEFAULT ((100.0 * 0.15) + 10),
|
||||
PRIMARY KEY (calculation_id)
|
||||
);
|
||||
`;
|
||||
const result = await fromSQLServer(sql);
|
||||
expect(result.tables).toHaveLength(1);
|
||||
const damageColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'base_damage'
|
||||
);
|
||||
expect(damageColumn?.default).toBe('(10 + 5)');
|
||||
const powerColumn = result.tables[0].columns.find(
|
||||
(c) => c.name === 'total_power'
|
||||
);
|
||||
expect(powerColumn?.default).toBe('((100.0 * 0.15) + 10)');
|
||||
});
|
||||
});
|
||||
});
|
||||
Reference in New Issue
Block a user