xref: /sqlite-3.40.0/test/indexexpr2.test (revision 8210233c)
1b8d29c2fSdan# 2017 April 11
2b8d29c2fSdan#
3b8d29c2fSdan# The author disclaims copyright to this source code.  In place of
4b8d29c2fSdan# a legal notice, here is a blessing:
5b8d29c2fSdan#
6b8d29c2fSdan#    May you do good and not evil.
7b8d29c2fSdan#    May you find forgiveness for yourself and forgive others.
8b8d29c2fSdan#    May you share freely, never taking more than you give.
9b8d29c2fSdan#
10b8d29c2fSdan#***********************************************************************
11b8d29c2fSdan# This file implements regression tests for SQLite library.
12b8d29c2fSdan#
13b8d29c2fSdan
14b8d29c2fSdanset testdir [file dirname $argv0]
15b8d29c2fSdansource $testdir/tester.tcl
16b8d29c2fSdanset testprefix indexexpr2
17b8d29c2fSdan
18b8d29c2fSdando_execsql_test 1 {
19b8d29c2fSdan  CREATE TABLE t1(a, b);
20b8d29c2fSdan  INSERT INTO t1 VALUES(1, 'one');
21b8d29c2fSdan  INSERT INTO t1 VALUES(2, 'two');
22b8d29c2fSdan  INSERT INTO t1 VALUES(3, 'three');
23b8d29c2fSdan
24b8d29c2fSdan  CREATE INDEX i1 ON t1(b || 'x');
25b8d29c2fSdan}
26b8d29c2fSdan
27b8d29c2fSdando_execsql_test 1.1 {
28b8d29c2fSdan  SELECT 'TWOX' == (b || 'x') FROM t1 WHERE (b || 'x')>'onex'
29b8d29c2fSdan} {0 0}
30b8d29c2fSdan
31b8d29c2fSdando_execsql_test 1.2 {
32b8d29c2fSdan  SELECT 'TWOX' == (b || 'x') COLLATE nocase  FROM t1 WHERE (b || 'x')>'onex'
33b8d29c2fSdan} {0 1}
34b8d29c2fSdan
3539c9d3a3Sdando_execsql_test 2.0 {
3639c9d3a3Sdan  CREATE INDEX i2 ON t1(a+1);
3739c9d3a3Sdan}
3839c9d3a3Sdan
3939c9d3a3Sdando_execsql_test 2.1 {
4039c9d3a3Sdan  SELECT a+1, quote(a+1) FROM t1 ORDER BY 1;
4139c9d3a3Sdan} {2 2 3 3 4 4}
4239c9d3a3Sdan
4362f6f51aSdan#-------------------------------------------------------------------------
4462f6f51aSdan# At one point SQLite was incorrectly using indexes on expressions to
4562f6f51aSdan# optimize ORDER BY and GROUP BY clauses even when the collation
4662f6f51aSdan# sequences of the query and index did not match (ticket [e20dd54ab0e4]).
4762f6f51aSdan# The following tests - 3.* - attempt to verify that this has been fixed.
4862f6f51aSdan#
4962f6f51aSdan
5062f6f51aSdanreset_db
5162f6f51aSdando_execsql_test 3.1.0 {
5262f6f51aSdan  CREATE TABLE t1(a, b);
5362f6f51aSdan  CREATE INDEX i1 ON t1(a, b);
5462f6f51aSdan} {}
5562f6f51aSdan
5662f6f51aSdando_eqp_test 3.1.1 {
5762f6f51aSdan  SELECT b FROM t1 WHERE b IS NOT NULL AND a IS NULL
5862f6f51aSdan  GROUP BY b COLLATE nocase
5962f6f51aSdan  ORDER BY b COLLATE nocase;
6070739addSdrh} {/USE TEMP B-TREE FOR GROUP BY/}
6162f6f51aSdan
6262f6f51aSdando_execsql_test 3.2.0 {
6362f6f51aSdan  CREATE TABLE t2(x);
6462f6f51aSdan
6562f6f51aSdan  INSERT INTO t2 VALUES('.ABC');
6662f6f51aSdan  INSERT INTO t2 VALUES('.abcd');
6762f6f51aSdan  INSERT INTO t2 VALUES('.defg');
6862f6f51aSdan  INSERT INTO t2 VALUES('.DEF');
6962f6f51aSdan} {}
7062f6f51aSdan
7162f6f51aSdando_execsql_test 3.2.1 {
7262f6f51aSdan  SELECT x FROM t2 ORDER BY substr(x, 2) COLLATE nocase;
7362f6f51aSdan} {
7462f6f51aSdan  .ABC .abcd .DEF .defg
7562f6f51aSdan}
7662f6f51aSdan
7762f6f51aSdando_execsql_test 3.2.2 {
7862f6f51aSdan  CREATE INDEX i2 ON t2( substr(x, 2) );
7962f6f51aSdan  SELECT x FROM t2 ORDER BY substr(x, 2) COLLATE nocase;
8062f6f51aSdan} {
8162f6f51aSdan  .ABC .abcd .DEF .defg
8262f6f51aSdan}
8362f6f51aSdan
8462f6f51aSdando_execsql_test 3.3.0 {
8562f6f51aSdan  CREATE TABLE t3(x);
8662f6f51aSdan}
8762f6f51aSdan
8870739addSdrhifcapable json1 {
8962f6f51aSdan  do_eqp_test 3.3.1 {
9062f6f51aSdan    SELECT json_extract(x, '$.b') FROM t2
9162f6f51aSdan    WHERE json_extract(x, '$.b') IS NOT NULL AND json_extract(x, '$.a') IS NULL
9262f6f51aSdan    GROUP BY json_extract(x, '$.b') COLLATE nocase
9362f6f51aSdan    ORDER BY json_extract(x, '$.b') COLLATE nocase;
94b3f0276bSdrh  } [string map {"\n  " \n} {
95b3f0276bSdrh    QUERY PLAN
96*8210233cSdrh    |--SCAN t2
97b3f0276bSdrh    `--USE TEMP B-TREE FOR GROUP BY
98b3f0276bSdrh  }]
9962f6f51aSdan
10062f6f51aSdan  do_execsql_test 3.3.2 {
10162f6f51aSdan    CREATE INDEX i3 ON t3(json_extract(x, '$.a'), json_extract(x, '$.b'));
10262f6f51aSdan  } {}
10362f6f51aSdan
10462f6f51aSdan  do_eqp_test 3.3.3 {
10562f6f51aSdan    SELECT json_extract(x, '$.b') FROM t3
10662f6f51aSdan    WHERE json_extract(x, '$.b') IS NOT NULL AND json_extract(x, '$.a') IS NULL
10762f6f51aSdan    GROUP BY json_extract(x, '$.b') COLLATE nocase
10862f6f51aSdan    ORDER BY json_extract(x, '$.b') COLLATE nocase;
109b3f0276bSdrh  } [string map {"\n  " \n} {
110b3f0276bSdrh    QUERY PLAN
111*8210233cSdrh    |--SEARCH t3 USING INDEX i3 (<expr>=?)
112b3f0276bSdrh    `--USE TEMP B-TREE FOR GROUP BY
113b3f0276bSdrh  }]
11470739addSdrh}
11562f6f51aSdan
11662f6f51aSdando_execsql_test 3.4.0 {
11762f6f51aSdan  CREATE TABLE t4(a, b);
11862f6f51aSdan  INSERT INTO t4 VALUES('.ABC', 1);
11962f6f51aSdan  INSERT INTO t4 VALUES('.abc', 2);
12062f6f51aSdan  INSERT INTO t4 VALUES('.ABC', 3);
12162f6f51aSdan  INSERT INTO t4 VALUES('.abc', 4);
12262f6f51aSdan}
12362f6f51aSdan
12462f6f51aSdando_execsql_test 3.4.1 {
12562f6f51aSdan  SELECT * FROM t4
12662f6f51aSdan  WHERE substr(a, 2) = 'abc' COLLATE NOCASE
12762f6f51aSdan  ORDER BY substr(a, 2), b;
12862f6f51aSdan} {
12962f6f51aSdan  .ABC 1   .ABC 3   .abc 2   .abc 4
13062f6f51aSdan}
13162f6f51aSdan
13262f6f51aSdando_execsql_test 3.4.2 {
13362f6f51aSdan  CREATE INDEX i4 ON t4( substr(a, 2) COLLATE NOCASE, b );
13462f6f51aSdan  SELECT * FROM t4
13562f6f51aSdan  WHERE substr(a, 2) = 'abc' COLLATE NOCASE
13662f6f51aSdan  ORDER BY substr(a, 2), b;
13762f6f51aSdan} {
13862f6f51aSdan  .ABC 1   .ABC 3   .abc 2   .abc 4
13962f6f51aSdan}
14062f6f51aSdan
141db8e68b4Sdrhdo_execsql_test 3.4.3 {
142db8e68b4Sdrh  DROP INDEX i4;
143db8e68b4Sdrh  UPDATE t4 SET a = printf('%s%d',a,b);
144db8e68b4Sdrh  SELECT * FROM t4 ORDER BY Substr(a,-2) COLLATE nocase;
145db8e68b4Sdrh} {.ABC1 1 .abc2 2 .ABC3 3 .abc4 4}
146db8e68b4Sdrhdo_execsql_test 3.4.4 {
147db8e68b4Sdrh  SELECT * FROM t4 ORDER BY Substr(a,-2) COLLATE binary;
148db8e68b4Sdrh} {.ABC1 1 .ABC3 3 .abc2 2 .abc4 4}
149db8e68b4Sdrh
150db8e68b4Sdrhdo_execsql_test 3.4.5 {
151db8e68b4Sdrh  CREATE INDEX i4 ON t4( Substr(a,-2) COLLATE nocase );
152db8e68b4Sdrh  SELECT * FROM t4 ORDER BY Substr(a,-2) COLLATE nocase;
153db8e68b4Sdrh} {.ABC1 1 .abc2 2 .ABC3 3 .abc4 4}
154db8e68b4Sdrhdo_execsql_test 3.4.5eqp {
155db8e68b4Sdrh  EXPLAIN QUERY PLAN
156db8e68b4Sdrh  SELECT * FROM t4 ORDER BY Substr(a,-2) COLLATE nocase;
157*8210233cSdrh} {/SCAN t4 USING INDEX i4/}
158db8e68b4Sdrhdo_execsql_test 3.4.6 {
159db8e68b4Sdrh  SELECT * FROM t4 ORDER BY Substr(a,-2) COLLATE binary;
160db8e68b4Sdrh} {.ABC1 1 .ABC3 3 .abc2 2 .abc4 4}
161db8e68b4Sdrh
162e9816d82Sdrh# 2014-09-15:  Verify that UPDATEs of columns not referenced by a
163e9816d82Sdrh# index on expression do not modify the index.
164e9816d82Sdrh#
165e9816d82Sdrhunset -nocomplain cnt
166e9816d82Sdrhset cnt 0
167e9816d82Sdrhproc refcnt {x} {
168e9816d82Sdrh  global cnt
169e9816d82Sdrh  incr cnt
170e9816d82Sdrh  return $x
171e9816d82Sdrh}
172e9816d82Sdrhdb close
173e9816d82Sdrhsqlite3 db :memory:
174e9816d82Sdrhdb function refcnt -deterministic refcnt
175e9816d82Sdrhdo_test 4.100 {
176e9816d82Sdrh  db eval {
177e9816d82Sdrh    CREATE TABLE t1(a,b,c,d,e,f);
178e9816d82Sdrh    CREATE INDEX t1abc ON t1(refcnt(a+b+c));
179e9816d82Sdrh  }
180e9816d82Sdrh  set ::cnt
181e9816d82Sdrh} {0}
182e9816d82Sdrhdo_test 4.110 {
183e9816d82Sdrh  db eval {INSERT INTO t1 VALUES(1,2,3,4,5,6);}
184e9816d82Sdrh  set ::cnt
185e9816d82Sdrh  # The refcnt() function is invoked once to compute the index value
186e9816d82Sdrh} {1}
187e9816d82Sdrhdo_test 4.120 {
188e9816d82Sdrh  set ::cnt 0
189e9816d82Sdrh  db eval {UPDATE t1 SET b=b+1;}
190e9816d82Sdrh  set ::cnt
191e9816d82Sdrh  # The refcnt() function is invoked twice, once to remove the old index
192e9816d82Sdrh  # entry and a second time to insert the new one.
193e9816d82Sdrh} {2}
194e9816d82Sdrhdo_test 4.130 {
195e9816d82Sdrh  set ::cnt 0
196e9816d82Sdrh  db eval {UPDATE t1 SET d=d+1;}
197e9816d82Sdrh  set ::cnt
198e9816d82Sdrh  # Refcnt() should not be invoked because that index does not change.
199e9816d82Sdrh} {0}
200db8e68b4Sdrh
2019b84f035Sdrh# Additional test cases to show that UPDATE does not modify indexes that
2029b84f035Sdrh# do not involve unchanged columns.
2039b84f035Sdrh#
204909f78cbSdanifcapable vtab {
2059b84f035Sdrh  load_static_extension db explain
2069b84f035Sdrh  do_execsql_test 4.200 {
2079b84f035Sdrh    CREATE TABLE t2(a,b,c,d,e,f);
2089b84f035Sdrh    INSERT INTO t2 VALUES(2,3,4,5,6,7);
2099b84f035Sdrh    CREATE INDEX t2abc ON t2(a+b+c);
2109b84f035Sdrh    CREATE INDEX t2cd ON t2(c*d);
2119b84f035Sdrh    CREATE INDEX t2def ON t2(d,e+25*f);
2129b84f035Sdrh    SELECT sqlite_master.name
2139b84f035Sdrh      FROM sqlite_master, explain('UPDATE t2 SET b=b+1')
2149b84f035Sdrh     WHERE explain.opcode LIKE 'Open%'
2159b84f035Sdrh       AND sqlite_master.rootpage=explain.p2
2169b84f035Sdrh     ORDER BY 1;
2179b84f035Sdrh  } {t2 t2abc}
2189b84f035Sdrh  do_execsql_test 4.210 {
2199b84f035Sdrh    SELECT sqlite_master.name
2209b84f035Sdrh      FROM sqlite_master, explain('UPDATE t2 SET c=c+1')
2219b84f035Sdrh     WHERE explain.opcode LIKE 'Open%'
2229b84f035Sdrh       AND sqlite_master.rootpage=explain.p2
2239b84f035Sdrh     ORDER BY 1;
2249b84f035Sdrh  } {t2 t2abc t2cd}
2259b84f035Sdrh  do_execsql_test 4.220 {
2269b84f035Sdrh    SELECT sqlite_master.name
2279b84f035Sdrh      FROM sqlite_master, explain('UPDATE t2 SET c=c+1, f=NULL')
2289b84f035Sdrh     WHERE explain.opcode LIKE 'Open%'
2299b84f035Sdrh       AND sqlite_master.rootpage=explain.p2
2309b84f035Sdrh     ORDER BY 1;
2319b84f035Sdrh  } {t2 t2abc t2cd t2def}
232909f78cbSdan}
2339b84f035Sdrh
2347525b87bSdan#-------------------------------------------------------------------------
2357525b87bSdan# Test that ticket [d96eba87] has been fixed.
2367525b87bSdan#
2377525b87bSdando_execsql_test 5.0 {
2387525b87bSdan  CREATE TABLE t5(a INTEGER, b INTEGER);
2397525b87bSdan  INSERT INTO t5 VALUES(2, 4), (3, 9);
2407525b87bSdan}
2417525b87bSdando_execsql_test 5.1 {
2427525b87bSdan  SELECT * FROM t5 WHERE abs(a)=2 or abs(b)=9;
2437525b87bSdan} {2 4 3 9}
2447525b87bSdando_execsql_test 5.2 {
2457525b87bSdan  CREATE INDEX t5a ON t5( abs(a) );
2467525b87bSdan  CREATE INDEX t5b ON t5( abs(b) );
2477525b87bSdan}
2487525b87bSdando_execsql_test 5.4 {
2497525b87bSdan  SELECT * FROM t5 WHERE abs(a)=2 or abs(b)=9;
2507525b87bSdan} {2 4 3 9}
2517525b87bSdan
25295d5a880Sdan#-------------------------------------------------------------------------
25395d5a880Sdando_execsql_test 6.0 {
25495d5a880Sdan  CREATE TABLE x1(a INTEGER PRIMARY KEY, b);
25595d5a880Sdan  INSERT INTO x1 VALUES
25695d5a880Sdan      (1, 123), (2, '123'), (3, '123abc'), (4, 123.0), (5, 1234);
25795d5a880Sdan}
25895d5a880Sdan
25995d5a880Sdando_execsql_test 6.1.1 {
26095d5a880Sdan  SELECT a, b FROM x1 WHERE CAST(b AS INTEGER) = 123;
26195d5a880Sdan} {1 123   2 123   3 123abc  4 123.0}
26295d5a880Sdando_execsql_test 6.1.2 {
26395d5a880Sdan  CREATE INDEX x1i ON x1( CAST(b AS INTEGER) );
26495d5a880Sdan  SELECT a, b FROM x1 WHERE CAST(b AS INTEGER) = 123;
26595d5a880Sdan} {1 123   2 123   3 123abc  4 123.0}
26695d5a880Sdando_eqp_test 6.1.3 {
26795d5a880Sdan  SELECT a, b FROM x1 WHERE CAST(b AS INTEGER) = 123;
268*8210233cSdrh} {SEARCH x1 USING INDEX x1i (<expr>=?)}
26995d5a880Sdan
27095d5a880Sdando_execsql_test 6.2.1 {
27195d5a880Sdan  SELECT a, b FROM x1 WHERE CAST(b AS TEXT) = 123;
27295d5a880Sdan} {1 123   2 123}
27395d5a880Sdando_execsql_test 6.2.2 {
27495d5a880Sdan  CREATE INDEX x1i2 ON x1( CAST(b AS TEXT) );
27595d5a880Sdan  SELECT a, b FROM x1 WHERE CAST(b AS TEXT) = 123;
27695d5a880Sdan} {1 123   2 123}
27795d5a880Sdando_eqp_test 6.2.3 {
27895d5a880Sdan  SELECT a, b FROM x1 WHERE CAST(b AS TEXT) = 123;
279*8210233cSdrh} {SEARCH x1 USING INDEX x1i2 (<expr>=?)}
2807525b87bSdan
281ef14abbfSdando_execsql_test 7.0 {
282ef14abbfSdan  CREATE TABLE IF NOT EXISTS t0(c0);
283ef14abbfSdan  INSERT INTO t0(c0) VALUES (-9223372036854775808);
284ef14abbfSdan  BEGIN;
285ef14abbfSdan}
286ef14abbfSdando_catchsql_test 7.1 {
287ef14abbfSdan  CREATE INDEX i0 ON t0(ABS(c0));
288ef14abbfSdan} {1 {integer overflow}}
289ef14abbfSdando_execsql_test 7.2 {
290ef14abbfSdan  COMMIT;
291ef14abbfSdan  SELECT sql FROM sqlite_master WHERE tbl_name = 't0';
292ef14abbfSdan  CREATE INDEX i0 ON t0(c0);
293ef14abbfSdan} {{CREATE TABLE t0(c0)}}
2947ed6c068Sdando_execsql_test 7.3 {
2957ed6c068Sdan  REINDEX;
2967ed6c068Sdan} {}
297ef14abbfSdan
2981cd382e3Sdan#-------------------------------------------------------------------------
2991cd382e3Sdanreset_db
3001cd382e3Sdando_execsql_test 8.0 {
3011cd382e3Sdan  CREATE TABLE t0(c0);
3021cd382e3Sdan  CREATE INDEX i0 ON t0(c0) WHERE c0 NOT NULL;
3031cd382e3Sdan  INSERT INTO t0(c0) VALUES (NULL);
3041cd382e3Sdan}
3051cd382e3Sdan
3069d23ea74Sdando_execsql_test 8.1.1 {
3071cd382e3Sdan  SELECT * FROM t0 WHERE ~('' BETWEEN t0.c0 AND TRUE);
3081cd382e3Sdan} {{}}
3099d23ea74Sdando_execsql_test 8.1.2 {
3101cd382e3Sdan  SELECT ~('' BETWEEN t0.c0 AND TRUE) FROM t0;
3111cd382e3Sdan} {-1}
3121cd382e3Sdan
3139d23ea74Sdanforeach {tn expr} {
3149d23ea74Sdan  1 " 0  ==  (34 BETWEEN c0 AND 33)"
3159d23ea74Sdan  2 " 1  !=  (34 BETWEEN c0 AND 33)"
3169d23ea74Sdan  3 "-1   <  (34 BETWEEN c0 AND 33)"
3179d23ea74Sdan  4 "-1  <=  (34 BETWEEN c0 AND 33)"
3189d23ea74Sdan  5 " 1   >  (34 BETWEEN c0 AND 33)"
3199d23ea74Sdan  6 " 1  >=  (34 BETWEEN c0 AND 33)"
3209d23ea74Sdan  7 " 1   -  (34 BETWEEN c0 AND 33)"
3219d23ea74Sdan  8 "-1   +  (34 BETWEEN c0 AND 33)"
3229d23ea74Sdan  9 " 1   |  (34 BETWEEN c0 AND 33)"
3239d23ea74Sdan 10 " 1  <<  (34 BETWEEN c0 AND 33)"
3249d23ea74Sdan 11 " 1  >>  (34 BETWEEN c0 AND 33)"
3259d23ea74Sdan 12 " 1  ||  (34 BETWEEN c0 AND 33)"
3269d23ea74Sdan} {
3279d23ea74Sdan  do_execsql_test 8.3.$tn.1 "SELECT * FROM t0 WHERE $expr ORDER BY c0" { {} }
3289d23ea74Sdan  do_execsql_test 8.3.$tn.2 "SELECT ($expr) IS TRUE FROM t0"           { 1 }
3299d23ea74Sdan}
330ef14abbfSdan
3319d23ea74Sdando_execsql_test 8.4 {
3329d23ea74Sdan  CREATE TABLE t1(a, b);
3339d23ea74Sdan  INSERT INTO t1 VALUES(1, 2), (3, 4);
3349d23ea74Sdan  CREATE TABLE t2(x, y);
3359d23ea74Sdan}
3369d23ea74Sdan
3379d23ea74Sdanforeach {tn expr} {
3389d23ea74Sdan  1 " 0  ==  (a=0 AND y=1)"
3399d23ea74Sdan  2 " 1  !=  (a=0 AND y=1)"
3409d23ea74Sdan  3 "-1  <   (a=0 AND y=1)"
3419d23ea74Sdan  4 "-1  <=  (a=0 AND y=1)"
3429d23ea74Sdan  5 " 1   >  (a=0 AND y=1)"
3439d23ea74Sdan  6 " 1  >=  (a=0 AND y=1)"
3449d23ea74Sdan  7 " 1   -  (a=0 AND y=1)"
3459d23ea74Sdan  8 "-1   +  (a=0 AND y=1)"
3469d23ea74Sdan  9 " 1   |  (a=0 AND y=1)"
3479d23ea74Sdan  10 "1  <<  (a=0 AND y=1)"
3489d23ea74Sdan  11 "1  >>  (a=0 AND y=1)"
3499d23ea74Sdan  12 "1  ||  (a=0 AND y=1)"
3509d23ea74Sdan
3519d23ea74Sdan  13 " 0  ==  (10 BETWEEN y AND b)"
3529d23ea74Sdan  14 " 1  !=  (10 BETWEEN y AND b)"
3539d23ea74Sdan  15 "-1  <   (10 BETWEEN y AND b)"
3549d23ea74Sdan  16 "-1  <=  (10 BETWEEN y AND b)"
3559d23ea74Sdan  17 " 1   >  (10 BETWEEN y AND b)"
3569d23ea74Sdan  18 " 1  >=  (10 BETWEEN y AND b)"
3579d23ea74Sdan  19 " 1   -  (10 BETWEEN y AND b)"
3589d23ea74Sdan  20 "-1   +  (10 BETWEEN y AND b)"
3599d23ea74Sdan  21 " 1   |  (10 BETWEEN y AND b)"
3609d23ea74Sdan  22 " 1  <<  (10 BETWEEN y AND b)"
3619d23ea74Sdan  23 " 1  >>  (10 BETWEEN y AND b)"
3629d23ea74Sdan  24 " 1  ||  (10 BETWEEN y AND b)"
3639d23ea74Sdan
3649d23ea74Sdan  25 " 1  ||  (10 BETWEEN y AND b)"
3659d23ea74Sdan} {
3669d23ea74Sdan  do_execsql_test 8.5.$tn.1 "
3679d23ea74Sdan    SELECT * FROM t1 LEFT JOIN t2 WHERE $expr
3689d23ea74Sdan  " {1 2 {} {} 3 4 {} {}}
3699d23ea74Sdan
3709d23ea74Sdan  do_execsql_test 8.5.$tn.2 "
3719d23ea74Sdan    SELECT ($expr) IS TRUE FROM t1 LEFT JOIN t2
3729d23ea74Sdan  " {1 1}
3739d23ea74Sdan}
3749b84f035Sdrh
375b8d29c2fSdanfinish_test
376