Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Update the speed.html documentation. Recent optimizations have made the library much faster. (CVS 846) |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
ed47d162a072a2f98b633cc14f2be147 |
User & Date: | drh 2003-01-25 14:25:42.000 |
Context
2003-01-25
| ||
14:32 | Preparations for the release of version 2.7.6. (CVS 847) (check-in: 5143d4814d user: drh tags: trunk) | |
14:25 | Update the speed.html documentation. Recent optimizations have made the library much faster. (CVS 846) (check-in: ed47d162a0 user: drh tags: trunk) | |
2003-01-24
| ||
12:14 | Add asserts to btree.c that check for the correct size of various typedefs and structures. Ticket #233. (CVS 845) (check-in: c7e647d011 user: drh tags: trunk) | |
Changes
Changes to www/speed.tcl.
1 2 3 | # # Run this Tcl script to generate the speed.html file. # | | | 1 2 3 4 5 6 7 8 9 10 11 | # # Run this Tcl script to generate the speed.html file. # set rcsid {$Id: speed.tcl,v 1.10 2003/01/25 14:25:42 drh Exp $ } puts {<html> <head> <title>Database Speed Comparison: SQLite versus PostgreSQL</title> </head> <body bgcolor=white> <h1 align=center> |
︙ | ︙ | |||
27 28 29 30 31 32 33 | <ul> <li><p> SQLite 2.7.6 is significantly faster (sometimes as much as 10 or 20 times faster) than PostgreSQL 7.1.3 for most common operations. </p></li> <li><p> | | | | > > > > | | 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 | <ul> <li><p> SQLite 2.7.6 is significantly faster (sometimes as much as 10 or 20 times faster) than PostgreSQL 7.1.3 for most common operations. </p></li> <li><p> SQLite 2.7.6 is often faster (sometimes more than twice as fast) than MySQL 3.23.41 for most common operations. </p></li> <li><p> SQLite does not execute CREATE INDEX or DROP TABLE as fast as the other databases. But this as not seen is a problem because those are infrequent operations. </p></li> <li><p> SQLite works best if you group multiple operations together into a single transaction. </p></li> </ul> <p> The results presented here come with the following caveats: </p> <ul> <li><p> These tests did not attempt to measure multi-user performance or optimization of complex queries involving multiple joins and subqueries. </p></li> <li><p> These tests are on a relatively small (approximately 14 megabyte) database. They do not measure how well the database engines scale to larger problems. </p></li> </ul> <h2>Test Environment</h2> <p> |
︙ | ︙ | |||
123 124 125 126 127 128 129 | INSERT INTO t1 VALUES(2,75560,'seventy five thousand five hundred sixty');<br> <i>... 995 lines omitted</i><br> INSERT INTO t1 VALUES(998,66289,'sixty six thousand two hundred eighty nine');<br> INSERT INTO t1 VALUES(999,24322,'twenty four thousand three hundred twenty two');<br> INSERT INTO t1 VALUES(1000,94142,'ninety four thousand one hundred forty two');<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> | | | | | > > | > > | | < > > > | | | | | | | | > > > > > > > > > > > > > > > > > > > > > > > > > | | | | | > | | | < | < < < | | | | | | | < | | | | | | | > | | | | | | | | < | | | | | | | | | | | | | | | | | | | | | | | | | > > > > > > | | | | | < | > > | < < < | | | | | | | < | | | | | < | | | | | > | | | | | | | | | | | | | | | | | 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 | INSERT INTO t1 VALUES(2,75560,'seventy five thousand five hundred sixty');<br> <i>... 995 lines omitted</i><br> INSERT INTO t1 VALUES(998,66289,'sixty six thousand two hundred eighty nine');<br> INSERT INTO t1 VALUES(999,24322,'twenty four thousand three hundred twenty two');<br> INSERT INTO t1 VALUES(1000,94142,'ninety four thousand one hundred forty two');<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 4.373</td></tr> <tr><td>MySQL:</td><td align="right"> 0.114</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 13.061</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.223</td></tr> </table> <p> Because it does not have a central server to coordinate access, SQLite must close and reopen the database file, and thus invalidate its cache, for each transaction. In this test, each SQL statement is a separate transaction so the database file must be opened and closed and the cache must be flushed 1000 times. In spite of this, the asynchronous version of SQLite is still nearly as fast as MySQL. Notice how much slower the synchronous version is, however. SQLite calls <b>fsync()</b> after each synchronous transaction to make sure that all data is safely on the disk surface before continuing. For most of the 13 seconds in the synchronous test, SQLite was sitting idle waiting on disk I/O to complete.</p> <h2>Test 2: 25000 INSERTs in a transaction</h2> <blockquote> BEGIN;<br> CREATE TABLE t2(a INTEGER, b INTEGER, c VARCHAR(100));<br> INSERT INTO t2 VALUES(1,59672,'fifty nine thousand six hundred seventy two');<br> <i>... 24997 lines omitted</i><br> INSERT INTO t2 VALUES(24999,89569,'eighty nine thousand five hundred sixty nine');<br> INSERT INTO t2 VALUES(25000,94666,'ninety four thousand six hundred sixty six');<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 4.900</td></tr> <tr><td>MySQL:</td><td align="right"> 2.184</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.914</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.757</td></tr> </table> <p> When all the INSERTs are put in a transaction, SQLite no longer has to close and reopen the database or invalidate its cache between each statement. It also does not have to do any fsync()s until the very end. When unshackled in this way, SQLite is much faster than either PostgreSQL and MySQL. </p> <h2>Test 3: 25000 INSERTs into an indexed tablel</h2> <blockquote> BEGIN;<br> CREATE TABLE t3(a INTEGER, b INTEGER, c VARCHAR(100));<br> CREATE INDEX i3 ON t3(c);<br> <i>... 24998 lines omitted</i><br> INSERT INTO t3 VALUES(24999,88509,'eighty eight thousand five hundred nine');<br> INSERT INTO t3 VALUES(25000,84791,'eighty four thousand seven hundred ninety one');<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 8.175</td></tr> <tr><td>MySQL:</td><td align="right"> 3.197</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 1.555</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.402</td></tr> </table> <p> There were reports that SQLite did not perform as well on an indexed table. This test was recently added to disprove those rumors. It is true that SQLite is not as fast at creating new index entries as the other engines (see Test 6 below) but its overall speed is still better. </p> <h2>Test 4: 100 SELECTs without an index</h2> <blockquote> BEGIN;<br> SELECT count(*), avg(b) FROM t2 WHERE b>=0 AND b<1000;<br> SELECT count(*), avg(b) FROM t2 WHERE b>=100 AND b<1100;<br> <i>... 96 lines omitted</i><br> SELECT count(*), avg(b) FROM t2 WHERE b>=9800 AND b<10800;<br> SELECT count(*), avg(b) FROM t2 WHERE b>=9900 AND b<10900;<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 3.629</td></tr> <tr><td>MySQL:</td><td align="right"> 2.760</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 2.494</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 2.526</td></tr> </table> <p> This test does 100 queries on a 25000 entry table without an index, thus requiring a full table scan. Prior versions of SQLite used to be slower than PostgreSQL and MySQL on this test, but recent performance enhancements have increased its speed so that it is now the fastest of the group. </p> <h2>Test 5: 100 SELECTs on a string comparison</h2> <blockquote> BEGIN;<br> SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%one%';<br> SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%two%';<br> <i>... 96 lines omitted</i><br> SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%ninety nine%';<br> SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%one hundred%';<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 13.409</td></tr> <tr><td>MySQL:</td><td align="right"> 4.640</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 3.362</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 3.372</td></tr> </table> <p> This test still does 100 full table scans but it uses uses string comparisons instead of numerical comparisions. SQLite is over three times faster than PostgreSQL here and about 30% faster than MySQL. </p> <h2>Test 6: Creating an index</h2> <blockquote> CREATE INDEX i2a ON t2(a);<br>CREATE INDEX i2b ON t2(b); </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 0.381</td></tr> <tr><td>MySQL:</td><td align="right"> 0.318</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.777</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.659</td></tr> </table> <p> SQLite is slower at creating new indices. This is not a huge problem (since new indices are not created very often) but it is something that is being worked on. Hopefully, future versions of SQLite will do better here. </p> <h2>Test 7: 5000 SELECTs with an index</h2> <blockquote> SELECT count(*), avg(b) FROM t2 WHERE b>=0 AND b<100;<br> SELECT count(*), avg(b) FROM t2 WHERE b>=100 AND b<200;<br> SELECT count(*), avg(b) FROM t2 WHERE b>=200 AND b<300;<br> <i>... 4994 lines omitted</i><br> SELECT count(*), avg(b) FROM t2 WHERE b>=499700 AND b<499800;<br> SELECT count(*), avg(b) FROM t2 WHERE b>=499800 AND b<499900;<br> SELECT count(*), avg(b) FROM t2 WHERE b>=499900 AND b<500000;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 4.614</td></tr> <tr><td>MySQL:</td><td align="right"> 1.270</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 1.121</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.162</td></tr> </table> <p> All three database engines run faster when they have indices to work with. But SQLite is still the fastest. </p> <h2>Test 8: 1000 UPDATEs without an index</h2> <blockquote> BEGIN;<br> UPDATE t1 SET b=b*2 WHERE a>=0 AND a<10;<br> UPDATE t1 SET b=b*2 WHERE a>=10 AND a<20;<br> <i>... 996 lines omitted</i><br> UPDATE t1 SET b=b*2 WHERE a>=9980 AND a<9990;<br> UPDATE t1 SET b=b*2 WHERE a>=9990 AND a<10000;<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 1.739</td></tr> <tr><td>MySQL:</td><td align="right"> 8.410</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.637</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.638</td></tr> </table> <p> For this particular UPDATE test, MySQL is consistently five or ten times slower than PostgreSQL and SQLite. I do not know why. MySQL is normally a very fast engine. Perhaps this problem has been addressed in later versions of MySQL. </p> <h2>Test 9: 25000 UPDATEs with an index</h2> <blockquote> BEGIN;<br> UPDATE t2 SET b=468026 WHERE a=1;<br> UPDATE t2 SET b=121928 WHERE a=2;<br> <i>... 24996 lines omitted</i><br> UPDATE t2 SET b=35065 WHERE a=24999;<br> UPDATE t2 SET b=347393 WHERE a=25000;<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 18.797</td></tr> <tr><td>MySQL:</td><td align="right"> 8.134</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 3.520</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 3.104</td></tr> </table> <p> As recently as version 2.7.0, SQLite ran at about the same speed as MySQL on this test. But recent optimizations to SQLite have more than doubled speed of UPDATEs. </p> <h2>Test 10: 25000 text UPDATEs with an index</h2> <blockquote> BEGIN;<br> UPDATE t2 SET c='one hundred forty eight thousand three hundred eighty two' WHERE a=1;<br> UPDATE t2 SET c='three hundred sixty six thousand five hundred two' WHERE a=2;<br> <i>... 24996 lines omitted</i><br> UPDATE t2 SET c='three hundred eighty three thousand ninety nine' WHERE a=24999;<br> UPDATE t2 SET c='two hundred fifty six thousand eight hundred thirty' WHERE a=25000;<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 48.133</td></tr> <tr><td>MySQL:</td><td align="right"> 6.982</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 2.408</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.725</td></tr> </table> <p> Here again, version 2.7.0 of SQLite used to run at about the same speed as MySQL. But now version 2.7.6 is over two times faster than MySQL and over twenty times faster than PostgreSQL. </p> <p> In fairness to PostgreSQL, it started thrashing on this test. A knowledgeable administrator might be able to get PostgreSQL to run a lot faster here by tweaking and tuning the server a little. </p> <h2>Test 11: INSERTs from a SELECT</h2> <blockquote> BEGIN;<br>INSERT INTO t1 SELECT b,a,c FROM t2;<br>INSERT INTO t2 SELECT b,a,c FROM t1;<br>COMMIT; </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 61.364</td></tr> <tr><td>MySQL:</td><td align="right"> 1.537</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 2.787</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.599</td></tr> </table> <p> The asynchronous SQLite is just a shade slower than MySQL on this test. (MySQL seems to be especially adept at INSERT...SELECT statements.) The PostgreSQL engine is still thrashing - most of the 61 seconds it used were spent waiting on disk I/O. </p> <h2>Test 12: DELETE without an index</h2> <blockquote> DELETE FROM t2 WHERE c LIKE '%fifty%'; </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 1.509</td></tr> <tr><td>MySQL:</td><td align="right"> 0.975</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 4.004</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.560</td></tr> </table> <p> The synchronous version of SQLite is the slowest of the group in this test, but the asynchronous version is the fastest. The difference is the extra time needed to execute fsync(). </p> <h2>Test 13: DELETE with an index</h2> <blockquote> DELETE FROM t2 WHERE a>10 AND a<20000; </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 1.316</td></tr> <tr><td>MySQL:</td><td align="right"> 2.262</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 2.068</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.752</td></tr> </table> <p> This test is significant because it is one of the few where PostgreSQL is faster than MySQL. The asynchronous SQLite is, however, faster then both the other two. </p> <h2>Test 14: A big INSERT after a big DELETE</h2> <blockquote> INSERT INTO t2 SELECT * FROM t1; </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 13.168</td></tr> <tr><td>MySQL:</td><td align="right"> 1.815</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 3.210</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.485</td></tr> </table> <p> Some older versions of SQLite (prior to version 2.4.0) would show decreasing performance after a sequence of DELETEs followed by new INSERTs. As this test shows, the problem has now been resolved. </p> <h2>Test 15: A big DELETE followed by many small INSERTs</h2> <blockquote> BEGIN;<br> DELETE FROM t1;<br> INSERT INTO t1 VALUES(1,10719,'ten thousand seven hundred nineteen');<br> <i>... 11997 lines omitted</i><br> INSERT INTO t1 VALUES(11999,72836,'seventy two thousand eight hundred thirty six');<br> INSERT INTO t1 VALUES(12000,64231,'sixty four thousand two hundred thirty one');<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 4.556</td></tr> <tr><td>MySQL:</td><td align="right"> 1.704</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.618</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.406</td></tr> </table> <p> SQLite is very good at doing INSERTs within a transaction, which probably explains why it is so much faster than the other databases at this test. </p> <h2>Test 16: DROP TABLE</h2> <blockquote> DROP TABLE t1;<br>DROP TABLE t2;<br>DROP TABLE t3; </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 0.135</td></tr> <tr><td>MySQL:</td><td align="right"> 0.015</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.939</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.254</td></tr> </table> <p> SQLite is slower than the other databases when it comes to dropping tables. This probably is because when SQLite drops a table, it has to go through and erase the records in the database file that deal with that table. MySQL and PostgreSQL, on the other hand, use separate files to represent each table |
︙ | ︙ |