OpenSolaris_b135/lib/libsqlite/test/view.test


#pragma ident	"%Z%%M%	%I%	%E% SMI"

# 2002 February 26
#
# The author disclaims copyright to this source code.  In place of
# a legal notice, here is a blessing:
#
#    May you do good and not evil.
#    May you find forgiveness for yourself and forgive others.
#    May you share freely, never taking more than you give.
#
#***********************************************************************
# This file implements regression tests for SQLite library.  The
# focus of this file is testing VIEW statements.
#
# $Id: view.test,v 1.16.2.1 2004/07/20 00:20:47 drh Exp $
set testdir [file dirname $argv0]
source $testdir/tester.tcl

do_test view-1.0 {
  execsql {
    CREATE TABLE t1(a,b,c);
    INSERT INTO t1 VALUES(1,2,3);
    INSERT INTO t1 VALUES(4,5,6);
    INSERT INTO t1 VALUES(7,8,9);
    SELECT * FROM t1;
  }
} {1 2 3 4 5 6 7 8 9}

do_test view-1.1 {
  execsql {
    BEGIN;
    CREATE VIEW v1 AS SELECT a,b FROM t1;
    SELECT * FROM v1 ORDER BY a;
  }
} {1 2 4 5 7 8}
do_test view-1.2 {
  catchsql {
    ROLLBACK;
    SELECT * FROM v1 ORDER BY a;
  }
} {1 {no such table: v1}}
do_test view-1.3 {
  execsql {
    CREATE VIEW v1 AS SELECT a,b FROM t1;
    SELECT * FROM v1 ORDER BY a;
  }
} {1 2 4 5 7 8}
do_test view-1.3.1 {
  db close
  sqlite db test.db
  execsql {
    SELECT * FROM v1 ORDER BY a;
  }
} {1 2 4 5 7 8}
do_test view-1.4 {
  catchsql {
    DROP VIEW v1;
    SELECT * FROM v1 ORDER BY a;
  }
} {1 {no such table: v1}}
do_test view-1.5 {
  execsql {
    CREATE VIEW v1 AS SELECT a,b FROM t1;
    SELECT * FROM v1 ORDER BY a;
  }
} {1 2 4 5 7 8}
do_test view-1.6 {
  catchsql {
    DROP TABLE t1;
    SELECT * FROM v1 ORDER BY a;
  }
} {1 {no such table: main.t1}}
do_test view-1.7 {
  execsql {
    CREATE TABLE t1(x,a,b,c);
    INSERT INTO t1 VALUES(1,2,3,4);
    INSERT INTO t1 VALUES(4,5,6,7);
    INSERT INTO t1 VALUES(7,8,9,10);
    SELECT * FROM v1 ORDER BY a;
  }
} {2 3 5 6 8 9}
do_test view-1.8 {
  db close
  sqlite db test.db
  execsql {
    SELECT * FROM v1 ORDER BY a;
  }
} {2 3 5 6 8 9}

do_test view-2.1 {
  execsql {
    CREATE VIEW v2 AS SELECT * FROM t1 WHERE a>5
  };  # No semicolon
  execsql2 {
    SELECT * FROM v2;
  }
} {x 7 a 8 b 9 c 10}
do_test view-2.2 {
  catchsql {
    INSERT INTO v2 VALUES(1,2,3,4);
  }
} {1 {cannot modify v2 because it is a view}}
do_test view-2.3 {
  catchsql {
    UPDATE v2 SET a=10 WHERE a=5;
  }
} {1 {cannot modify v2 because it is a view}}
do_test view-2.4 {
  catchsql {
    DELETE FROM v2;
  }
} {1 {cannot modify v2 because it is a view}}
do_test view-2.5 {
  execsql {
    INSERT INTO t1 VALUES(11,12,13,14);
    SELECT * FROM v2 ORDER BY x;
  }
} {7 8 9 10 11 12 13 14}
do_test view-2.6 {
  execsql {
    SELECT x FROM v2 WHERE a>10
  }
} {11}

# Test that column name of views are generated correctly.
#
do_test view-3.1 {
  execsql2 {
    SELECT * FROM v1 LIMIT 1
  }
} {a 2 b 3}
do_test view-3.2 {
  execsql2 {
    SELECT * FROM v2 LIMIT 1
  }
} {x 7 a 8 b 9 c 10}
do_test view-3.3 {
  execsql2 {
    DROP VIEW v1;
    CREATE VIEW v1 AS SELECT a AS 'xyz', b+c AS 'pqr', c-b FROM t1;
    SELECT * FROM v1 LIMIT 1
  }
} {xyz 2 pqr 7 c-b 1}
do_test  view-3.4 {
  execsql2 {
    CREATE VIEW v3 AS SELECT a FROM t1 UNION SELECT b FROM t1 ORDER BY b;
    SELECT * FROM v3 LIMIT 4;
  }
} {b 2 b 3 b 5 b 6}
do_test  view-3.5 {
  execsql2 {
    CREATE VIEW v4 AS 
      SELECT a, b FROM t1 
      UNION
      SELECT b AS 'x', a AS 'y' FROM t1
      ORDER BY x, y;
    SELECT y FROM v4 ORDER BY y LIMIT 4;
  }
} {y 2 y 3 y 5 y 6}


do_test view-4.1 {
  catchsql {
    DROP VIEW t1;
  }
} {1 {use DROP TABLE to delete table t1}}
do_test view-4.2 {
  execsql {
    SELECT 1 FROM t1 LIMIT 1;
  }
} 1
do_test view-4.3 {
  catchsql {
    DROP TABLE v1;
  }
} {1 {use DROP VIEW to delete view v1}}
do_test view-4.4 {
  execsql {
     SELECT 1 FROM v1 LIMIT 1;
  }
} {1}
do_test view-4.5 {
  catchsql {
    CREATE INDEX i1v1 ON v1(xyz);
  }
} {1 {views may not be indexed}}

do_test view-5.1 {
  execsql {
    CREATE TABLE t2(y,a);
    INSERT INTO t2 VALUES(22,2);
    INSERT INTO t2 VALUES(33,3);
    INSERT INTO t2 VALUES(44,4);
    INSERT INTO t2 VALUES(55,5);
    SELECT * FROM t2;
  }
} {22 2 33 3 44 4 55 5}
do_test view-5.2 {
  execsql {
    CREATE VIEW v5 AS
      SELECT t1.x AS v, t2.y AS w FROM t1 JOIN t2 USING(a);
    SELECT * FROM v5;
  }
} {1 22 4 55}

# Verify that the view v5 gets flattened.  see sqliteFlattenSubquery().
# Ticket #272
do_test view-5.3 {
  lsearch [execsql {
    EXPLAIN SELECT * FROM v5;
  }] OpenTemp
} {-1}
do_test view-5.4 {
  execsql {
    SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
  }
} {1 22 22 2 4 55 55 5}
do_test view-5.5 {
  lsearch [execsql {
    EXPLAIN SELECT * FROM v5 AS a, t2 AS b WHERE a.w=b.y;
  }] OpenTemp
} {-1}
do_test view-5.6 {
  execsql {
    SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
  }
} {22 2 1 22 55 5 4 55}
do_test view-5.7 {
  lsearch [execsql {
    EXPLAIN SELECT * FROM t2 AS b, v5 AS a WHERE a.w=b.y;
  }] OpenTemp
} {-1}
do_test view-5.8 {
  execsql {
    SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
  }
} {1 2 3 4 1 22 22 2 4 5 6 7 4 55 55 5}
do_test view-5.9 {
  lsearch [execsql {
    EXPLAIN SELECT * FROM t1 AS a, v5 AS b, t2 AS c WHERE a.x=b.v AND b.w=c.y;
  }] OpenTemp
} {-1}

do_test view-6.1 {
  execsql {
    SELECT min(x), min(a), min(b), min(c), min(a+b+c) FROM v2;
  }
} {7 8 9 10 27}
do_test view-6.2 {
  execsql {
    SELECT max(x), max(a), max(b), max(c), max(a+b+c) FROM v2;
  }
} {11 12 13 14 39}

do_test view-7.1 {
  execsql {
    CREATE TABLE test1(id integer primary key, a);
    CREATE TABLE test2(id integer, b);
    INSERT INTO test1 VALUES(1,2);
    INSERT INTO test2 VALUES(1,3);
    CREATE VIEW test AS
      SELECT test1.id, a, b
      FROM test1 JOIN test2 ON test2.id=test1.id;
    SELECT * FROM test;
  }
} {1 2 3}
do_test view-7.2 {
  db close
  sqlite db test.db
  execsql {
    SELECT * FROM test;
  }
} {1 2 3}
do_test view-7.3 {
  execsql {
    DROP VIEW test;
    CREATE VIEW test AS
      SELECT test1.id, a, b
      FROM test1 JOIN test2 USING(id);
    SELECT * FROM test;
  }
} {1 2 3}
do_test view-7.4 {
  db close
  sqlite db test.db
  execsql {
    SELECT * FROM test;
  }
} {1 2 3}
do_test view-7.5 {
  execsql {
    DROP VIEW test;
    CREATE VIEW test AS
      SELECT test1.id, a, b
      FROM test1 NATURAL JOIN test2;
    SELECT * FROM test;
  }
} {1 2 3}
do_test view-7.6 {
  db close
  sqlite db test.db
  execsql {
    SELECT * FROM test;
  }
} {1 2 3}

do_test view-8.1 {
  execsql {
    CREATE VIEW v6 AS SELECT pqr, xyz FROM v1;
    SELECT * FROM v6 ORDER BY xyz;
  }
} {7 2 13 5 19 8 27 12}
do_test view-8.2 {
  db close
  sqlite db test.db
  execsql {
    SELECT * FROM v6 ORDER BY xyz;
  }
} {7 2 13 5 19 8 27 12}
do_test view-8.3 {
  execsql {
    CREATE VIEW v7 AS SELECT pqr+xyz AS a FROM v6;
    SELECT * FROM v7 ORDER BY a;
  }
} {9 18 27 39}
do_test view-8.4 {
  execsql {
    CREATE VIEW v8 AS SELECT max(cnt) AS mx FROM
      (SELECT a%2 AS eo, count(*) AS cnt FROM t1 GROUP BY eo);
    SELECT * FROM v8;
  }
} 3
do_test view-8.5 {
  execsql {
    SELECT mx+10, mx*2 FROM v8;
  }
} {13 6}
do_test view-8.6 {
  execsql {
    SELECT mx+10, pqr FROM v6, v8 WHERE xyz=2;
  }
} {13 7}
do_test view-8.7 {
  execsql {
    SELECT mx+10, pqr FROM v6, v8 WHERE xyz>2;
  }
} {13 13 13 19 13 27}

# Tests for a bug found by Michiel de Wit involving ORDER BY in a VIEW.
#
do_test view-9.1 {
  execsql {
    INSERT INTO t2 SELECT * FROM t2 WHERE a<5;
    INSERT INTO t2 SELECT * FROM t2 WHERE a<4;
    INSERT INTO t2 SELECT * FROM t2 WHERE a<3;
    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1;
  }
} {1 2 4 8}
do_test view-9.2 {
  execsql {
    SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
  }
} {1 2 4}
do_test view-9.3 {
  execsql {
    CREATE VIEW v9 AS 
       SELECT DISTINCT count(*) FROM t2 GROUP BY a ORDER BY 1 LIMIT 3;
    SELECT * FROM v9;
  }
} {1 2 4}
do_test view-9.4 {
  execsql {
    SELECT * FROM v9 ORDER BY 1 DESC;
  }
} {4 2 1}
do_test view-9.5 {
  execsql {
    CREATE VIEW v10 AS 
       SELECT DISTINCT a, count(*) FROM t2 GROUP BY a ORDER BY 2 LIMIT 3;
    SELECT * FROM v10;
  }
} {5 1 4 2 3 4}
do_test view-9.6 {
  execsql {
    SELECT * FROM v10 ORDER BY 1;
  }
} {3 4 4 2 5 1}

# Tables with columns having peculiar quoted names used in views
# Ticket #756.
#
do_test view-10.1 {
  execsql {
    CREATE TABLE t3("9" integer, [4] text);
    INSERT INTO t3 VALUES(1,2);
    CREATE VIEW v_t3_a AS SELECT a.[9] FROM t3 AS a;
    CREATE VIEW v_t3_b AS SELECT "4" FROM t3;
    SELECT * FROM v_t3_a;
  }
} {1}
do_test view-10.2 {
  execsql {
    SELECT * FROM v_t3_b;
  }
} {2}


finish_test