1
0
mirror of https://github.com/sqlite/sqlite.git synced 2025-07-30 19:03:16 +03:00

Some progress on user-defined collation sequences. (CVS 1544)

FossilOrigin-Name: c634e71f1909819fb55c728bc410e5cc390428e3
This commit is contained in:
danielk1977
2004-06-09 09:55:16 +00:00
parent 80242055e5
commit 0202b29ef7
24 changed files with 2456 additions and 293 deletions

226
test/collate1.test Normal file
View File

@ -0,0 +1,226 @@
#
# The author or author's hereby grant to the public domain a non-exclusive,
# fully paid-up, perpetual, license in the software and all related
# intellectual property to make, have made, use, have used, reproduce,
# prepare derivative works, distribute, perform and display the work.
#
#*************************************************************************
# This file implements regression tests for SQLite library. The
# focus of this file is testing the ORDER BY clause with
# user-defined collation sequences.
#
# $Id: collate1.test,v 1.1 2004/06/09 09:55:20 danielk1977 Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
#
# Tests are roughly organised as follows:
#
# collate1-1.* - Single-field ORDER BY with an explicit COLLATE clause.
# collate1-2.* - Multi-field ORDER BY with an explicit COLLATE clause.
# collate1-3.* - ORDER BY using a default collation type. Also that an
# explict collate type overrides a default collate type.
# collate1-4.* - ORDER BY using a data type.
#
#
# Collation type 'HEX'. If an argument can be interpreted as a hexadecimal
# number, then it is converted to one before the comparison is performed.
# Numbers are less than other strings. If neither argument is a number,
# [string compare] is used.
#
db collate HEX hex_collate
proc hex_collate {lhs rhs} {
set lhs_ishex [regexp {^(0x|)[1234567890abcdefABCDEF]+$} $lhs]
set rhs_ishex [regexp {^(0x|)[1234567890abcdefABCDEF]+$} $rhs]
if {$lhs_ishex && $rhs_ishex} {
set lhsx [scan $lhs %x]
set rhsx [scan $rhs %x]
if {$lhs < $rhs} {return -1}
if {$lhs == $rhs} {return 0}
if {$lhs > $rhs} {return 1}
}
if {$lhs_ishex} {
return -1;
}
if {$rhs_ishex} {
return 1;
}
return [string compare $lhs $rhs]
}
db function hex {format 0x%X}
# Mimic the SQLite 2 collation type NUMERIC.
db collate numeric numeric_collate
proc numeric_collate {lhs rhs} {
if {$lhs == $rhs} {return 0}
return [expr ($lhs>$rhs)?1:-1]
}
do_test collate1-1.0 {
execsql {
CREATE TABLE collate1t1(c1, c2);
INSERT INTO collate1t1 VALUES(45, hex(45));
INSERT INTO collate1t1 VALUES(NULL, NULL);
INSERT INTO collate1t1 VALUES(281, hex(281));
}
} {}
do_test collate1-1.1 {
execsql {
SELECT c2 FROM collate1t1 ORDER BY 1;
}
} {{} 0x119 0x2D}
do_test collate1-1.2 {
execsql {
SELECT c2 FROM collate1t1 ORDER BY 1 COLLATE hex;
}
} {{} 0x2D 0x119}
do_test collate1-1.3 {
execsql {
SELECT c2 FROM collate1t1 ORDER BY 1 COLLATE hex DESC;
}
} {0x119 0x2D {}}
do_test collate1-1.4 {
execsql {
SELECT c2 FROM collate1t1 ORDER BY 1 COLLATE hex ASC;
}
} {{} 0x2D 0x119}
do_test collate1-1.5 {
execsql {
DROP TABLE collate1t1;
}
} {}
do_test collate1-2.0 {
execsql {
CREATE TABLE collate1t1(c1, c2);
INSERT INTO collate1t1 VALUES('5', '0x11');
INSERT INTO collate1t1 VALUES('5', '0xA');
INSERT INTO collate1t1 VALUES(NULL, NULL);
INSERT INTO collate1t1 VALUES('7', '0xA');
INSERT INTO collate1t1 VALUES('11', '0x11');
INSERT INTO collate1t1 VALUES('11', '0x101');
}
} {}
do_test collate1-2.2 {
execsql {
SELECT c1, c2 FROM collate1t1 ORDER BY 1 COLLATE numeric, 2 COLLATE hex;
}
} {{} {} 5 0xA 5 0x11 7 0xA 11 0x11 11 0x101}
do_test collate1-2.3 {
execsql {
SELECT c1, c2 FROM collate1t1 ORDER BY 1 COLLATE binary, 2 COLLATE hex;
}
} {{} {} 11 0x11 11 0x101 5 0xA 5 0x11 7 0xA}
do_test collate1-2.4 {
execsql {
SELECT c1, c2 FROM collate1t1 ORDER BY 1 COLLATE binary DESC, 2 COLLATE hex;
}
} {7 0xA 5 0xA 5 0x11 11 0x11 11 0x101 {} {}}
do_test collate1-2.5 {
execsql {
SELECT c1, c2 FROM collate1t1
ORDER BY 1 COLLATE binary DESC, 2 COLLATE hex DESC;
}
} {7 0xA 5 0x11 5 0xA 11 0x101 11 0x11 {} {}}
do_test collate1-2.6 {
execsql {
SELECT c1, c2 FROM collate1t1
ORDER BY 1 COLLATE binary ASC, 2 COLLATE hex ASC;
}
} {{} {} 11 0x11 11 0x101 5 0xA 5 0x11 7 0xA}
do_test collate1-2.7 {
execsql {
DROP TABLE collate1t1;
}
} {}
#
# These tests ensure that the default collation type for a column is used
# by an ORDER BY clause correctly. The focus is all the different ways
# the column can be referenced. i.e. a, collate2t1.a, main.collate2t1.a etc.
#
do_test collate1-3.0 {
execsql {
CREATE TABLE collate1t1(a COLLATE hex, b);
INSERT INTO collate1t1 VALUES( '0x5', 5 );
INSERT INTO collate1t1 VALUES( '1', 1 );
INSERT INTO collate1t1 VALUES( '0x45', 69 );
INSERT INTO collate1t1 VALUES( NULL, NULL );
SELECT * FROM collate1t1 ORDER BY a;
}
} {{} {} 1 1 0x5 5 0x45 69}
do_test collate1-3.1 {
execsql {
SELECT * FROM collate1t1 ORDER BY 1;
}
} {{} {} 1 1 0x5 5 0x45 69}
do_test collate1-3.2 {
execsql {
SELECT * FROM collate1t1 ORDER BY collate1t1.a;
}
} {{} {} 1 1 0x5 5 0x45 69}
do_test collate1-3.3 {
execsql {
SELECT * FROM collate1t1 ORDER BY main.collate1t1.a;
}
} {{} {} 1 1 0x5 5 0x45 69}
do_test collate1-3.4 {
execsql {
SELECT a as c1, b as c2 FROM collate1t1 ORDER BY c1;
}
} {{} {} 1 1 0x5 5 0x45 69}
do_test collate1-3.5 {
execsql {
SELECT a as c1, b as c2 FROM collate1t1 ORDER BY c1 COLLATE binary;
}
} {{} {} 0x45 69 0x5 5 1 1}
do_test collate1-3.6 {
execsql {
DROP TABLE collate1t1;
}
} {}
# Update for SQLite version 3. The collate1-4.* test cases were written
# before manifest types were introduced. The following test cases still
# work, due to the 'affinity' mechanism, but they don't prove anything
# about collation sequences.
#
do_test collate1-4.0 {
execsql {
CREATE TABLE collate1t1(c1 numeric, c2 text);
INSERT INTO collate1t1 VALUES(1, 1);
INSERT INTO collate1t1 VALUES(12, 12);
INSERT INTO collate1t1 VALUES(NULL, NULL);
INSERT INTO collate1t1 VALUES(101, 101);
}
} {}
do_test collate1-4.1 {
execsql {
SELECT c1 FROM collate1t1 ORDER BY 1;
}
} {{} 1 12 101}
do_test collate1-4.2 {
execsql {
SELECT c2 FROM collate1t1 ORDER BY 1;
}
} {{} 1 101 12}
do_test collate1-4.3 {
execsql {
SELECT c2+0 FROM collate1t1 ORDER BY 1;
}
} {{} 1 12 101}
do_test collate1-4.4 {
execsql {
SELECT c1||'' FROM collate1t1 ORDER BY 1;
}
} {{} 1 101 12}
do_test collate1-4.5 {
execsql {
DROP TABLE collate1t1;
}
} {}
finish_test

604
test/collate2.test Normal file
View File

@ -0,0 +1,604 @@
#
# The author or author's hereby grant to the public domain a non-exclusive,
# fully paid-up, perpetual, license in the software and all related
# intellectual property to make, have made, use, have used, reproduce,
# prepare derivative works, distribute, perform and display the work.
#
#*************************************************************************
# This file implements regression tests for SQLite library. The
# focus of this file is testing comparison operators in expressions
# that use user-defined collation sequences.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
#
# Tests are organised as follows:
#
# collate2-1.* WHERE <expr> expressions (sqliteExprIfTrue).
# collate2-2.* WHERE NOT <expr> expressions (sqliteExprIfFalse).
# collate2-3.* SELECT <expr> expressions (sqliteExprCode).
# collate2-4.* Precedence of collation/data types in binary comparisons
# collate2-5.* JOIN syntax.
#
# Create a collation type BACKWARDS for use in testing. This collation type
# is similar to the built-in TEXT collation type except the order of
# characters in each string is reversed before the comparison is performed.
db collate BACKWARDS backwards_collate
proc backwards_collate {a b} {
set ra {};
set rb {}
foreach c [split $a {}] { set ra $c$ra }
foreach c [split $b {}] { set rb $c$rb }
return [string compare $ra $rb]
}
# The following values are used in these tests:
# NULL aa ab ba bb aA aB bA bB Aa Ab Ba Bb AA AB BA BB
#
# The collation orders for each of the tested collation types are:
#
# BINARY: NULL AA AB Aa Ab BA BB Ba Bb aA aB aa ab bA bB ba bb
# NOCASE: NULL aa aA Aa AA ab aB Ab AB ba bA Ba BA bb bB Bb BB
# BACKWARDS: NULL AA BA aA bA AB BB aB bB Aa Ba aa ba Ab Bb ab bb
#
# These tests verify that the default collation type for a column is used
# for comparison operators (<, >, <=, >=, =) involving that column and
# an expression that is not a column with a default collation type.
#
# The collation sequences BINARY and NOCASE are built-in, the BACKWARDS
# collation sequence is implemented by the TCL proc backwards_collate
# above.
#
do_test collate2-1.0 {
execsql {
CREATE TABLE collate2t1(
a COLLATE BINARY,
b COLLATE NOCASE,
c COLLATE BACKWARDS
);
INSERT INTO collate2t1 VALUES( NULL, NULL, NULL );
INSERT INTO collate2t1 VALUES( 'aa', 'aa', 'aa' );
INSERT INTO collate2t1 VALUES( 'ab', 'ab', 'ab' );
INSERT INTO collate2t1 VALUES( 'ba', 'ba', 'ba' );
INSERT INTO collate2t1 VALUES( 'bb', 'bb', 'bb' );
INSERT INTO collate2t1 VALUES( 'aA', 'aA', 'aA' );
INSERT INTO collate2t1 VALUES( 'aB', 'aB', 'aB' );
INSERT INTO collate2t1 VALUES( 'bA', 'bA', 'bA' );
INSERT INTO collate2t1 VALUES( 'bB', 'bB', 'bB' );
INSERT INTO collate2t1 VALUES( 'Aa', 'Aa', 'Aa' );
INSERT INTO collate2t1 VALUES( 'Ab', 'Ab', 'Ab' );
INSERT INTO collate2t1 VALUES( 'Ba', 'Ba', 'Ba' );
INSERT INTO collate2t1 VALUES( 'Bb', 'Bb', 'Bb' );
INSERT INTO collate2t1 VALUES( 'AA', 'AA', 'AA' );
INSERT INTO collate2t1 VALUES( 'AB', 'AB', 'AB' );
INSERT INTO collate2t1 VALUES( 'BA', 'BA', 'BA' );
INSERT INTO collate2t1 VALUES( 'BB', 'BB', 'BB' );
}
if {[info exists collate_test_use_index]} {
execsql {
CREATE INDEX collate2t1_i1 ON collate2t1(a);
CREATE INDEX collate2t1_i2 ON collate2t1(b);
CREATE INDEX collate2t1_i3 ON collate2t1(c);
}
}
} {}
do_test collate2-1.1 {
execsql {
SELECT a FROM collate2t1 WHERE a > 'aa' ORDER BY 1;
}
} {ab bA bB ba bb}
do_test collate2-1.2 {
execsql {
SELECT b FROM collate2t1 WHERE b > 'aa' ORDER BY 1, oid;
}
} {ab aB Ab AB ba bA Ba BA bb bB Bb BB}
do_test collate2-1.3 {
execsql {
SELECT c FROM collate2t1 WHERE c > 'aa' ORDER BY 1;
}
} {ba Ab Bb ab bb}
do_test collate2-1.4 {
execsql {
SELECT a FROM collate2t1 WHERE a < 'aa' ORDER BY 1;
}
} {AA AB Aa Ab BA BB Ba Bb aA aB}
do_test collate2-1.5 {
execsql {
SELECT b FROM collate2t1 WHERE b < 'aa' ORDER BY 1, oid;
}
} {}
do_test collate2-1.6 {
execsql {
SELECT c FROM collate2t1 WHERE c < 'aa' ORDER BY 1;
}
} {AA BA aA bA AB BB aB bB Aa Ba}
do_test collate2-1.7 {
execsql {
SELECT a FROM collate2t1 WHERE a = 'aa';
}
} {aa}
do_test collate2-1.8 {
execsql {
SELECT b FROM collate2t1 WHERE b = 'aa' ORDER BY oid;
}
} {aa aA Aa AA}
do_test collate2-1.9 {
execsql {
SELECT c FROM collate2t1 WHERE c = 'aa';
}
} {aa}
do_test collate2-1.10 {
execsql {
SELECT a FROM collate2t1 WHERE a >= 'aa' ORDER BY 1;
}
} {aa ab bA bB ba bb}
do_test collate2-1.11 {
execsql {
SELECT b FROM collate2t1 WHERE b >= 'aa' ORDER BY 1, oid;
}
} {aa aA Aa AA ab aB Ab AB ba bA Ba BA bb bB Bb BB}
do_test collate2-1.12 {
execsql {
SELECT c FROM collate2t1 WHERE c >= 'aa' ORDER BY 1;
}
} {aa ba Ab Bb ab bb}
do_test collate2-1.13 {
execsql {
SELECT a FROM collate2t1 WHERE a <= 'aa' ORDER BY 1;
}
} {AA AB Aa Ab BA BB Ba Bb aA aB aa}
do_test collate2-1.14 {
execsql {
SELECT b FROM collate2t1 WHERE b <= 'aa' ORDER BY 1, oid;
}
} {aa aA Aa AA}
do_test collate2-1.15 {
execsql {
SELECT c FROM collate2t1 WHERE c <= 'aa' ORDER BY 1;
}
} {AA BA aA bA AB BB aB bB Aa Ba aa}
do_test collate2-1.16 {
execsql {
SELECT a FROM collate2t1 WHERE a BETWEEN 'Aa' AND 'Bb' ORDER BY 1;
}
} {Aa Ab BA BB Ba Bb}
do_test collate2-1.17 {
execsql {
SELECT b FROM collate2t1 WHERE b BETWEEN 'Aa' AND 'Bb' ORDER BY 1, oid;
}
} {aa aA Aa AA ab aB Ab AB ba bA Ba BA bb bB Bb BB}
do_test collate2-1.18 {
execsql {
SELECT c FROM collate2t1 WHERE c BETWEEN 'Aa' AND 'Bb' ORDER BY 1;
}
} {Aa Ba aa ba Ab Bb}
do_test collate2-1.19 {
execsql {
SELECT a FROM collate2t1 WHERE
CASE a WHEN 'aa' THEN 1 ELSE 0 END
ORDER BY 1, oid;
}
} {aa}
do_test collate2-1.20 {
execsql {
SELECT b FROM collate2t1 WHERE
CASE b WHEN 'aa' THEN 1 ELSE 0 END
ORDER BY 1, oid;
}
} {aa aA Aa AA}
do_test collate2-1.21 {
execsql {
SELECT c FROM collate2t1 WHERE
CASE c WHEN 'aa' THEN 1 ELSE 0 END
ORDER BY 1, oid;
}
} {aa}
do_test collate2-1.22 {
execsql {
SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb') ORDER BY 1, oid;
}
} {aa bb}
do_test collate2-1.23 {
execsql {
SELECT b FROM collate2t1 WHERE b IN ('aa', 'bb') ORDER BY 1, oid;
}
} {aa aA Aa AA bb bB Bb BB}
do_test collate2-1.24 {
execsql {
SELECT c FROM collate2t1 WHERE c IN ('aa', 'bb') ORDER BY 1, oid;
}
} {aa bb}
do_test collate2-1.25 {
execsql {
SELECT a FROM collate2t1
WHERE a IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'));
}
} {aa bb}
do_test collate2-1.26 {
execsql {
SELECT b FROM collate2t1
WHERE b IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'));
}
} {aa bb aA bB Aa Bb AA BB}
do_test collate2-1.27 {
execsql {
SELECT c FROM collate2t1
WHERE c IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'));
}
} {aa bb}
do_test collate2-2.1 {
execsql {
SELECT a FROM collate2t1 WHERE NOT a > 'aa' ORDER BY 1;
}
} {AA AB Aa Ab BA BB Ba Bb aA aB aa}
do_test collate2-2.2 {
execsql {
SELECT b FROM collate2t1 WHERE NOT b > 'aa' ORDER BY 1, oid;
}
} {aa aA Aa AA}
do_test collate2-2.3 {
execsql {
SELECT c FROM collate2t1 WHERE NOT c > 'aa' ORDER BY 1;
}
} {AA BA aA bA AB BB aB bB Aa Ba aa}
do_test collate2-2.4 {
execsql {
SELECT a FROM collate2t1 WHERE NOT a < 'aa' ORDER BY 1;
}
} {aa ab bA bB ba bb}
do_test collate2-2.5 {
execsql {
SELECT b FROM collate2t1 WHERE NOT b < 'aa' ORDER BY 1, oid;
}
} {aa aA Aa AA ab aB Ab AB ba bA Ba BA bb bB Bb BB}
do_test collate2-2.6 {
execsql {
SELECT c FROM collate2t1 WHERE NOT c < 'aa' ORDER BY 1;
}
} {aa ba Ab Bb ab bb}
do_test collate2-2.7 {
execsql {
SELECT a FROM collate2t1 WHERE NOT a = 'aa';
}
} {ab ba bb aA aB bA bB Aa Ab Ba Bb AA AB BA BB}
do_test collate2-2.8 {
execsql {
SELECT b FROM collate2t1 WHERE NOT b = 'aa';
}
} {ab ba bb aB bA bB Ab Ba Bb AB BA BB}
do_test collate2-2.9 {
execsql {
SELECT c FROM collate2t1 WHERE NOT c = 'aa';
}
} {ab ba bb aA aB bA bB Aa Ab Ba Bb AA AB BA BB}
do_test collate2-2.10 {
execsql {
SELECT a FROM collate2t1 WHERE NOT a >= 'aa' ORDER BY 1;
}
} {AA AB Aa Ab BA BB Ba Bb aA aB}
do_test collate2-2.11 {
execsql {
SELECT b FROM collate2t1 WHERE NOT b >= 'aa' ORDER BY 1, oid;
}
} {}
do_test collate2-2.12 {
execsql {
SELECT c FROM collate2t1 WHERE NOT c >= 'aa' ORDER BY 1;
}
} {AA BA aA bA AB BB aB bB Aa Ba}
do_test collate2-2.13 {
execsql {
SELECT a FROM collate2t1 WHERE NOT a <= 'aa' ORDER BY 1;
}
} {ab bA bB ba bb}
do_test collate2-2.14 {
execsql {
SELECT b FROM collate2t1 WHERE NOT b <= 'aa' ORDER BY 1, oid;
}
} {ab aB Ab AB ba bA Ba BA bb bB Bb BB}
do_test collate2-2.15 {
execsql {
SELECT c FROM collate2t1 WHERE NOT c <= 'aa' ORDER BY 1;
}
} {ba Ab Bb ab bb}
do_test collate2-2.16 {
execsql {
SELECT a FROM collate2t1 WHERE a NOT BETWEEN 'Aa' AND 'Bb' ORDER BY 1;
}
} {AA AB aA aB aa ab bA bB ba bb}
do_test collate2-2.17 {
execsql {
SELECT b FROM collate2t1 WHERE b NOT BETWEEN 'Aa' AND 'Bb' ORDER BY 1, oid;
}
} {}
do_test collate2-2.18 {
execsql {
SELECT c FROM collate2t1 WHERE c NOT BETWEEN 'Aa' AND 'Bb' ORDER BY 1;
}
} {AA BA aA bA AB BB aB bB ab bb}
do_test collate2-2.19 {
execsql {
SELECT a FROM collate2t1 WHERE NOT CASE a WHEN 'aa' THEN 1 ELSE 0 END;
}
} {{} ab ba bb aA aB bA bB Aa Ab Ba Bb AA AB BA BB}
do_test collate2-2.20 {
execsql {
SELECT b FROM collate2t1 WHERE NOT CASE b WHEN 'aa' THEN 1 ELSE 0 END;
}
} {{} ab ba bb aB bA bB Ab Ba Bb AB BA BB}
do_test collate2-2.21 {
execsql {
SELECT c FROM collate2t1 WHERE NOT CASE c WHEN 'aa' THEN 1 ELSE 0 END;
}
} {{} ab ba bb aA aB bA bB Aa Ab Ba Bb AA AB BA BB}
do_test collate2-2.22 {
execsql {
SELECT a FROM collate2t1 WHERE NOT a IN ('aa', 'bb');
}
} {ab ba aA aB bA bB Aa Ab Ba Bb AA AB BA BB}
do_test collate2-2.23 {
execsql {
SELECT b FROM collate2t1 WHERE NOT b IN ('aa', 'bb');
}
} {ab ba aB bA Ab Ba AB BA}
do_test collate2-2.24 {
execsql {
SELECT c FROM collate2t1 WHERE NOT c IN ('aa', 'bb');
}
} {ab ba aA aB bA bB Aa Ab Ba Bb AA AB BA BB}
do_test collate2-2.25 {
execsql {
SELECT a FROM collate2t1
WHERE NOT a IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'));
}
} {ab ba aA aB bA bB Aa Ab Ba Bb AA AB BA BB}
do_test collate2-2.26 {
execsql {
SELECT b FROM collate2t1
WHERE NOT b IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'));
}
} {ab ba aB bA Ab Ba AB BA}
do_test collate2-2.27 {
execsql {
SELECT c FROM collate2t1
WHERE NOT c IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'));
}
} {ab ba aA aB bA bB Aa Ab Ba Bb AA AB BA BB}
do_test collate2-3.1 {
execsql {
SELECT a > 'aa' FROM collate2t1;
}
} {{} 0 1 1 1 0 0 1 1 0 0 0 0 0 0 0 0}
do_test collate2-3.2 {
execsql {
SELECT b > 'aa' FROM collate2t1;
}
} {{} 0 1 1 1 0 1 1 1 0 1 1 1 0 1 1 1}
do_test collate2-3.3 {
execsql {
SELECT c > 'aa' FROM collate2t1;
}
} {{} 0 1 1 1 0 0 0 0 0 1 0 1 0 0 0 0}
do_test collate2-3.4 {
execsql {
SELECT a < 'aa' FROM collate2t1;
}
} {{} 0 0 0 0 1 1 0 0 1 1 1 1 1 1 1 1}
do_test collate2-3.5 {
execsql {
SELECT b < 'aa' FROM collate2t1;
}
} {{} 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-3.6 {
execsql {
SELECT c < 'aa' FROM collate2t1;
}
} {{} 0 0 0 0 1 1 1 1 1 0 1 0 1 1 1 1}
do_test collate2-3.7 {
execsql {
SELECT a = 'aa' FROM collate2t1;
}
} {{} 1 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-3.8 {
execsql {
SELECT b = 'aa' FROM collate2t1;
}
} {{} 1 0 0 0 1 0 0 0 1 0 0 0 1 0 0 0}
do_test collate2-3.9 {
execsql {
SELECT c = 'aa' FROM collate2t1;
}
} {{} 1 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-3.10 {
execsql {
SELECT a <= 'aa' FROM collate2t1;
}
} {{} 1 0 0 0 1 1 0 0 1 1 1 1 1 1 1 1}
do_test collate2-3.11 {
execsql {
SELECT b <= 'aa' FROM collate2t1;
}
} {{} 1 0 0 0 1 0 0 0 1 0 0 0 1 0 0 0}
do_test collate2-3.12 {
execsql {
SELECT c <= 'aa' FROM collate2t1;
}
} {{} 1 0 0 0 1 1 1 1 1 0 1 0 1 1 1 1}
do_test collate2-3.13 {
execsql {
SELECT a >= 'aa' FROM collate2t1;
}
} {{} 1 1 1 1 0 0 1 1 0 0 0 0 0 0 0 0}
do_test collate2-3.14 {
execsql {
SELECT b >= 'aa' FROM collate2t1;
}
} {{} 1 1 1 1 1 1 1 1 1 1 1 1 1 1 1 1}
do_test collate2-3.15 {
execsql {
SELECT c >= 'aa' FROM collate2t1;
}
} {{} 1 1 1 1 0 0 0 0 0 1 0 1 0 0 0 0}
do_test collate2-3.16 {
execsql {
SELECT a BETWEEN 'Aa' AND 'Bb' FROM collate2t1;
}
} {{} 0 0 0 0 0 0 0 0 1 1 1 1 0 0 1 1}
do_test collate2-3.17 {
execsql {
SELECT b BETWEEN 'Aa' AND 'Bb' FROM collate2t1;
}
} {{} 1 1 1 1 1 1 1 1 1 1 1 1 1 1 1 1}
do_test collate2-3.18 {
execsql {
SELECT c BETWEEN 'Aa' AND 'Bb' FROM collate2t1;
}
} {{} 1 0 1 0 0 0 0 0 1 1 1 1 0 0 0 0}
do_test collate2-3.19 {
execsql {
SELECT CASE a WHEN 'aa' THEN 1 ELSE 0 END FROM collate2t1;
}
} {0 1 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-3.20 {
execsql {
SELECT CASE b WHEN 'aa' THEN 1 ELSE 0 END FROM collate2t1;
}
} {0 1 0 0 0 1 0 0 0 1 0 0 0 1 0 0 0}
do_test collate2-3.21 {
execsql {
SELECT CASE c WHEN 'aa' THEN 1 ELSE 0 END FROM collate2t1;
}
} {0 1 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-3.22 {
execsql {
SELECT a IN ('aa', 'bb') FROM collate2t1;
}
} {{} 1 0 0 1 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-3.23 {
execsql {
SELECT b IN ('aa', 'bb') FROM collate2t1;
}
} {{} 1 0 0 1 1 0 0 1 1 0 0 1 1 0 0 1}
do_test collate2-3.24 {
execsql {
SELECT c IN ('aa', 'bb') FROM collate2t1;
}
} {{} 1 0 0 1 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-3.25 {
execsql {
SELECT a IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'))
FROM collate2t1;
}
} {{} 1 0 0 1 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-3.26 {
execsql {
SELECT b IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'))
FROM collate2t1;
}
} {{} 1 0 0 1 1 0 0 1 1 0 0 1 1 0 0 1}
do_test collate2-3.27 {
execsql {
SELECT c IN (SELECT a FROM collate2t1 WHERE a IN ('aa', 'bb'))
FROM collate2t1;
}
} {{} 1 0 0 1 0 0 0 0 0 0 0 0 0 0 0 0}
do_test collate2-4.0 {
execsql {
CREATE TABLE collate2t2(b COLLATE binary);
CREATE TABLE collate2t3(b text);
INSERT INTO collate2t2 VALUES('aa');
INSERT INTO collate2t3 VALUES('aa');
}
} {}
# Test that when both sides of a binary comparison operator have
# default collation types, the collate type for the leftmost term
# is used.
do_test collate2-4.1 {
execsql {
SELECT collate2t1.a FROM collate2t1, collate2t2
WHERE collate2t1.b = collate2t2.b;
}
} {aa aA Aa AA}
do_test collate2-4.2 {
execsql {
SELECT collate2t1.a FROM collate2t1, collate2t2
WHERE collate2t2.b = collate2t1.b;
}
} {aa}
# Test that when one side has a default collation type and the other
# does not, the collation type is used.
do_test collate2-4.3 {
execsql {
SELECT collate2t1.a FROM collate2t1, collate2t3
WHERE collate2t1.b = collate2t3.b||'';
}
} {aa aA Aa AA}
do_test collate2-4.4 {
execsql {
SELECT collate2t1.a FROM collate2t1, collate2t3
WHERE collate2t3.b||'' = collate2t1.b;
}
} {aa aA Aa AA}
do_test collate2-4.5 {
execsql {
DROP TABLE collate2t3;
}
} {}
#
# Test that the default collation types are used when the JOIN syntax
# is used in place of a WHERE clause.
#
# SQLite transforms the JOIN syntax into a WHERE clause internally, so
# the focus of these tests is to ensure that the table on the left-hand-side
# of the join determines the collation type used.
#
do_test collate2-5.0 {
execsql {
SELECT collate2t1.b FROM collate2t1 JOIN collate2t2 USING (b);
}
} {aa aA Aa AA}
do_test collate2-5.1 {
execsql {
SELECT collate2t1.b FROM collate2t2 JOIN collate2t1 USING (b);
}
} {aa}
do_test collate2-5.2 {
execsql {
SELECT collate2t1.b FROM collate2t1 NATURAL JOIN collate2t2;
}
} {aa aA Aa AA}
do_test collate2-5.3 {
execsql {
SELECT collate2t1.b FROM collate2t2 NATURAL JOIN collate2t1;
}
} {aa}
do_test collate2-5.4 {
execsql {
SELECT collate2t2.b FROM collate2t1 LEFT OUTER JOIN collate2t2 USING (b) order by collate2t1.oid;
}
} {{} aa {} {} {} aa {} {} {} aa {} {} {} aa {} {} {}}
do_test collate2-5.5 {
execsql {
SELECT collate2t1.b, collate2t2.b FROM collate2t2 LEFT OUTER JOIN collate2t1 USING (b);
}
} {aa aa}
finish_test

860
test/collate4.test Normal file
View File

@ -0,0 +1,860 @@
#
# The author or author's hereby grant to the public domain a non-exclusive,
# fully paid-up, perpetual, license in the software and all related
# intellectual property to make, have made, use, have used, reproduce,
# prepare derivative works, distribute, perform and display the work.
#
#*************************************************************************
# This file implements regression tests for SQLite library. The
# focus of this file is testing indices that use user-defined collation
# sequences.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
db collate TEXT text_collate
proc text_collate {a b} {
return [string compare $a $b]
}
# Do an SQL statement. Append the search count to the end of the result.
#
proc count sql {
set ::sqlite_search_count 0
return [concat [execsql $sql] $::sqlite_search_count]
}
# This procedure executes the SQL. Then it checks the generated program
# for the SQL and appends a "nosort" to the result if the program contains the
# SortCallback opcode. If the program does not contain the SortCallback
# opcode it appends "sort"
#
proc cksort {sql} {
set data [execsql $sql]
set prog [execsql "EXPLAIN $sql"]
if {[regexp Sort $prog]} {set x sort} {set x nosort}
lappend data $x
return $data
}
#
# Test cases are organized roughly as follows:
#
# collate4-1.* ORDER BY.
# collate4-2.* WHERE clauses.
# collate4-3.* constraints (primary key, unique).
# collate4-4.* simple min() or max() queries.
# collate4-5.* REINDEX command
# collate4-6.* INTEGER PRIMARY KEY indices.
#
#
# These tests - collate4-1.* - check that indices are correctly
# selected or not selected to implement ORDER BY clauses when
# user defined collation sequences are involved.
#
# Because these tests also exercise all the different ways indices
# can be created, they also serve to verify that indices are correctly
# initialised with user-defined collation sequences when they are
# created.
#
# Tests named collate4-1.1.* use indices with a single column. Tests
# collate4-1.2.* use indices with two columns.
#
do_test collate4-1.1.0 {
execsql {
CREATE TABLE collate4t1(a COLLATE NOCASE, b COLLATE TEXT);
INSERT INTO collate4t1 VALUES( 'a', 'a' );
INSERT INTO collate4t1 VALUES( 'b', 'b' );
INSERT INTO collate4t1 VALUES( NULL, NULL );
INSERT INTO collate4t1 VALUES( 'B', 'B' );
INSERT INTO collate4t1 VALUES( 'A', 'A' );
CREATE INDEX collate4i1 ON collate4t1(a);
CREATE INDEX collate4i2 ON collate4t1(b);
}
} {}
do_test collate4-1.1.1 {
cksort {SELECT a FROM collate4t1 ORDER BY a}
} {{} a A b B nosort}
do_test collate4-1.1.2 {
cksort {SELECT a FROM collate4t1 ORDER BY a COLLATE NOCASE}
} {{} a A b B nosort}
do_test collate4-1.1.3 {
cksort {SELECT a FROM collate4t1 ORDER BY a COLLATE TEXT}
} {{} A B a b sort}
do_test collate4-1.1.4 {
cksort {SELECT b FROM collate4t1 ORDER BY b}
} {{} A B a b nosort}
do_test collate4-1.1.5 {
cksort {SELECT b FROM collate4t1 ORDER BY b COLLATE TEXT}
} {{} A B a b nosort}
do_test collate4-1.1.6 {
cksort {SELECT b FROM collate4t1 ORDER BY b COLLATE NOCASE}
} {{} A a B b sort}
do_test collate4-1.1.7 {
execsql {
CREATE TABLE collate4t2(
a PRIMARY KEY COLLATE NOCASE,
b UNIQUE COLLATE TEXT
);
INSERT INTO collate4t2 VALUES( 'a', 'a' );
INSERT INTO collate4t2 VALUES( NULL, NULL );
INSERT INTO collate4t2 VALUES( 'B', 'B' );
}
} {}
do_test collate4-1.1.8 {
cksort {SELECT a FROM collate4t2 ORDER BY a}
} {{} a B nosort}
do_test collate4-1.1.9 {
cksort {SELECT a FROM collate4t2 ORDER BY a COLLATE NOCASE}
} {{} a B nosort}
do_test collate4-1.1.10 {
cksort {SELECT a FROM collate4t2 ORDER BY a COLLATE TEXT}
} {{} B a sort}
do_test collate4-1.1.11 {
cksort {SELECT b FROM collate4t2 ORDER BY b}
} {{} B a nosort}
do_test collate4-1.1.12 {
cksort {SELECT b FROM collate4t2 ORDER BY b COLLATE TEXT}
} {{} B a nosort}
do_test collate4-1.1.13 {
cksort {SELECT b FROM collate4t2 ORDER BY b COLLATE NOCASE}
} {{} a B sort}
do_test collate4-1.1.14 {
execsql {
CREATE TABLE collate4t3(
b COLLATE TEXT,
a COLLATE NOCASE,
UNIQUE(a), PRIMARY KEY(b)
);
INSERT INTO collate4t3 VALUES( 'a', 'a' );
INSERT INTO collate4t3 VALUES( NULL, NULL );
INSERT INTO collate4t3 VALUES( 'B', 'B' );
}
} {}
do_test collate4-1.1.15 {
cksort {SELECT a FROM collate4t3 ORDER BY a}
} {{} a B nosort}
do_test collate4-1.1.16 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE NOCASE}
} {{} a B nosort}
do_test collate4-1.1.17 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE TEXT}
} {{} B a sort}
do_test collate4-1.1.18 {
cksort {SELECT b FROM collate4t3 ORDER BY b}
} {{} B a nosort}
do_test collate4-1.1.19 {
cksort {SELECT b FROM collate4t3 ORDER BY b COLLATE TEXT}
} {{} B a nosort}
do_test collate4-1.1.20 {
cksort {SELECT b FROM collate4t3 ORDER BY b COLLATE NOCASE}
} {{} a B sort}
do_test collate4-1.1.21 {
execsql {
CREATE TABLE collate4t4(a COLLATE NOCASE, b COLLATE TEXT);
INSERT INTO collate4t4 VALUES( 'a', 'a' );
INSERT INTO collate4t4 VALUES( 'b', 'b' );
INSERT INTO collate4t4 VALUES( NULL, NULL );
INSERT INTO collate4t4 VALUES( 'B', 'B' );
INSERT INTO collate4t4 VALUES( 'A', 'A' );
CREATE INDEX collate4i3 ON collate4t4(a COLLATE TEXT);
CREATE INDEX collate4i4 ON collate4t4(b COLLATE NOCASE);
}
} {}
do_test collate4-1.1.22 {
cksort {SELECT a FROM collate4t4 ORDER BY a}
} {{} A a B b sort}
do_test collate4-1.1.23 {
cksort {SELECT a FROM collate4t4 ORDER BY a COLLATE NOCASE}
} {{} A a B b sort}
do_test collate4-1.1.24 {
cksort {SELECT a FROM collate4t4 ORDER BY a COLLATE TEXT}
} {{} A B a b nosort}
do_test collate4-1.1.25 {
cksort {SELECT b FROM collate4t4 ORDER BY b}
} {{} A B a b sort}
do_test collate4-1.1.26 {
cksort {SELECT b FROM collate4t4 ORDER BY b COLLATE TEXT}
} {{} A B a b sort}
do_test collate4-1.1.27 {
cksort {SELECT b FROM collate4t4 ORDER BY b COLLATE NOCASE}
} {{} a A b B nosort}
do_test collate4-1.1.30 {
execsql {
DROP TABLE collate4t1;
DROP TABLE collate4t2;
DROP TABLE collate4t3;
DROP TABLE collate4t4;
}
} {}
do_test collate4-1.2.0 {
execsql {
CREATE TABLE collate4t1(a COLLATE NOCASE, b COLLATE TEXT);
INSERT INTO collate4t1 VALUES( 'a', 'a' );
INSERT INTO collate4t1 VALUES( 'b', 'b' );
INSERT INTO collate4t1 VALUES( NULL, NULL );
INSERT INTO collate4t1 VALUES( 'B', 'B' );
INSERT INTO collate4t1 VALUES( 'A', 'A' );
CREATE INDEX collate4i1 ON collate4t1(a, b);
}
} {}
do_test collate4-1.2.1 {
cksort {SELECT a FROM collate4t1 ORDER BY a}
} {{} A a B b nosort}
do_test collate4-1.2.2 {
cksort {SELECT a FROM collate4t1 ORDER BY a COLLATE nocase}
} {{} A a B b nosort}
do_test collate4-1.2.3 {
cksort {SELECT a FROM collate4t1 ORDER BY a COLLATE text}
} {{} A B a b sort}
do_test collate4-1.2.4 {
cksort {SELECT a FROM collate4t1 ORDER BY a, b}
} {{} A a B b nosort}
do_test collate4-1.2.5 {
cksort {SELECT a FROM collate4t1 ORDER BY a, b COLLATE nocase}
} {{} A a B b sort}
do_test collate4-1.2.6 {
cksort {SELECT a FROM collate4t1 ORDER BY a, b COLLATE text}
} {{} A a B b nosort}
do_test collate4-1.2.7 {
execsql {
CREATE TABLE collate4t2(
a COLLATE NOCASE,
b COLLATE TEXT,
PRIMARY KEY(a, b)
);
INSERT INTO collate4t2 VALUES( 'a', 'a' );
INSERT INTO collate4t2 VALUES( NULL, NULL );
INSERT INTO collate4t2 VALUES( 'B', 'B' );
}
} {}
do_test collate4-1.2.8 {
cksort {SELECT a FROM collate4t2 ORDER BY a}
} {{} a B nosort}
do_test collate4-1.2.9 {
cksort {SELECT a FROM collate4t2 ORDER BY a COLLATE nocase}
} {{} a B nosort}
do_test collate4-1.2.10 {
cksort {SELECT a FROM collate4t2 ORDER BY a COLLATE text}
} {{} B a sort}
do_test collate4-1.2.11 {
cksort {SELECT a FROM collate4t2 ORDER BY a, b}
} {{} a B nosort}
do_test collate4-1.2.12 {
cksort {SELECT a FROM collate4t2 ORDER BY a, b COLLATE nocase}
} {{} a B sort}
do_test collate4-1.2.13 {
cksort {SELECT a FROM collate4t2 ORDER BY a, b COLLATE text}
} {{} a B nosort}
do_test collate4-1.2.14 {
execsql {
CREATE TABLE collate4t3(a COLLATE NOCASE, b COLLATE TEXT);
INSERT INTO collate4t3 VALUES( 'a', 'a' );
INSERT INTO collate4t3 VALUES( 'b', 'b' );
INSERT INTO collate4t3 VALUES( NULL, NULL );
INSERT INTO collate4t3 VALUES( 'B', 'B' );
INSERT INTO collate4t3 VALUES( 'A', 'A' );
CREATE INDEX collate4i2 ON collate4t3(a COLLATE TEXT, b COLLATE NOCASE);
}
} {}
do_test collate4-1.2.15 {
cksort {SELECT a FROM collate4t3 ORDER BY a}
} {{} A a B b sort}
do_test collate4-1.2.16 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE nocase}
} {{} A a B b sort}
do_test collate4-1.2.17 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE text}
} {{} A B a b nosort}
do_test collate4-1.2.18 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE text, b}
} {{} A B a b sort}
do_test collate4-1.2.19 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE text, b COLLATE nocase}
} {{} A B a b nosort}
do_test collate4-1.2.20 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE text, b COLLATE text}
} {{} A B a b sort}
do_test collate4-1.2.21 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE text DESC}
} {b a B A {} nosort}
do_test collate4-1.2.22 {
cksort {SELECT a FROM collate4t3 ORDER BY a COLLATE text DESC, b}
} {b a B A {} sort}
do_test collate4-1.2.23 {
cksort {SELECT a FROM collate4t3
ORDER BY a COLLATE text DESC, b COLLATE nocase}
} {b a B A {} sort}
do_test collate4-1.2.24 {
cksort {SELECT a FROM collate4t3
ORDER BY a COLLATE text DESC, b COLLATE nocase DESC}
} {b a B A {} nosort}
do_test collate4-1.2.25 {
execsql {
DROP TABLE collate4t1;
DROP TABLE collate4t2;
DROP TABLE collate4t3;
}
} {}
#
# These tests - collate4-2.* - check that indices are correctly
# selected or not selected to implement WHERE clauses when user
# defined collation sequences are involved.
#
# Indices may optimise WHERE clauses using <, >, <=, >=, = or IN
# operators.
#
do_test collate4-2.1.0 {
execsql {
CREATE TABLE collate4t1(a COLLATE NOCASE);
CREATE TABLE collate4t2(b COLLATE TEXT);
INSERT INTO collate4t1 VALUES('a');
INSERT INTO collate4t1 VALUES('A');
INSERT INTO collate4t1 VALUES('b');
INSERT INTO collate4t1 VALUES('B');
INSERT INTO collate4t1 VALUES('c');
INSERT INTO collate4t1 VALUES('C');
INSERT INTO collate4t1 VALUES('d');
INSERT INTO collate4t1 VALUES('D');
INSERT INTO collate4t1 VALUES('e');
INSERT INTO collate4t1 VALUES('D');
INSERT INTO collate4t2 VALUES('A');
INSERT INTO collate4t2 VALUES('Z');
}
} {}
do_test collate4-2.1.1 {
count {
SELECT * FROM collate4t2, collate4t1 WHERE a = b;
}
} {A a A A 19}
do_test collate4-2.1.2 {
execsql {
CREATE INDEX collate4i1 ON collate4t1(a);
}
count {
SELECT * FROM collate4t2, collate4t1 WHERE a = b;
}
} {A a A A 7}
do_test collate4-2.1.3 {
count {
SELECT * FROM collate4t2, collate4t1 WHERE b = a;
}
} {A A 19}
do_test collate4-2.1.4 {
execsql {
DROP INDEX collate4i1;
CREATE INDEX collate4i1 ON collate4t1(a COLLATE TEXT);
}
count {
SELECT * FROM collate4t2, collate4t1 WHERE a = b;
}
} {A a A A 19}
do_test collate4-2.1.5 {
count {
SELECT * FROM collate4t2, collate4t1 WHERE b = a;
}
} {A A 5}
do_test collate4-2.1.6 {
count {
SELECT a FROM collate4t1 WHERE a IN (SELECT * FROM collate4t2);
}
} {a A 10}
do_test collate4-2.1.7 {
execsql {
DROP INDEX collate4i1;
CREATE INDEX collate4i1 ON collate4t1(a);
}
count {
SELECT a FROM collate4t1 WHERE a IN (SELECT * FROM collate4t2);
}
} {a A 8}
do_test collate4-2.1.8 {
count {
SELECT a FROM collate4t1 WHERE a IN ('z', 'a');
}
} {a A 7}
do_test collate4-2.1.9 {
execsql {
DROP INDEX collate4i1;
CREATE INDEX collate4i1 ON collate4t1(a COLLATE TEXT);
}
count {
SELECT a FROM collate4t1 WHERE a IN ('z', 'a');
}
} {a A 9}
do_test collate4-2.1.10 {
execsql {
DROP TABLE collate4t1;
DROP TABLE collate4t2;
}
} {}
do_test collate4-2.2.0 {
execsql {
CREATE TABLE collate4t1(a COLLATE nocase, b COLLATE text, c);
CREATE TABLE collate4t2(a COLLATE nocase, b COLLATE text, c COLLATE TEXT);
INSERT INTO collate4t1 VALUES('0', '0', '0');
INSERT INTO collate4t1 VALUES('0', '0', '1');
INSERT INTO collate4t1 VALUES('0', '1', '0');
INSERT INTO collate4t1 VALUES('0', '1', '1');
INSERT INTO collate4t1 VALUES('1', '0', '0');
INSERT INTO collate4t1 VALUES('1', '0', '1');
INSERT INTO collate4t1 VALUES('1', '1', '0');
INSERT INTO collate4t1 VALUES('1', '1', '1');
insert into collate4t2 SELECT * FROM collate4t1;
}
} {}
do_test collate4-2.2.1 {
count {
SELECT * FROM collate4t2 NATURAL JOIN collate4t1;
}
} {0 0 0 0 0 1 0 1 0 0 1 1 1 0 0 1 0 1 1 1 0 1 1 1 63}
do_test collate4-2.2.1 {
execsql {
CREATE INDEX collate4i1 ON collate4t1(a, b, c);
}
count {
SELECT * FROM collate4t2 NATURAL JOIN collate4t1;
}
} {0 0 0 0 0 1 0 1 0 0 1 1 1 0 0 1 0 1 1 1 0 1 1 1 45}
do_test collate4-2.2.2 {
execsql {
DROP INDEX collate4i1;
CREATE INDEX collate4i1 ON collate4t1(a, b, c COLLATE text);
}
count {
SELECT * FROM collate4t2 NATURAL JOIN collate4t1;
}
} {0 0 0 0 0 1 0 1 0 0 1 1 1 0 0 1 0 1 1 1 0 1 1 1 22}
do_test collate4-2.2.10 {
execsql {
DROP TABLE collate4t1;
DROP TABLE collate4t2;
}
} {}
#
# These tests - collate4-3.* verify that indices that implement
# UNIQUE and PRIMARY KEY constraints operate correctly with user
# defined collation sequences.
#
do_test collate4-3.0 {
execsql {
CREATE TABLE collate4t1(a PRIMARY KEY COLLATE NOCASE);
}
} {}
do_test collate4-3.1 {
catchsql {
INSERT INTO collate4t1 VALUES('abc');
INSERT INTO collate4t1 VALUES('ABC');
}
} {1 {column a is not unique}}
do_test collate4-3.2 {
execsql {
SELECT * FROM collate4t1;
}
} {abc}
do_test collate4-3.3 {
catchsql {
INSERT INTO collate4t1 SELECT upper(a) FROM collate4t1;
}
} {1 {column a is not unique}}
do_test collate4-3.4 {
catchsql {
INSERT INTO collate4t1 VALUES(1);
UPDATE collate4t1 SET a = 'abc';
}
} {1 {column a is not unique}}
do_test collate4-3.5 {
execsql {
DROP TABLE collate4t1;
CREATE TABLE collate4t1(a COLLATE NOCASE UNIQUE);
}
} {}
do_test collate4-3.6 {
catchsql {
INSERT INTO collate4t1 VALUES('abc');
INSERT INTO collate4t1 VALUES('ABC');
}
} {1 {column a is not unique}}
do_test collate4-3.7 {
execsql {
SELECT * FROM collate4t1;
}
} {abc}
do_test collate4-3.8 {
catchsql {
INSERT INTO collate4t1 SELECT upper(a) FROM collate4t1;
}
} {1 {column a is not unique}}
do_test collate4-3.9 {
catchsql {
INSERT INTO collate4t1 VALUES(1);
UPDATE collate4t1 SET a = 'abc';
}
} {1 {column a is not unique}}
do_test collate4-3.10 {
execsql {
DROP TABLE collate4t1;
CREATE TABLE collate4t1(a);
CREATE UNIQUE INDEX collate4i1 ON collate4t1(a COLLATE NOCASE);
}
} {}
do_test collate4-3.11 {
catchsql {
INSERT INTO collate4t1 VALUES('abc');
INSERT INTO collate4t1 VALUES('ABC');
}
} {1 {column a is not unique}}
do_test collate4-3.12 {
execsql {
SELECT * FROM collate4t1;
}
} {abc}
do_test collate4-3.13 {
catchsql {
INSERT INTO collate4t1 SELECT upper(a) FROM collate4t1;
}
} {1 {column a is not unique}}
do_test collate4-3.14 {
catchsql {
INSERT INTO collate4t1 VALUES(1);
UPDATE collate4t1 SET a = 'abc';
}
} {1 {column a is not unique}}
do_test collate4-3.15 {
execsql {
DROP TABLE collate4t1;
}
} {}
#
# These tests - collate4-4.* check that min() and max() only ever
# use indices constructed with built-in collation type numeric.
#
# CHANGED: min() and max() now use the collation type. If there
# is an indice that can be used, it is used.
#
# FIX ME: min() and max() are currently broken.
if 0 {
do_test collate4-4.0 {
execsql {
CREATE TABLE collate4t1(a COLLATE TEXT);
INSERT INTO collate4t1 VALUES(2);
INSERT INTO collate4t1 VALUES(10);
INSERT INTO collate4t1 VALUES(20);
INSERT INTO collate4t1 VALUES(104);
}
} {}
do_test collate4-4.1 {
count {
SELECT max(a) FROM collate4t1
}
} {20 3}
do_test collate4-4.2 {
count {
SELECT min(a) FROM collate4t1
}
} {10 3}
do_test collate4-4.3 {
# Test that the index with collation type TEXT is used.
execsql {
CREATE INDEX collate4i1 ON collate4t1(a);
}
count {
SELECT min(a) FROM collate4t1;
}
} {10 1}
do_test collate4-4.4 {
count {
SELECT max(a) FROM collate4t1;
}
} {20 1}
do_test collate4-4.5 {
# Test that the index with collation type NUMERIC is not used.
execsql {
DROP INDEX collate4i1;
CREATE INDEX collate4i1 ON collate4t1(a COLLATE NUMERIC);
}
count {
SELECT min(a) FROM collate4t1;
}
} {10 3}
do_test collate4-4.6 {
count {
SELECT max(a) FROM collate4t1;
}
} {20 3}
do_test collate4-4.7 {
execsql {
DROP TABLE collate4t1;
}
} {}
# Also test the scalar min() and max() functions.
#
do_test collate4-4.8 {
execsql {
CREATE TABLE collate4t1(a NUMERIC, b TEXT,
c COLLATE TEXT, d COLLATE NUMERIC);
INSERT INTO collate4t1 VALUES(11, 101, 1001, 10001);
INSERT INTO collate4t1 VALUES(20002, 2002, 202, 22);
}
} {}
do_test collate4-4.9 {
execsql {
SELECT max(a, b, c) FROM collate4t1;
}
} {11 202}
do_test collate4-4.10 {
execsql {
SELECT max(c, b, a) FROM collate4t1;
}
} {11 202}
do_test collate4-4.11 {
execsql {
SELECT max(a, b) FROM collate4t1;
}
} {101 20002}
do_test collate4-4.12 {
execsql {
SELECT max(b, a) FROM collate4t1;
}
} {101 20002}
do_test collate4-4.13 {
execsql {
SELECT max(b, a) FROM collate4t1;
}
} {101 20002}
do_test collate4-4.14 {
execsql {
SELECT max(b, '11') FROM collate4t1;
}
} {11 2002}
do_test collate4-4.15 {
execsql {
SELECT max('11', b) FROM collate4t1;
}
} {11 2002}
do_test collate4-4.16 {
execsql {
SELECT max(11, b) FROM collate4t1;
}
} {101 2002}
do_test collate4-4.17 {
execsql {
SELECT max(b, 11) FROM collate4t1;
}
} {101 2002}
do_test collate4-4.18 {
execsql {
SELECT max(c, d) FROM collate4t1;
}
} {1001 22}
do_test collate4-4.19 {
execsql {
SELECT max(d, c) FROM collate4t1;
}
} {10001 202}
do_test collate4-4.20 {
execsql {
DROP TABLE collate4t1;
}
} {}
}
#
# These tests - collate4-5.* - test the REINDEX command.
#
# FIX ME: Find out if version 3 needs REINDEX.
if 0 {
proc install_normal_collate {} {
db collate collate1 "string compare"
}
proc inverse_collate {l r} {
expr -1 * [string compare $l $r]
}
proc install_inverse_collate {} {
db collate collate1 inverse_collate
}
install_normal_collate
do_test collate4-5.0 {
execsql {
CREATE TABLE collate4t1(a COLLATE collate1);
INSERT INTO collate4t1 VALUES('A');
INSERT INTO collate4t1 VALUES(NULL);
INSERT INTO collate4t1 VALUES('B');
CREATE INDEX collate4i1 ON collate4t1(a);
}
} {}
do_test collate4-5.1 {
cksort {
SELECT * FROM collate4t1 ORDER BY 1;
}
} {{} A B nosort}
do_test collate4-5.2 {
install_inverse_collate
cksort {
SELECT * FROM collate4t1 ORDER BY 1;
}
} {{} A B nosort} ;# This is incorrect - because we need to REINDEX
do_test collate4-5.3 {
install_inverse_collate
cksort {
REINDEX collate4t1;
SELECT * FROM collate4t1 ORDER BY 1;
}
} {{} B A nosort}
do_test collate4-5.4 {
install_normal_collate
cksort {
REINDEX;
SELECT * FROM collate4t1 ORDER BY 1;
}
} {{} A B nosort}
do_test collate4-5.5 {
install_inverse_collate
cksort {
REINDEX main.collate4t1;
SELECT * FROM collate4t1 ORDER BY 1;
}
} {{} B A nosort}
do_test collate4-5.6 {
catchsql {
REINDEX garbage;
}
} {1 {no such table: garbage}}
do_test collate4-5.7 {
execsql {
DROP TABLE collate4t1;
CREATE TEMP TABLE collate4t1(a COLLATE collate1, b COLLATE collate1);
CREATE INDEX collatei1 ON collate4t1(a);
CREATE INDEX collatei2 ON collate4t1(b);
INSERT INTO collate4t1 VALUES(1, 1);
INSERT INTO collate4t1 VALUES(NULL, NULL);
INSERT INTO collate4t1 VALUES(2, 2);
}
} {}
do_test collate4-5.8 {
cksort {
SELECT * FROM collate4t1 ORDER BY 1
}
} {{} {} 2 2 1 1 nosort}
do_test collate4-5.9 {
install_normal_collate
cksort {
REINDEX;
SELECT * FROM collate4t1 order by 2;
}
} {{} {} 1 1 2 2 nosort}
do_test collate4-5.10 {
install_inverse_collate
cksort {
REINDEX collate4t1;
SELECT * FROM collate4t1 order by 1;
}
} {{} {} 2 2 1 1 nosort}
do_test collate4-5.11 {
install_normal_collate
cksort {
REINDEX temp.collate4t1;
SELECT * FROM collate4t1 order by 2;
}
} {{} {} 1 1 2 2 nosort}
# This checks that if a REINDEX operation produces a conflict an error
# is raised and the checkpoint rolled back.
do_test collate4-5.12 {
execsql {
BEGIN;
CREATE UNIQUE INDEX collate4i3 ON collate4t1(a);
INSERT INTO collate4t1 VALUES(3, 3);
}
db collate collate1 "expr 0 ;"
catchsql {
REINDEX;
}
} {1 {indexed columns are not unique}}
do_test collate4-5.13 {
execsql {
COMMIT;
SELECT * FROM collate4t1;
}
} {1 1 {} {} 2 2 3 3}
# Do an EXPLAIN REINDEX, just in case it leaks memory or something.
do_test collate4-5.14 {
execsql {
EXPLAIN REINDEX;
}
expr 0
} {0}
do_test collate4-5.15 {
execsql {
EXPLAIN REINDEX collate4t1;
}
expr 0
} {0}
do_test collate4-5.16 {
execsql {
DROP TABLE collate4t1;
}
} {}
}
#
# These tests - collate4.6.* - ensure that implict INTEGER PRIMARY KEY
# indices do not confuse collation sequences.
#
# These indices are never used for sorting in SQLite. And you can't
# create another index on an INTEGER PRIMARY KEY column, so we don't have
# to test that.
#
do_test collate4-6.0 {
execsql {
CREATE TABLE collate4t1(a INTEGER PRIMARY KEY);
INSERT INTO collate4t1 VALUES(101);
INSERT INTO collate4t1 VALUES(10);
INSERT INTO collate4t1 VALUES(15);
}
} {}
do_test collate4-6.1 {
cksort {
SELECT * FROM collate4t1 ORDER BY 1;
}
} {10 15 101 sort}
do_test collate4-6.2 {
cksort {
SELECT * FROM collate4t1 ORDER BY oid;
}
} {10 15 101 sort}
do_test collate4-6.3 {
cksort {
SELECT * FROM collate4t1 ORDER BY oid||'' COLLATE TEXT;
}
} {10 101 15 sort}
finish_test

View File

@ -1,4 +1,4 @@
# 2001 September 15
# 2001 September 15.
#
# The author disclaims copyright to this source code. In place of
# a legal notice, here is a blessing:
@ -13,11 +13,24 @@
# This file implements tests for miscellanous features that were
# left out of other test files.
#
# $Id: misc1.test,v 1.25 2004/05/31 08:26:49 danielk1977 Exp $
# $Id: misc1.test,v 1.26 2004/06/09 09:55:20 danielk1977 Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
# Mimic the SQLite 2 collation type NUMERIC.
db collate numeric numeric_collate
proc numeric_collate {lhs rhs} {
if {$lhs == $rhs} {return 0}
return [expr ($lhs>$rhs)?1:-1]
}
# Mimic the SQLite 2 collation type TEXT.
db collate text text_collate
proc numeric_collate {lhs rhs} {
return [string compare $lhs $rhs]
}
# Test the creation and use of tables that have a large number
# of columns.
#
@ -381,11 +394,14 @@ do_test misc1-12.9 {
# identifiers can be used as a collating sequence. Collation is by text
# if the identifier contains "text", "blob", or "clob" and is numeric
# otherwise.
do_test misc1-12.10 {
catchsql {
SELECT * FROM t6 ORDER BY a COLLATE unknown;
}
} {0 {0 0.0 y 0}}
#
# Update: In v3, it is an error again.
#
#do_test misc1-12.10 {
# catchsql {
# SELECT * FROM t6 ORDER BY a COLLATE unknown;
# }
#} {0 {0 0.0 y 0}}
do_test misc1-12.11 {
execsql {
CREATE TABLE t8(x TEXT COLLATE numeric, y INTEGER COLLATE text, z);

View File

@ -1,4 +1,4 @@
# 2001 September 15
# 2001 September 15.
#
# The author disclaims copyright to this source code. In place of
# a legal notice, here is a blessing:
@ -11,7 +11,7 @@
# This file implements regression tests for SQLite library. The
# focus of this file is testing the CREATE TABLE statement.
#
# $Id: sort.test,v 1.12 2004/05/27 17:22:56 drh Exp $
# $Id: sort.test,v 1.13 2004/06/09 09:55:20 danielk1977 Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
@ -323,26 +323,26 @@ do_test sort-7.8 {
# SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE integer;
# }
#} {1 2 11 12}
do_test sort-7.11 {
execsql {
SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE text;
}
} {1 11 12 2}
do_test sort-7.12 {
execsql {
SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE blob;
}
} {1 11 12 2}
do_test sort-7.13 {
execsql {
SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE clob;
}
} {1 11 12 2}
do_test sort-7.14 {
execsql {
SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE varchar;
}
} {1 11 12 2}
#do_test sort-7.11 {
# execsql {
# SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE text;
# }
#} {1 11 12 2}
#do_test sort-7.12 {
# execsql {
# SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE blob;
# }
#} {1 11 12 2}
#do_test sort-7.13 {
# execsql {
# SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE clob;
# }
#} {1 11 12 2}
#do_test sort-7.14 {
# execsql {
# SELECT b FROM t4 UNION SELECT b FROM v4 ORDER BY 1 COLLATE varchar;
# }
#} {1 11 12 2}
# Ticket #297
#

View File

@ -15,7 +15,7 @@
# interface is pretty well tested. This file contains some addition
# tests for fringe issues that the main test suite does not cover.
#
# $Id: tclsqlite.test,v 1.21 2004/06/02 00:41:10 drh Exp $
# $Id: tclsqlite.test,v 1.22 2004/06/09 09:55:20 danielk1977 Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl
@ -34,7 +34,7 @@ do_test tcl-1.1 {
do_test tcl-1.2 {
set v [catch {db bogus} msg]
lappend v $msg
} {1 {bad option "bogus": must be authorizer, busy, changes, close, commit_hook, complete, errorcode, eval, function, last_insert_rowid, last_statement_changes, onecolumn, progress, rekey, timeout, or trace}}
} {1 {bad option "bogus": must be authorizer, busy, changes, close, commit_hook, complete, errorcode, eval, function, last_insert_rowid, last_statement_changes, onecolumn, progress, rekey, timeout, trace, or collate}}
do_test tcl-1.3 {
execsql {CREATE TABLE t1(a int, b int)}
execsql {INSERT INTO t1 VALUES(10,20)}