Skip to content

Commit 3cdd721

Browse files
Copilotmathiasrw
andauthored
Let UNIQUE constraint support JSON properties and expressions to fix #925 (#2193)
Co-authored-by: copilot-swe-agent[bot] <[email protected]> Co-authored-by: mathiasrw <[email protected]> Co-authored-by: Mathias Wulff <[email protected]>
1 parent 7ce536b commit 3cdd721

File tree

6 files changed

+201
-17
lines changed

6 files changed

+201
-17
lines changed

src/60createtable.js

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -219,8 +219,8 @@ yy.CreateTable.prototype.execute = function (databaseid, params, cb) {
219219
table.uk.push(uk);
220220
uk.columns = con.columns;
221221
uk.onrightfns = uk.columns
222-
.map(function (columnid) {
223-
return `r[${JSON.stringify(columnid)}]`;
222+
.map(function (expr) {
223+
return expr.expression.toJS('r', '');
224224
})
225225
.join("+'`'+");
226226
uk.onrightfn = new Function('r', 'var y;return ' + uk.onrightfns);

src/65createindex.js

Lines changed: 20 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -35,17 +35,32 @@ yy.CreateIndex.prototype.execute = function (databaseid, params, cb) {
3535
var rightfn = new Function('r,params,alasql', 'return ' + rightfns);
3636

3737
if (this.unique) {
38+
// Create a unique constraint similar to table.uk
39+
var uniqueConstraint = {};
40+
table.uk = table.uk || [];
41+
table.uk.push(uniqueConstraint);
42+
uniqueConstraint.columns = this.columns;
43+
uniqueConstraint.onrightfns = rightfns;
44+
uniqueConstraint.onrightfn = rightfn;
45+
uniqueConstraint.hh = hash(rightfns);
46+
47+
// Store in uniqdefs for reference
3848
table.uniqdefs[indexid] = {
3949
rightfns: rightfns,
50+
hh: uniqueConstraint.hh,
4051
};
41-
var ux = (table.uniqs[indexid] = {});
52+
53+
// Initialize the unique index
54+
table.uniqs[uniqueConstraint.hh] = {};
55+
56+
// Populate existing data and check for duplicates
4257
if (table.data.length > 0) {
4358
for (var i = 0, ilen = table.data.length; i < ilen; i++) {
44-
var addr = rightfns(table.data[i]);
45-
if (!ux[addr]) {
46-
ux[addr] = {num: 0};
59+
var addr = rightfn(table.data[i], params, alasql);
60+
if (typeof table.uniqs[uniqueConstraint.hh][addr] !== 'undefined') {
61+
throw new Error('Cannot create unique index with duplicate values');
4762
}
48-
ux[addr].num++;
63+
table.uniqs[uniqueConstraint.hh][addr] = table.data[i];
4964
}
5065
}
5166
} else {

src/alasqlparser.jison

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2018,7 +2018,7 @@ OnUpdateClause
20182018
;
20192019

20202020
UniqueKey
2021-
: UNIQUE KEY? Literal? LPAR ColumnsList RPAR
2021+
: UNIQUE KEY? Literal? LPAR OrderExpressionsList RPAR
20222022
{
20232023
$$ = {type: 'UNIQUE', columns: $5, clustered:($3+'').toUpperCase()};
20242024
}

src/alasqlparser.js

Lines changed: 1 addition & 1 deletion
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

test/test122.js

Lines changed: 5 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -26,20 +26,17 @@ describe('Test 122 - PRIMARY KEY, CREATE INDEX UNIQUE', function () {
2626
done();
2727
});
2828

29-
it.skip('2. UNIQUE Index with repeated data', function (done) {
30-
assert.throws(function () {
29+
it('2. UNIQUE Index with repeated data', () => {
30+
assert.throws(() => {
3131
alasql('insert into one values (1,40)');
3232
}, Error);
33-
done();
3433
});
3534

36-
it('3. normal Index with repeated data', function (done) {
35+
it('3. normal Index with repeated data', () => {
3736
alasql('insert into one values (4,30)');
38-
done();
3937
});
4038

41-
it('4. same data index', function (done) {
42-
alasql('insert into one values (4,30)');
43-
done();
39+
it('4. same data index', () => {
40+
alasql('insert into one values (5,30)');
4441
});
4542
});

test/test925.js

Lines changed: 172 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,172 @@
1+
if (typeof exports === 'object') {
2+
var assert = require('assert');
3+
var alasql = require('..');
4+
}
5+
6+
describe('Test 925 - UNIQUE JSON property', function () {
7+
const test = '925';
8+
9+
before(function () {
10+
alasql('create database test' + test);
11+
alasql('use test' + test);
12+
});
13+
14+
after(function () {
15+
alasql('drop database test' + test);
16+
});
17+
18+
it('A) UNIQUE with JSON property using -> operator should work', () => {
19+
alasql('CREATE TABLE BOM1(name JSON, UNIQUE(name->test))');
20+
21+
// First insert should work
22+
alasql('INSERT INTO BOM1 VALUES (@{test:1})');
23+
24+
// Second insert with same value should fail
25+
assert.throws(() => {
26+
alasql('INSERT INTO BOM1 VALUES (@{test:1})');
27+
}, Error);
28+
29+
// Insert with different value should work
30+
alasql('INSERT INTO BOM1 VALUES (@{test:2})');
31+
32+
var res = alasql('SELECT * FROM BOM1');
33+
assert.deepEqual(res, [{name: {test: 1}}, {name: {test: 2}}]);
34+
});
35+
36+
it('B) UNIQUE with JSON property using . operator should work', () => {
37+
alasql('CREATE TABLE BOM2(name JSON, UNIQUE(name.test))');
38+
39+
// First insert should work
40+
alasql('INSERT INTO BOM2 VALUES (@{test:1})');
41+
42+
// Second insert with same value should fail
43+
assert.throws(() => {
44+
alasql('INSERT INTO BOM2 VALUES (@{test:1})');
45+
}, Error);
46+
47+
// Insert with different value should work
48+
alasql('INSERT INTO BOM2 VALUES (@{test:2})');
49+
50+
var res = alasql('SELECT * FROM BOM2');
51+
assert.deepEqual(res, [{name: {test: 1}}, {name: {test: 2}}]);
52+
});
53+
54+
it('C) CREATE UNIQUE INDEX with JSON property should check uniqueness', () => {
55+
alasql('CREATE TABLE BOM3(name JSON)');
56+
alasql('CREATE UNIQUE INDEX xx on BOM3(name->test)');
57+
58+
// First insert should work
59+
alasql('INSERT INTO BOM3 VALUES (@{test:1})');
60+
61+
// Second insert with same value should fail
62+
assert.throws(() => {
63+
alasql('INSERT INTO BOM3 VALUES (@{test:1})');
64+
}, Error);
65+
66+
// Insert with different value should work
67+
alasql('INSERT INTO BOM3 VALUES (@{test:2})');
68+
69+
var res = alasql('SELECT * FROM BOM3');
70+
assert.deepEqual(res, [{name: {test: 1}}, {name: {test: 2}}]);
71+
});
72+
73+
it('D) Regular (non-unique) index with JSON property allows duplicates', () => {
74+
alasql('CREATE TABLE BOM4(name JSON)');
75+
alasql('CREATE INDEX idx_regular on BOM4(name->test)');
76+
77+
// Insert same value multiple times - should all succeed
78+
alasql('INSERT INTO BOM4 VALUES (@{test:1})');
79+
alasql('INSERT INTO BOM4 VALUES (@{test:1})');
80+
alasql('INSERT INTO BOM4 VALUES (@{test:2})');
81+
alasql('INSERT INTO BOM4 VALUES (@{test:2})');
82+
83+
var res = alasql('SELECT * FROM BOM4');
84+
assert.equal(res.length, 4, 'Should allow duplicate values in regular index');
85+
assert.deepEqual(res, [
86+
{name: {test: 1}},
87+
{name: {test: 1}},
88+
{name: {test: 2}},
89+
{name: {test: 2}},
90+
]);
91+
});
92+
93+
it('E) Multiple indexes (unique and regular) on same table', () => {
94+
alasql('CREATE TABLE BOM5(id INT, data JSON)');
95+
alasql('CREATE UNIQUE INDEX idx_id on BOM5(id)');
96+
alasql('CREATE INDEX idx_data on BOM5(data->amount)');
97+
98+
// Insert records with unique id but duplicate data->amount
99+
alasql('INSERT INTO BOM5 VALUES (1, @{amount:100})');
100+
alasql('INSERT INTO BOM5 VALUES (2, @{amount:100})'); // Same data->amount, different id - OK
101+
alasql('INSERT INTO BOM5 VALUES (3, @{amount:200})');
102+
103+
var res = alasql('SELECT * FROM BOM5 ORDER BY id');
104+
assert.equal(res.length, 3);
105+
assert.deepEqual(res, [
106+
{id: 1, data: {amount: 100}},
107+
{id: 2, data: {amount: 100}},
108+
{id: 3, data: {amount: 200}},
109+
]);
110+
111+
// Try to insert duplicate id - should fail
112+
assert.throws(() => {
113+
alasql('INSERT INTO BOM5 VALUES (1, @{amount:300})');
114+
}, Error);
115+
});
116+
117+
it('F) Multiple unique indexes on different JSON properties', () => {
118+
alasql('CREATE TABLE BOM6(data JSON)');
119+
alasql('CREATE UNIQUE INDEX idx_prop1 on BOM6(data->prop1)');
120+
alasql('CREATE UNIQUE INDEX idx_prop2 on BOM6(data->prop2)');
121+
122+
// Insert records
123+
alasql('INSERT INTO BOM6 VALUES (@{prop1:1, prop2:"a"})');
124+
alasql('INSERT INTO BOM6 VALUES (@{prop1:2, prop2:"b"})');
125+
126+
// Try to insert duplicate prop1 - should fail
127+
assert.throws(() => {
128+
alasql('INSERT INTO BOM6 VALUES (@{prop1:1, prop2:"c"})');
129+
}, Error);
130+
131+
// Try to insert duplicate prop2 - should fail
132+
assert.throws(() => {
133+
alasql('INSERT INTO BOM6 VALUES (@{prop1:3, prop2:"a"})');
134+
}, Error);
135+
136+
// Insert with unique values for both - should succeed
137+
alasql('INSERT INTO BOM6 VALUES (@{prop1:3, prop2:"c"})');
138+
139+
var res = alasql('SELECT * FROM BOM6');
140+
assert.equal(res.length, 3);
141+
});
142+
143+
it('G) Mixed unique constraints: table-level and index-level', () => {
144+
alasql('CREATE TABLE BOM7(id INT, name JSON, UNIQUE(id))');
145+
alasql('CREATE UNIQUE INDEX idx_name on BOM7(name->val)');
146+
147+
// Insert records
148+
alasql('INSERT INTO BOM7 VALUES (1, @{val:"x"})');
149+
alasql('INSERT INTO BOM7 VALUES (2, @{val:"y"})');
150+
151+
// Try to insert duplicate id (table constraint) - should fail
152+
assert.throws(() => {
153+
alasql('INSERT INTO BOM7 VALUES (1, @{val:"z"})');
154+
}, Error);
155+
156+
// Try to insert duplicate name->val (index constraint) - should fail
157+
assert.throws(() => {
158+
alasql('INSERT INTO BOM7 VALUES (3, @{val:"x"})');
159+
}, Error);
160+
161+
// Insert with unique values for both - should succeed
162+
alasql('INSERT INTO BOM7 VALUES (3, @{val:"z"})');
163+
164+
var res = alasql('SELECT * FROM BOM7 ORDER BY id');
165+
assert.equal(res.length, 3);
166+
assert.deepEqual(res, [
167+
{id: 1, name: {val: 'x'}},
168+
{id: 2, name: {val: 'y'}},
169+
{id: 3, name: {val: 'z'}},
170+
]);
171+
});
172+
});

0 commit comments

Comments
 (0)