1*4520Snw141292 2*4520Snw141292#pragma ident "%Z%%M% %I% %E% SMI" 3*4520Snw141292 4*4520Snw141292#!/usr/bin/tclsh 5*4520Snw141292# 6*4520Snw141292# Run this script using TCLSH to do a speed comparison between 7*4520Snw141292# various versions of SQLite and PostgreSQL and MySQL 8*4520Snw141292# 9*4520Snw141292 10*4520Snw141292# Run a test 11*4520Snw141292# 12*4520Snw141292set cnt 1 13*4520Snw141292proc runtest {title} { 14*4520Snw141292 global cnt 15*4520Snw141292 set sqlfile test$cnt.sql 16*4520Snw141292 puts "<h2>Test $cnt: $title</h2>" 17*4520Snw141292 incr cnt 18*4520Snw141292 set fd [open $sqlfile r] 19*4520Snw141292 set sql [string trim [read $fd [file size $sqlfile]]] 20*4520Snw141292 close $fd 21*4520Snw141292 set sx [split $sql \n] 22*4520Snw141292 set n [llength $sx] 23*4520Snw141292 if {$n>8} { 24*4520Snw141292 set sql {} 25*4520Snw141292 for {set i 0} {$i<3} {incr i} {append sql [lindex $sx $i]<br>\n} 26*4520Snw141292 append sql "<i>... [expr {$n-6}] lines omitted</i><br>\n" 27*4520Snw141292 for {set i [expr {$n-3}]} {$i<$n} {incr i} { 28*4520Snw141292 append sql [lindex $sx $i]<br>\n 29*4520Snw141292 } 30*4520Snw141292 } else { 31*4520Snw141292 regsub -all \n [string trim $sql] <br> sql 32*4520Snw141292 } 33*4520Snw141292 puts "<blockquote>" 34*4520Snw141292 puts "$sql" 35*4520Snw141292 puts "</blockquote><table border=0 cellpadding=0 cellspacing=0>" 36*4520Snw141292 set format {<tr><td>%s</td><td align="right"> %.3f</td></tr>} 37*4520Snw141292 set delay 1000 38*4520Snw141292# exec sync; after $delay; 39*4520Snw141292# set t [time "exec psql drh <$sqlfile" 1] 40*4520Snw141292# set t [expr {[lindex $t 0]/1000000.0}] 41*4520Snw141292# puts [format $format PostgreSQL: $t] 42*4520Snw141292 exec sync; after $delay; 43*4520Snw141292 set t [time "exec mysql -f drh <$sqlfile" 1] 44*4520Snw141292 set t [expr {[lindex $t 0]/1000000.0}] 45*4520Snw141292 puts [format $format MySQL: $t] 46*4520Snw141292# set t [time "exec ./sqlite232 s232.db <$sqlfile" 1] 47*4520Snw141292# set t [expr {[lindex $t 0]/1000000.0}] 48*4520Snw141292# puts [format $format {SQLite 2.3.2:} $t] 49*4520Snw141292# set t [time "exec ./sqlite-100 s100.db <$sqlfile" 1] 50*4520Snw141292# set t [expr {[lindex $t 0]/1000000.0}] 51*4520Snw141292# puts [format $format {SQLite 2.4 (cache=100):} $t] 52*4520Snw141292 exec sync; after $delay; 53*4520Snw141292 set t [time "exec ./sqlite248 s2k.db <$sqlfile" 1] 54*4520Snw141292 set t [expr {[lindex $t 0]/1000000.0}] 55*4520Snw141292 puts [format $format {SQLite 2.4.8:} $t] 56*4520Snw141292 exec sync; after $delay; 57*4520Snw141292 set t [time "exec ./sqlite248 sns.db <$sqlfile" 1] 58*4520Snw141292 set t [expr {[lindex $t 0]/1000000.0}] 59*4520Snw141292 puts [format $format {SQLite 2.4.8 (nosync):} $t] 60*4520Snw141292 exec sync; after $delay; 61*4520Snw141292 set t [time "exec ./sqlite2412 s2kb.db <$sqlfile" 1] 62*4520Snw141292 set t [expr {[lindex $t 0]/1000000.0}] 63*4520Snw141292 puts [format $format {SQLite 2.4.12:} $t] 64*4520Snw141292 exec sync; after $delay; 65*4520Snw141292 set t [time "exec ./sqlite2412 snsb.db <$sqlfile" 1] 66*4520Snw141292 set t [expr {[lindex $t 0]/1000000.0}] 67*4520Snw141292 puts [format $format {SQLite 2.4.12 (nosync):} $t] 68*4520Snw141292# set t [time "exec ./sqlite-t1 st1.db <$sqlfile" 1] 69*4520Snw141292# set t [expr {[lindex $t 0]/1000000.0}] 70*4520Snw141292# puts [format $format {SQLite 2.4 (test):} $t] 71*4520Snw141292 puts "</table>" 72*4520Snw141292} 73*4520Snw141292 74*4520Snw141292# Initialize the environment 75*4520Snw141292# 76*4520Snw141292expr srand(1) 77*4520Snw141292catch {exec /bin/sh -c {rm -f s*.db}} 78*4520Snw141292set fd [open clear.sql w] 79*4520Snw141292puts $fd { 80*4520Snw141292 drop table t1; 81*4520Snw141292 drop table t2; 82*4520Snw141292} 83*4520Snw141292close $fd 84*4520Snw141292catch {exec psql drh <clear.sql} 85*4520Snw141292catch {exec mysql drh <clear.sql} 86*4520Snw141292set fd [open 2kinit.sql w] 87*4520Snw141292puts $fd { 88*4520Snw141292 PRAGMA default_cache_size=2000; 89*4520Snw141292 PRAGMA default_synchronous=on; 90*4520Snw141292} 91*4520Snw141292close $fd 92*4520Snw141292exec ./sqlite248 s2k.db <2kinit.sql 93*4520Snw141292exec ./sqlite2412 s2kb.db <2kinit.sql 94*4520Snw141292set fd [open nosync-init.sql w] 95*4520Snw141292puts $fd { 96*4520Snw141292 PRAGMA default_cache_size=2000; 97*4520Snw141292 PRAGMA default_synchronous=off; 98*4520Snw141292} 99*4520Snw141292close $fd 100*4520Snw141292exec ./sqlite248 sns.db <nosync-init.sql 101*4520Snw141292exec ./sqlite2412 snsb.db <nosync-init.sql 102*4520Snw141292set ones {zero one two three four five six seven eight nine 103*4520Snw141292 ten eleven twelve thirteen fourteen fifteen sixteen seventeen 104*4520Snw141292 eighteen nineteen} 105*4520Snw141292set tens {{} ten twenty thirty forty fifty sixty seventy eighty ninety} 106*4520Snw141292proc number_name {n} { 107*4520Snw141292 if {$n>=1000} { 108*4520Snw141292 set txt "[number_name [expr {$n/1000}]] thousand" 109*4520Snw141292 set n [expr {$n%1000}] 110*4520Snw141292 } else { 111*4520Snw141292 set txt {} 112*4520Snw141292 } 113*4520Snw141292 if {$n>=100} { 114*4520Snw141292 append txt " [lindex $::ones [expr {$n/100}]] hundred" 115*4520Snw141292 set n [expr {$n%100}] 116*4520Snw141292 } 117*4520Snw141292 if {$n>=20} { 118*4520Snw141292 append txt " [lindex $::tens [expr {$n/10}]]" 119*4520Snw141292 set n [expr {$n%10}] 120*4520Snw141292 } 121*4520Snw141292 if {$n>0} { 122*4520Snw141292 append txt " [lindex $::ones $n]" 123*4520Snw141292 } 124*4520Snw141292 set txt [string trim $txt] 125*4520Snw141292 if {$txt==""} {set txt zero} 126*4520Snw141292 return $txt 127*4520Snw141292} 128*4520Snw141292 129*4520Snw141292 130*4520Snw141292 131*4520Snw141292set fd [open test$cnt.sql w] 132*4520Snw141292puts $fd "CREATE TABLE t1(a INTEGER, b INTEGER, c VARCHAR(100));" 133*4520Snw141292for {set i 1} {$i<=1000} {incr i} { 134*4520Snw141292 set r [expr {int(rand()*100000)}] 135*4520Snw141292 puts $fd "INSERT INTO t1 VALUES($i,$r,'[number_name $r]');" 136*4520Snw141292} 137*4520Snw141292close $fd 138*4520Snw141292runtest {1000 INSERTs} 139*4520Snw141292 140*4520Snw141292 141*4520Snw141292 142*4520Snw141292set fd [open test$cnt.sql w] 143*4520Snw141292puts $fd "BEGIN;" 144*4520Snw141292puts $fd "CREATE TABLE t2(a INTEGER, b INTEGER, c VARCHAR(100));" 145*4520Snw141292for {set i 1} {$i<=25000} {incr i} { 146*4520Snw141292 set r [expr {int(rand()*500000)}] 147*4520Snw141292 puts $fd "INSERT INTO t2 VALUES($i,$r,'[number_name $r]');" 148*4520Snw141292} 149*4520Snw141292puts $fd "COMMIT;" 150*4520Snw141292close $fd 151*4520Snw141292runtest {25000 INSERTs in a transaction} 152*4520Snw141292 153*4520Snw141292 154*4520Snw141292 155*4520Snw141292set fd [open test$cnt.sql w] 156*4520Snw141292for {set i 0} {$i<100} {incr i} { 157*4520Snw141292 set lwr [expr {$i*100}] 158*4520Snw141292 set upr [expr {($i+10)*100}] 159*4520Snw141292 puts $fd "SELECT count(*), avg(b) FROM t2 WHERE b>=$lwr AND b<$upr;" 160*4520Snw141292} 161*4520Snw141292close $fd 162*4520Snw141292runtest {100 SELECTs without an index} 163*4520Snw141292 164*4520Snw141292 165*4520Snw141292 166*4520Snw141292set fd [open test$cnt.sql w] 167*4520Snw141292for {set i 1} {$i<=100} {incr i} { 168*4520Snw141292 puts $fd "SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%[number_name $i]%';" 169*4520Snw141292} 170*4520Snw141292close $fd 171*4520Snw141292runtest {100 SELECTs on a string comparison} 172*4520Snw141292 173*4520Snw141292 174*4520Snw141292 175*4520Snw141292set fd [open test$cnt.sql w] 176*4520Snw141292puts $fd {CREATE INDEX i2a ON t2(a);} 177*4520Snw141292puts $fd {CREATE INDEX i2b ON t2(b);} 178*4520Snw141292close $fd 179*4520Snw141292runtest {Creating an index} 180*4520Snw141292 181*4520Snw141292 182*4520Snw141292 183*4520Snw141292set fd [open test$cnt.sql w] 184*4520Snw141292for {set i 0} {$i<5000} {incr i} { 185*4520Snw141292 set lwr [expr {$i*100}] 186*4520Snw141292 set upr [expr {($i+1)*100}] 187*4520Snw141292 puts $fd "SELECT count(*), avg(b) FROM t2 WHERE b>=$lwr AND b<$upr;" 188*4520Snw141292} 189*4520Snw141292close $fd 190*4520Snw141292runtest {5000 SELECTs with an index} 191*4520Snw141292 192*4520Snw141292 193*4520Snw141292 194*4520Snw141292set fd [open test$cnt.sql w] 195*4520Snw141292puts $fd "BEGIN;" 196*4520Snw141292for {set i 0} {$i<1000} {incr i} { 197*4520Snw141292 set lwr [expr {$i*10}] 198*4520Snw141292 set upr [expr {($i+1)*10}] 199*4520Snw141292 puts $fd "UPDATE t1 SET b=b*2 WHERE a>=$lwr AND a<$upr;" 200*4520Snw141292} 201*4520Snw141292puts $fd "COMMIT;" 202*4520Snw141292close $fd 203*4520Snw141292runtest {1000 UPDATEs without an index} 204*4520Snw141292 205*4520Snw141292 206*4520Snw141292 207*4520Snw141292set fd [open test$cnt.sql w] 208*4520Snw141292puts $fd "BEGIN;" 209*4520Snw141292for {set i 1} {$i<=25000} {incr i} { 210*4520Snw141292 set r [expr {int(rand()*500000)}] 211*4520Snw141292 puts $fd "UPDATE t2 SET b=$r WHERE a=$i;" 212*4520Snw141292} 213*4520Snw141292puts $fd "COMMIT;" 214*4520Snw141292close $fd 215*4520Snw141292runtest {25000 UPDATEs with an index} 216*4520Snw141292 217*4520Snw141292 218*4520Snw141292set fd [open test$cnt.sql w] 219*4520Snw141292puts $fd "BEGIN;" 220*4520Snw141292for {set i 1} {$i<=25000} {incr i} { 221*4520Snw141292 set r [expr {int(rand()*500000)}] 222*4520Snw141292 puts $fd "UPDATE t2 SET c='[number_name $r]' WHERE a=$i;" 223*4520Snw141292} 224*4520Snw141292puts $fd "COMMIT;" 225*4520Snw141292close $fd 226*4520Snw141292runtest {25000 text UPDATEs with an index} 227*4520Snw141292 228*4520Snw141292 229*4520Snw141292 230*4520Snw141292set fd [open test$cnt.sql w] 231*4520Snw141292puts $fd "BEGIN;" 232*4520Snw141292puts $fd "INSERT INTO t1 SELECT * FROM t2;" 233*4520Snw141292puts $fd "INSERT INTO t2 SELECT * FROM t1;" 234*4520Snw141292puts $fd "COMMIT;" 235*4520Snw141292close $fd 236*4520Snw141292runtest {INSERTs from a SELECT} 237*4520Snw141292 238*4520Snw141292 239*4520Snw141292 240*4520Snw141292set fd [open test$cnt.sql w] 241*4520Snw141292puts $fd {DELETE FROM t2 WHERE c LIKE '%fifty%';} 242*4520Snw141292close $fd 243*4520Snw141292runtest {DELETE without an index} 244*4520Snw141292 245*4520Snw141292 246*4520Snw141292 247*4520Snw141292set fd [open test$cnt.sql w] 248*4520Snw141292puts $fd {DELETE FROM t2 WHERE a>10 AND a<20000;} 249*4520Snw141292close $fd 250*4520Snw141292runtest {DELETE with an index} 251*4520Snw141292 252*4520Snw141292 253*4520Snw141292 254*4520Snw141292set fd [open test$cnt.sql w] 255*4520Snw141292puts $fd {INSERT INTO t2 SELECT * FROM t1;} 256*4520Snw141292close $fd 257*4520Snw141292runtest {A big INSERT after a big DELETE} 258*4520Snw141292 259*4520Snw141292 260*4520Snw141292 261*4520Snw141292set fd [open test$cnt.sql w] 262*4520Snw141292puts $fd {BEGIN;} 263*4520Snw141292puts $fd {DELETE FROM t1;} 264*4520Snw141292for {set i 1} {$i<=3000} {incr i} { 265*4520Snw141292 set r [expr {int(rand()*100000)}] 266*4520Snw141292 puts $fd "INSERT INTO t1 VALUES($i,$r,'[number_name $r]');" 267*4520Snw141292} 268*4520Snw141292puts $fd {COMMIT;} 269*4520Snw141292close $fd 270*4520Snw141292runtest {A big DELETE followed by many small INSERTs} 271*4520Snw141292 272*4520Snw141292 273*4520Snw141292 274*4520Snw141292set fd [open test$cnt.sql w] 275*4520Snw141292puts $fd {DROP TABLE t1;} 276*4520Snw141292puts $fd {DROP TABLE t2;} 277*4520Snw141292close $fd 278*4520Snw141292runtest {DROP TABLE} 279