Skip to content

Commit 794e77c

Browse files
Copilotmathiasrw
andauthored
Let INSERT INTO SELECT FROM overwrite data with defaults to fix #1484 (#2210)
Co-authored-by: copilot-swe-agent[bot] <[email protected]> Co-authored-by: mathiasrw <[email protected]> Co-authored-by: Mathias Wulff <[email protected]>
1 parent f57ad42 commit 794e77c

File tree

2 files changed

+193
-1
lines changed

2 files changed

+193
-1
lines changed

src/70insert.js

Lines changed: 4 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -243,7 +243,10 @@ yy.Insert.prototype.compile = function (databaseid) {
243243
return statement;
244244
} else {
245245
// console.log(224,table.defaultfns);
246-
var defaultfns = 'return alasql.utils.extend(r,{' + table.defaultfns + '})';
246+
var defaultfns =
247+
'var defaults={' +
248+
table.defaultfns +
249+
'};for(var key in defaults){if(!(key in r)){r[key]=defaults[key]}}return r';
247250
var defaultfn = new Function('r,db,params,alasql', defaultfns);
248251
var insertfn = function (db, params, alasql) {
249252
var res = selectfn(params).data;

test/test1484.js

Lines changed: 189 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,189 @@
1+
if (typeof exports === 'object') {
2+
var assert = require('assert');
3+
var alasql = require('..');
4+
}
5+
6+
describe('Test 1484 - INSERT FROM parameter with defaults', function () {
7+
it('1. INSERT INTO table SELECT * FROM ? with data array', () => {
8+
// Create a new database like in the issue
9+
var inmemDB = new alasql.Database('test_insert_db');
10+
11+
// Create table
12+
var query =
13+
"CREATE TABLE IF NOT EXISTS [BCPartners] (RecordNum INTEGER PRIMARY KEY AUTOINCREMENT, [TABLE_NAME] TEXT DEFAULT '', [BC] TEXT DEFAULT '')";
14+
inmemDB.exec(query);
15+
16+
// Prepare test data
17+
var data = [
18+
{TABLE_NAME: 'Table1', BC: 'BC1'},
19+
{TABLE_NAME: 'Table2', BC: 'BC2'},
20+
{TABLE_NAME: 'Table3', BC: 'BC3'},
21+
];
22+
23+
// Insert data
24+
inmemDB.exec('INSERT INTO [BCPartners] SELECT * FROM ?', [data]);
25+
26+
// Verify data was inserted correctly
27+
var result = inmemDB.exec('SELECT * FROM [BCPartners]');
28+
29+
var expected = [
30+
{RecordNum: 1, TABLE_NAME: 'Table1', BC: 'BC1'},
31+
{RecordNum: 2, TABLE_NAME: 'Table2', BC: 'BC2'},
32+
{RecordNum: 3, TABLE_NAME: 'Table3', BC: 'BC3'},
33+
];
34+
assert.deepEqual(result, expected);
35+
36+
// Clean up
37+
alasql('DROP DATABASE test_insert_db');
38+
});
39+
40+
it('2. INSERT INTO table SELECT * FROM ? using default database', () => {
41+
// Test with default database (alasql)
42+
alasql('DROP TABLE IF EXISTS BCPartners');
43+
alasql(
44+
"CREATE TABLE BCPartners (RecordNum INTEGER PRIMARY KEY AUTOINCREMENT, TABLE_NAME TEXT DEFAULT '', BC TEXT DEFAULT '')"
45+
);
46+
47+
// Prepare test data
48+
var data = [
49+
{TABLE_NAME: 'Table1', BC: 'BC1'},
50+
{TABLE_NAME: 'Table2', BC: 'BC2'},
51+
];
52+
53+
// Insert data
54+
alasql('INSERT INTO BCPartners SELECT * FROM ?', [data]);
55+
56+
// Verify data was inserted correctly
57+
var result = alasql('SELECT * FROM BCPartners');
58+
59+
var expected = [
60+
{RecordNum: 1, TABLE_NAME: 'Table1', BC: 'BC1'},
61+
{RecordNum: 2, TABLE_NAME: 'Table2', BC: 'BC2'},
62+
];
63+
assert.deepEqual(result, expected);
64+
65+
// Clean up
66+
alasql('DROP TABLE BCPartners');
67+
});
68+
69+
it('3. INSERT with partial columns - defaults should apply for missing columns', () => {
70+
alasql('DROP TABLE IF EXISTS TestDefaults');
71+
alasql(
72+
'CREATE TABLE TestDefaults (id INT, name TEXT DEFAULT "NoName", status TEXT DEFAULT "Active")'
73+
);
74+
75+
// Insert data with only id and name
76+
var data = [
77+
{id: 1, name: 'Item1'},
78+
{id: 2, name: 'Item2'},
79+
];
80+
alasql('INSERT INTO TestDefaults SELECT * FROM ?', [data]);
81+
82+
var result = alasql('SELECT * FROM TestDefaults');
83+
84+
// status should have default value
85+
var expected = [
86+
{id: 1, name: 'Item1', status: 'Active'},
87+
{id: 2, name: 'Item2', status: 'Active'},
88+
];
89+
assert.deepEqual(result, expected);
90+
91+
alasql('DROP TABLE TestDefaults');
92+
});
93+
94+
it('4. INSERT with empty source columns should preserve empty values not defaults', () => {
95+
alasql('DROP TABLE IF EXISTS TestEmpty');
96+
alasql('CREATE TABLE TestEmpty (id INT, val TEXT DEFAULT "DefaultValue")');
97+
98+
// Insert data with empty string (not undefined/missing)
99+
var data = [
100+
{id: 1, val: ''},
101+
{id: 2, val: ''},
102+
];
103+
alasql('INSERT INTO TestEmpty SELECT * FROM ?', [data]);
104+
105+
var result = alasql('SELECT * FROM TestEmpty');
106+
107+
// Empty strings should be preserved, not replaced with defaults
108+
var expected = [
109+
{id: 1, val: ''},
110+
{id: 2, val: ''},
111+
];
112+
assert.deepEqual(result, expected);
113+
114+
alasql('DROP TABLE TestEmpty');
115+
});
116+
117+
it('5. INSERT from subquery with defaults', () => {
118+
alasql('DROP TABLE IF EXISTS Source');
119+
alasql('DROP TABLE IF EXISTS TargetTable');
120+
alasql('CREATE TABLE Source (id INT, name TEXT)');
121+
alasql('CREATE TABLE TargetTable (id INT, name TEXT, timestamp TEXT DEFAULT "2025")');
122+
123+
// Insert source data
124+
alasql('INSERT INTO Source VALUES (1, "A"), (2, "B")');
125+
126+
// Insert from source to target - timestamp should get default
127+
alasql('INSERT INTO TargetTable SELECT * FROM Source');
128+
129+
var result = alasql('SELECT * FROM TargetTable');
130+
131+
var expected = [
132+
{id: 1, name: 'A', timestamp: '2025'},
133+
{id: 2, name: 'B', timestamp: '2025'},
134+
];
135+
assert.deepEqual(result, expected);
136+
137+
alasql('DROP TABLE Source');
138+
alasql('DROP TABLE TargetTable');
139+
});
140+
141+
it('6. INSERT with mixed present and missing columns', () => {
142+
alasql('DROP TABLE IF EXISTS MixedTest');
143+
alasql(
144+
'CREATE TABLE MixedTest (a INT, b TEXT DEFAULT "B_default", c TEXT DEFAULT "C_default", d TEXT DEFAULT "D_default")'
145+
);
146+
147+
// Some records have different columns
148+
var data = [
149+
{a: 1, b: 'B1', c: 'C1'}, // missing d
150+
{a: 2, c: 'C2', d: 'D2'}, // missing b
151+
{a: 3, b: 'B3', d: 'D3'}, // missing c
152+
];
153+
alasql('INSERT INTO MixedTest SELECT * FROM ?', [data]);
154+
155+
var result = alasql('SELECT * FROM MixedTest');
156+
157+
var expected = [
158+
{a: 1, b: 'B1', c: 'C1', d: 'D_default'},
159+
{a: 2, b: 'B_default', c: 'C2', d: 'D2'},
160+
{a: 3, b: 'B3', c: 'C_default', d: 'D3'},
161+
];
162+
assert.deepEqual(result, expected);
163+
164+
alasql('DROP TABLE MixedTest');
165+
});
166+
167+
it('7. INSERT with undefined values should preserve undefined not apply defaults', () => {
168+
alasql('DROP TABLE IF EXISTS UndefinedTest');
169+
alasql('CREATE TABLE UndefinedTest (id INT, val TEXT DEFAULT "DefaultVal")');
170+
171+
// Explicitly set val to undefined
172+
var data = [
173+
{id: 1, val: undefined},
174+
{id: 2, val: null},
175+
];
176+
alasql('INSERT INTO UndefinedTest SELECT * FROM ?', [data]);
177+
178+
var result = alasql('SELECT * FROM UndefinedTest');
179+
180+
// undefined and null should be preserved
181+
var expected = [
182+
{id: 1, val: undefined},
183+
{id: 2, val: null},
184+
];
185+
assert.deepEqual(result, expected);
186+
187+
alasql('DROP TABLE UndefinedTest');
188+
});
189+
});

0 commit comments

Comments
 (0)