Skip to content

Commit

Permalink
sql: remove one row limit in EXISTS subquery
Browse files Browse the repository at this point in the history
According to ANSI, EXISTS is a predicate that tests a given subquery and
returns true if it returns more than 0 rows, false otherwise. However,
after 2a720d1, EXISTS worked correctly only if there were exactly 0
or 1 rows, and in all other cases it gave an error. This patch makes
EXITS work properly.

Closes #8676

NO_DOC=bugfix
  • Loading branch information
ImeevMA authored and igormunkin committed Nov 27, 2023
1 parent 4111455 commit a5e498d
Show file tree
Hide file tree
Showing 4 changed files with 59 additions and 28 deletions.
4 changes: 4 additions & 0 deletions changelogs/unreleased/gh-8676-fix-exists-predicate.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
## bugfix/sql

* The `EXISTS` predicate no longer requires `LIMIT 1` to work correctly if more
than one row is returned in the subselect (gh-8676).
23 changes: 15 additions & 8 deletions src/box/sql/expr.c
Original file line number Diff line number Diff line change
Expand Up @@ -2774,9 +2774,6 @@ sqlCodeSubselect(Parse * pParse, /* Parsing context */
*
* If this is an EXISTS, write an integer 0 (not exists) or 1 (exists)
* into a register and return that register number.
*
* In both cases, the query is augmented with "LIMIT 1". Any
* preexisting limit is discarded in place of the new LIMIT 1.
*/
Select *pSel; /* SELECT statement to encode */
SelectDest dest; /* How to deal with SELECT result */
Expand All @@ -2802,12 +2799,22 @@ sqlCodeSubselect(Parse * pParse, /* Parsing context */
sqlVdbeAddOp2(v, OP_Bool, false, dest.iSDParm);
VdbeComment((v, "Init EXISTS result"));
}
if (pSel->pLimit == NULL) {
pSel->pLimit = sql_expr_new(TK_INTEGER,
&sqlIntTokens[1]);
ExprSetProperty(pSel->pLimit, EP_System);
if (pExpr->op == TK_SELECT) {
if (pSel->pLimit == NULL) {
pSel->pLimit = sql_expr_new_int(1);
ExprSetProperty(pSel->pLimit,
EP_System);
}
pSel->selFlags |= SF_SingleRow;
} else {
/*
* For EXISTS it doesn't matter whether we
* return one or more results, so just replace
* limit with 1.
*/
sql_expr_delete(pSel->pLimit);
pSel->pLimit = sql_expr_new_int(1);
}
pSel->selFlags |= SF_SingleRow;
pSel->iLimit = 0;
pSel->selFlags &= ~SF_MultiValue;
if (sqlSelect(pParse, pSel, &dest)) {
Expand Down
20 changes: 20 additions & 0 deletions test/sql-luatest/gh_8676_exists_in_multiselect_test.lua
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
local server = require('luatest.server')
local t = require('luatest')

local g = t.group()

g.before_all(function()
g.server = server:new({alias = 'master'})
g.server:start()
end)

g.after_all(function()
g.server:stop()
end)

g.test_exists = function()
g.server:exec(function()
local res = box.execute([[SELECT EXISTS (VALUES (1), (2));]])
t.assert_equals(res.rows, {{true}})
end)
end
40 changes: 20 additions & 20 deletions test/sql-tap/tkt1473.test.lua
Original file line number Diff line number Diff line change
Expand Up @@ -199,14 +199,14 @@ test:do_execsql_test(
-- </tkt1473-2.9>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-3.2",
[[
SELECT EXISTS
(SELECT 1 FROM t1 WHERE a=1 UNION ALL SELECT 2 FROM t1 WHERE b=0)
]], {
-- <tkt1473-3.2>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-3.2>
})

Expand All @@ -221,36 +221,36 @@ test:do_execsql_test(
-- </tkt1473-3.3>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-3.4",
[[
SELECT EXISTS
(SELECT 1 FROM t1 WHERE a=1 UNION ALL SELECT 2 FROM t1 WHERE b=4)
]], {
-- <tkt1473-3.4>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-3.4>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-3.5",
[[
SELECT EXISTS
(SELECT 1 FROM t1 WHERE a=1 UNION SELECT 2 FROM t1 WHERE b=4)
]], {
-- <tkt1473-3.5>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-3.5>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-3.6",
[[
SELECT EXISTS
(SELECT 1 FROM t1 WHERE a=0 UNION ALL SELECT 2 FROM t1 WHERE b=4)
]], {
-- <tkt1473-3.6>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-3.6>
})

Expand Down Expand Up @@ -483,7 +483,7 @@ test:do_execsql_test(
-- </tkt1473-4.7>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-5.3",
[[
SELECT EXISTS (
Expand All @@ -509,11 +509,11 @@ test:do_catchsql_test(
)
]], {
-- <tkt1473-5.3>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-5.3>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-5.4",
[[
SELECT EXISTS (
Expand All @@ -539,11 +539,11 @@ test:do_catchsql_test(
)
]], {
-- <tkt1473-5.4>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-5.4>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-5.5",
[[
SELECT EXISTS (
Expand All @@ -569,11 +569,11 @@ test:do_catchsql_test(
)
]], {
-- <tkt1473-5.5>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-5.5>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-5.6",
[[
SELECT EXISTS (
Expand All @@ -599,7 +599,7 @@ test:do_catchsql_test(
)
]], {
-- <tkt1473-5.6>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-5.6>
})

Expand Down Expand Up @@ -633,7 +633,7 @@ test:do_execsql_test(
-- </tkt1473-5.7>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-6.3",
[[
SELECT EXISTS (
Expand All @@ -659,11 +659,11 @@ test:do_catchsql_test(
)
]], {
-- <tkt1473-6.3>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-6.3>
})

test:do_catchsql_test(
test:do_execsql_test(
"tkt1473-6.4",
[[
SELECT EXISTS (
Expand All @@ -689,7 +689,7 @@ test:do_catchsql_test(
)
]], {
-- <tkt1473-6.4>
1, "Failed to execute SQL statement: Expression subquery returned more than 1 row"
true
-- </tkt1473-6.4>
})

Expand Down

0 comments on commit a5e498d

Please sign in to comment.