From fa21e7a4fa947946ebc5dc1cb294b1c64adf013f Mon Sep 17 00:00:00 2001 From: "copilot-swe-agent[bot]" <198982749+Copilot@users.noreply.github.com> Date: Tue, 2 Dec 2025 13:14:36 +0000 Subject: [PATCH 1/5] Initial plan From 06a51a19506b4f1451c3e521369bb995ecf505c5 Mon Sep 17 00:00:00 2001 From: "copilot-swe-agent[bot]" <198982749+Copilot@users.noreply.github.com> Date: Thu, 4 Dec 2025 03:09:00 +0000 Subject: [PATCH 2/5] Implement SQL-compliant NULL handling for IN and NOT IN operators Co-authored-by: mathiasrw <1063454+mathiasrw@users.noreply.github.com> --- src/50expression.js | 103 ++++++++++++++++++++++++++++++++++++++++---- test/test1414.js | 86 ++++++++++++++++++++++++++++++++++++ 2 files changed, 181 insertions(+), 8 deletions(-) create mode 100644 test/test1414.js diff --git a/src/50expression.js b/src/50expression.js index b1a32bd1b2..1ec208d634 100755 --- a/src/50expression.js +++ b/src/50expression.js @@ -367,39 +367,126 @@ s = `(${this.op === 'NOT BETWEEN' ? '!' : ''}((${ref(this.right1)} <= ${left}) && (${left} <= ${ref(this.right2)})))`; } else if (this.op === 'IN') { if (this.right instanceof yy.Select) { - s = `alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})).indexOf(alasql.utils.getValueOf(${leftJS()})) > -1`; + // SQL semantics: x IN (subquery with NULL) should handle NULL properly + // If x is NULL, return false (UNKNOWN). If x matches a value, return true. + // If x doesn't match but NULL exists in subquery, return false (UNKNOWN). + const leftVal = leftJS(); + s = `((v => { + const lv = alasql.utils.getValueOf(v); + if (lv == null) return false; + const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); + return arr.some(item => { + const iv = alasql.utils.getValueOf(item); + return iv != null && iv === lv; + }); + })(${leftVal}))`; } else if (Array.isArray(this.right)) { if (!alasql.options.cache || this.right.some(value => value instanceof yy.ParamValue)) { // Leverage JS Set for faster lookups than arrays - s = `(new Set([${this.right.map(ref).join(',')}]).has(alasql.utils.getValueOf(${leftJS()})))`; + const leftVal = leftJS(); + const rightVals = `[${this.right.map(ref).join(',')}]`; + s = `((lv => { + const leftVal = alasql.utils.getValueOf(lv); + if (leftVal == null) return false; + const vals = ${rightVals}; + return vals.some(v => { + const rv = alasql.utils.getValueOf(v); + return rv != null && rv === leftVal; + }); + })(${leftVal}))`; } else { // Use a cache to avoid re-creating the Set on every identical query alasql.sets = alasql.sets || {}; const allValues = this.right.map(value => value.value); const allValuesStr = allValues.join(','); alasql.sets[allValuesStr] = alasql.sets[allValuesStr] || new Set(allValues); - s = `alasql.sets["${allValuesStr}"].has(alasql.utils.getValueOf(${leftJS()}))`; + const leftVal = leftJS(); + s = `((lv => { + const leftVal = alasql.utils.getValueOf(lv); + if (leftVal == null) return false; + return alasql.sets["${allValuesStr}"].has(leftVal); + })(${leftVal}))`; } } else { - s = `(${rightJS()}.indexOf(${leftJS()}) > -1)`; + const leftVal = leftJS(); + s = `((lv => { + const leftVal = alasql.utils.getValueOf(lv); + if (leftVal == null) return false; + const arr = ${rightJS()}; + return arr.some(item => { + const iv = alasql.utils.getValueOf(item); + return iv != null && iv === leftVal; + }); + })(${leftVal}))`; } } else if (this.op === 'NOT IN') { if (this.right instanceof yy.Select) { - s = `alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, p)).indexOf(alasql.utils.getValueOf(${leftJS()})) < 0`; + // SQL semantics: x NOT IN (subquery with NULL) should return false (UNKNOWN) + // If x is NULL, return false (UNKNOWN). If subquery contains NULL and x is not found, return false (UNKNOWN). + const leftVal = leftJS(); + s = `((v => { + const lv = alasql.utils.getValueOf(v); + if (lv == null) return false; + const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, p)); + const hasNull = arr.some(item => alasql.utils.getValueOf(item) == null); + const hasMatch = arr.some(item => { + const iv = alasql.utils.getValueOf(item); + return iv != null && iv === lv; + }); + if (hasMatch) return false; + if (hasNull) return false; + return true; + })(${leftVal}))`; } else if (Array.isArray(this.right)) { if (!alasql.options.cache || this.right.some(value => value instanceof yy.ParamValue)) { // Leverage JS Set for faster lookups than arrays - s = `(!(new Set([${this.right.map(ref).join(',')}]).has(alasql.utils.getValueOf(${leftJS()}))))`; + const leftVal = leftJS(); + const rightVals = `[${this.right.map(ref).join(',')}]`; + s = `((lv => { + const leftVal = alasql.utils.getValueOf(lv); + if (leftVal == null) return false; + const vals = ${rightVals}; + const hasNull = vals.some(v => alasql.utils.getValueOf(v) == null); + const hasMatch = vals.some(v => { + const rv = alasql.utils.getValueOf(v); + return rv != null && rv === leftVal; + }); + if (hasMatch) return false; + if (hasNull) return false; + return true; + })(${leftVal}))`; } else { // Use a cache to avoid re-creating the Set on every identical query alasql.sets = alasql.sets || {}; const allValues = this.right.map(value => value.value); const allValuesStr = allValues.join(','); + const hasNull = allValues.some(v => v == null); alasql.sets[allValuesStr] = alasql.sets[allValuesStr] || new Set(allValues); - s = `!alasql.sets["${allValuesStr}"].has(alasql.utils.getValueOf(${leftJS()}))`; + const leftVal = leftJS(); + s = `((lv => { + const leftVal = alasql.utils.getValueOf(lv); + if (leftVal == null) return false; + const hasMatch = alasql.sets["${allValuesStr}"].has(leftVal); + if (hasMatch) return false; + if (${hasNull}) return false; + return true; + })(${leftVal}))`; } } else { - s = `(${rightJS()}.indexOf(${leftJS()}) === -1)`; + const leftVal = leftJS(); + s = `((lv => { + const leftVal = alasql.utils.getValueOf(lv); + if (leftVal == null) return false; + const arr = ${rightJS()}; + const hasNull = arr.some(item => alasql.utils.getValueOf(item) == null); + const hasMatch = arr.some(item => { + const iv = alasql.utils.getValueOf(item); + return iv != null && iv === leftVal; + }); + if (hasMatch) return false; + if (hasNull) return false; + return true; + })(${leftVal}))`; } } diff --git a/test/test1414.js b/test/test1414.js new file mode 100644 index 0000000000..14620cef0a --- /dev/null +++ b/test/test1414.js @@ -0,0 +1,86 @@ +if (typeof exports === 'object') { + var assert = require('assert'); + var alasql = require('..'); +} + +describe('Test 1414 - NOT IN with NULL values should follow SQL semantics', function () { + const test = '1414'; + + before(function () { + alasql('create database test' + test); + alasql('use test' + test); + }); + + after(function () { + alasql('drop database test' + test); + }); + + it('A) NOT IN with NULL in subquery should return empty result', function () { + alasql('CREATE TABLE R (a number)'); + alasql('CREATE TABLE S (b number)'); + alasql.tables.R.data = [{a: 1}, {a: null}]; + alasql.tables.S.data = [{b: null}]; + var res = alasql('select a from R where a not in (select b from S)'); + // When subquery contains NULL, NOT IN should return empty result + // because comparison with NULL is UNKNOWN, and NOT IN UNKNOWN = UNKNOWN (false in WHERE) + assert.deepEqual(res, []); + }); + + it('B) NOT IN with NULL value on left side', function () { + alasql('DROP TABLE IF EXISTS R'); + alasql('DROP TABLE IF EXISTS S'); + alasql('CREATE TABLE R (a number)'); + alasql('CREATE TABLE S (b number)'); + alasql.tables.R.data = [{a: null}, {a: 2}]; + alasql.tables.S.data = [{b: 1}]; + var res = alasql('select a from R where a not in (select b from S)'); + // NULL NOT IN (1) should evaluate to UNKNOWN (excluded from WHERE result) + // 2 NOT IN (1) should be TRUE (included) + assert.deepEqual(res, [{a: 2}]); + }); + + it('C) NOT IN without NULL should work normally', function () { + alasql('DROP TABLE IF EXISTS R'); + alasql('DROP TABLE IF EXISTS S'); + alasql('CREATE TABLE R (a number)'); + alasql('CREATE TABLE S (b number)'); + alasql.tables.R.data = [{a: 1}, {a: 2}, {a: 3}]; + alasql.tables.S.data = [{b: 2}]; + var res = alasql('select a from R where a not in (select b from S)'); + // 1 NOT IN (2) = TRUE, 2 NOT IN (2) = FALSE, 3 NOT IN (2) = TRUE + assert.deepEqual(res, [{a: 1}, {a: 3}]); + }); + + it('D) NOT IN with multiple values including NULL', function () { + alasql('DROP TABLE IF EXISTS R'); + alasql('DROP TABLE IF EXISTS S'); + alasql('CREATE TABLE R (a number)'); + alasql('CREATE TABLE S (b number)'); + alasql.tables.R.data = [{a: 1}, {a: 2}, {a: 3}]; + alasql.tables.S.data = [{b: 2}, {b: null}]; + var res = alasql('select a from R where a not in (select b from S)'); + // When subquery contains NULL, all comparisons are UNKNOWN + assert.deepEqual(res, []); + }); + + it('E) NOT IN with array literal containing NULL', function () { + alasql('DROP TABLE IF EXISTS R'); + alasql('CREATE TABLE R (a number)'); + alasql.tables.R.data = [{a: 1}, {a: 2}, {a: 3}]; + var res = alasql('select a from R where a not in (2, NULL)'); + // When list contains NULL, all NOT IN comparisons are UNKNOWN + assert.deepEqual(res, []); + }); + + it('F) IN with NULL in subquery', function () { + alasql('DROP TABLE IF EXISTS R'); + alasql('DROP TABLE IF EXISTS S'); + alasql('CREATE TABLE R (a number)'); + alasql('CREATE TABLE S (b number)'); + alasql.tables.R.data = [{a: 1}, {a: 2}]; + alasql.tables.S.data = [{b: 1}, {b: null}]; + var res = alasql('select a from R where a in (select b from S)'); + // 1 IN (1, NULL) = TRUE, 2 IN (1, NULL) = UNKNOWN (excluded) + assert.deepEqual(res, [{a: 1}]); + }); +}); From 13261b44b2d2a08c2dc103b2afefa5179d2e7175 Mon Sep 17 00:00:00 2001 From: "copilot-swe-agent[bot]" <198982749+Copilot@users.noreply.github.com> Date: Thu, 4 Dec 2025 03:11:17 +0000 Subject: [PATCH 3/5] Fix context parameter consistency in NOT IN operator Co-authored-by: mathiasrw <1063454+mathiasrw@users.noreply.github.com> --- src/50expression.js | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/50expression.js b/src/50expression.js index 1ec208d634..45ab334ec4 100755 --- a/src/50expression.js +++ b/src/50expression.js @@ -427,7 +427,7 @@ s = `((v => { const lv = alasql.utils.getValueOf(v); if (lv == null) return false; - const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, p)); + const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); const hasNull = arr.some(item => alasql.utils.getValueOf(item) == null); const hasMatch = arr.some(item => { const iv = alasql.utils.getValueOf(item); From 7f5f328a9857b6137ba307cc62100e9d0d13f026 Mon Sep 17 00:00:00 2001 From: "copilot-swe-agent[bot]" <198982749+Copilot@users.noreply.github.com> Date: Sun, 7 Dec 2025 00:42:05 +0000 Subject: [PATCH 4/5] Fix NULL handling in IN/NOT IN after merge with develop branch caching logic Co-authored-by: mathiasrw <1063454+mathiasrw@users.noreply.github.com> --- src/50expression.js | 60 ++++++++++++++++++++++++++++++++++----------- 1 file changed, 46 insertions(+), 14 deletions(-) diff --git a/src/50expression.js b/src/50expression.js index 6a7653f260..11c729c537 100755 --- a/src/50expression.js +++ b/src/50expression.js @@ -371,7 +371,13 @@ // If x is NULL, return false (UNKNOWN). If x matches a value, return true. // If x doesn't match but NULL exists in subquery, return false (UNKNOWN). const leftVal = leftJS(); - s = `((v => { + // Check if this is a correlated subquery (references outer tables) + // If correlated, we cannot cache the results as they depend on the current row + const cacheKey = `in${this.queriesidx}`; + const checkCorrelated = `(this.queriesfn[${this.queriesidx}].query && this.queriesfn[${this.queriesidx}].query.isCorrelated)`; + + // SQL-compliant uncached lookup + const uncachedLookup = `((v => { const lv = alasql.utils.getValueOf(v); if (lv == null) return false; const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); @@ -380,12 +386,20 @@ return iv != null && iv === lv; }); })(${leftVal}))`; - // Check if this is a correlated subquery (references outer tables) - // If correlated, we cannot cache the results as they depend on the current row - const cacheKey = `in${this.queriesidx}`; - const checkCorrelated = `(this.queriesfn[${this.queriesidx}].query && this.queriesfn[${this.queriesidx}].query.isCorrelated)`; - const cachedLookup = `((this.subqueryCache = this.subqueryCache || {}, this.subqueryCache.${cacheKey} || (this.subqueryCache.${cacheKey} = new Set(alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})).map(alasql.utils.getValueOf)))).has(alasql.utils.getValueOf(${leftJS()})))`; - const uncachedLookup = `(alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})).indexOf(alasql.utils.getValueOf(${leftJS()})) > -1)`; + + // SQL-compliant cached lookup + const cachedLookup = `((v => { + const lv = alasql.utils.getValueOf(v); + if (lv == null) return false; + this.subqueryCache = this.subqueryCache || {}; + if (!this.subqueryCache.${cacheKey}) { + const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); + const nonNullSet = new Set(arr.filter(item => alasql.utils.getValueOf(item) != null).map(item => alasql.utils.getValueOf(item))); + this.subqueryCache.${cacheKey} = nonNullSet; + } + return this.subqueryCache.${cacheKey}.has(lv); + })(${leftVal}))`; + s = `(${checkCorrelated} ? ${uncachedLookup} : ${cachedLookup})`; } else if (Array.isArray(this.right)) { if (!alasql.options.cache || this.right.some(value => value instanceof yy.ParamValue)) { @@ -431,7 +445,13 @@ // SQL semantics: x NOT IN (subquery with NULL) should return false (UNKNOWN) // If x is NULL, return false (UNKNOWN). If subquery contains NULL and x is not found, return false (UNKNOWN). const leftVal = leftJS(); - s = `((v => { + // Check if this is a correlated subquery (references outer tables) + // If correlated, we cannot cache the results as they depend on the current row + const cacheKey = `notIn${this.queriesidx}`; + const checkCorrelated = `(this.queriesfn[${this.queriesidx}].query && this.queriesfn[${this.queriesidx}].query.isCorrelated)`; + + // SQL-compliant uncached lookup + const uncachedLookup = `((v => { const lv = alasql.utils.getValueOf(v); if (lv == null) return false; const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); @@ -444,12 +464,24 @@ if (hasNull) return false; return true; })(${leftVal}))`; - // Check if this is a correlated subquery (references outer tables) - // If correlated, we cannot cache the results as they depend on the current row - const cacheKey = `notIn${this.queriesidx}`; - const checkCorrelated = `(this.queriesfn[${this.queriesidx}].query && this.queriesfn[${this.queriesidx}].query.isCorrelated)`; - const cachedLookup = `(!(this.subqueryCache = this.subqueryCache || {}, this.subqueryCache.${cacheKey} || (this.subqueryCache.${cacheKey} = new Set(alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})).map(alasql.utils.getValueOf)))).has(alasql.utils.getValueOf(${leftJS()})))`; - const uncachedLookup = `(alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})).indexOf(alasql.utils.getValueOf(${leftJS()})) < 0)`; + + // SQL-compliant cached lookup + const cachedLookup = `((v => { + const lv = alasql.utils.getValueOf(v); + if (lv == null) return false; + this.subqueryCache = this.subqueryCache || {}; + if (!this.subqueryCache.${cacheKey}) { + const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); + const hasNull = arr.some(item => alasql.utils.getValueOf(item) == null); + const nonNullSet = new Set(arr.filter(item => alasql.utils.getValueOf(item) != null).map(item => alasql.utils.getValueOf(item))); + this.subqueryCache.${cacheKey} = { hasNull, set: nonNullSet }; + } + const cache = this.subqueryCache.${cacheKey}; + if (cache.set.has(lv)) return false; + if (cache.hasNull) return false; + return true; + })(${leftVal}))`; + s = `(${checkCorrelated} ? ${uncachedLookup} : ${cachedLookup})`; } else if (Array.isArray(this.right)) { if (!alasql.options.cache || this.right.some(value => value instanceof yy.ParamValue)) { From 386672b8a7ab5c0268bd5c9a6e53a6a35bc37146 Mon Sep 17 00:00:00 2001 From: "copilot-swe-agent[bot]" <198982749+Copilot@users.noreply.github.com> Date: Wed, 10 Dec 2025 10:37:45 +0000 Subject: [PATCH 5/5] Simplify NULL handling with utility functions for IN/NOT IN operators Co-authored-by: mathiasrw <1063454+mathiasrw@users.noreply.github.com> --- src/15utility.js | 37 ++++++++++++ src/50expression.js | 144 ++++---------------------------------------- 2 files changed, 49 insertions(+), 132 deletions(-) diff --git a/src/15utility.js b/src/15utility.js index 3de55a7161..74e1eb4345 100755 --- a/src/15utility.js +++ b/src/15utility.js @@ -65,6 +65,43 @@ function returnTrue() { */ function returnUndefined() {} +/** + SQL-compliant IN check that handles NULL values according to SQL three-valued logic + @param {*} leftValue - The value to check + @param {Array} arr - The array to check against + @return {boolean} True if leftValue is in arr (excluding NULLs), false otherwise + */ +utils.sqlInCheck = function (leftValue, arr) { + var lv = utils.getValueOf(leftValue); + if (lv == null) return false; + for (var i = 0; i < arr.length; i++) { + var iv = utils.getValueOf(arr[i]); + if (iv != null && iv === lv) return true; + } + return false; +}; + +/** + SQL-compliant NOT IN check that handles NULL values according to SQL three-valued logic + @param {*} leftValue - The value to check + @param {Array} arr - The array to check against + @return {boolean} False if leftValue is NULL, or if arr contains NULL and no match found, true otherwise + */ +utils.sqlNotInCheck = function (leftValue, arr) { + var lv = utils.getValueOf(leftValue); + if (lv == null) return false; + var hasNull = false; + for (var i = 0; i < arr.length; i++) { + var iv = utils.getValueOf(arr[i]); + if (iv == null) { + hasNull = true; + } else if (iv === lv) { + return false; + } + } + return !hasNull; +}; + /** Escape string @function diff --git a/src/50expression.js b/src/50expression.js index 11c729c537..b286f9d4c3 100755 --- a/src/50expression.js +++ b/src/50expression.js @@ -367,172 +367,52 @@ s = `(${this.op === 'NOT BETWEEN' ? '!' : ''}((${ref(this.right1)} <= ${left}) && (${left} <= ${ref(this.right2)})))`; } else if (this.op === 'IN') { if (this.right instanceof yy.Select) { - // SQL semantics: x IN (subquery with NULL) should handle NULL properly - // If x is NULL, return false (UNKNOWN). If x matches a value, return true. - // If x doesn't match but NULL exists in subquery, return false (UNKNOWN). - const leftVal = leftJS(); // Check if this is a correlated subquery (references outer tables) // If correlated, we cannot cache the results as they depend on the current row const cacheKey = `in${this.queriesidx}`; const checkCorrelated = `(this.queriesfn[${this.queriesidx}].query && this.queriesfn[${this.queriesidx}].query.isCorrelated)`; - - // SQL-compliant uncached lookup - const uncachedLookup = `((v => { - const lv = alasql.utils.getValueOf(v); - if (lv == null) return false; - const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); - return arr.some(item => { - const iv = alasql.utils.getValueOf(item); - return iv != null && iv === lv; - }); - })(${leftVal}))`; - - // SQL-compliant cached lookup - const cachedLookup = `((v => { - const lv = alasql.utils.getValueOf(v); - if (lv == null) return false; - this.subqueryCache = this.subqueryCache || {}; - if (!this.subqueryCache.${cacheKey}) { - const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); - const nonNullSet = new Set(arr.filter(item => alasql.utils.getValueOf(item) != null).map(item => alasql.utils.getValueOf(item))); - this.subqueryCache.${cacheKey} = nonNullSet; - } - return this.subqueryCache.${cacheKey}.has(lv); - })(${leftVal}))`; - + const cachedLookup = `((this.subqueryCache = this.subqueryCache || {}, this.subqueryCache.${cacheKey} || (this.subqueryCache.${cacheKey} = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})).filter(function(v){return alasql.utils.getValueOf(v)!=null}).map(alasql.utils.getValueOf))).indexOf(alasql.utils.getValueOf(${leftJS()}))>-1&&alasql.utils.getValueOf(${leftJS()})!=null)`; + const uncachedLookup = `alasql.utils.sqlInCheck(${leftJS()},alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})))`; s = `(${checkCorrelated} ? ${uncachedLookup} : ${cachedLookup})`; } else if (Array.isArray(this.right)) { if (!alasql.options.cache || this.right.some(value => value instanceof yy.ParamValue)) { // Leverage JS Set for faster lookups than arrays - const leftVal = leftJS(); - const rightVals = `[${this.right.map(ref).join(',')}]`; - s = `((lv => { - const leftVal = alasql.utils.getValueOf(lv); - if (leftVal == null) return false; - const vals = ${rightVals}; - return vals.some(v => { - const rv = alasql.utils.getValueOf(v); - return rv != null && rv === leftVal; - }); - })(${leftVal}))`; + s = `alasql.utils.sqlInCheck(${leftJS()},[${this.right.map(ref).join(',')}])`; } else { // Use a cache to avoid re-creating the Set on every identical query alasql.sets = alasql.sets || {}; const allValues = this.right.map(value => value.value); const allValuesStr = allValues.join(','); - alasql.sets[allValuesStr] = alasql.sets[allValuesStr] || new Set(allValues); - const leftVal = leftJS(); - s = `((lv => { - const leftVal = alasql.utils.getValueOf(lv); - if (leftVal == null) return false; - return alasql.sets["${allValuesStr}"].has(leftVal); - })(${leftVal}))`; + alasql.sets[allValuesStr] = alasql.sets[allValuesStr] || new Set(allValues.filter(v => v != null)); + s = `(alasql.sets["${allValuesStr}"].has(alasql.utils.getValueOf(${leftJS()}))&&alasql.utils.getValueOf(${leftJS()})!=null)`; } } else { - const leftVal = leftJS(); - s = `((lv => { - const leftVal = alasql.utils.getValueOf(lv); - if (leftVal == null) return false; - const arr = ${rightJS()}; - return arr.some(item => { - const iv = alasql.utils.getValueOf(item); - return iv != null && iv === leftVal; - }); - })(${leftVal}))`; + s = `alasql.utils.sqlInCheck(${leftJS()},${rightJS()})`; } } else if (this.op === 'NOT IN') { if (this.right instanceof yy.Select) { - // SQL semantics: x NOT IN (subquery with NULL) should return false (UNKNOWN) - // If x is NULL, return false (UNKNOWN). If subquery contains NULL and x is not found, return false (UNKNOWN). - const leftVal = leftJS(); // Check if this is a correlated subquery (references outer tables) // If correlated, we cannot cache the results as they depend on the current row const cacheKey = `notIn${this.queriesidx}`; const checkCorrelated = `(this.queriesfn[${this.queriesidx}].query && this.queriesfn[${this.queriesidx}].query.isCorrelated)`; - - // SQL-compliant uncached lookup - const uncachedLookup = `((v => { - const lv = alasql.utils.getValueOf(v); - if (lv == null) return false; - const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); - const hasNull = arr.some(item => alasql.utils.getValueOf(item) == null); - const hasMatch = arr.some(item => { - const iv = alasql.utils.getValueOf(item); - return iv != null && iv === lv; - }); - if (hasMatch) return false; - if (hasNull) return false; - return true; - })(${leftVal}))`; - - // SQL-compliant cached lookup - const cachedLookup = `((v => { - const lv = alasql.utils.getValueOf(v); - if (lv == null) return false; - this.subqueryCache = this.subqueryCache || {}; - if (!this.subqueryCache.${cacheKey}) { - const arr = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})); - const hasNull = arr.some(item => alasql.utils.getValueOf(item) == null); - const nonNullSet = new Set(arr.filter(item => alasql.utils.getValueOf(item) != null).map(item => alasql.utils.getValueOf(item))); - this.subqueryCache.${cacheKey} = { hasNull, set: nonNullSet }; - } - const cache = this.subqueryCache.${cacheKey}; - if (cache.set.has(lv)) return false; - if (cache.hasNull) return false; - return true; - })(${leftVal}))`; - + const cachedLookup = `((this.subqueryCache = this.subqueryCache || {}, this.subqueryCache.${cacheKey} || (this.subqueryCache.${cacheKey} = alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context}))),alasql.utils.sqlNotInCheck(${leftJS()},this.subqueryCache.${cacheKey})))`; + const uncachedLookup = `alasql.utils.sqlNotInCheck(${leftJS()},alasql.utils.flatArray(this.queriesfn[${this.queriesidx}](params, null, ${context})))`; s = `(${checkCorrelated} ? ${uncachedLookup} : ${cachedLookup})`; } else if (Array.isArray(this.right)) { if (!alasql.options.cache || this.right.some(value => value instanceof yy.ParamValue)) { // Leverage JS Set for faster lookups than arrays - const leftVal = leftJS(); - const rightVals = `[${this.right.map(ref).join(',')}]`; - s = `((lv => { - const leftVal = alasql.utils.getValueOf(lv); - if (leftVal == null) return false; - const vals = ${rightVals}; - const hasNull = vals.some(v => alasql.utils.getValueOf(v) == null); - const hasMatch = vals.some(v => { - const rv = alasql.utils.getValueOf(v); - return rv != null && rv === leftVal; - }); - if (hasMatch) return false; - if (hasNull) return false; - return true; - })(${leftVal}))`; + s = `alasql.utils.sqlNotInCheck(${leftJS()},[${this.right.map(ref).join(',')}])`; } else { // Use a cache to avoid re-creating the Set on every identical query alasql.sets = alasql.sets || {}; const allValues = this.right.map(value => value.value); const allValuesStr = allValues.join(','); const hasNull = allValues.some(v => v == null); - alasql.sets[allValuesStr] = alasql.sets[allValuesStr] || new Set(allValues); - const leftVal = leftJS(); - s = `((lv => { - const leftVal = alasql.utils.getValueOf(lv); - if (leftVal == null) return false; - const hasMatch = alasql.sets["${allValuesStr}"].has(leftVal); - if (hasMatch) return false; - if (${hasNull}) return false; - return true; - })(${leftVal}))`; + alasql.sets[allValuesStr] = alasql.sets[allValuesStr] || new Set(allValues.filter(v => v != null)); + s = `(${hasNull}?false:(alasql.utils.getValueOf(${leftJS()})!=null&&!alasql.sets["${allValuesStr}"].has(alasql.utils.getValueOf(${leftJS()}))))`; } } else { - const leftVal = leftJS(); - s = `((lv => { - const leftVal = alasql.utils.getValueOf(lv); - if (leftVal == null) return false; - const arr = ${rightJS()}; - const hasNull = arr.some(item => alasql.utils.getValueOf(item) == null); - const hasMatch = arr.some(item => { - const iv = alasql.utils.getValueOf(item); - return iv != null && iv === leftVal; - }); - if (hasMatch) return false; - if (hasNull) return false; - return true; - })(${leftVal}))`; + s = `alasql.utils.sqlNotInCheck(${leftJS()},${rightJS()})`; } }