Skip to content

Commit

Permalink
Make SELECT TOP (NULL) throw error instead of returning all rows
Browse files Browse the repository at this point in the history
Previously, SELECT TOP (NULL) returned all rows. This commit makes it throw an error instead by adding a NULL-check in the execution of LIMIT node, and also in the planner because the planner by default skips building a LIMIT node if the LIMIT count is NULL.

Task: BABEL-1181
Author: Zitao Quan <qztao@amazon.com>
Signed-off-by: Sharu Goel <goelshar@amazon.com>
  • Loading branch information
thephantomthief authored and nasbyj committed Apr 13, 2022
1 parent 2755f80 commit bc997b0
Show file tree
Hide file tree
Showing 5 changed files with 229 additions and 13 deletions.
8 changes: 4 additions & 4 deletions contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-rule.y
Original file line number Diff line number Diff line change
Expand Up @@ -2731,11 +2731,11 @@ tsql_top_clause:
A_Const* n = (A_Const *)$3;
if(n->val.type == T_Integer && n->val.val.ival == 100)
{
$$ = makeNullAConst(@1);
$$ = NULL;
}
else if(n->val.type == T_Float && atof(n->val.val.str) == 100.0)
{
$$ = makeNullAConst(@1);
$$ = NULL;
}
else
{
Expand All @@ -2760,11 +2760,11 @@ tsql_top_clause:
A_Const* n = (A_Const *)$2;
if(n->val.type == T_Integer && n->val.val.ival == 100)
{
$$ = makeNullAConst(@1);
$$ = NULL;
}
else if(n->val.type == T_Float && atof(n->val.val.str) == 100.0)
{
$$ = makeNullAConst(@1);
$$ = NULL;
}
else
{
Expand Down
11 changes: 4 additions & 7 deletions test/JDBC/expected/BABEL-1161.out
Original file line number Diff line number Diff line change
Expand Up @@ -121,17 +121,14 @@ int


-- empty scalar subquery
-- note: we have a bug here: BABEL-1181
-- please update the comment and expected output once the bug is fixed.
-- SELECT TOP (NULL) should throw error
select top (select a from babel_1161_t31 where a2 = 'c') * from babel_1161_t32 order by b;
GO
~~START~~
int
1
2
3
4
~~END~~
~~ERROR (Code: 33557097)~~

~~ERROR (Message: A TOP or FETCH clause contains an invalid value.)~~


-- not a single row
Expand Down
146 changes: 146 additions & 0 deletions test/JDBC/expected/BABEL-1181.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,146 @@
create table t1 (a int);
insert into t1 values (1);
insert into t1 values (2);
insert into t1 values (3);
go
~~ROW COUNT: 1~~

~~ROW COUNT: 1~~

~~ROW COUNT: 1~~

-- top (2) should only return 2 rows
select top (2) * from t1;
go
~~START~~
int
1
2
~~END~~

-- top (NULL) should throw error
select top (NULL) * from t1;
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: A TOP or FETCH clause contains an invalid value.)~~


create table t2 (a int, b int);
insert into t2 values (1, NULL);
go
~~ROW COUNT: 1~~

-- top (1) should only return 1 row
select top (select a from t2) * from t1;
go
~~START~~
int
1
~~END~~

-- top (NULL) should throw error
select top (select b from t2) * from t1;
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: A TOP or FETCH clause contains an invalid value.)~~


declare @a int;
set @a = 1;
-- top (1) should only return 1 row
select top (@a) * from t1;
go
~~START~~
int
1
~~END~~

declare @a int;
set @a = NULL;
-- top (NULL) should throw error
select top (@a) * from t1;
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: A TOP or FETCH clause contains an invalid value.)~~


-- test CTE
create table t3 (a int, b int);
insert into t3 values (1, NULL);
insert into t3 values (100, 1);
insert into t3 values (200, 2);
go
~~ROW COUNT: 1~~

~~ROW COUNT: 1~~

~~ROW COUNT: 1~~

-- test TOP as part of query
-- top (1) should only return 1 row
with cte (cte_a) as (select a from t3 as cte)
select top (1) * from cte;
go
~~START~~
int
1
~~END~~

-- top (NULL) should throw error
with cte (cte_a) as (select a from t3 as cte)
select top (NULL) * from cte;
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: A TOP or FETCH clause contains an invalid value.)~~


-- test TOP as part of CTE
-- top (2) should only return 2 rows
with cte (cte_a) as (select top(2) a from t3 as cte)
select * from cte;
go
~~START~~
int
1
100
~~END~~

-- top (NULL) should throw error
with cte (cte_a) as (select top(NULL) a from t3 as cte)
select * from cte;
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: A TOP or FETCH clause contains an invalid value.)~~


-- test TOP as part of both CTE and query
-- top (1) should only return 1 row
with cte (cte_a) as (select top(2) a from t3 as cte)
select top(1) * from cte;
go
~~START~~
int
1
~~END~~

-- top (NULL) should throw error
with cte (cte_a) as (select top(2) a from t3 as cte)
select top(NULL) * from cte;
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: A TOP or FETCH clause contains an invalid value.)~~


-- cleanup
drop table t1;
drop table t2;
drop table t3;
go
3 changes: 1 addition & 2 deletions test/JDBC/input/BABEL-1161.sql
Original file line number Diff line number Diff line change
Expand Up @@ -97,8 +97,7 @@ select top (select a from babel_1161_t31 where a2 = 'b') * from babel_1161_t32 o
GO

-- empty scalar subquery
-- note: we have a bug here: BABEL-1181
-- please update the comment and expected output once the bug is fixed.
-- SELECT TOP (NULL) should throw error
select top (select a from babel_1161_t31 where a2 = 'c') * from babel_1161_t32 order by b;
GO

Expand Down
74 changes: 74 additions & 0 deletions test/JDBC/input/BABEL-1181.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
create table t1 (a int);
insert into t1 values (1);
insert into t1 values (2);
insert into t1 values (3);
go
-- top (2) should only return 2 rows
select top (2) * from t1;
go
-- top (NULL) should throw error
select top (NULL) * from t1;
go

create table t2 (a int, b int);
insert into t2 values (1, NULL);
go
-- top (1) should only return 1 row
select top (select a from t2) * from t1;
go
-- top (NULL) should throw error
select top (select b from t2) * from t1;
go

declare @a int;
set @a = 1;
-- top (1) should only return 1 row
select top (@a) * from t1;
go
declare @a int;
set @a = NULL;
-- top (NULL) should throw error
select top (@a) * from t1;
go

-- test CTE
create table t3 (a int, b int);
insert into t3 values (1, NULL);
insert into t3 values (100, 1);
insert into t3 values (200, 2);
go
-- test TOP as part of query
-- top (1) should only return 1 row
with cte (cte_a) as (select a from t3 as cte)
select top (1) * from cte;
go
-- top (NULL) should throw error
with cte (cte_a) as (select a from t3 as cte)
select top (NULL) * from cte;
go

-- test TOP as part of CTE
-- top (2) should only return 2 rows
with cte (cte_a) as (select top(2) a from t3 as cte)
select * from cte;
go
-- top (NULL) should throw error
with cte (cte_a) as (select top(NULL) a from t3 as cte)
select * from cte;
go

-- test TOP as part of both CTE and query
-- top (1) should only return 1 row
with cte (cte_a) as (select top(2) a from t3 as cte)
select top(1) * from cte;
go
-- top (NULL) should throw error
with cte (cte_a) as (select top(2) a from t3 as cte)
select top(NULL) * from cte;
go

-- cleanup
drop table t1;
drop table t2;
drop table t3;
go

0 comments on commit bc997b0

Please sign in to comment.