1# 2002 February 26 2# 3# The author disclaims copyright to this source code. In place of 4# a legal notice, here is a blessing: 5# 6# May you do good and not evil. 7# May you find forgiveness for yourself and forgive others. 8# May you share freely, never taking more than you give. 9# 10#*********************************************************************** 11# This file implements regression tests for SQLite library. The 12# focus of this file is testing VIEW statements. 13# 14# $Id: view.test,v 1.39 2008/12/14 14:45:21 danielk1977 Exp $ 15set testdir [file dirname $argv0] 16source $testdir/tester.tcl 17 18# Omit this entire file if the library is not configured with views enabled. 19ifcapable !view { 20 finish_test 21 return 22} 23 24do_test view-1.0 { 25 execsql { 26 CREATE TABLE t1(a,b,c); 27 INSERT INTO t1 VALUES(1,2,3); 28 INSERT INTO t1 VALUES(4,5,6); 29 INSERT INTO t1 VALUES(7,8,9); 30 SELECT * FROM t1; 31 } 32} {1 2 3 4 5 6 7 8 9} 33 34do_test view-1.1 { 35 execsql { 36 BEGIN; 37 CREATE VIEW IF NOT EXISTS v1 AS SELECT a,b FROM t1; 38 SELECT * FROM v1 ORDER BY a; 39 } 40} {1 2 4 5 7 8} 41do_test view-1.1.100 { 42 db config enable_view off 43 catchsql { 44 SELECT * FROM v1 ORDER BY a; 45 } 46} {1 {access to view "v1" prohibited}} 47do_test view-1.1.110 { 48 db config enable_view on 49 catchsql { 50 SELECT * FROM v1 ORDER BY a; 51 } 52} {0 {1 2 4 5 7 8}} 53do_test view-1.2 { 54 catchsql { 55 ROLLBACK; 56 SELECT * FROM v1 ORDER BY a; 57 } 58} {1 {no such table: v1}} 59do_test view-1.3 { 60 execsql { 61 CREATE VIEW v1 AS SELECT a,b FROM t1; 62 SELECT * FROM v1 ORDER BY a; 63 } 64} {1 2 4 5 7 8} 65do_test view-1.3.1 { 66 db close 67 sqlite3 db test.db 68 execsql { 69 SELECT * FROM v1 ORDER BY a; 70 } 71} {1 2 4 5 7 8} 72do_test view-1.4 { 73 catchsql { 74 DROP VIEW IF EXISTS v1; 75 SELECT * FROM v1 ORDER BY a; 76 } 77} {1 {no such table: v1}} 78do_test view-1.5 { 79 execsql { 80 CREATE VIEW v1 AS SELECT a,b FROM t1; 81 SELECT * FROM v1 ORDER BY a; 82 } 83} {1 2 4 5 7 8} 84do_test view-1.6 { 85 catchsql { 86 DROP TABLE t1; 87 SELECT * FROM v1 ORDER BY a; 88 } 89} {1 {no such table: main.t1}} 90do_test view-1.7 { 91 execsql { 92 CREATE TABLE t1(x,a,b,c); 93 INSERT INTO t1 VALUES(1,2,3,4); 94 INSERT INTO t1 VALUES(4,5,6,7); 95 INSERT INTO t1 VALUES(7,8,9,10); 96 SELECT * FROM v1 ORDER BY a; 97 } 98} {2 3 5 6 8 9} 99do_test view-1.8 { 100 db close 101 sqlite3 db test.db 102 execsql { 103 SELECT * FROM v1 ORDER BY a; 104 } 105} {2 3 5 6 8 9} 106 107do_execsql_test view-1.10 { 108 CREATE TABLE t9(x INTEGER); 109 CREATE VIEW v9a AS SELECT x FROM t9; 110 CREATE VIEW v9b AS SELECT * FROM t9; 111 CREATE VIEW v9c(x) AS SELECT x FROM t9; 112 CREATE VIEW v9d(x) AS SELECT * FROM t9; 113} {} 114do_execsql_test view-1.11 { 115 PRAGMA table_info(v9a); 116} {0 x INTEGER 0 {} 0} 117do_execsql_test view-1.12 { 118 PRAGMA table_info(v9b); 119} {0 x INTEGER 0 {} 0} 120do_execsql_test view-1.13 { 121 PRAGMA table_info(v9c); 122} {0 x INTEGER 0 {} 0} 123do_execsql_test view-1.14 { 124 PRAGMA table_info(v9d); 125} {0 x INTEGER 0 {} 0} 126 127do_test view-2.1 { 128 execsql { 129 CREATE VIEW v2 AS SELECT * FROM t1 WHERE a>5 130 }; # No semicolon 131 execsql2 { 132 SELECT * FROM v2; 133 } 134} {x 7 a 8 b 9 c 10} 135do_test view-2.2 { 136 catchsql { 137 INSERT INTO v2 VALUES(1,2,3,4); 138 } 139} {1 {cannot modify v2 because it is a view}} 140do_test view-2.3 { 141 catchsql { 142 UPDATE v2 SET a=10 WHERE a=5; 143 } 144} {1 {cannot modify v2 because it is a view}} 145do_test view-2.4 { 146 catchsql { 147 DELETE FROM v2; 148 } 149} {1 {cannot modify v2 because it is a view}} 150do_test view-2.5 { 151 execsql { 152 INSERT INTO t1 VALUES(11,12,13,14); 153 SELECT * FROM v2 ORDER BY x; 154 } 155} {7 8 9 10 11 12 13 14} 156do_test view-2.6 { 157 execsql { 158 SELECT x FROM v2 WHERE a>10 159 } 160} {11} 161 162# Test that column name of views are generated correctly. 163# 164do_test view-3.1 { 165 execsql2 { 166 SELECT * FROM v1 LIMIT 1 167 } 168} {a 2 b 3} 169do_test view-3.2 { 170 execsql2 { 171 SELECT * FROM v2 LIMIT 1 172 } 173} {x 7 a 8 b 9 c 10} 174do_test view-3.3.1 { 175 execsql2 { 176 DROP VIEW v1; 177 CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1; 178 SELECT * FROM v1 LIMIT 1 179 } 180} {xyz 2 pqr 7 c-b 1} 181do_test view-3.3.2 { 182 execsql2 { 183 CREATE VIEW v1b AS SELECT t1.a, b+c, t1.c FROM t1; 184 SELECT * FROM v1b LIMIT 1 185 } 186} {a 2 b+c 7 c 4} 187do_test view-3.3.3 { 188 execsql2 { 189 CREATE VIEW v1c(x,y,z) AS SELECT a, b+c, c-b FROM t1; 190 SELECT * FROM v1c LIMIT 1; 191 } 192} {x 2 y 7 z 1} 193do_catchsql_test view-3.3.4 { 194 CREATE VIEW v1err(x,y DESC,z) AS SELECT a, b+c, c-b FROM t1; 195} {1 {syntax error after column name "y"}} 196do_catchsql_test view-3.3.5 { 197 DROP VIEW IF EXISTS v1err; 198 CREATE VIEW v1err(x,y) AS SELECT a, b+c, c-b FROM t1; 199 SELECT * FROM v1err; 200} {1 {expected 2 columns for 'v1err' but got 3}} 201do_catchsql_test view-3.3.6 { 202 DROP VIEW IF EXISTS v1err; 203 CREATE VIEW v1err(w,x,y,z) AS SELECT a, b+c, c-b FROM t1; 204 SELECT * FROM v1err; 205} {1 {expected 4 columns for 'v1err' but got 3}} 206 207ifcapable compound { 208do_test view-3.4 { 209 execsql2 { 210 CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b; 211 SELECT * FROM v3 LIMIT 4; 212 } 213} {a 2 a 3 a 5 a 6} 214do_test view-3.5 { 215 execsql2 { 216 CREATE VIEW v4 AS 217 SELECT a, b FROM t1 218 UNION 219 SELECT b AS 'x', a AS 'y' FROM t1 220 ORDER BY x, y; 221 SELECT b FROM v4 ORDER BY b LIMIT 4; 222 } 223} {b 2 b 3 b 5 b 6} 224} ;# ifcapable compound 225 226 227do_test view-4.1 { 228 catchsql { 229 DROP VIEW t1; 230 } 231} {1 {use DROP TABLE to delete table t1}} 232do_test view-4.2 { 233 execsql { 234 SELECT 1 FROM t1 LIMIT 1; 235 } 236} 1 237do_test view-4.3 { 238 catchsql { 239 DROP TABLE v1; 240 } 241} {1 {use DROP VIEW to delete view v1}} 242do_test view-4.4 { 243 execsql { 244 SELECT 1 FROM v1 LIMIT 1; 245 } 246} {1} 247do_test view-4.5 { 248 catchsql { 249 CREATE INDEX i1v1 ON v1(xyz); 250 } 251} {1 {views may not be indexed}} 252 253do_test view-5.1 { 254 execsql { 255 CREATE TABLE t2(y,a); 256 INSERT INTO t2 VALUES(22,2); 257 INSERT INTO t2 VALUES(33,3); 258 INSERT INTO t2 VALUES(44,4); 259 INSERT INTO t2 VALUES(55,5); 260 SELECT * FROM t2; 261 } 262} {22 2 33 3 44 4 55 5} 263do_test view-5.2 { 264 execsql { 265 CREATE VIEW v5 AS 266 SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a); 267 SELECT * FROM v5; 268 } 269} {1 22 4 55} 270 271# Verify that the view v5 gets flattened. see sqliteFlattenSubquery(). 272# This will only work if EXPLAIN is enabled. 273# Ticket #272 274# 275ifcapable {explain} { 276do_test view-5.3 { 277 lsearch [execsql { 278 EXPLAIN SELECT * FROM v5; 279 }] OpenEphemeral 280} {-1} 281do_test view-5.4 { 282 execsql { 283 SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y; 284 } 285} {1 22 22 2 4 55 55 5} 286do_test view-5.5 { 287 lsearch [execsql { 288 EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y; 289 }] OpenEphemeral 290} {-1} 291do_test view-5.6 { 292 execsql { 293 SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y; 294 } 295} {22 2 1 22 55 5 4 55} 296do_test view-5.7 { 297 lsearch [execsql { 298 EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y; 299 }] OpenEphemeral 300} {-1} 301do_test view-5.8 { 302 execsql { 303 SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y; 304 } 305} {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5} 306do_test view-5.9 { 307 lsearch [execsql { 308 EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y; 309 }] OpenEphemeral 310} {-1} 311} ;# endif explain 312 313do_test view-6.1 { 314 execsql { 315 SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2; 316 } 317} {7 8 9 10 27} 318do_test view-6.2 { 319 execsql { 320 SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2; 321 } 322} {11 12 13 14 39} 323 324do_test view-7.1 { 325 execsql { 326 CREATE TABLE test1(id integer primary key, a); 327 CREATE TABLE test2(id integer, b); 328 INSERT INTO test1 VALUES(1,2); 329 INSERT INTO test2 VALUES(1,3); 330 CREATE VIEW test AS 331 SELECT test1.id, a, b 332 FROM test1 JOIN test2 ON test2.id=test1.id; 333 SELECT * FROM test; 334 } 335} {1 2 3} 336do_test view-7.2 { 337 db close 338 sqlite3 db test.db 339 execsql { 340 SELECT * FROM test; 341 } 342} {1 2 3} 343do_test view-7.3 { 344 execsql { 345 DROP VIEW test; 346 CREATE VIEW test AS 347 SELECT test1.id, a, b 348 FROM test1 JOIN test2 USING(id); 349 SELECT * FROM test; 350 } 351} {1 2 3} 352do_test view-7.4 { 353 db close 354 sqlite3 db test.db 355 execsql { 356 SELECT * FROM test; 357 } 358} {1 2 3} 359do_test view-7.5 { 360 execsql { 361 DROP VIEW test; 362 CREATE VIEW test AS 363 SELECT test1.id, a, b 364 FROM test1 NATURAL JOIN test2; 365 SELECT * FROM test; 366 } 367} {1 2 3} 368do_test view-7.6 { 369 db close 370 sqlite3 db test.db 371 execsql { 372 SELECT * FROM test; 373 } 374} {1 2 3} 375 376do_test view-8.1 { 377 execsql { 378 CREATE VIEW v6 AS SELECT pqr, xyz FROM v1; 379 SELECT * FROM v6 ORDER BY xyz; 380 } 381} {7 2 13 5 19 8 27 12} 382do_test view-8.2 { 383 db close 384 sqlite3 db test.db 385 execsql { 386 SELECT * FROM v6 ORDER BY xyz; 387 } 388} {7 2 13 5 19 8 27 12} 389do_test view-8.3 { 390 execsql { 391 CREATE VIEW v7(a) AS SELECT pqr+xyz FROM v6; 392 SELECT * FROM v7 ORDER BY a; 393 } 394} {9 18 27 39} 395 396ifcapable subquery { 397 do_test view-8.4 { 398 execsql { 399 CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM 400 (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo); 401 SELECT * FROM v8; 402 } 403 } 3 404 do_test view-8.5 { 405 execsql { 406 SELECT mx+10, mx*2 FROM v8; 407 } 408 } {13 6} 409 do_test view-8.6 { 410 execsql { 411 SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2; 412 } 413 } {13 7} 414 do_test view-8.7 { 415 execsql { 416 SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2; 417 } 418 } {13 13 13 19 13 27} 419} ;# ifcapable subquery 420 421# Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW. 422# 423do_test view-9.1 { 424 execsql { 425 INSERT INTO t2 SELECT * FROM t2 WHERE a<5; 426 INSERT INTO t2 SELECT * FROM t2 WHERE a<4; 427 INSERT INTO t2 SELECT * FROM t2 WHERE a<3; 428 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1; 429 } 430} {1 2 4 8} 431do_test view-9.2 { 432 execsql { 433 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3; 434 } 435} {1 2 4} 436do_test view-9.3 { 437 execsql { 438 CREATE VIEW v9 AS 439 SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3; 440 SELECT * FROM v9; 441 } 442} {1 2 4} 443do_test view-9.4 { 444 execsql { 445 SELECT * FROM v9 ORDER BY 1 DESC; 446 } 447} {4 2 1} 448do_test view-9.5 { 449 execsql { 450 CREATE VIEW v10 AS 451 SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3; 452 SELECT * FROM v10; 453 } 454} {5 1 4 2 3 4} 455do_test view-9.6 { 456 execsql { 457 SELECT * FROM v10 ORDER BY 1; 458 } 459} {3 4 4 2 5 1} 460 461# Tables with columns having peculiar quoted names used in views 462# Ticket #756. 463# 464do_test view-10.1 { 465 execsql { 466 CREATE TABLE t3("9" integer, [4] text); 467 INSERT INTO t3 VALUES(1,2); 468 CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a; 469 CREATE VIEW v_t3_b AS SELECT "4" FROM t3; 470 SELECT * FROM v_t3_a; 471 } 472} {1} 473do_test view-10.2 { 474 execsql { 475 SELECT * FROM v_t3_b; 476 } 477} {2} 478 479do_test view-11.1 { 480 execsql { 481 CREATE TABLE t4(a COLLATE NOCASE); 482 INSERT INTO t4 VALUES('This'); 483 INSERT INTO t4 VALUES('this'); 484 INSERT INTO t4 VALUES('THIS'); 485 SELECT * FROM t4 WHERE a = 'THIS'; 486 } 487} {This this THIS} 488ifcapable subquery { 489 do_test view-11.2 { 490 execsql { 491 SELECT * FROM (SELECT * FROM t4) WHERE a = 'THIS'; 492 } 493 } {This this THIS} 494} 495do_test view-11.3 { 496 execsql { 497 CREATE VIEW v11 AS SELECT * FROM t4; 498 SELECT * FROM v11 WHERE a = 'THIS'; 499 } 500} {This this THIS} 501 502# Ticket #1270: Do not allow parameters in view definitions. 503# 504do_test view-12.1 { 505 catchsql { 506 CREATE VIEW v12 AS SELECT a FROM t1 WHERE b=? 507 } 508} {1 {parameters are not allowed in views}} 509do_test view-12.2 { 510 catchsql { 511 CREATE VIEW v12(x) AS SELECT a FROM t1 WHERE b=? 512 } 513} {1 {parameters are not allowed in views}} 514 515ifcapable attach { 516 do_test view-13.1 { 517 forcedelete test2.db 518 catchsql { 519 ATTACH 'test2.db' AS two; 520 CREATE TABLE two.t2(x,y); 521 CREATE VIEW v13 AS SELECT y FROM two.t2; 522 } 523 } {1 {view v13 cannot reference objects in database two}} 524} 525 526# Ticket #1658 527# 528do_test view-14.1 { 529 catchsql { 530 CREATE TEMP VIEW t1 AS SELECT a,b FROM t1; 531 SELECT * FROM temp.t1; 532 } 533} {1 {view t1 is circularly defined}} 534do_test view-14.2 { 535 catchsql { 536 DROP VIEW IF EXISTS temp.t1; 537 CREATE TEMP VIEW t1(a,b) AS SELECT a,b FROM t1; 538 SELECT * FROM temp.t1; 539 } 540} {1 {view t1 is circularly defined}} 541 542# Tickets #1688, #1709 543# 544do_test view-15.1 { 545 execsql2 { 546 CREATE VIEW v15 AS SELECT a AS x, b AS y FROM t1; 547 SELECT * FROM v15 LIMIT 1; 548 } 549} {x 2 y 3} 550do_test view-15.2 { 551 execsql2 { 552 SELECT x, y FROM v15 LIMIT 1 553 } 554} {x 2 y 3} 555 556do_test view-16.1 { 557 catchsql { 558 CREATE VIEW IF NOT EXISTS v1 AS SELECT * FROM t1; 559 } 560} {0 {}} 561do_test view-16.2 { 562 execsql { 563 SELECT sql FROM sqlite_master WHERE name='v1' 564 } 565} {{CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1}} 566do_test view-16.3 { 567 catchsql { 568 DROP VIEW IF EXISTS nosuchview 569 } 570} {0 {}} 571 572# correct error message when attempting to drop a view that does not 573# exist. 574# 575do_test view-17.1 { 576 catchsql { 577 DROP VIEW nosuchview 578 } 579} {1 {no such view: nosuchview}} 580do_test view-17.2 { 581 catchsql { 582 DROP VIEW main.nosuchview 583 } 584} {1 {no such view: main.nosuchview}} 585 586do_test view-18.1 { 587 execsql { 588 DROP VIEW t1; 589 DROP TABLE t1; 590 CREATE TABLE t1(a, b, c); 591 INSERT INTO t1 VALUES(1, 2, 3); 592 INSERT INTO t1 VALUES(4, 5, 6); 593 594 CREATE VIEW vv1 AS SELECT * FROM t1; 595 CREATE VIEW vv2 AS SELECT * FROM vv1; 596 CREATE VIEW vv3 AS SELECT * FROM vv2; 597 CREATE VIEW vv4 AS SELECT * FROM vv3; 598 CREATE VIEW vv5 AS SELECT * FROM vv4; 599 600 SELECT * FROM vv5; 601 } 602} {1 2 3 4 5 6} 603 604# Ticket #3308 605# Make sure "rowid" columns in a view are named correctly. 606# 607do_test view-19.1 { 608 execsql { 609 CREATE VIEW v3308a AS SELECT rowid, * FROM t1; 610 } 611 execsql2 { 612 SELECT * FROM v3308a 613 } 614} {rowid 1 a 1 b 2 c 3 rowid 2 a 4 b 5 c 6} 615do_test view-19.2 { 616 execsql { 617 CREATE VIEW v3308b AS SELECT t1.rowid, t1.a, t1.b+t1.c FROM t1; 618 } 619 execsql2 { 620 SELECT * FROM v3308b 621 } 622} {rowid 1 a 1 t1.b+t1.c 5 rowid 2 a 4 t1.b+t1.c 11} 623do_test view-19.3 { 624 execsql { 625 CREATE VIEW v3308c AS SELECT t1.oid, A, t1.b+t1.c AS x FROM t1; 626 } 627 execsql2 { 628 SELECT * FROM v3308c 629 } 630} {rowid 1 a 1 x 5 rowid 2 a 4 x 11} 631 632# Ticket #3539 had this crashing (see commit [5940]). 633do_test view-20.1 { 634 execsql { 635 DROP TABLE IF EXISTS t1; 636 DROP VIEW IF EXISTS v1; 637 CREATE TABLE t1(c1); 638 CREATE VIEW v1 AS SELECT c1 FROM (SELECT t1.c1 FROM t1); 639 } 640} {} 641 642# Ticket [d58ccbb3f1b]: Prevent Table.nRef overflow. 643db close 644sqlite3 db :memory: 645do_test view-21.1 { 646 catchsql { 647 CREATE TABLE t1(x); 648 INSERT INTO t1 VALUES(5); 649 CREATE VIEW v1 AS SELECT x*2 FROM t1; 650 CREATE VIEW v2 AS SELECT * FROM v1 UNION SELECT * FROM v1; 651 CREATE VIEW v4 AS SELECT * FROM v2 UNION SELECT * FROM v2; 652 CREATE VIEW v8 AS SELECT * FROM v4 UNION SELECT * FROM v4; 653 CREATE VIEW v16 AS SELECT * FROM v8 UNION SELECT * FROM v8; 654 CREATE VIEW v32 AS SELECT * FROM v16 UNION SELECT * FROM v16; 655 CREATE VIEW v64 AS SELECT * FROM v32 UNION SELECT * FROM v32; 656 CREATE VIEW v128 AS SELECT * FROM v64 UNION SELECT * FROM v64; 657 CREATE VIEW v256 AS SELECT * FROM v128 UNION SELECT * FROM v128; 658 CREATE VIEW v512 AS SELECT * FROM v256 UNION SELECT * FROM v256; 659 CREATE VIEW v1024 AS SELECT * FROM v512 UNION SELECT * FROM v512; 660 CREATE VIEW v2048 AS SELECT * FROM v1024 UNION SELECT * FROM v1024; 661 CREATE VIEW v4096 AS SELECT * FROM v2048 UNION SELECT * FROM v2048; 662 CREATE VIEW v8192 AS SELECT * FROM v4096 UNION SELECT * FROM v4096; 663 CREATE VIEW v16384 AS SELECT * FROM v8192 UNION SELECT * FROM v8192; 664 CREATE VIEW v32768 AS SELECT * FROM v16384 UNION SELECT * FROM v16384; 665 SELECT * FROM v32768 UNION SELECT * FROM v32768; 666 } 667} {1 {too many references to "v1": max 65535}} 668ifcapable progress { 669 do_test view-21.2 { 670 db progress 1000 {expr 1} 671 catchsql { 672 SELECT * FROM v32768; 673 } 674 } {1 interrupted} 675} 676 677db close 678sqlite3 db :memory: 679do_execsql_test view-22.1 { 680 CREATE VIEW x1 AS SELECT 123 AS '', 234 AS '', 345 AS ''; 681 SELECT * FROM x1; 682} {123 234 345} 683do_test view-22.2 { 684 unset -nocomplain x 685 db eval {SELECT * FROM x1} x break 686 lsort [array names x] 687} {{} * :1 :2} 688 689do_test view-25.1 { 690 db eval { 691 CREATE TABLE t25 (x); 692 INSERT INTO t25 (x) VALUES (1); 693 ANALYZE; 694 } 695 proc authLogDelete {code arg1 arg2 arg3 arg4 args} { 696 if {$code=="SQLITE_DELETE" && [string match sqlite_stat* $arg1]} { 697 # lappend ::log [list $code $arg1 $arg2 $arg3 $arg4 $args] 698 lappend ::log [list $code $arg1 $arg2 $arg3 $arg4] 699 } 700 return SQLITE_OK 701 } 702 set log "" 703 db authorizer ::authLogDelete 704 db eval {DROP VIEW x1;} 705 set log 706} {} 707 708set res [list {SQLITE_DELETE sqlite_stat1 {} main {}}] 709ifcapable stat4 { lappend res {SQLITE_DELETE sqlite_stat4 {} main {}} } 710do_test view-25.2 { 711 set log "" 712 db eval {DROP TABLE t25;} 713 set log 714} $res 715 716#------------------------------------------------------------------------- 717do_execsql_test view-26.0 { 718 CREATE TABLE t16(a, b, c UNIQUE); 719 INSERT INTO t16 VALUES(1, 1, 1); 720 INSERT INTO t16 VALUES(2, 2, 2); 721 INSERT INTO t16 VALUES(3, 3, 3); 722 CREATE VIEW v16 AS SELECT max(a) AS mx, min(b) AS mn FROM t16 GROUP BY c; 723 724 SELECT * FROM v16 AS one, v16 AS two WHERE one.mx=1; 725} { 726 1 1 1 1 727 1 1 2 2 728 1 1 3 3 729} 730do_execsql_test view-26.1 { 731 WITH v17(x,y) AS (SELECT max(a), min(b) FROM t16 GROUP BY c) 732 SELECT * FROM v17 AS one, v17 AS two WHERE one.x=1; 733} { 734 1 1 1 1 735 1 1 2 2 736 1 1 3 3 737} 738 739#------------------------------------------------------------------------- 740reset_db 741do_execsql_test view-27.0 { 742 CREATE TABLE t0(c0 TEXT, c1); 743 INSERT INTO t0(c0, c1) VALUES (-1, 0); 744 CREATE VIEW v0(c0, c1) AS SELECT t0.c0, AVG(t0.c1) FROM t0; 745} 746 747do_execsql_test view-27.1 { 748 SELECT c0, typeof(c0), c1, typeof(c1) FROM v0; 749} { 750 -1 text 751 0.0 real 752} 753 754do_execsql_test view-27.2 { SELECT c0<c1 FROM v0 } 1 755do_execsql_test view-27.3 { SELECT c1<c0 FROM v0 } 0 756do_execsql_test view-27.4 { 757 SELECT 1 FROM v0 WHERE c1<c0 758} {} 759do_execsql_test view-27.5 { 760 SELECT 1 FROM v0 WHERE c0<c1 761} {1} 762 763do_execsql_test view-27.6 { 764 SELECT c0<c1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) 765} 1 766do_execsql_test view-27.7 { 767 SELECT c1<c0 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) 768} 0 769do_execsql_test view-27.8 { 770 SELECT 1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) WHERE c1<c0 771} {} 772do_execsql_test view-27.9 { 773 SELECT 1 FROM (SELECT t0.c0 AS c0, AVG(t0.c1) AS c1 FROM t0) WHERE c0<c1 774} {1} 775 776#------------------------------------------------------------------------- 777reset_db 778do_execsql_test view-28.0 { 779 CREATE TABLE t0(c0 TEXT); 780 CREATE VIEW v0(c0) AS SELECT t0.c0 FROM t0; 781 INSERT INTO t0(c0) VALUES ('0'); 782} 783do_execsql_test view-28.1 { 784 SELECT 0 IN (c0) FROM t0; 785} {0} 786do_execsql_test view-28.2 { 787 SELECT 0 IN (c0) FROM (SELECT c0 FROM t0); 788} {0} 789 790finish_test 791