mirror of
https://github.com/sqlite/sqlite.git
synced 2025-07-30 19:03:16 +03:00
Refinements to NULL processing: NULLs are indistinct for DISTINCT and UNION.
Multiplying a NULL by zero yields zero. In a CASE expression, a NULL comparison is considered false, not NULL. With these changes, NULLs in SQLite now work the same as in PostgreSQL and in Oracle. (CVS 600) FossilOrigin-Name: da61aa1d238539dff9c43fd9f464d311e28d669f
This commit is contained in:
@ -11,7 +11,7 @@
|
||||
# This file implements regression tests for SQLite library. The
|
||||
# focus of this file is testing expressions.
|
||||
#
|
||||
# $Id: expr.test,v 1.23 2002/05/30 12:27:03 drh Exp $
|
||||
# $Id: expr.test,v 1.24 2002/05/31 15:51:26 drh Exp $
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
@ -337,23 +337,23 @@ test_expr expr-case.1 {i1=1, i2=2} \
|
||||
test_expr expr-case.2 {i1=2, i2=2} \
|
||||
{CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} eq
|
||||
test_expr expr-case.3 {i1=NULL, i2=2} \
|
||||
{CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} {{}}
|
||||
{CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} ne
|
||||
test_expr expr-case.4 {i1=2, i2=NULL} \
|
||||
{CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} {{}}
|
||||
{CASE WHEN i1 = i2 THEN 'eq' ELSE 'ne' END} ne
|
||||
test_expr expr-case.5 {i1=2} \
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 'error' END} two
|
||||
test_expr expr-case.6 {i1=1} \
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} one
|
||||
test_expr expr-case.7 {i1=2} \
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} {{}}
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} error
|
||||
test_expr expr-case.8 {i1=3} \
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} {{}}
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN NULL THEN 'two' ELSE 'error' END} error
|
||||
test_expr expr-case.9 {i1=3} \
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 'error' END} error
|
||||
test_expr expr-case.10 {i1=3} \
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' END} {{}}
|
||||
test_expr expr-case.11 {i1=null} \
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 3 END} {{}}
|
||||
{CASE i1 WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 3 END} 3
|
||||
test_expr expr-case.12 {i1=1} \
|
||||
{CASE i1 WHEN 1 THEN null WHEN 2 THEN 'two' ELSE 3 END} {{}}
|
||||
test_expr expr-case.13 {i1=7} \
|
||||
|
@ -13,7 +13,7 @@
|
||||
# aggregate min() and max() functions and which are handled as
|
||||
# as a special case.
|
||||
#
|
||||
# $Id: minmax.test,v 1.3 2002/05/29 23:22:23 drh Exp $
|
||||
# $Id: minmax.test,v 1.4 2002/05/31 15:51:26 drh Exp $
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
@ -128,5 +128,19 @@ do_test minmax-4.1 {
|
||||
(SELECT * FROM t1 UNION SELECT NULL as 'x', NULL as 'y')
|
||||
}
|
||||
} {1 20}
|
||||
do_test minmax-4.2 {
|
||||
execsql {
|
||||
SELECT y, sum(x) FROM
|
||||
(SELECT null, y+1 FROM t1 UNION SELECT * FROM t1)
|
||||
GROUP BY y ORDER BY y;
|
||||
}
|
||||
} {1 1 2 5 3 22 4 92 5 90 6 0}
|
||||
do_test minmax-4.3 {
|
||||
execsql {
|
||||
SELECT y, count(x), count(*) FROM
|
||||
(SELECT null, y+1 FROM t1 UNION SELECT * FROM t1)
|
||||
GROUP BY y ORDER BY y;
|
||||
}
|
||||
} {1 1 1 2 2 3 3 4 5 4 8 9 5 5 6 6 0 1}
|
||||
|
||||
finish_test
|
||||
|
183
test/null.test
Normal file
183
test/null.test
Normal file
@ -0,0 +1,183 @@
|
||||
# 2001 September 15
|
||||
#
|
||||
# The author disclaims copyright to this source code. In place of
|
||||
# a legal notice, here is a blessing:
|
||||
#
|
||||
# May you do good and not evil.
|
||||
# May you find forgiveness for yourself and forgive others.
|
||||
# May you share freely, never taking more than you give.
|
||||
#
|
||||
#***********************************************************************
|
||||
# This file implements regression tests for SQLite library.
|
||||
#
|
||||
# This file implements tests for proper treatment of the special
|
||||
# value NULL.
|
||||
#
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
|
||||
# Create a table and some data to work with.
|
||||
#
|
||||
do_test null-1.0 {
|
||||
execsql {
|
||||
begin;
|
||||
create table t1(a,b,c);
|
||||
insert into t1 values(1,0,0);
|
||||
insert into t1 values(2,0,1);
|
||||
insert into t1 values(3,1,0);
|
||||
insert into t1 values(4,1,1);
|
||||
insert into t1 values(5,null,0);
|
||||
insert into t1 values(6,null,1);
|
||||
insert into t1 values(7,null,null);
|
||||
commit;
|
||||
select * from t1;
|
||||
}
|
||||
} {1 0 0 2 0 1 3 1 0 4 1 1 5 {} 0 6 {} 1 7 {} {}}
|
||||
|
||||
# Check for how arithmetic expressions handle NULL
|
||||
#
|
||||
do_test null-1.1 {
|
||||
execsql {
|
||||
select ifnull(a+b,99) from t1;
|
||||
}
|
||||
} {1 2 4 5 99 99 99}
|
||||
do_test null-1.2 {
|
||||
execsql {
|
||||
select ifnull(b*c,99) from t1;
|
||||
}
|
||||
} {0 0 0 1 0 99 99}
|
||||
do_test null-1.2.1 {
|
||||
execsql {
|
||||
select ifnull(c*b,99) from t1;
|
||||
}
|
||||
} {0 0 0 1 0 99 99}
|
||||
|
||||
# Check to see how the CASE expression handles NULL values. The
|
||||
# first WHEN for which the test expression is TRUE is selected.
|
||||
# FALSE and UNKNOWN test expressions are skipped.
|
||||
#
|
||||
do_test null-2.1 {
|
||||
execsql {
|
||||
select ifnull(case when b<>0 then 1 else 0 end, 99) from t1;
|
||||
}
|
||||
} {0 0 1 1 0 0 0}
|
||||
do_test null-2.2 {
|
||||
execsql {
|
||||
select ifnull(case when not b<>0 then 1 else 0 end, 99) from t1;
|
||||
}
|
||||
} {1 1 0 0 0 0 0}
|
||||
do_test null-2.3 {
|
||||
execsql {
|
||||
select ifnull(case when b<>0 and c<>0 then 1 else 0 end, 99) from t1;
|
||||
}
|
||||
} {0 0 0 1 0 0 0}
|
||||
do_test null-2.4 {
|
||||
execsql {
|
||||
select ifnull(case when not (b<>0 and c<>0) then 1 else 0 end, 99) from t1;
|
||||
}
|
||||
} {1 1 1 0 1 0 0}
|
||||
do_test null-2.5 {
|
||||
execsql {
|
||||
select ifnull(case when b<>0 or c<>0 then 1 else 0 end, 99) from t1;
|
||||
}
|
||||
} {0 1 1 1 0 1 0}
|
||||
do_test null-2.6 {
|
||||
execsql {
|
||||
select ifnull(case when not (b<>0 or c<>0) then 1 else 0 end, 99) from t1;
|
||||
}
|
||||
} {1 0 0 0 0 0 0}
|
||||
do_test null-2.7 {
|
||||
execsql {
|
||||
select ifnull(case b when c then 1 else 0 end, 99) from t1;
|
||||
}
|
||||
} {1 0 0 1 0 0 0}
|
||||
do_test null-2.8 {
|
||||
execsql {
|
||||
select ifnull(case c when b then 1 else 0 end, 99) from t1;
|
||||
}
|
||||
} {1 0 0 1 0 0 0}
|
||||
|
||||
# Check to see that NULL values are ignored in aggregate functions.
|
||||
#
|
||||
do_test null-3.1 {
|
||||
execsql {
|
||||
select count(*), count(b), count(c), sum(b), sum(c),
|
||||
avg(b), avg(c), min(b), max(b) from t1;
|
||||
}
|
||||
} {7 4 6 2 3 0.5 0.5 0 1}
|
||||
|
||||
# Check to see how WHERE clauses handle NULL values. A NULL value
|
||||
# is the same as UNKNOWN. The WHERE clause should only select those
|
||||
# rows that are TRUE. FALSE and UNKNOWN rows are rejected.
|
||||
#
|
||||
do_test null-4.1 {
|
||||
execsql {
|
||||
select a from t1 where b<10
|
||||
}
|
||||
} {1 2 3 4}
|
||||
do_test null-4.2 {
|
||||
execsql {
|
||||
select a from t1 where not b>10
|
||||
}
|
||||
} {1 2 3 4}
|
||||
do_test null-4.3 {
|
||||
execsql {
|
||||
select a from t1 where b<10 or c=1;
|
||||
}
|
||||
} {1 2 3 4 6}
|
||||
do_test null-4.4 {
|
||||
execsql {
|
||||
select a from t1 where b<10 and c=1;
|
||||
}
|
||||
} {2 4}
|
||||
do_test null-4.5 {
|
||||
execsql {
|
||||
select a from t1 where not (b<10 and c=1);
|
||||
}
|
||||
} {1 3 5}
|
||||
|
||||
# The DISTINCT keyword on a SELECT statement should treat NULL values
|
||||
# as distinct
|
||||
#
|
||||
do_test null-5.1 {
|
||||
execsql {
|
||||
select distinct b from t1 order by b;
|
||||
}
|
||||
} {{} 0 1}
|
||||
|
||||
# A UNION to two queries should treat NULL values
|
||||
# as distinct
|
||||
#
|
||||
do_test null-6.1 {
|
||||
execsql {
|
||||
select b from t1 union select c from t1 order by c;
|
||||
}
|
||||
} {{} 0 1}
|
||||
|
||||
# The UNIQUE constraint only applies to non-null values
|
||||
#
|
||||
do_test null-7.1 {
|
||||
execsql {
|
||||
create table t2(a, b unique on conflict ignore);
|
||||
insert into t2 values(1,1);
|
||||
insert into t2 values(2,null);
|
||||
insert into t2 values(3,null);
|
||||
insert into t2 values(4,1);
|
||||
select a from t2;
|
||||
}
|
||||
} {1 2 3}
|
||||
do_test null-7.2 {
|
||||
execsql {
|
||||
create table t3(a, b, c, unique(b,c) on conflict ignore);
|
||||
insert into t3 values(1,1,1);
|
||||
insert into t3 values(2,null,1);
|
||||
insert into t3 values(3,null,1);
|
||||
insert into t3 values(4,1,1);
|
||||
select a from t3;
|
||||
}
|
||||
} {1 2 3}
|
||||
|
||||
|
||||
|
||||
finish_test
|
@ -12,7 +12,7 @@
|
||||
# focus of this file is testing UNION, INTERSECT and EXCEPT operators
|
||||
# in SELECT statements.
|
||||
#
|
||||
# $Id: select4.test,v 1.8 2002/05/27 01:04:51 drh Exp $
|
||||
# $Id: select4.test,v 1.9 2002/05/31 15:51:26 drh Exp $
|
||||
|
||||
set testdir [file dirname $argv0]
|
||||
source $testdir/tester.tcl
|
||||
@ -249,7 +249,8 @@ do_test select4-6.2 {
|
||||
}
|
||||
} {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
|
||||
|
||||
# NULLs are distinct. Make sure the UNION operator recognizes this
|
||||
# NULLs are indistinct for the UNION operator.
|
||||
# Make sure the UNION operator recognizes this
|
||||
#
|
||||
do_test select4-6.3 {
|
||||
execsql {
|
||||
@ -257,8 +258,8 @@ do_test select4-6.3 {
|
||||
SELECT 1 UNION SELECT 2 AS 'x'
|
||||
ORDER BY x;
|
||||
}
|
||||
} {{} {} 1 2}
|
||||
do_test select4-6.3 {
|
||||
} {{} 1 2}
|
||||
do_test select4-6.3.1 {
|
||||
execsql {
|
||||
SELECT NULL UNION ALL SELECT NULL UNION ALL
|
||||
SELECT 1 UNION ALL SELECT 2 AS 'x'
|
||||
@ -266,7 +267,7 @@ do_test select4-6.3 {
|
||||
}
|
||||
} {{} {} 1 2}
|
||||
|
||||
# Make sure the DISTINCT keyword treats NULLs as DISTINCT
|
||||
# Make sure the DISTINCT keyword treats NULLs as indistinct.
|
||||
#
|
||||
do_test select4-6.4 {
|
||||
execsql {
|
||||
@ -281,7 +282,7 @@ do_test select4-6.5 {
|
||||
SELECT NULL, 1 UNION ALL SELECT NULL, 1
|
||||
);
|
||||
}
|
||||
} {{} 1 {} 1}
|
||||
} {{} 1}
|
||||
do_test select4-6.6 {
|
||||
execsql {
|
||||
SELECT DISTINCT * FROM (
|
||||
@ -296,7 +297,7 @@ do_test select4-6.7 {
|
||||
execsql {
|
||||
SELECT NULL EXCEPT SELECT NULL
|
||||
}
|
||||
} {{}}
|
||||
} {}
|
||||
|
||||
|
||||
# Make sure column names are correct when a compound select appears as
|
||||
|
Reference in New Issue
Block a user