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