mkspeedsql.tcl 5.4 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238
  1. # 2008 October 9
  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 generates SQL text used for performance testing.
  12. #
  13. # $Id: mkspeedsql.tcl,v 1.1 2008/10/09 17:57:34 drh Exp $
  14. #
  15. # Set a uniform random seed
  16. expr srand(0)
  17. # The number_name procedure below converts its argment (an integer)
  18. # into a string which is the English-language name for that number.
  19. #
  20. # Example:
  21. #
  22. # puts [number_name 123] -> "one hundred twenty three"
  23. #
  24. set ones {zero one two three four five six seven eight nine
  25. ten eleven twelve thirteen fourteen fifteen sixteen seventeen
  26. eighteen nineteen}
  27. set tens {{} ten twenty thirty forty fifty sixty seventy eighty ninety}
  28. proc number_name {n} {
  29. if {$n>=1000} {
  30. set txt "[number_name [expr {$n/1000}]] thousand"
  31. set n [expr {$n%1000}]
  32. } else {
  33. set txt {}
  34. }
  35. if {$n>=100} {
  36. append txt " [lindex $::ones [expr {$n/100}]] hundred"
  37. set n [expr {$n%100}]
  38. }
  39. if {$n>=20} {
  40. append txt " [lindex $::tens [expr {$n/10}]]"
  41. set n [expr {$n%10}]
  42. }
  43. if {$n>0} {
  44. append txt " [lindex $::ones $n]"
  45. }
  46. set txt [string trim $txt]
  47. if {$txt==""} {set txt zero}
  48. return $txt
  49. }
  50. # Create a database schema.
  51. #
  52. puts {
  53. PRAGMA page_size=1024;
  54. PRAGMA cache_size=8192;
  55. PRAGMA locking_mode=EXCLUSIVE;
  56. CREATE TABLE t1(a INTEGER, b INTEGER, c TEXT);
  57. CREATE TABLE t2(a INTEGER, b INTEGER, c TEXT);
  58. CREATE INDEX i2a ON t2(a);
  59. CREATE INDEX i2b ON t2(b);
  60. SELECT name FROM sqlite_master ORDER BY 1;
  61. }
  62. # 50000 INSERTs on an unindexed table
  63. #
  64. set t1c_list {}
  65. puts {BEGIN;}
  66. for {set i 1} {$i<=50000} {incr i} {
  67. set r [expr {int(rand()*500000)}]
  68. set x [number_name $r]
  69. lappend t1c_list $x
  70. puts "INSERT INTO t1 VALUES($i,$r,'$x');"
  71. }
  72. puts {COMMIT;}
  73. # 50000 INSERTs on an indexed table
  74. #
  75. puts {BEGIN;}
  76. for {set i 1} {$i<=50000} {incr i} {
  77. set r [expr {int(rand()*500000)}]
  78. puts "INSERT INTO t2 VALUES($i,$r,'[number_name $r]');"
  79. }
  80. puts {COMMIT;}
  81. # 50 SELECTs on an integer comparison. There is no index so
  82. # a full table scan is required.
  83. #
  84. for {set i 0} {$i<50} {incr i} {
  85. set lwr [expr {$i*100}]
  86. set upr [expr {($i+10)*100}]
  87. puts "SELECT count(*), avg(b) FROM t1 WHERE b>=$lwr AND b<$upr;"
  88. }
  89. # 50 SELECTs on an LIKE comparison. There is no index so a full
  90. # table scan is required.
  91. #
  92. for {set i 0} {$i<50} {incr i} {
  93. puts "SELECT count(*), avg(b) FROM t1 WHERE c LIKE '%[number_name $i]%';"
  94. }
  95. # Create indices
  96. #
  97. puts {BEGIN;}
  98. puts {
  99. CREATE INDEX i1a ON t1(a);
  100. CREATE INDEX i1b ON t1(b);
  101. CREATE INDEX i1c ON t1(c);
  102. }
  103. puts {COMMIT;}
  104. # 5000 SELECTs on an integer comparison where the integer is
  105. # indexed.
  106. #
  107. set sql {}
  108. for {set i 0} {$i<5000} {incr i} {
  109. set lwr [expr {$i*100}]
  110. set upr [expr {($i+10)*100}]
  111. puts "SELECT count(*), avg(b) FROM t1 WHERE b>=$lwr AND b<$upr;"
  112. }
  113. # 100000 random SELECTs against rowid.
  114. #
  115. for {set i 1} {$i<=100000} {incr i} {
  116. set id [expr {int(rand()*50000)+1}]
  117. puts "SELECT c FROM t1 WHERE rowid=$id;"
  118. }
  119. # 100000 random SELECTs against a unique indexed column.
  120. #
  121. for {set i 1} {$i<=100000} {incr i} {
  122. set id [expr {int(rand()*50000)+1}]
  123. puts "SELECT c FROM t1 WHERE a=$id;"
  124. }
  125. # 50000 random SELECTs against an indexed column text column
  126. #
  127. set nt1c [llength $t1c_list]
  128. for {set i 0} {$i<50000} {incr i} {
  129. set r [expr {int(rand()*$nt1c)}]
  130. set c [lindex $t1c_list $i]
  131. puts "SELECT c FROM t1 WHERE c='$c';"
  132. }
  133. # Vacuum
  134. puts {VACUUM;}
  135. # 5000 updates of ranges where the field being compared is indexed.
  136. #
  137. puts {BEGIN;}
  138. for {set i 0} {$i<5000} {incr i} {
  139. set lwr [expr {$i*2}]
  140. set upr [expr {($i+1)*2}]
  141. puts "UPDATE t1 SET b=b*2 WHERE a>=$lwr AND a<$upr;"
  142. }
  143. puts {COMMIT;}
  144. # 50000 single-row updates. An index is used to find the row quickly.
  145. #
  146. puts {BEGIN;}
  147. for {set i 0} {$i<50000} {incr i} {
  148. set r [expr {int(rand()*500000)}]
  149. puts "UPDATE t1 SET b=$r WHERE a=$i;"
  150. }
  151. puts {COMMIT;}
  152. # 1 big text update that touches every row in the table.
  153. #
  154. puts {
  155. UPDATE t1 SET c=a;
  156. }
  157. # Many individual text updates. Each row in the table is
  158. # touched through an index.
  159. #
  160. puts {BEGIN;}
  161. for {set i 1} {$i<=50000} {incr i} {
  162. set r [expr {int(rand()*500000)}]
  163. puts "UPDATE t1 SET c='[number_name $r]' WHERE a=$i;"
  164. }
  165. puts {COMMIT;}
  166. # Delete all content in a table.
  167. #
  168. puts {DELETE FROM t1;}
  169. # Copy one table into another
  170. #
  171. puts {INSERT INTO t1 SELECT * FROM t2;}
  172. # Delete all content in a table, one row at a time.
  173. #
  174. puts {DELETE FROM t1 WHERE 1;}
  175. # Refill the table yet again
  176. #
  177. puts {INSERT INTO t1 SELECT * FROM t2;}
  178. # Drop the table and recreate it without its indices.
  179. #
  180. puts {BEGIN;}
  181. puts {
  182. DROP TABLE t1;
  183. CREATE TABLE t1(a INTEGER, b INTEGER, c TEXT);
  184. }
  185. puts {COMMIT;}
  186. # Refill the table yet again. This copy should be faster because
  187. # there are no indices to deal with.
  188. #
  189. puts {INSERT INTO t1 SELECT * FROM t2;}
  190. # Select 20000 rows from the table at random.
  191. #
  192. puts {
  193. SELECT rowid FROM t1 ORDER BY random() LIMIT 20000;
  194. }
  195. # Delete 20000 random rows from the table.
  196. #
  197. puts {
  198. DELETE FROM t1 WHERE rowid IN
  199. (SELECT rowid FROM t1 ORDER BY random() LIMIT 20000);
  200. }
  201. puts {SELECT count(*) FROM t1;}
  202. # Delete 20000 more rows at random from the table.
  203. #
  204. puts {
  205. DELETE FROM t1 WHERE rowid IN
  206. (SELECT rowid FROM t1 ORDER BY random() LIMIT 20000);
  207. }
  208. puts {SELECT count(*) FROM t1;}