File:  [ELWIX - Embedded LightWeight unIX -] / embedaddon / sqlite3 / test / analyze4.test
Revision 1.1: download - view: text, annotated - select for diffs - revision graph
Tue Feb 21 17:04:16 2012 UTC (12 years, 8 months ago) by misho
CVS tags: MAIN, HEAD
Initial revision

# 2011 January 04
#
# 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. This file 
# implements tests for ANALYZE to verify that multiple rows containing
# a NULL value count as distinct rows for the purposes of analyze 
# statistics.
#
# Also include test cases for collating sequences on indices.
#

set testdir [file dirname $argv0]
source $testdir/tester.tcl

do_test analyze4-1.0 {
  db eval {
    CREATE TABLE t1(a,b);
    CREATE INDEX t1a ON t1(a);
    CREATE INDEX t1b ON t1(b);
    INSERT INTO t1 VALUES(1,NULL);
    INSERT INTO t1 SELECT a+1, b FROM t1;
    INSERT INTO t1 SELECT a+2, b FROM t1;
    INSERT INTO t1 SELECT a+4, b FROM t1;
    INSERT INTO t1 SELECT a+8, b FROM t1;
    INSERT INTO t1 SELECT a+16, b FROM t1;
    INSERT INTO t1 SELECT a+32, b FROM t1;
    INSERT INTO t1 SELECT a+64, b FROM t1;
    ANALYZE;
  }

  # Should choose the t1a index since it is more specific than t1b.
  db eval {EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=5 AND b IS NULL}
} {0 0 0 {SEARCH TABLE t1 USING INDEX t1a (a=?) (~1 rows)}}

# Verify that the t1b index shows that it does not narrow down the
# search any at all.
#
do_test analyze4-1.1 {
  db eval {
    SELECT idx, stat FROM sqlite_stat1 WHERE tbl='t1' ORDER BY idx;
  }
} {t1a {128 1} t1b {128 128}}

# Change half of the b values from NULL to a constant.  Verify
# that the number of rows selected in stat1 is half the total 
# number of rows.
#
do_test analyze4-1.2 {
  db eval {
    UPDATE t1 SET b='x' WHERE a%2;
    ANALYZE;
    SELECT idx, stat FROM sqlite_stat1 WHERE tbl='t1' ORDER BY idx;
  }
} {t1a {128 1} t1b {128 64}}

# Change the t1.b values all back to NULL.  Add columns t1.c and t1.d.
# Create a multi-column indices using t1.b and verify that ANALYZE 
# processes them correctly.
#
do_test analyze4-1.3 {
  db eval {
    UPDATE t1 SET b=NULL;
    ALTER TABLE t1 ADD COLUMN c;
    ALTER TABLE t1 ADD COLUMN d;
    UPDATE t1 SET c=a/4, d=a/2;
    CREATE INDEX t1bcd ON t1(b,c,d);
    CREATE INDEX t1cdb ON t1(c,d,b);
    CREATE INDEX t1cbd ON t1(c,b,d);
    ANALYZE;
    SELECT idx, stat FROM sqlite_stat1 WHERE tbl='t1' ORDER BY idx;
  }
} {t1a {128 1} t1b {128 128} t1bcd {128 128 4 2} t1cbd {128 4 4 2} t1cdb {128 4 2 2}}

# Verify that collating sequences are taken into account when computing
# ANALYZE statistics.
#
do_test analyze4-2.0 {
  db eval {
    CREATE TABLE t2(
      x INTEGER PRIMARY KEY,
      a TEXT COLLATE nocase,
      b TEXT COLLATE rtrim,
      c TEXT COLLATE binary
    );
    CREATE INDEX t2a ON t2(a);
    CREATE INDEX t2b ON t2(b);
    CREATE INDEX t2c ON t2(c);
    CREATE INDEX t2c2 ON t2(c COLLATE nocase);
    CREATE INDEX t2c3 ON t2(c COLLATE rtrim);
    INSERT INTO t2 VALUES(1, 'abc', 'abc', 'abc');
    INSERT INTO t2 VALUES(2, 'abC', 'abC', 'abC');
    INSERT INTO t2 VALUES(3, 'abc ', 'abc ', 'abc ');
    INSERT INTO t2 VALUES(4, 'abC ', 'abC ', 'abC ');
    INSERT INTO t2 VALUES(5, 'aBc', 'aBc', 'aBc');
    INSERT INTO t2 VALUES(6, 'aBC', 'aBC', 'aBC');
    INSERT INTO t2 VALUES(7, 'aBc ', 'aBc ', 'aBc ');
    INSERT INTO t2 VALUES(8, 'aBC ', 'aBC ', 'aBC ');
    ANALYZE;
    SELECT idx, stat FROM sqlite_stat1 WHERE tbl='t2' ORDER BY idx;
  }
} {t2a {8 4} t2b {8 2} t2c {8 1} t2c2 {8 4} t2c3 {8 2}}

finish_test

FreeBSD-CVSweb <freebsd-cvsweb@FreeBSD.org>