Google

Database Speed Comparison

(This page was last modified on 2002/08/24 18:24:58 UTC)

Executive Summary

A series of tests were run to measure the relative performance of SQLite 2.7.0, PostgreSQL 7.1.3, and MySQL 3.23.41. The following are general conclusions drawn from these experiments:

  • SQLite 2.7.0 is significantly faster than PostgreSQL 7.1.3 for most common operations.

  • The speed of SQLite 2.7.0 is similar to MySQL 3.23.41. This is true in spite of the fact that SQLite contains full transaction support whereas the version of MySQL tested did not.

  • These tests did not attempt to measure multi-user performance or optimization of complex queries involving multiple joins and subqueries.

Test Environment

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 a stock kernel.

The PostgreSQL and MySQL servers used were as delivered by default on RedHat 7.2. (PostgreSQL version 7.1.3 and MySQL version 3.23.41.) No effort was made to tune these engines. Note in particular the the default MySQL configuration on RedHat 7.2 does not support transactions. Not having to support transactions gives MySQL a big speed advantage, but SQLite is still able to hold its own on most tests. On the other hand, I am told that the default PostgreSQL configuration is unnecessarily conservative (it is designed to work on a machine with 8MB of RAM) and that PostgreSQL could be made to run a lot faster with some knowledgable configuration tuning. I have not, however, been able to personally confirm these reports.

SQLite was tested in the same configuration that it appears on the website. It was compiled with -O6 optimization and with the -DNDEBUG=1 switch which disables the many "assert()" statements in the SQLite code. The -DNDEBUG=1 compiler option roughly doubles the speed of SQLite.

All tests are conducted on an otherwise quiescent machine. A simple Tcl script was used to generate and run all the tests. A copy of this Tcl script can be found in the SQLite source tree in the file tools/speedtest.tcl.

The times reported on all tests represent wall-clock time in seconds. Two separate time values are reported for SQLite. The first value is for SQLite in its default configuration with full disk synchronization turned on. With synchronization turned on, SQLite executes an fsync() system call (or the equivalent) at key points to make certain that critical data has actually been written to the disk drive surface. Synchronization is necessary to guarantee the integrity of the database if the operating system crashes or the computer powers down unexpectedly in the middle of a database update. The second time reported for SQLite is when synchronization is turned off. With synchronization off, SQLite is sometimes much faster, but there is a risk that an operating system crash or an unexpected power failure could damage the database. Generally speaking, the synchronous SQLite times are for comparison against PostgreSQL (which is also synchronous) and the asynchronous SQLite times are for comparison against the asynchronous MySQL engine.

Test 1: 1000 INSERTs

CREATE TABLE t1(a INTEGER, b INTEGER, c VARCHAR(100));
INSERT INTO t1 VALUES(1,13153,'thirteen thousand one hundred fifty three');
INSERT INTO t1 VALUES(2,75560,'seventy five thousand five hundred sixty');
... 995 lines omitted
INSERT INTO t1 VALUES(998,66289,'sixty six thousand two hundred eighty nine');
INSERT INTO t1 VALUES(999,24322,'twenty four thousand three hundred twenty two');
INSERT INTO t1 VALUES(1000,94142,'ninety four thousand one hundred forty two');
PostgreSQL:   3.613
MySQL:   0.086
SQLite 2.7.0:   8.672
SQLite 2.7.0 (nosync):   0.286

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 fsync() after each SQL statement.

Test 2: 25000 INSERTs in a transaction

BEGIN;
CREATE TABLE t2(a INTEGER, b INTEGER, c VARCHAR(100));
INSERT INTO t2 VALUES(1,298361,'two hundred ninety eight thousand three hundred sixty one');
... 24997 lines omitted
INSERT INTO t2 VALUES(24999,447847,'four hundred forty seven thousand eight hundred forty seven');
INSERT INTO t2 VALUES(25000,473330,'four hundred seventy three thousand three hundred thirty');
COMMIT;
PostgreSQL:   4.430
MySQL:   2.025
SQLite 2.7.0:   0.885
SQLite 2.7.0 (nosync):   0.753

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.

Test 3: 100 SELECTs without an index

SELECT count(*), avg(b) FROM t2 WHERE b>=0 AND b<1000;
SELECT count(*), avg(b) FROM t2 WHERE b>=100 AND b<1100;
SELECT count(*), avg(b) FROM t2 WHERE b>=200 AND b<1200;
... 94 lines omitted
SELECT count(*), avg(b) FROM t2 WHERE b>=9700 AND b<10700;
SELECT count(*), avg(b) FROM t2 WHERE b>=9800 AND b<10800;
SELECT count(*), avg(b) FROM t2 WHERE b>=9900 AND b<10900;
PostgreSQL:   3.274
MySQL:   2.624
SQLite 2.7.0:   5.585
SQLite 2.7.0 (nosync):   5.443

This test does 100 queries on a 25000 entry table without an index, thus requiring a full table scan. SQLite is about half the speed of PostgreSQL and MySQL. This is because SQLite stores all data as strings and must therefore call strtod() 5 million times 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.

Test 4: 100 SELECTs on a string comparison

SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%one%';
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%two%';
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%three%';
... 94 lines omitted
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%ninety eight%';
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%ninety nine%';
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%one hundred%';
PostgreSQL:   14.511
MySQL:   4.616
SQLite 2.7.0:   5.966
SQLite 2.7.0 (nosync):   5.918

This set of 100 queries uses string comparisons instead of numerical comparisions. As a result, the speed of SQLite is compariable to or better then PostgreSQL and MySQL.

Test 5: Creating an index

CREATE INDEX i2a ON t2(a);
CREATE INDEX i2b ON t2(b);
PostgreSQL:   0.483
MySQL:   0.304
SQLite 2.7.0:   0.779
SQLite 2.7.0 (nosync):   0.637

SQLite is slower at creating new indices. But since creating new indices is an uncommon operation, this is not seen as a problem.

Test 6: 5000 SELECTs with an index

SELECT count(*), avg(b) FROM t2 WHERE b>=0 AND b<100;
SELECT count(*), avg(b) FROM t2 WHERE b>=100 AND b<200;
SELECT count(*), avg(b) FROM t2 WHERE b>=200 AND b<300;
... 4994 lines omitted
SELECT count(*), avg(b) FROM t2 WHERE b>=499700 AND b<499800;
SELECT count(*), avg(b) FROM t2 WHERE b>=499800 AND b<499900;
SELECT count(*), avg(b) FROM t2 WHERE b>=499900 AND b<500000;
PostgreSQL:   4.939
MySQL:   1.335
SQLite 2.7.0:   1.165
SQLite 2.7.0 (nosync):   1.144

This test runs a set of 5000 queries that are similar in form to those in test 3. But now instead of being half as fast, SQLite is faster than both PostgreSQL and MySQL.

Test 7: 1000 UPDATEs without an index

BEGIN;
UPDATE t1 SET b=b*2 WHERE a>=0 AND a<10;
UPDATE t1 SET b=b*2 WHERE a>=10 AND a<20;
... 996 lines omitted
UPDATE t1 SET b=b*2 WHERE a>=9980 AND a<9990;
UPDATE t1 SET b=b*2 WHERE a>=9990 AND a<10000;
COMMIT;
PostgreSQL:   1.536
MySQL:   7.281
SQLite 2.7.0:   0.817
SQLite 2.7.0 (nosync):   0.726

Here is a case where MySQL is over 10 times slower than SQLite. The reason for this is unclear.

Test 8: 25000 UPDATEs with an index

BEGIN;
UPDATE t2 SET b=271822 WHERE a=1;
UPDATE t2 SET b=28304 WHERE a=2;
... 24996 lines omitted
UPDATE t2 SET b=442549 WHERE a=24999;
UPDATE t2 SET b=423958 WHERE a=25000;
COMMIT;
PostgreSQL:   29.318
MySQL:   7.514
SQLite 2.7.0:   7.681
SQLite 2.7.0 (nosync):   7.852

In this case MySQL is slightly faster than SQLite, though not by much. The difference is believed to have to do with the fact SQLite handles the integers as strings instead of binary numbers.

Test 9: 25000 text UPDATEs with an index

BEGIN;
UPDATE t2 SET c='four hundred sixty eight thousand twenty six' WHERE a=1;
UPDATE t2 SET c='one hundred twenty one thousand nine hundred twenty eight' WHERE a=2;
... 24996 lines omitted
UPDATE t2 SET c='thirty five thousand sixty five' WHERE a=24999;
UPDATE t2 SET c='three hundred forty seven thousand three hundred ninety three' WHERE a=25000;
COMMIT;
PostgreSQL:   50.020
MySQL:   5.841
SQLite 2.7.0:   5.346
SQLite 2.7.0 (nosync):   5.393

When updating a text field instead of an integer field, SQLite is slightly faster than MySQL.

Test 10: INSERTs from a SELECT

BEGIN;
INSERT INTO t1 SELECT * FROM t2;
INSERT INTO t2 SELECT * FROM t1;
COMMIT;
PostgreSQL:   57.834
MySQL:   1.335
SQLite 2.7.0:   5.073
SQLite 2.7.0 (nosync):   2.085

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.

SQLite is slower than MySQL because it creates a temporary table to store the result of the query, then does an insert from the temporary table. A future enhancement that moves data directly from teh query into the insert table should double the speed of SQLite.

Test 11: DELETE without an index

DELETE FROM t2 WHERE c LIKE '%fifty%';
PostgreSQL:   0.733
MySQL:   0.768
SQLite 2.7.0:   5.418
SQLite 2.7.0 (nosync):   0.668

Test 12: DELETE with an index

DELETE FROM t2 WHERE a>10 AND a<20000;
PostgreSQL:   0.867
MySQL:   2.068
SQLite 2.7.0:   1.453
SQLite 2.7.0 (nosync):   0.745

Test 13: A big INSERT after a big DELETE

INSERT INTO t2 SELECT * FROM t1;
PostgreSQL:   66.099
MySQL:   1.663
SQLite 2.7.0:   4.029
SQLite 2.7.0 (nosync):   1.729

Earlier 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.

Test 14: A big DELETE followed by many small INSERTs

BEGIN;
DELETE FROM t1;
INSERT INTO t1 VALUES(1,29676,'twenty nine thousand six hundred seventy six');
... 2997 lines omitted
INSERT INTO t1 VALUES(2999,37835,'thirty seven thousand eight hundred thirty five');
INSERT INTO t1 VALUES(3000,97817,'ninety seven thousand eight hundred seventeen');
COMMIT;
PostgreSQL:   1.168
MySQL:   0.866
SQLite 2.7.0:   0.288
SQLite 2.7.0 (nosync):   0.155

Test 15: DROP TABLE

DROP TABLE t1;
DROP TABLE t2;
PostgreSQL:   0.100
MySQL:   0.012
SQLite 2.7.0:   0.572
SQLite 2.7.0 (nosync):   0.168

SQLite is slower than the other databases when it comes to dropping tables. This is not seen as a big problem, however, since DROP TABLE is seldom used in speed-critical situations.


Back to the SQLite Home Page