xref: /sqlite-3.40.0/test/speed4.test (revision e8f52c50)
10d6e7a00Sdanielk1977# 2007 October 23
20d6e7a00Sdanielk1977#
30d6e7a00Sdanielk1977# The author disclaims copyright to this source code.  In place of
40d6e7a00Sdanielk1977# a legal notice, here is a blessing:
50d6e7a00Sdanielk1977#
60d6e7a00Sdanielk1977#    May you do good and not evil.
70d6e7a00Sdanielk1977#    May you find forgiveness for yourself and forgive others.
80d6e7a00Sdanielk1977#    May you share freely, never taking more than you give.
90d6e7a00Sdanielk1977#
100d6e7a00Sdanielk1977#*************************************************************************
110d6e7a00Sdanielk1977# This file implements regression tests for SQLite library.  The
120d6e7a00Sdanielk1977# focus of this script is measuring executing speed. More specifically,
130d6e7a00Sdanielk1977# the focus is on the speed of:
140d6e7a00Sdanielk1977#
150d6e7a00Sdanielk1977#   * joins
160d6e7a00Sdanielk1977#   * views
170d6e7a00Sdanielk1977#   * sub-selects
180d6e7a00Sdanielk1977#   * triggers
190d6e7a00Sdanielk1977#
20*e8f52c50Sdrh# $Id: speed4.test,v 1.2 2008/07/12 14:52:20 drh Exp $
210d6e7a00Sdanielk1977#
220d6e7a00Sdanielk1977
230d6e7a00Sdanielk1977set testdir [file dirname $argv0]
240d6e7a00Sdanielk1977source $testdir/tester.tcl
250d6e7a00Sdanielk1977speed_trial_init speed1
260d6e7a00Sdanielk1977
270d6e7a00Sdanielk1977# Set a uniform random seed
280d6e7a00Sdanielk1977expr srand(0)
290d6e7a00Sdanielk1977
300d6e7a00Sdanielk1977set sqlout [open speed1.txt w]
310d6e7a00Sdanielk1977proc tracesql {sql} {
320d6e7a00Sdanielk1977  puts $::sqlout $sql\;
330d6e7a00Sdanielk1977}
340d6e7a00Sdanielk1977#db trace tracesql
350d6e7a00Sdanielk1977
360d6e7a00Sdanielk1977# The number_name procedure below converts its argment (an integer)
370d6e7a00Sdanielk1977# into a string which is the English-language name for that number.
380d6e7a00Sdanielk1977#
390d6e7a00Sdanielk1977# Example:
400d6e7a00Sdanielk1977#
410d6e7a00Sdanielk1977#     puts [number_name 123]   ->  "one hundred twenty three"
420d6e7a00Sdanielk1977#
430d6e7a00Sdanielk1977set ones {zero one two three four five six seven eight nine
440d6e7a00Sdanielk1977          ten eleven twelve thirteen fourteen fifteen sixteen seventeen
450d6e7a00Sdanielk1977          eighteen nineteen}
460d6e7a00Sdanielk1977set tens {{} ten twenty thirty forty fifty sixty seventy eighty ninety}
470d6e7a00Sdanielk1977proc number_name {n} {
480d6e7a00Sdanielk1977  if {$n>=1000} {
490d6e7a00Sdanielk1977    set txt "[number_name [expr {$n/1000}]] thousand"
500d6e7a00Sdanielk1977    set n [expr {$n%1000}]
510d6e7a00Sdanielk1977  } else {
520d6e7a00Sdanielk1977    set txt {}
530d6e7a00Sdanielk1977  }
540d6e7a00Sdanielk1977  if {$n>=100} {
550d6e7a00Sdanielk1977    append txt " [lindex $::ones [expr {$n/100}]] hundred"
560d6e7a00Sdanielk1977    set n [expr {$n%100}]
570d6e7a00Sdanielk1977  }
580d6e7a00Sdanielk1977  if {$n>=20} {
590d6e7a00Sdanielk1977    append txt " [lindex $::tens [expr {$n/10}]]"
600d6e7a00Sdanielk1977    set n [expr {$n%10}]
610d6e7a00Sdanielk1977  }
620d6e7a00Sdanielk1977  if {$n>0} {
630d6e7a00Sdanielk1977    append txt " [lindex $::ones $n]"
640d6e7a00Sdanielk1977  }
650d6e7a00Sdanielk1977  set txt [string trim $txt]
660d6e7a00Sdanielk1977  if {$txt==""} {set txt zero}
670d6e7a00Sdanielk1977  return $txt
680d6e7a00Sdanielk1977}
690d6e7a00Sdanielk1977
700d6e7a00Sdanielk1977# Summary of tests:
710d6e7a00Sdanielk1977#
720d6e7a00Sdanielk1977#   speed4-join1: Join three tables using IPK index.
730d6e7a00Sdanielk1977#   speed4-join2: Join three tables using an index.
740d6e7a00Sdanielk1977#   speed4-join3: Join two tables without an index.
750d6e7a00Sdanielk1977#
760d6e7a00Sdanielk1977#   speed4-view1:  Querying a view.
770d6e7a00Sdanielk1977#   speed4-table1: Same queries as in speed4-view1, but run directly against
780d6e7a00Sdanielk1977#                  the tables for comparison purposes.
790d6e7a00Sdanielk1977#
800d6e7a00Sdanielk1977#   speed4-subselect1: A SELECT statement that uses many sub-queries..
810d6e7a00Sdanielk1977#
820d6e7a00Sdanielk1977#   speed4-trigger1: An INSERT statement that fires a trigger.
830d6e7a00Sdanielk1977#   speed4-trigger2: An UPDATE statement that fires a trigger.
840d6e7a00Sdanielk1977#   speed4-trigger3: A DELETE statement that fires a trigger.
850d6e7a00Sdanielk1977#   speed4-notrigger1: Same operation as trigger1, but without the trigger.
860d6e7a00Sdanielk1977#   speed4-notrigger2:        "          trigger2           "
870d6e7a00Sdanielk1977#   speed4-notrigger3:        "          trigger3           "
880d6e7a00Sdanielk1977#
890d6e7a00Sdanielk1977
900d6e7a00Sdanielk1977# Set up the schema. Each of the tables t1, t2 and t3 contain 50,000 rows.
910d6e7a00Sdanielk1977# This creates a database of around 16MB.
920d6e7a00Sdanielk1977execsql {
930d6e7a00Sdanielk1977  BEGIN;
940d6e7a00Sdanielk1977  CREATE TABLE t1(rowid INTEGER PRIMARY KEY, i INTEGER, t TEXT);
950d6e7a00Sdanielk1977  CREATE TABLE t2(rowid INTEGER PRIMARY KEY, i INTEGER, t TEXT);
960d6e7a00Sdanielk1977  CREATE TABLE t3(rowid INTEGER PRIMARY KEY, i INTEGER, t TEXT);
970d6e7a00Sdanielk1977
980d6e7a00Sdanielk1977  CREATE VIEW v1 AS SELECT rowid, i, t FROM t1;
990d6e7a00Sdanielk1977  CREATE VIEW v2 AS SELECT rowid, i, t FROM t2;
1000d6e7a00Sdanielk1977  CREATE VIEW v3 AS SELECT rowid, i, t FROM t3;
1010d6e7a00Sdanielk1977}
1020d6e7a00Sdanielk1977for {set jj 1} {$jj <= 3} {incr jj} {
1030d6e7a00Sdanielk1977  set stmt [string map "%T% t$jj" {INSERT INTO %T% VALUES(NULL, $i, $t)}]
1040d6e7a00Sdanielk1977  for {set ii 0} {$ii < 50000} {incr ii} {
1050d6e7a00Sdanielk1977    set i [expr {int(rand()*50000)}]
1060d6e7a00Sdanielk1977    set t [number_name $i]
1070d6e7a00Sdanielk1977    execsql $stmt
1080d6e7a00Sdanielk1977  }
1090d6e7a00Sdanielk1977}
1100d6e7a00Sdanielk1977execsql {
1110d6e7a00Sdanielk1977  CREATE INDEX i1 ON t1(t);
1120d6e7a00Sdanielk1977  CREATE INDEX i2 ON t2(t);
1130d6e7a00Sdanielk1977  CREATE INDEX i3 ON t3(t);
1140d6e7a00Sdanielk1977  COMMIT;
1150d6e7a00Sdanielk1977}
1160d6e7a00Sdanielk1977
1170d6e7a00Sdanielk1977# Before running these tests, disable the compiled statement cache built into
1180d6e7a00Sdanielk1977# the Tcl interface. This is because we want to test the speed of SQL
1190d6e7a00Sdanielk1977# compilation as well as execution.
1200d6e7a00Sdanielk1977#
1210d6e7a00Sdanielk1977db cache size 0
1220d6e7a00Sdanielk1977
1230d6e7a00Sdanielk1977# Join t1, t2, t3 on IPK.
1240d6e7a00Sdanielk1977set sql "SELECT * FROM t1, t2, t3 WHERE t1.oid = t2.oid AND t2.oid = t3.oid"
1250d6e7a00Sdanielk1977speed_trial speed4-join1 50000 row $sql
1260d6e7a00Sdanielk1977
1270d6e7a00Sdanielk1977# Join t1, t2, t3 on the non-IPK index.
1280d6e7a00Sdanielk1977set sql "SELECT * FROM t1, t2, t3 WHERE t1.t = t2.t AND t2.t = t3.t"
1290d6e7a00Sdanielk1977speed_trial speed4-join2 50000 row $sql
1300d6e7a00Sdanielk1977
1310d6e7a00Sdanielk1977# Run 10000 simple queries against the views.
1320d6e7a00Sdanielk1977set sql ""
1330d6e7a00Sdanielk1977for {set ii 1} {$ii < 10000} {incr ii} {
1340d6e7a00Sdanielk1977  append sql "SELECT * FROM v[expr {($ii%3)+1}] WHERE rowid = [expr {$ii*3}];"
1350d6e7a00Sdanielk1977}
1360d6e7a00Sdanielk1977speed_trial speed4-view1 10000 stmt $sql
1370d6e7a00Sdanielk1977
1380d6e7a00Sdanielk1977# Run the same 10000 simple queries as in the previous test case against
1390d6e7a00Sdanielk1977# the underlying tables. The compiled vdbe programs should be identical, so
1400d6e7a00Sdanielk1977# the only difference in running time is the extra time taken to compile
1410d6e7a00Sdanielk1977# the view definitions.
1420d6e7a00Sdanielk1977#
1430d6e7a00Sdanielk1977set sql ""
1440d6e7a00Sdanielk1977for {set ii 1} {$ii < 10000} {incr ii} {
1450d6e7a00Sdanielk1977  append sql "SELECT t FROM t[expr {($ii%3)+1}] WHERE rowid = [expr {$ii*3}];"
1460d6e7a00Sdanielk1977}
1470d6e7a00Sdanielk1977speed_trial speed4-table1 10000 stmt $sql
1480d6e7a00Sdanielk1977
1490d6e7a00Sdanielk1977# Run a SELECT that uses sub-queries 10000 times. A total of 30000 sub-selects.
1500d6e7a00Sdanielk1977#
1510d6e7a00Sdanielk1977set sql ""
1520d6e7a00Sdanielk1977for {set ii 1} {$ii < 10000} {incr ii} {
1530d6e7a00Sdanielk1977  append sql "
1540d6e7a00Sdanielk1977    SELECT (SELECT t FROM t1 WHERE rowid = [expr {$ii*3}]),
1550d6e7a00Sdanielk1977           (SELECT t FROM t2 WHERE rowid = [expr {$ii*3}]),
1560d6e7a00Sdanielk1977           (SELECT t FROM t3 WHERE rowid = [expr {$ii*3}])
1570d6e7a00Sdanielk1977  ;"
1580d6e7a00Sdanielk1977}
1590d6e7a00Sdanielk1977speed_trial speed4-subselect1 10000 stmt $sql
1600d6e7a00Sdanielk1977
1610d6e7a00Sdanielk1977# The following block tests the speed of some DML statements that cause
1620d6e7a00Sdanielk1977# triggers to fire.
1630d6e7a00Sdanielk1977#
1640d6e7a00Sdanielk1977execsql {
1650d6e7a00Sdanielk1977  CREATE TABLE log(op TEXT, r INTEGER, i INTEGER, t TEXT);
1660d6e7a00Sdanielk1977  CREATE TABLE t4(rowid INTEGER PRIMARY KEY, i INTEGER, t TEXT);
1670d6e7a00Sdanielk1977  CREATE TRIGGER t4_trigger1 AFTER INSERT ON t4 BEGIN
1680d6e7a00Sdanielk1977    INSERT INTO log VALUES('INSERT INTO t4', new.rowid, new.i, new.t);
1690d6e7a00Sdanielk1977  END;
1700d6e7a00Sdanielk1977  CREATE TRIGGER t4_trigger2 AFTER UPDATE ON t4 BEGIN
1710d6e7a00Sdanielk1977    INSERT INTO log VALUES('UPDATE OF t4', new.rowid, new.i, new.t);
1720d6e7a00Sdanielk1977  END;
1730d6e7a00Sdanielk1977  CREATE TRIGGER t4_trigger3 AFTER DELETE ON t4 BEGIN
1740d6e7a00Sdanielk1977    INSERT INTO log VALUES('DELETE OF t4', old.rowid, old.i, old.t);
1750d6e7a00Sdanielk1977  END;
1760d6e7a00Sdanielk1977  BEGIN;
1770d6e7a00Sdanielk1977}
1780d6e7a00Sdanielk1977set sql ""
1790d6e7a00Sdanielk1977for {set ii 1} {$ii < 10000} {incr ii} {
1800d6e7a00Sdanielk1977  append sql "INSERT INTO t4 VALUES(NULL, $ii, '[number_name $ii]');"
1810d6e7a00Sdanielk1977}
1820d6e7a00Sdanielk1977speed_trial speed4-trigger1 10000 stmt $sql
1830d6e7a00Sdanielk1977set sql ""
1840d6e7a00Sdanielk1977for {set ii 1} {$ii < 20000} {incr ii 2} {
1850d6e7a00Sdanielk1977  set ii2 [expr {$ii*2}]
1860d6e7a00Sdanielk1977  append sql "
1870d6e7a00Sdanielk1977    UPDATE t4 SET i = $ii2, t = '[number_name $ii2]' WHERE rowid = $ii;
1880d6e7a00Sdanielk1977  "
1890d6e7a00Sdanielk1977}
1900d6e7a00Sdanielk1977speed_trial speed4-trigger2 10000 stmt $sql
1910d6e7a00Sdanielk1977set sql ""
1920d6e7a00Sdanielk1977for {set ii 1} {$ii < 20000} {incr ii 2} {
1930d6e7a00Sdanielk1977  append sql "DELETE FROM t4 WHERE rowid = $ii;"
1940d6e7a00Sdanielk1977}
1950d6e7a00Sdanielk1977speed_trial speed4-trigger3 10000 stmt $sql
1960d6e7a00Sdanielk1977execsql {COMMIT}
1970d6e7a00Sdanielk1977
1980d6e7a00Sdanielk1977# The following block contains the same tests as the above block that
1990d6e7a00Sdanielk1977# tests triggers, with one crucial difference: no triggers are defined.
2000d6e7a00Sdanielk1977# So the difference in speed between these tests and the preceding ones
2010d6e7a00Sdanielk1977# is the amount of time taken to compile and execute the trigger programs.
2020d6e7a00Sdanielk1977#
2030d6e7a00Sdanielk1977execsql {
2040d6e7a00Sdanielk1977  DROP TABLE t4;
2050d6e7a00Sdanielk1977  DROP TABLE log;
2060d6e7a00Sdanielk1977  VACUUM;
2070d6e7a00Sdanielk1977  CREATE TABLE t4(rowid INTEGER PRIMARY KEY, i INTEGER, t TEXT);
2080d6e7a00Sdanielk1977  BEGIN;
2090d6e7a00Sdanielk1977}
2100d6e7a00Sdanielk1977set sql ""
2110d6e7a00Sdanielk1977for {set ii 1} {$ii < 10000} {incr ii} {
2120d6e7a00Sdanielk1977  append sql "INSERT INTO t4 VALUES(NULL, $ii, '[number_name $ii]');"
2130d6e7a00Sdanielk1977}
2140d6e7a00Sdanielk1977speed_trial speed4-notrigger1 10000 stmt $sql
2150d6e7a00Sdanielk1977set sql ""
2160d6e7a00Sdanielk1977for {set ii 1} {$ii < 20000} {incr ii 2} {
2170d6e7a00Sdanielk1977  set ii2 [expr {$ii*2}]
2180d6e7a00Sdanielk1977  append sql "
2190d6e7a00Sdanielk1977    UPDATE t4 SET i = $ii2, t = '[number_name $ii2]' WHERE rowid = $ii;
2200d6e7a00Sdanielk1977  "
2210d6e7a00Sdanielk1977}
2220d6e7a00Sdanielk1977speed_trial speed4-notrigger2 10000 stmt $sql
2230d6e7a00Sdanielk1977set sql ""
2240d6e7a00Sdanielk1977for {set ii 1} {$ii < 20000} {incr ii 2} {
2250d6e7a00Sdanielk1977  append sql "DELETE FROM t4 WHERE rowid = $ii;"
2260d6e7a00Sdanielk1977}
2270d6e7a00Sdanielk1977speed_trial speed4-notrigger3 10000 stmt $sql
2280d6e7a00Sdanielk1977execsql {COMMIT}
2290d6e7a00Sdanielk1977
2300d6e7a00Sdanielk1977speed_trial_summary speed4
2310d6e7a00Sdanielk1977finish_test
232