Skip to content

Commit 67514e8

Browse files
authored
fix(migration): invalid behavior while using -- or /* */ inside column string (#397)
1 parent 9ff2d78 commit 67514e8

File tree

2 files changed

+261
-14
lines changed

2 files changed

+261
-14
lines changed

src/runtime/database/server/utils/migrations/helpers.ts

+55-14
Original file line numberDiff line numberDiff line change
@@ -25,28 +25,69 @@ export const CreateMigrationsTableQuery = `CREATE TABLE IF NOT EXISTS _hub_migra
2525
export const AppliedMigrationsQuery = 'select "id", "name", "applied_at" from "_hub_migrations" order by "_hub_migrations"."id"'
2626

2727
export function splitSqlQueries(sqlFileContent: string): string[] {
28-
// Remove all inline comments (-- ...)
29-
let content = sqlFileContent.replace(/--.*$/gm, '')
28+
const queries = []
29+
// Track whether we're inside a string literal
30+
let inString = false
31+
let stringFence = ''
32+
let result = ''
3033

31-
// Remove all multi-line comments (/* ... */)
32-
content = content.replace(/\/\*[\s\S]*?\*\//g, '')
34+
// Process the content character by character
35+
for (let i = 0; i < sqlFileContent.length; i += 1) {
36+
const char = sqlFileContent[i]
37+
const nextChar = sqlFileContent[i + 1]
3338

34-
// Split by semicolons but keep them in the result
35-
const rawQueries = content.split(/(?<=;)/)
39+
// Handle string literals
40+
if ((char === '\'' || char === '"') && sqlFileContent[i - 1] !== '\\') {
41+
if (!inString) {
42+
inString = true
43+
stringFence = char
44+
} else if (char === stringFence) {
45+
inString = false
46+
}
47+
}
48+
49+
// Only remove comments when not inside a string
50+
if (!inString) {
51+
// `--` comments
52+
if (char === '-' && nextChar === '-') {
53+
while (i < sqlFileContent.length && sqlFileContent[i] !== '\n') {
54+
i += 1
55+
}
56+
continue
57+
}
58+
59+
// `/* */` comments
60+
if (char === '/' && nextChar === '*') {
61+
i += 2
62+
while (i < sqlFileContent.length && !(sqlFileContent[i] === '*' && sqlFileContent[i + 1] === '/')) {
63+
i += 1
64+
}
65+
i += 2
66+
continue
67+
}
68+
69+
if (char === ';' && sqlFileContent[i - 1] !== '\\') {
70+
if (result.trim() !== '') {
71+
result += char
72+
queries.push(result.trim())
73+
result = ''
74+
}
75+
continue
76+
}
77+
}
78+
79+
result += char
80+
}
81+
if (result.trim() !== '') {
82+
queries.push(result.trim())
83+
}
3684

3785
// Process each query
38-
return rawQueries
39-
.map(query => query.trim()) // Remove whitespace
40-
.filter((query) => {
41-
// Remove empty queries and standalone semicolons
42-
return query !== '' && query !== ';'
43-
})
86+
return queries
4487
.map((query) => {
45-
// Ensure each query ends with exactly one semicolon
4688
if (!query.endsWith(';')) {
4789
query += ';'
4890
}
49-
// Remove multiple semicolons at the end
5091
return query.replace(/;+$/, ';')
5192
})
5293
}

test/migration.helpers.test.ts

+206
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,206 @@
1+
import { describe, expect, it } from 'vitest'
2+
import { splitSqlQueries } from '~/src/runtime/database/server/utils/migrations/helpers'
3+
4+
describe('splitSqlQueries', () => {
5+
it('Should split minified sql', () => {
6+
const sqlFileContent = `CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));INSERT INTO users (id, name) VALUES (1, 'Jo;hn');`
7+
const queries = splitSqlQueries(sqlFileContent)
8+
expect(queries).toHaveLength(2)
9+
expect(queries).toMatchObject([
10+
'CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));',
11+
'INSERT INTO users (id, name) VALUES (1, \'Jo;hn\');'
12+
])
13+
})
14+
15+
it('Should respect ; within a query', () => {
16+
const sqlFileContent = `
17+
CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));
18+
INSERT INTO users (id, name) VALUES (1, 'Jo;hn');
19+
`
20+
const queries = splitSqlQueries(sqlFileContent)
21+
expect(queries).toHaveLength(2)
22+
})
23+
24+
it('Should ignore extra semicolons', () => {
25+
const sqlFileContent = `
26+
;;;;;
27+
CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));
28+
INSERT INTO users (id, name) VALUES (1, 'Jo;hn');;;;;;;
29+
INSERT INTO users (id, name) VALUES (1, 'Jo;hn');;;;;;;
30+
;;;;
31+
`
32+
const queries = splitSqlQueries(sqlFileContent)
33+
expect(queries).toHaveLength(3)
34+
})
35+
36+
it('Should handle last query without semicolon', () => {
37+
const sqlFileContent = `
38+
CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));
39+
INSERT INTO users (id, name) VALUES (1, 'Jo;hn')
40+
`
41+
const queries = splitSqlQueries(sqlFileContent)
42+
expect(queries).toHaveLength(2)
43+
})
44+
45+
it('should split the SQL file into separate queries', () => {
46+
const sqlFileContent = `
47+
CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));
48+
INSERT INTO users (id, name) VALUES (1, 'John');
49+
`
50+
const queries = splitSqlQueries(sqlFileContent)
51+
expect(queries).toHaveLength(2)
52+
})
53+
54+
it('should respect -- and /* */ comments', () => {
55+
const sqlFileContent = `
56+
-- This is a comment
57+
CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));
58+
/*
59+
This is a multi-line comment
60+
*/
61+
INSERT INTO users (id, name) VALUES (1, 'John');
62+
`
63+
const queries = splitSqlQueries(sqlFileContent)
64+
expect(queries).toHaveLength(2)
65+
})
66+
67+
it('Should respect -- within a query', () => {
68+
const sqlFileContent = `
69+
CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));
70+
INSERT INTO users (id, name) VALUES (1, 'John'); -- This is a comment
71+
`
72+
const queries = splitSqlQueries(sqlFileContent)
73+
expect(queries).toHaveLength(2)
74+
})
75+
76+
it('Should respect -- within a string', () => {
77+
const sqlFileContent = `
78+
CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));
79+
INSERT INTO users (id, name) VALUES (1, 'John -- This is a comment');
80+
`
81+
const queries = splitSqlQueries(sqlFileContent)
82+
expect(queries).toHaveLength(2)
83+
expect(queries[1]).toBe('INSERT INTO users (id, name) VALUES (1, \'John -- This is a comment\');')
84+
})
85+
86+
it('Should respect /* */ within a string', () => {
87+
const sqlFileContent = `
88+
CREATE TABLE users (id INT PRIMARY KEY, name VARCHAR(255));
89+
INSERT INTO users (id, name) VALUES (1, 'John /* This is a comment */');
90+
`
91+
const queries = splitSqlQueries(sqlFileContent)
92+
expect(queries).toHaveLength(2)
93+
expect(queries[1]).toBe('INSERT INTO users (id, name) VALUES (1, \'John /* This is a comment */\');')
94+
})
95+
96+
it('Should work with a large number of edge cases', () => {
97+
const sqlFileContent = `
98+
-- 1. Null Handling
99+
INSERT INTO users (id, name, email) VALUES (1, 'Alice', NULL);
100+
SELECT * FROM users WHERE email IS NULL;
101+
SELECT * FROM users WHERE email = '';
102+
103+
-- 2. Empty Results
104+
SELECT * FROM users WHERE id = -1;
105+
SELECT orders.id, users.name
106+
FROM orders
107+
LEFT JOIN users ON orders.user_id = users.id
108+
WHERE users.id IS NULL;
109+
110+
-- 3. Duplicate Handling
111+
INSERT INTO products (id, name) VALUES (1, 'Widget'), (1, 'Widget');
112+
SELECT name, COUNT(*) AS cnt
113+
FROM products
114+
GROUP BY name
115+
HAVING cnt > 1;
116+
117+
-- 4. Aggregation Edge Cases
118+
SELECT AVG(price), SUM(price) FROM orders WHERE 1 = 0;
119+
SELECT user_id, COUNT(*) FROM orders WHERE user_id = 1 GROUP BY user_id;
120+
121+
-- 5. Extreme Numeric Values
122+
INSERT INTO transactions (id, amount) VALUES (1, 999999999999), (2, -999999999999);
123+
SELECT * FROM transactions WHERE amount > 1000000000000 OR amount < -1000000000000;
124+
125+
-- 6. Non-ASCII or Special Characters
126+
INSERT INTO users (id, name) VALUES (2, '李小龙'), (3, 'O\\'Connor');
127+
SELECT * FROM users WHERE name LIKE 'O%';
128+
129+
-- 7. Recursive Query (CTE Edge Case)
130+
WITH RECURSIVE cte AS (
131+
SELECT 1 AS num
132+
UNION ALL
133+
SELECT num + 1 FROM cte WHERE num < 5
134+
)
135+
SELECT * FROM cte;
136+
137+
-- 8. Cross Join Edge Case
138+
SELECT * FROM users CROSS JOIN roles;
139+
140+
-- 9. Overlapping Ranges
141+
SELECT * FROM events WHERE start_time <= '2024-01-01' AND end_time >= '2024-01-01';
142+
143+
-- 10. Case Sensitivity
144+
INSERT INTO tags (id, label) VALUES (1, 'SQL'), (2, 'sql');
145+
SELECT * FROM tags WHERE label = 'SQL';
146+
147+
-- 11. Index Edge Case
148+
SELECT * FROM orders FORCE INDEX (order_date_index) WHERE order_date = '2024-01-01';
149+
150+
-- 12. Date Handling
151+
INSERT INTO events (id, event_date) VALUES (1, '2024-02-29'), (2, '0000-00-00'), (3, '9999-12-31');
152+
SELECT * FROM events WHERE event_date BETWEEN '2024-01-01' AND '2024-12-31';
153+
154+
-- 13. Self-JOIN
155+
SELECT a.id AS parent_id, b.id AS child_id
156+
FROM users a
157+
JOIN users b ON a.id = b.parent_id;
158+
159+
-- 14. Triggers or Constraints
160+
INSERT INTO users (id, name, email) VALUES (NULL, 'Test', '[email protected]'); -- Violates NOT NULL
161+
INSERT INTO orders (id, status) VALUES (NULL, NULL); -- Default status should be applied
162+
`
163+
const queries = splitSqlQueries(sqlFileContent)
164+
expect(queries).toHaveLength(24)
165+
166+
expect(queries).toMatchObject([
167+
'INSERT INTO users (id, name, email) VALUES (1, \'Alice\', NULL);',
168+
'SELECT * FROM users WHERE email IS NULL;',
169+
'SELECT * FROM users WHERE email = \'\';',
170+
'SELECT * FROM users WHERE id = -1;',
171+
'SELECT orders.id, users.name \n'
172+
+ ' FROM orders \n'
173+
+ ' LEFT JOIN users ON orders.user_id = users.id \n'
174+
+ ' WHERE users.id IS NULL;',
175+
'INSERT INTO products (id, name) VALUES (1, \'Widget\'), (1, \'Widget\');',
176+
'SELECT name, COUNT(*) AS cnt \n'
177+
+ ' FROM products \n'
178+
+ ' GROUP BY name \n'
179+
+ ' HAVING cnt > 1;',
180+
'SELECT AVG(price), SUM(price) FROM orders WHERE 1 = 0;',
181+
'SELECT user_id, COUNT(*) FROM orders WHERE user_id = 1 GROUP BY user_id;',
182+
'INSERT INTO transactions (id, amount) VALUES (1, 999999999999), (2, -999999999999);',
183+
'SELECT * FROM transactions WHERE amount > 1000000000000 OR amount < -1000000000000;',
184+
'INSERT INTO users (id, name) VALUES (2, \'李小龙\'), (3, \'O\\\'Connor\');',
185+
'SELECT * FROM users WHERE name LIKE \'O%\';',
186+
'WITH RECURSIVE cte AS (\n'
187+
+ ' SELECT 1 AS num\n'
188+
+ ' UNION ALL\n'
189+
+ ' SELECT num + 1 FROM cte WHERE num < 5\n'
190+
+ ' )\n'
191+
+ ' SELECT * FROM cte;',
192+
'SELECT * FROM users CROSS JOIN roles;',
193+
'SELECT * FROM events WHERE start_time <= \'2024-01-01\' AND end_time >= \'2024-01-01\';',
194+
'INSERT INTO tags (id, label) VALUES (1, \'SQL\'), (2, \'sql\');',
195+
'SELECT * FROM tags WHERE label = \'SQL\';',
196+
'SELECT * FROM orders FORCE INDEX (order_date_index) WHERE order_date = \'2024-01-01\';',
197+
'INSERT INTO events (id, event_date) VALUES (1, \'2024-02-29\'), (2, \'0000-00-00\'), (3, \'9999-12-31\');',
198+
'SELECT * FROM events WHERE event_date BETWEEN \'2024-01-01\' AND \'2024-12-31\';',
199+
'SELECT a.id AS parent_id, b.id AS child_id \n'
200+
+ ' FROM users a \n'
201+
+ ' JOIN users b ON a.id = b.parent_id;',
202+
'INSERT INTO users (id, name, email) VALUES (NULL, \'Test\', \'[email protected]\');',
203+
'INSERT INTO orders (id, status) VALUES (NULL, NULL);'
204+
])
205+
})
206+
})

0 commit comments

Comments
 (0)