diff --git a/src/runtime/database/server/utils/migrations/helpers.ts b/src/runtime/database/server/utils/migrations/helpers.ts index ea2cf120..26ed840f 100644 --- a/src/runtime/database/server/utils/migrations/helpers.ts +++ b/src/runtime/database/server/utils/migrations/helpers.ts @@ -78,20 +78,28 @@ export async function copyDatabaseQueriesToHubDir(hub: HubConfig) { // #endregion // #region Utils +/** + * Split a string containing SQL queries into an array of individual queries after removing comments + */ export function splitSqlQueries(sqlFileContent: string): string[] { - const queries = [] - // Track whether we're inside a string literal + const queries: string[] = [] let inString = false let stringFence = '' let result = '' - // Process the content character by character + let currentGeneralWord = '' + let previousGeneralWord = '' + let inTrigger = false + + let currentTriggerWord = '' + let triggerBlockNestingLevel = 0 + for (let i = 0; i < sqlFileContent.length; i += 1) { const char = sqlFileContent[i] const nextChar = sqlFileContent[i + 1] // Handle string literals - if ((char === '\'' || char === '"') && sqlFileContent[i - 1] !== '\\') { + if ((char === '\'' || char === '"') && (i === 0 || sqlFileContent[i - 1] !== '\\')) { if (!inString) { inString = true stringFence = char @@ -102,7 +110,7 @@ export function splitSqlQueries(sqlFileContent: string): string[] { // Only remove comments when not inside a string if (!inString) { - // `--` comments + // Handle -- comments if (char === '-' && nextChar === '-') { while (i < sqlFileContent.length && sqlFileContent[i] !== '\n') { i += 1 @@ -110,7 +118,7 @@ export function splitSqlQueries(sqlFileContent: string): string[] { continue } - // `/* */` comments + // Handle /* */ comments if (char === '/' && nextChar === '*') { i += 2 while (i < sqlFileContent.length && !(sqlFileContent[i] === '*' && sqlFileContent[i + 1] === '/')) { @@ -120,29 +128,82 @@ export function splitSqlQueries(sqlFileContent: string): string[] { continue } + // Track general keywords for CREATE TRIGGER detection + if (/\w/.test(char)) { + currentGeneralWord += char.toLowerCase() + } else { + // Check if previous word was 'create' and current is 'trigger' + if (previousGeneralWord === 'create' && currentGeneralWord === 'trigger') { + inTrigger = true + } + previousGeneralWord = currentGeneralWord + currentGeneralWord = '' + } + + // If in trigger, track BEGIN/END + if (inTrigger) { + if (/\w/.test(char)) { + currentTriggerWord += char.toLowerCase() + } else { + if (currentTriggerWord === 'begin') { + triggerBlockNestingLevel++ + } else if (currentTriggerWord === 'end') { + triggerBlockNestingLevel = Math.max(triggerBlockNestingLevel - 1, 0) + } + currentTriggerWord = '' + } + } + + // Handle semicolon if (char === ';' && sqlFileContent[i - 1] !== '\\') { - if (result.trim() !== '') { + if (inTrigger) { + if (triggerBlockNestingLevel === 0) { + // End of trigger, split here + result += char + const trimmedResult = result.trim() + if (trimmedResult !== '') { + queries.push(trimmedResult) + } + result = '' + inTrigger = false + triggerBlockNestingLevel = 0 + continue + } else { + // Inside trigger, do not split + result += char + } + } else { + // Not in trigger, split as usual result += char - queries.push(result.trim()) + const trimmedResult = result.trim() + if (trimmedResult !== '') { + queries.push(trimmedResult) + } result = '' + continue } - continue } } result += char } - if (result.trim() !== '') { - queries.push(result.trim()) + + // Add any remaining content as a query + const finalTrimmed = result.trim() + if (finalTrimmed !== '') { + queries.push(finalTrimmed) } - // Process each query + // Process each query to ensure it ends with a single semicolon and filter out empty/semicolon-only return queries .map((query) => { - if (!query.endsWith(';')) { - query += ';' + // Handle semicolons in trigger bodies + if (query.includes('TRIGGER') && query.includes('BEGIN')) { + // First, handle the statements inside the trigger + query = query.replace(/;+(?=\s+(?:END|\S|$))/g, ';') } return query.replace(/;+$/, ';') }) + .filter(query => query !== ';' && query.trim() !== '') } // #endregion diff --git a/test/migration.helpers.test.ts b/test/migration.helpers.test.ts index 3f3caa48..041dae69 100644 --- a/test/migration.helpers.test.ts +++ b/test/migration.helpers.test.ts @@ -76,7 +76,7 @@ describe('splitSqlQueries', () => { it('Should respect -- within a string', () => { const sqlFileContent = ` CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255)); - INSERT INTO users (id, name) VALUES (1, 'John -- This is a comment'); + INSERT INTO users (id, name) VALUES (1, 'John -- This is a comment'); ` const queries = splitSqlQueries(sqlFileContent) expect(queries).toHaveLength(2) @@ -86,7 +86,7 @@ describe('splitSqlQueries', () => { it('Should respect /* */ within a string', () => { const sqlFileContent = ` CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255)); - INSERT INTO users (id, name) VALUES (1, 'John /* This is a comment */'); + INSERT INTO users (id, name) VALUES (1, 'John /* This is a comment */'); ` const queries = splitSqlQueries(sqlFileContent) expect(queries).toHaveLength(2) @@ -102,16 +102,16 @@ describe('splitSqlQueries', () => { -- 2. Empty Results SELECT * FROM users WHERE id = -1; - SELECT orders.id, users.name - FROM orders - LEFT JOIN users ON orders.user_id = users.id + SELECT orders.id, users.name + FROM orders + LEFT JOIN users ON orders.user_id = users.id WHERE users.id IS NULL; -- 3. Duplicate Handling INSERT INTO products (id, name) VALUES (1, 'Widget'), (1, 'Widget'); - SELECT name, COUNT(*) AS cnt - FROM products - GROUP BY name + SELECT name, COUNT(*) AS cnt + FROM products + GROUP BY name HAVING cnt > 1; -- 4. Aggregation Edge Cases @@ -152,8 +152,8 @@ describe('splitSqlQueries', () => { SELECT * FROM events WHERE event_date BETWEEN '2024-01-01' AND '2024-12-31'; -- 13. Self-JOIN - SELECT a.id AS parent_id, b.id AS child_id - FROM users a + SELECT a.id AS parent_id, b.id AS child_id + FROM users a JOIN users b ON a.id = b.parent_id; -- 14. Triggers or Constraints @@ -168,14 +168,14 @@ describe('splitSqlQueries', () => { 'SELECT * FROM users WHERE email IS NULL;', 'SELECT * FROM users WHERE email = \'\';', 'SELECT * FROM users WHERE id = -1;', - 'SELECT orders.id, users.name \n' - + ' FROM orders \n' - + ' LEFT JOIN users ON orders.user_id = users.id \n' + 'SELECT orders.id, users.name\n' + + ' FROM orders\n' + + ' LEFT JOIN users ON orders.user_id = users.id\n' + ' WHERE users.id IS NULL;', 'INSERT INTO products (id, name) VALUES (1, \'Widget\'), (1, \'Widget\');', - 'SELECT name, COUNT(*) AS cnt \n' - + ' FROM products \n' - + ' GROUP BY name \n' + 'SELECT name, COUNT(*) AS cnt\n' + + ' FROM products\n' + + ' GROUP BY name\n' + ' HAVING cnt > 1;', 'SELECT AVG(price), SUM(price) FROM orders WHERE 1 = 0;', 'SELECT user_id, COUNT(*) FROM orders WHERE user_id = 1 GROUP BY user_id;', @@ -196,11 +196,33 @@ describe('splitSqlQueries', () => { 'SELECT * FROM orders FORCE INDEX (order_date_index) WHERE order_date = \'2024-01-01\';', 'INSERT INTO events (id, event_date) VALUES (1, \'2024-02-29\'), (2, \'0000-00-00\'), (3, \'9999-12-31\');', 'SELECT * FROM events WHERE event_date BETWEEN \'2024-01-01\' AND \'2024-12-31\';', - 'SELECT a.id AS parent_id, b.id AS child_id \n' - + ' FROM users a \n' + 'SELECT a.id AS parent_id, b.id AS child_id\n' + + ' FROM users a\n' + ' JOIN users b ON a.id = b.parent_id;', 'INSERT INTO users (id, name, email) VALUES (NULL, \'Test\', \'test@example.com\');', 'INSERT INTO orders (id, status) VALUES (NULL, NULL);' ]) }) + + it('Should keep trigger sql queries as one query', () => { + const sqlFileContent = ` + -- Create a table. And an external content fts5 table to index it. + CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c); + CREATE VIRTUAL TABLE fts_idx USING fts5(b, c, content='t1', content_rowid='a'); + + -- Triggers to keep the FTS index up to date. + CREATE TRIGGER t1_ai AFTER INSERT ON t1 BEGIN + INSERT INTO fts_idx(rowid, b, c) VALUES (new.a, new.b, new.c); + END; + CREATE TRIGGER t1_ad AFTER DELETE ON t1 BEGIN + INSERT INTO fts_idx(fts_idx, rowid, b, c) VALUES('delete', old.a, old.b, old.c); + END; + CREATE TRIGGER t1_au AFTER UPDATE ON t1 BEGIN + INSERT INTO fts_idx(fts_idx, rowid, b, c) VALUES('delete', old.a, old.b, old.c); + INSERT INTO fts_idx(rowid, b, c) VALUES (new.a, new.b, new.c); + END; + ` + const queries = splitSqlQueries(sqlFileContent) + expect(queries).toHaveLength(5) + }) })