diff --git a/packages/plpgsql-deparser/__tests__/__snapshots__/deparser-fixes.test.ts.snap b/packages/plpgsql-deparser/__tests__/__snapshots__/deparser-fixes.test.ts.snap new file mode 100644 index 00000000..65553e4f --- /dev/null +++ b/packages/plpgsql-deparser/__tests__/__snapshots__/deparser-fixes.test.ts.snap @@ -0,0 +1,157 @@ +// Jest Snapshot v1, https://jestjs.io/docs/snapshot-testing + +exports[`plpgsql-deparser bug fixes INTO clause depth-aware scanner should handle INTO STRICT 1`] = ` +"DECLARE + v_id integer; +BEGIN + SELECT id INTO STRICT v_id FROM users WHERE email = 'test@example.com'; + RETURN v_id; +END" +`; + +exports[`plpgsql-deparser bug fixes INTO clause depth-aware scanner should handle INTO with CTE 1`] = ` +"DECLARE + v_total integer; +BEGIN + WITH totals AS ( + SELECT sum(amount) as total FROM orders + ) + SELECT total INTO v_total FROM totals; + RETURN v_total; +END" +`; + +exports[`plpgsql-deparser bug fixes INTO clause depth-aware scanner should handle INTO with UNION 1`] = ` +"DECLARE + v_count integer; +BEGIN + SELECT count(*) INTO v_count FROM ( + SELECT id FROM users + UNION ALL + SELECT id FROM admins + ) combined; + RETURN v_count; +END" +`; + +exports[`plpgsql-deparser bug fixes INTO clause depth-aware scanner should handle INTO with dollar-quoted strings 1`] = ` +"DECLARE + v_result text; +BEGIN + SELECT $tag$some FROM text$tag$ INTO v_result FROM dual; + RETURN v_result; +END" +`; + +exports[`plpgsql-deparser bug fixes INTO clause depth-aware scanner should handle INTO with quoted identifiers 1`] = ` +"DECLARE + v_name text; +BEGIN + SELECT "user-name" INTO v_name FROM "my-schema"."user-table" WHERE id = 1; + RETURN v_name; +END" +`; + +exports[`plpgsql-deparser bug fixes INTO clause depth-aware scanner should insert INTO at correct position for simple SELECT 1`] = ` +"DECLARE + v_count integer; +BEGIN + SELECT count(*) INTO v_count FROM users; + RETURN v_count; +END" +`; + +exports[`plpgsql-deparser bug fixes INTO clause depth-aware scanner should not insert INTO inside subqueries 1`] = ` +"DECLARE + v_result integer; +BEGIN + SELECT (SELECT max(id) FROM orders) INTO v_result FROM users WHERE id = 1; + RETURN v_result; +END" +`; + +exports[`plpgsql-deparser bug fixes PERFORM SELECT fix should handle PERFORM with complex expressions 1`] = ` +"BEGIN + PERFORM set_config('search_path', 'public', true); + PERFORM nextval('my_sequence'); + RETURN; +END" +`; + +exports[`plpgsql-deparser bug fixes PERFORM SELECT fix should handle PERFORM with subquery 1`] = ` +"BEGIN + PERFORM 1 FROM users WHERE id = 1; + RETURN; +END" +`; + +exports[`plpgsql-deparser bug fixes PERFORM SELECT fix should strip SELECT keyword from PERFORM statements 1`] = ` +"BEGIN + PERFORM pg_sleep(1); + RETURN; +END" +`; + +exports[`plpgsql-deparser bug fixes Record field qualification (recfield) should handle OLD and NEW record references 1`] = ` +"BEGIN + IF OLD.status <> NEW.status THEN + INSERT INTO audit_log (old_status, new_status) VALUES (OLD.status, NEW.status); + END IF; + RETURN NEW; +END" +`; + +exports[`plpgsql-deparser bug fixes Record field qualification (recfield) should handle SELECT INTO with record fields 1`] = ` +"BEGIN + SELECT is_active INTO new.is_active FROM users WHERE id = NEW.user_id; + RETURN NEW; +END" +`; + +exports[`plpgsql-deparser bug fixes Record field qualification (recfield) should handle custom record types 1`] = ` +"DECLARE + r RECORD; +BEGIN + FOR r IN SELECT id, name FROM users LOOP + RAISE NOTICE 'User: % - %', r.id, r.name; + END LOOP; + RETURN; +END" +`; + +exports[`plpgsql-deparser bug fixes Record field qualification (recfield) should handle record field assignment 1`] = ` +"BEGIN + NEW.created_at := COALESCE(NEW.created_at, now()); + NEW.updated_at := now(); + NEW.version := COALESCE(OLD.version, 0) + 1; + RETURN NEW; +END" +`; + +exports[`plpgsql-deparser bug fixes Record field qualification (recfield) should qualify record fields with parent record name in triggers 1`] = ` +"BEGIN + IF NEW.is_active THEN + NEW.updated_at := now(); + END IF; + RETURN NEW; +END" +`; + +exports[`plpgsql-deparser bug fixes combined scenarios should handle PERFORM with record fields 1`] = ` +"BEGIN + PERFORM notify_change(NEW.id, NEW.status); + RETURN NEW; +END" +`; + +exports[`plpgsql-deparser bug fixes combined scenarios should handle SELECT INTO with subquery and record fields 1`] = ` +"DECLARE + v_count integer; +BEGIN + SELECT count(*) INTO v_count FROM orders WHERE user_id = NEW.user_id; + IF v_count > 100 THEN + NEW.is_premium := true; + END IF; + RETURN NEW; +END" +`; diff --git a/packages/plpgsql-deparser/__tests__/deparser-fixes.test.ts b/packages/plpgsql-deparser/__tests__/deparser-fixes.test.ts new file mode 100644 index 00000000..0f4329f4 --- /dev/null +++ b/packages/plpgsql-deparser/__tests__/deparser-fixes.test.ts @@ -0,0 +1,351 @@ +import { loadModule, parsePlPgSQLSync } from '@libpg-query/parser'; +import { deparseSync, PLpgSQLParseResult } from '../src'; +import { PLpgSQLTestUtils } from '../test-utils'; + +describe('plpgsql-deparser bug fixes', () => { + let testUtils: PLpgSQLTestUtils; + + beforeAll(async () => { + await loadModule(); + testUtils = new PLpgSQLTestUtils(); + }); + + describe('PERFORM SELECT fix', () => { + it('should strip SELECT keyword from PERFORM statements', async () => { + const sql = `CREATE FUNCTION test_perform() RETURNS void +LANGUAGE plpgsql +AS $$ +BEGIN + PERFORM pg_sleep(1); +END; +$$`; + + // Round-trip test: parse -> deparse -> reparse -> compare ASTs + await testUtils.expectAstMatch('PERFORM basic', sql); + + // Also verify specific output characteristics + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + expect(deparsed).toContain('PERFORM pg_sleep'); + expect(deparsed).not.toMatch(/PERFORM\s+SELECT/i); + }); + + it('should handle PERFORM with complex expressions', async () => { + const sql = `CREATE FUNCTION test_perform_complex() RETURNS void +LANGUAGE plpgsql +AS $$ +BEGIN + PERFORM set_config('search_path', 'public', true); + PERFORM nextval('my_sequence'); +END; +$$`; + + await testUtils.expectAstMatch('PERFORM complex', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + expect(deparsed).not.toMatch(/PERFORM\s+SELECT/i); + }); + + it('should handle PERFORM with subquery', async () => { + const sql = `CREATE FUNCTION test_perform_subquery() RETURNS void +LANGUAGE plpgsql +AS $$ +BEGIN + PERFORM 1 FROM users WHERE id = 1; +END; +$$`; + + await testUtils.expectAstMatch('PERFORM subquery', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + expect(deparsed).not.toMatch(/PERFORM\s+SELECT/i); + }); + }); + + describe('INTO clause depth-aware scanner', () => { + it('should insert INTO at correct position for simple SELECT', async () => { + const sql = `CREATE FUNCTION test_into_simple() RETURNS integer +LANGUAGE plpgsql +AS $$ +DECLARE + v_count integer; +BEGIN + SELECT count(*) INTO v_count FROM users; + RETURN v_count; +END; +$$`; + + await testUtils.expectAstMatch('INTO simple', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + expect(deparsed).toContain('INTO'); + }); + + it('should not insert INTO inside subqueries', async () => { + const sql = `CREATE FUNCTION test_into_subquery() RETURNS integer +LANGUAGE plpgsql +AS $$ +DECLARE + v_result integer; +BEGIN + SELECT (SELECT max(id) FROM orders) INTO v_result FROM users WHERE id = 1; + RETURN v_result; +END; +$$`; + + await testUtils.expectAstMatch('INTO subquery', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle INTO with CTE', async () => { + const sql = `CREATE FUNCTION test_into_cte() RETURNS integer +LANGUAGE plpgsql +AS $$ +DECLARE + v_total integer; +BEGIN + WITH totals AS ( + SELECT sum(amount) as total FROM orders + ) + SELECT total INTO v_total FROM totals; + RETURN v_total; +END; +$$`; + + await testUtils.expectAstMatch('INTO CTE', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle INTO with UNION', async () => { + const sql = `CREATE FUNCTION test_into_union() RETURNS integer +LANGUAGE plpgsql +AS $$ +DECLARE + v_count integer; +BEGIN + SELECT count(*) INTO v_count FROM ( + SELECT id FROM users + UNION ALL + SELECT id FROM admins + ) combined; + RETURN v_count; +END; +$$`; + + await testUtils.expectAstMatch('INTO UNION', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle INTO with quoted identifiers', async () => { + const sql = `CREATE FUNCTION test_into_quoted() RETURNS text +LANGUAGE plpgsql +AS $$ +DECLARE + v_name text; +BEGIN + SELECT "user-name" INTO v_name FROM "my-schema"."user-table" WHERE id = 1; + RETURN v_name; +END; +$$`; + + await testUtils.expectAstMatch('INTO quoted', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle INTO with dollar-quoted strings', async () => { + const sql = `CREATE FUNCTION test_into_dollar_quote() RETURNS text +LANGUAGE plpgsql +AS $$ +DECLARE + v_result text; +BEGIN + SELECT $tag$some FROM text$tag$ INTO v_result FROM dual; + RETURN v_result; +END; +$$`; + + await testUtils.expectAstMatch('INTO dollar-quote', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle INTO STRICT', async () => { + const sql = `CREATE FUNCTION test_into_strict() RETURNS integer +LANGUAGE plpgsql +AS $$ +DECLARE + v_id integer; +BEGIN + SELECT id INTO STRICT v_id FROM users WHERE email = 'test@example.com'; + RETURN v_id; +END; +$$`; + + await testUtils.expectAstMatch('INTO STRICT', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + expect(deparsed).toContain('STRICT'); + }); + }); + + describe('Record field qualification (recfield)', () => { + it('should qualify record fields with parent record name in triggers', async () => { + const sql = `CREATE FUNCTION test_trigger() RETURNS trigger +LANGUAGE plpgsql +AS $$ +BEGIN + IF NEW.is_active THEN + NEW.updated_at := now(); + END IF; + RETURN NEW; +END; +$$`; + + await testUtils.expectAstMatch('recfield trigger', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle OLD and NEW record references', async () => { + const sql = `CREATE FUNCTION test_trigger_old_new() RETURNS trigger +LANGUAGE plpgsql +AS $$ +BEGIN + IF OLD.status <> NEW.status THEN + INSERT INTO audit_log (old_status, new_status) VALUES (OLD.status, NEW.status); + END IF; + RETURN NEW; +END; +$$`; + + await testUtils.expectAstMatch('recfield OLD NEW', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle record field assignment', async () => { + const sql = `CREATE FUNCTION test_record_assign() RETURNS trigger +LANGUAGE plpgsql +AS $$ +BEGIN + NEW.created_at := COALESCE(NEW.created_at, now()); + NEW.updated_at := now(); + NEW.version := COALESCE(OLD.version, 0) + 1; + RETURN NEW; +END; +$$`; + + await testUtils.expectAstMatch('recfield assignment', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle SELECT INTO with record fields', async () => { + const sql = `CREATE FUNCTION test_select_into_record() RETURNS trigger +LANGUAGE plpgsql +AS $$ +BEGIN + SELECT is_active INTO NEW.is_active FROM users WHERE id = NEW.user_id; + RETURN NEW; +END; +$$`; + + await testUtils.expectAstMatch('recfield SELECT INTO', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + + it('should handle custom record types', async () => { + const sql = `CREATE FUNCTION test_custom_record() RETURNS void +LANGUAGE plpgsql +AS $$ +DECLARE + r RECORD; +BEGIN + FOR r IN SELECT id, name FROM users LOOP + RAISE NOTICE 'User: % - %', r.id, r.name; + END LOOP; +END; +$$`; + + await testUtils.expectAstMatch('recfield custom record', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + }); + + describe('combined scenarios', () => { + it('should handle PERFORM with record fields', async () => { + const sql = `CREATE FUNCTION test_perform_record() RETURNS trigger +LANGUAGE plpgsql +AS $$ +BEGIN + PERFORM notify_change(NEW.id, NEW.status); + RETURN NEW; +END; +$$`; + + await testUtils.expectAstMatch('combined PERFORM recfield', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + expect(deparsed).not.toMatch(/PERFORM\s+SELECT/i); + }); + + it('should handle SELECT INTO with subquery and record fields', async () => { + const sql = `CREATE FUNCTION test_complex_trigger() RETURNS trigger +LANGUAGE plpgsql +AS $$ +DECLARE + v_count integer; +BEGIN + SELECT count(*) INTO v_count FROM orders WHERE user_id = NEW.user_id; + IF v_count > 100 THEN + NEW.is_premium := true; + END IF; + RETURN NEW; +END; +$$`; + + await testUtils.expectAstMatch('combined INTO recfield', sql); + + const parsed = parsePlPgSQLSync(sql) as unknown as PLpgSQLParseResult; + const deparsed = deparseSync(parsed); + expect(deparsed).toMatchSnapshot(); + }); + }); +}); diff --git a/packages/plpgsql-deparser/src/plpgsql-deparser.ts b/packages/plpgsql-deparser/src/plpgsql-deparser.ts index a8087a21..f3e46e56 100644 --- a/packages/plpgsql-deparser/src/plpgsql-deparser.ts +++ b/packages/plpgsql-deparser/src/plpgsql-deparser.ts @@ -1056,22 +1056,192 @@ export class PLpgSQLDeparser { const kw = this.keyword; let sql = exec.sqlstmt ? this.deparseExpr(exec.sqlstmt) : ''; - if (exec.into && exec.target) { + if (exec.into && exec.target !== undefined) { + // exec.target is a PLpgSQLDatum object (e.g., {PLpgSQL_recfield: {...}}) const targetName = this.deparseDatumName(exec.target, context); - // Check if the SQL already contains INTO - if (!sql.toUpperCase().includes(' INTO ')) { - // Insert INTO clause after SELECT - const selectMatch = sql.match(/^(SELECT\s+.+?)(\s+FROM\s+)/i); - if (selectMatch) { - const strict = exec.strict ? kw('STRICT') + ' ' : ''; - sql = `${selectMatch[1]} ${kw('INTO')} ${strict}${targetName}${selectMatch[2]}${sql.slice(selectMatch[0].length)}`; - } + const strict = exec.strict ? kw('STRICT') + ' ' : ''; + const intoClause = ` ${kw('INTO')} ${strict}${targetName}`; + // Use depth-aware scanner to find the correct insertion point + // Only insert INTO at depth 0 (not inside subqueries) + const insertPos = this.findIntoInsertionPoint(sql); + if (insertPos !== -1) { + // The parser strips "INTO " from the query but leaves whitespace behind. + // We need to normalize the leading whitespace after the insertion point to avoid + // large gaps like "SELECT x INTO y FROM z" + const before = sql.slice(0, insertPos); + let after = sql.slice(insertPos); + // Collapse leading whitespace (but preserve a single space before the next keyword) + after = after.replace(/^[ \t]+/, ' '); + sql = before + intoClause + after; + } else { + // -1 means INTO already exists at depth 0, don't add another one + // (this shouldn't happen in practice since the parser strips INTO) } } return sql; } + /** + * Find the correct position to insert INTO clause in a SQL statement. + * Uses a depth-aware scanner to avoid inserting inside subqueries. + * Returns the position to insert INTO, or -1 if INTO already exists at depth 0. + */ + private findIntoInsertionPoint(sql: string): number { + let depth = 0; + let inSingleQuote = false; + let inDoubleQuote = false; + let inDollarQuote = false; + let dollarQuoteTag = ''; + let inLineComment = false; + let inBlockComment = false; + const upperSql = sql.toUpperCase(); + const len = sql.length; + + // Clause keywords that end the SELECT target list at depth 0 + const clauseKeywords = ['FROM', 'WHERE', 'GROUP', 'HAVING', 'WINDOW', 'ORDER', 'LIMIT', 'OFFSET', 'FETCH', 'FOR', 'UNION', 'INTERSECT', 'EXCEPT']; + + for (let i = 0; i < len; i++) { + const char = sql[i]; + const nextChar = sql[i + 1] || ''; + + // Handle line comments + if (!inSingleQuote && !inDoubleQuote && !inDollarQuote && !inBlockComment) { + if (char === '-' && nextChar === '-') { + inLineComment = true; + i++; + continue; + } + } + if (inLineComment) { + if (char === '\n') { + inLineComment = false; + } + continue; + } + + // Handle block comments + if (!inSingleQuote && !inDoubleQuote && !inDollarQuote && !inLineComment) { + if (char === '/' && nextChar === '*') { + inBlockComment = true; + i++; + continue; + } + } + if (inBlockComment) { + if (char === '*' && nextChar === '/') { + inBlockComment = false; + i++; + } + continue; + } + + // Handle dollar quotes + if (!inSingleQuote && !inDoubleQuote && !inBlockComment && !inLineComment) { + if (char === '$') { + let tagEnd = i + 1; + while (tagEnd < len && (/[a-zA-Z0-9_]/.test(sql[tagEnd]) || sql[tagEnd] === '$')) { + if (sql[tagEnd] === '$') { + tagEnd++; + break; + } + tagEnd++; + } + const tag = sql.slice(i, tagEnd); + if (tag.endsWith('$')) { + if (inDollarQuote && tag === dollarQuoteTag) { + inDollarQuote = false; + dollarQuoteTag = ''; + i = tagEnd - 1; + continue; + } else if (!inDollarQuote) { + inDollarQuote = true; + dollarQuoteTag = tag; + i = tagEnd - 1; + continue; + } + } + } + } + if (inDollarQuote) { + continue; + } + + // Handle single quotes + if (!inDoubleQuote && !inBlockComment && !inLineComment && !inDollarQuote) { + if (char === "'") { + if (inSingleQuote && nextChar === "'") { + i++; + continue; + } + inSingleQuote = !inSingleQuote; + continue; + } + } + if (inSingleQuote) { + continue; + } + + // Handle double quotes (identifiers) + if (!inSingleQuote && !inBlockComment && !inLineComment && !inDollarQuote) { + if (char === '"') { + if (inDoubleQuote && nextChar === '"') { + i++; + continue; + } + inDoubleQuote = !inDoubleQuote; + continue; + } + } + if (inDoubleQuote) { + continue; + } + + // Track parentheses depth + if (char === '(') { + depth++; + continue; + } + if (char === ')') { + depth--; + continue; + } + + // Only look for keywords at depth 0 + if (depth === 0) { + // Check if we're at a word boundary before checking keywords + const prevChar = i > 0 ? sql[i - 1] : ' '; + const isWordBoundary = /\s/.test(prevChar) || prevChar === '(' || prevChar === ')' || prevChar === ',' || i === 0; + + if (isWordBoundary) { + // Check if INTO already exists at depth 0 + if (/^INTO\s/i.test(upperSql.slice(i))) { + return -1; + } + + // Check for clause keywords that end the target list + for (const keyword of clauseKeywords) { + const pattern = new RegExp(`^${keyword}\\b`, 'i'); + if (pattern.test(upperSql.slice(i))) { + let insertPos = i; + while (insertPos > 0 && /\s/.test(sql[insertPos - 1])) { + insertPos--; + } + return insertPos; + } + } + } + } + } + + // No clause keyword found - append at end + let insertPos = len; + while (insertPos > 0 && /\s/.test(sql[insertPos - 1])) { + insertPos--; + } + return insertPos; + } + /** * Deparse a dynamic EXECUTE statement */ @@ -1241,10 +1411,15 @@ export class PLpgSQLDeparser { /** * Deparse a PERFORM statement + * + * PERFORM in PL/pgSQL is equivalent to SELECT but discards results. + * The parser stores the query as "SELECT ...", so we need to strip the SELECT keyword. */ private deparsePerform(perform: PLpgSQL_stmt_perform, context: PLpgSQLDeparserContext): string { const kw = this.keyword; - const expr = perform.expr ? this.deparseExpr(perform.expr) : ''; + let expr = perform.expr ? this.deparseExpr(perform.expr) : ''; + // Strip leading SELECT keyword since PERFORM replaces it + expr = expr.replace(/^\s*SELECT\s+/i, ''); return `${kw('PERFORM')} ${expr}`; } @@ -1310,7 +1485,9 @@ export class PLpgSQLDeparser { /** * Get the name from a datum * For PLpgSQL_row with refname "(unnamed row)", expand the fields array - * to get the actual variable names + * to get the actual variable names. + * For PLpgSQL_recfield, construct the full qualified reference (e.g., new.is_active) + * by looking up the parent record name. */ private deparseDatumName(datum: PLpgSQLDatum, context?: PLpgSQLDeparserContext): string { if ('PLpgSQL_var' in datum) { @@ -1327,8 +1504,8 @@ export class PLpgSQLDeparser { // Try to resolve the varno to get the actual variable name const fieldDatum = context.datums[field.varno]; if (fieldDatum) { - // Recursively get the name, but without context to avoid infinite loops - return this.deparseDatumName(fieldDatum); + // Recursively get the name, passing context to resolve parent records + return this.deparseDatumName(fieldDatum, context); } // Fall back to the field name if we can't resolve the varno return field.name; @@ -1338,7 +1515,18 @@ export class PLpgSQLDeparser { return row.refname; } if ('PLpgSQL_recfield' in datum) { - return datum.PLpgSQL_recfield.fieldname; + const recfield = datum.PLpgSQL_recfield; + // Get the parent record name to construct the full field reference (e.g., new.is_active) + if (recfield.recparentno !== undefined && context?.datums) { + const parentDatum = context.datums[recfield.recparentno]; + if (parentDatum) { + const parentName = this.deparseDatumName(parentDatum); + if (parentName) { + return `${parentName}.${recfield.fieldname}`; + } + } + } + return recfield.fieldname; } return ''; } diff --git a/packages/plpgsql-deparser/test-utils/index.ts b/packages/plpgsql-deparser/test-utils/index.ts index aeace48e..c5c8041b 100644 --- a/packages/plpgsql-deparser/test-utils/index.ts +++ b/packages/plpgsql-deparser/test-utils/index.ts @@ -54,6 +54,106 @@ export function loadPLpgSQLFixtures(): PLpgSQLTestCase[] { const noop = (): undefined => undefined; +/** + * Normalize SQL whitespace for comparison purposes. + * Collapses multiple whitespace characters (spaces, tabs, newlines) into single spaces, + * but preserves content inside string literals and dollar-quoted strings. + */ +const normalizeQueryWhitespace = (query: string): string => { + if (!query || typeof query !== 'string') return query; + + let result = ''; + let i = 0; + const len = query.length; + + while (i < len) { + const char = query[i]; + + // Handle single-quoted strings + if (char === "'") { + result += char; + i++; + while (i < len) { + result += query[i]; + if (query[i] === "'" && query[i + 1] === "'") { + result += query[i + 1]; + i += 2; + } else if (query[i] === "'") { + i++; + break; + } else { + i++; + } + } + continue; + } + + // Handle double-quoted identifiers + if (char === '"') { + result += char; + i++; + while (i < len) { + result += query[i]; + if (query[i] === '"' && query[i + 1] === '"') { + result += query[i + 1]; + i += 2; + } else if (query[i] === '"') { + i++; + break; + } else { + i++; + } + } + continue; + } + + // Handle dollar-quoted strings + if (char === '$') { + let tag = '$'; + let j = i + 1; + while (j < len && (query[j].match(/[a-zA-Z0-9_]/) || query[j] === '$')) { + tag += query[j]; + if (query[j] === '$') { + j++; + break; + } + j++; + } + if (tag.endsWith('$') && tag.length >= 2) { + result += tag; + i = j; + // Find closing tag + const closeIdx = query.indexOf(tag, i); + if (closeIdx !== -1) { + result += query.slice(i, closeIdx + tag.length); + i = closeIdx + tag.length; + } else { + result += query.slice(i); + i = len; + } + continue; + } + } + + // Handle whitespace - collapse to single space + if (/\s/.test(char)) { + if (result.length > 0 && !result.endsWith(' ')) { + result += ' '; + } + i++; + while (i < len && /\s/.test(query[i])) { + i++; + } + continue; + } + + result += char; + i++; + } + + return result.trim(); +}; + export const transform = (obj: any, props: any): any => { let copy: any = null; if (obj == null || typeof obj !== 'object') { @@ -105,6 +205,7 @@ export const cleanPlpgsqlTree = (tree: any) => { location: noop, stmt_len: noop, stmt_location: noop, + query: normalizeQueryWhitespace, }); };