Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Update the speed comparison page. (CVS 840) |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
424cb2edb0c51b911791422ce7a9f528 |
User & Date: | drh 2003-01-18 22:01:07.000 |
Context
2003-01-19
| ||
03:59 | Update comments. No changes to code. (CVS 841) (check-in: f6a8706872 user: drh tags: trunk) | |
2003-01-18
| ||
22:01 | Update the speed comparison page. (CVS 840) (check-in: 424cb2edb0 user: drh tags: trunk) | |
20:11 | Fix datatype reporting and collating sequence selection so that it works correctly on views and with the UNION, EXCEPT, and INTERCEPT operators. (CVS 839) (check-in: 71cc292dce user: drh tags: trunk) | |
Changes
Changes to www/index.tcl.
1 2 3 | # # Run this TCL script to generate HTML for the index.html file. # | | | 1 2 3 4 5 6 7 8 9 10 11 | # # Run this TCL script to generate HTML for the index.html file. # set rcsid {$Id: index.tcl,v 1.72 2003/01/18 22:01:07 drh Exp $} puts {<html> <head><title>SQLite: An Embeddable SQL Database Engine</title></head> <body bgcolor=white> <h1 align=center>SQLite<br>An Embeddable SQL Database Engine</h1> <p align=center>} puts "This page was last modified on [lrange $rcsid 3 4] UTC<br>" |
︙ | ︙ | |||
53 54 55 56 57 58 59 | <li>A complete database (with multiple tables and indices) is stored in a single disk file.</li> <li>Atomic commit and rollback protect data integrity.</li> <li>Database files can be freely shared between machines with different byte orders.</li> <li>Supports databases up to 2 terabytes (2^41 bytes) in size.</li> <li>Small memory footprint: less than 25K lines of C code.</li> | | > | | 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 | <li>A complete database (with multiple tables and indices) is stored in a single disk file.</li> <li>Atomic commit and rollback protect data integrity.</li> <li>Database files can be freely shared between machines with different byte orders.</li> <li>Supports databases up to 2 terabytes (2^41 bytes) in size.</li> <li>Small memory footprint: less than 25K lines of C code.</li> <li><a href="speed.html">10x faster</a> than PostgreSQL and <a href="speed.html">2x faster</a> than MySQL for many common operations.</li> <li>Very simple <a href="c_interface.html">C/C++ interface</a> requires the use of only three functions and one opaque structure.</li> <li><a href="tclsqlite.html">TCL bindings</a> included. Bindings for many other languages available separately.</li> <li>Simple, well-commented source code.</li> <li>Automated test suite provides near 100% code coverage.</li> |
︙ | ︙ |
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 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 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 | # # Run this Tcl script to generate the speed.html file. # set rcsid {$Id: speed.tcl,v 1.9 2003/01/18 22:01:07 drh Exp $ } puts {<html> <head> <title>Database Speed Comparison: SQLite versus PostgreSQL</title> </head> <body bgcolor=white> <h1 align=center> Database Speed Comparison </h1>} puts "<p align=center> (This page was last modified on [lrange $rcsid 3 4] UTC) </p>" puts { <h2>Executive Summary</h2> <p>A series of tests were run to measure the relative performance of SQLite 2.7.6, PostgreSQL 7.1.3, and MySQL 3.23.41. The following are general conclusions drawn from these experiments: </p> <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 usually faster than MySQL 3.23.41 (sometimes more than twice as fast) though for some operations such as full table scans, it can be as much as 30% slower. </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> </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 10 megabyte) database. They do not measure how well the database engines scale to larger problems. </p></li> </ul> <h2>Test Environment</h2> <p> The platform used for these tests is a 1.6GHz Athlon with 1GB or memory and an IDE disk drive. The operating system is RedHat Linux 7.2 with |
︙ | ︙ | |||
106 107 108 109 110 111 112 | 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> | | | | | > | | | | > < | < > | | | | | > | | > > < | < > | | | | > | | > | | | | | | | | | | | | | | | | > > > | | | | | | | | | | | | | > | | | | | < | < < < | | | | | | > > > > > > > | | | | > > > > > > > | | | | | | | | | | | | > > > > > | | | | | > > > > | > > > | 123 124 125 126 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 | 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"> 3.658</td></tr> <tr><td>MySQL:</td><td align="right"> 0.109</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 7.177</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.266</td></tr> </table> <p>SQLite must close and reopen the database file, and thus invalidate its cache, for each SQL statement. 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. This is due to the necessity of calling <b>fsync()</b> after each SQL statement.</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,298361,'two hundred ninety eight thousand three hundred sixty one');<br> <i>... 24997 lines omitted</i><br> INSERT INTO t2 VALUES(24999,447847,'four hundred forty seven thousand eight hundred forty seven');<br> INSERT INTO t2 VALUES(25000,473330,'four hundred seventy three thousand three hundred thirty');<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 5.058</td></tr> <tr><td>MySQL:</td><td align="right"> 2.271</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.912</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.798</td></tr> </table> <p> When all the INSERTs are put in a transaction, SQLite no longer has to close and reopen the database 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: 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.657</td></tr> <tr><td>MySQL:</td><td align="right"> 3.368</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 4.386</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 4.314</td></tr> </table> <p> This test does 100 queries on a 25000 entry table without an index, thus requiring a full table scan. SQLite is about 20% or 30% slower than PostgreSQL and MySQL. The reason for this is believed to be because SQLite stores all data as strings and must therefore do 5 million string-to-number conversions in the course of evaluating the WHERE clauses. Both PostgreSQL and MySQL store data as binary values where appropriate and can forego this conversion effort. </p> <h2>Test 4: 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"> 15.967</td></tr> <tr><td>MySQL:</td><td align="right"> 5.088</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 5.419</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 5.367</td></tr> </table> <p> This test still does 100 full table scans but it uses uses string comparisons instead of numerical comparisions. SQLite is almost three times faster than PostgreSQL here. But it is still 15% slower than MySQL. MySQL appears to be very good at doing full table scans. </p> <h2>Test 5: 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.431</td></tr> <tr><td>MySQL:</td><td align="right"> 0.340</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.814</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.675</td></tr> </table> <p> SQLite is slower at creating new indices. But since creating new indices is an uncommon operation, this is not seen as a problem. </p> <h2>Test 6: 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"> 5.369</td></tr> <tr><td>MySQL:</td><td align="right"> 1.489</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 1.423</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.358</td></tr> </table> <p> This test runs a set of 5000 queries that are similar in form to those in test 3. But now instead of being slower, SQLite is faster than both PostgreSQL and MySQL. </p> <h2>Test 7: 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.740</td></tr> <tr><td>MySQL:</td><td align="right"> 8.162</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.635</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.608</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 8: 25000 UPDATEs with an index</h2> <blockquote> BEGIN;<br> UPDATE t2 SET b=271822 WHERE a=1;<br> UPDATE t2 SET b=28304 WHERE a=2;<br> <i>... 24996 lines omitted</i><br> UPDATE t2 SET b=442549 WHERE a=24999;<br> UPDATE t2 SET b=423958 WHERE a=25000;<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 32.118</td></tr> <tr><td>MySQL:</td><td align="right"> 8.132</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 4.109</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 3.712</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 doubled speed of UPDATEs. </p> <h2>Test 9: 25000 text UPDATEs with an index</h2> <blockquote> BEGIN;<br> UPDATE t2 SET c='four hundred sixty eight thousand twenty six' WHERE a=1;<br> UPDATE t2 SET c='one hundred twenty one thousand nine hundred twenty eight' WHERE a=2;<br> <i>... 24996 lines omitted</i><br> UPDATE t2 SET c='thirty five thousand sixty five' WHERE a=24999;<br> UPDATE t2 SET c='three hundred forty seven thousand three hundred ninety three' WHERE a=25000;<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 55.309</td></tr> <tr><td>MySQL:</td><td align="right"> 6.585</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 2.474</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.800</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> <h2>Test 10: 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"> 58.956</td></tr> <tr><td>MySQL:</td><td align="right"> 1.465</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 2.926</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.664</td></tr> </table> <p> The poor performance of PostgreSQL in this case appears to be due to its synchronous behavior. The CPU was mostly idle the test run. Presumably, PostgreSQL was spending most of its time waiting on disk I/O to complete. I'm not sure why SQLite performs poorly here. It use to be quicker at this test, but the same enhancements that sped up the UPDATE logic seem to have slowed down this test. </p> <h2>Test 11: 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.365</td></tr> <tr><td>MySQL:</td><td align="right"> 0.849</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 4.005</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.631</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. SQLite used about the same amount of CPU time in both versions; the difference is the extra time needed to write information to the disk surface. </p> <h2>Test 12: 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.340</td></tr> <tr><td>MySQL:</td><td align="right"> 2.167</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 2.344</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.858</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> </table> <h2>Test 13: 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"> 12.672</td></tr> <tr><td>MySQL:</td><td align="right"> 1.837</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 3.076</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 1.570</td></tr> </table> <p> Some older versions of SQLite would show decreasing performance after a sequence DELETEs followed by new INSERTs. As this test shows, the problem has now been resolved. </p> <h2>Test 14: A big DELETE followed by many small INSERTs</h2> <blockquote> BEGIN;<br> DELETE FROM t1;<br> INSERT INTO t1 VALUES(1,29676,'twenty nine thousand six hundred seventy six');<br> <i>... 11997 lines omitted</i><br> INSERT INTO t1 VALUES(11999,71818,'seventy one thousand eight hundred eighteen');<br> INSERT INTO t1 VALUES(12000,58579,'fifty eight thousand five hundred seventy nine');<br> COMMIT;<br> </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 4.165</td></tr> <tr><td>MySQL:</td><td align="right"> 1.733</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.652</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.465</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 15: DROP TABLE</h2> <blockquote> DROP TABLE t1;<br>DROP TABLE t2; </blockquote><table border=0 cellpadding=0 cellspacing=0> <tr><td>PostgreSQL:</td><td align="right"> 0.133</td></tr> <tr><td>MySQL:</td><td align="right"> 0.014</td></tr> <tr><td>SQLite 2.7.6:</td><td align="right"> 0.873</td></tr> <tr><td>SQLite 2.7.6 (nosync):</td><td align="right"> 0.224</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 so they can drop a table simply by deleting a file, which is much faster. </p> <p> On the other hand, dropping tables is not a very common operation so if SQLite takes a little longer, that is not seen as a big problem. </p> } puts { <p><hr /></p> <p><a href="index.html"><img src="/goback.jpg" border=0 /> Back to the SQLite Home Page</a> </p> </body></html>} |