From 28b4e4890b2b3d022d71a36fd93cf6df24ea867b Mon Sep 17 00:00:00 2001
From: drh $desc
The current implementation supports the following pragmas:
PRAGMA cache_size = Number-of-pages;
-Change the maximum number of database disk pages that SQLite - will hold in memory at once. Each page uses about 1.5K of RAM. - The default cache size is 100. If you are doing UPDATEs or DELETEs +
PRAGMA cache_size;
+
PRAGMA cache_size = Number-of-pages;
Query or change the maximum number of database disk pages that SQLite + will hold in memory at once. Each page uses about 1.5K of memory. + The default cache size is 2000. If you are doing UPDATEs or DELETEs that change many rows of a database and you do not mind if SQLite uses more memory, you can increase the cache size for a possible speed - improvement.
When you change the cache size using the cache_size pragma, the + change only endures for the current session. The cache size reverts + to the default value when the database is closed and reopened. Use + the default_cache_size pragma to check the cache size permanently +
PRAGMA count_changes = ON;
PRAGMA count_changes = OFF;
PRAGMA default_cache_size;
+
PRAGMA default_cache_size = Number-of-pages;
Query or change the maximum number of database disk pages that SQLite + will hold in memory at once. Each page uses about 1.5K of memory. + This pragma works like the cache_size pragma with the addition + feature that it changes the cache size persistently. With this pragma, + you can set the cache size once and that setting is retained and reused + everytime you reopen the database.
PRAGMA default_synchronous;
+
PRAGMA default_synchronous = ON;
+
PRAGMA default_synchronous = OFF;
Query or change the setting of the "synchronous" flag in + the database. When synchronous is on (the default), the SQLite database + engine will pause at critical moments to make sure that data has actually + be written to the disk surface. (In other words, it invokes the + equivalent of the fsync() system call.) In synchronous mode, + an SQLite database should be fully recoverable even if the operating + system crashes or power is interrupted unexpectedly. The penalty for + this assurance is that some database operations take longer because the + engine has to wait on the (relatively slow) disk drive. The alternative + is to turn synchronous off. With synchronous off, SQLite continues + processing as soon as it has handed data off to the operating system. + If the application running SQLite crashes, the data will be safe, but + the database could (in theory) become corrupted if the operating system + crashes or the computer suddenly loses power. On the other hand, some + operations are as much as 50 or more times faster with synchronous off. +
+This pragma changes the synchronous mode persistently. Once changed, + the mode stays as set even if the database is closed and reopened. The + synchronous pragma does the same thing but only applies the setting + to the current session.
+PRAGMA empty_result_callbacks = ON;
PRAGMA empty_result_callbacks = OFF;
When on, the EMPTY_RESULT_CALLBACKS pragma causes the callback @@ -873,6 +912,16 @@ with caution.
a description of all problems. If everything is in order, "ok" is returned. +PRAGMA synchronous;
+
PRAGMA synchronous = ON;
+
PRAGMA synchronous = OFF;
Query or change the setting of the "synchronous" flag in + the database for the duration of the current database connect. + The synchronous flag reverts to its default value when the database + is closed and reopened. For additional information on the synchronous + flag, see the description of the default_synchronous pragma.
+PRAGMA table_info(table-name);
For each column in the named table, invoke the callback function once with information about that column, including the column name, diff --git a/www/speed.tcl b/www/speed.tcl index 2833c810b8..0e387a290e 100644 --- a/www/speed.tcl +++ b/www/speed.tcl @@ -1,7 +1,7 @@ # # Run this Tcl script to generate the speed.html file. # -set rcsid {$Id: speed.tcl,v 1.5 2001/11/24 13:23:05 drh Exp $ } +set rcsid {$Id: speed.tcl,v 1.6 2002/03/11 02:06:14 drh Exp $ } puts {
@@ -18,282 +18,365 @@ puts "puts {
A series of tests are run to measure the relative performance of -SQLite version 1.0 and 2.0 and PostgreSQL version 6.4. +
A series of tests were run to measure the relative performance of +SQLite 2.4.0, PostgreSQL, and MySQL The following are general conclusions drawn from these experiments:
- SQLite 2.0 is significantly faster than both SQLite 1.0 and PostgreSQL + SQLite 2.4.0 is significantly faster than PostgreSQL for most common operations. - SQLite 2.0 is over 4 times faster than PostgreSQL for simple - query operations and about 7 times faster for INSERT statements - within a transaction.
- PostgreSQL performs better on complex queries, possibly due to having - a more sophisticated query optimizer. -
- SQLite 2.0 is significantly slower than both SQLite 1.0 and PostgreSQL - on DROP TABLE statements and on doing lots of small INSERT - statements that are not grouped into a single transaction. + The speed of SQLite 2.4.0 is similar to MySQL. + This is true in spite of the + fact that SQLite contains full transaction support whereas the + version of MySQL tested did not.
-The platform used for these tests is a 550MHz Athlon with 256MB or memory -and 33MHz IDE disk drives. The operating system is RedHat Linux 6.0 with -various upgrades, including an upgrade to kernel version 2.2.18. +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.
-PostgreSQL version 6.4.2 was used for these tests because that is what -came pre-installed with RedHat 6.0. Newer version of PostgreSQL may give -better performance. +The PostgreSQL and MySQL servers used were as delivered by default on +RedHat 7.2. 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 advantage, but SQLite is still able to hold its own on most +tests.
-SQLite version 1.0.32 was compiled with -O2 optimization and without -the -DNDEBUG=1 switch. Setting the NDEBUG macro disables all "assert()" -statements within the code, but SQLite version 1.0 does not have any -expensive assert() statements so the difference in performance is -negligible. -
- --SQLite version 2.0-alpha-2 was compiled with -O2 optimization and -with the -DNDEBUG=1 compiler switch. Setting the NDEBUG macro is very -important in SQLite version 2.0. SQLite 2.0 contains some expensive -"assert()" statements in the inner loop of its processing. Setting -the NDEBUG macro makes SQLite 2.0 run nearly twice as fast. +SQLite 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 shell script was used to generate and run all the tests. -Each test reports three different times: +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.
-
+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: | 4.027 |
MySQL: | 0.113 |
SQLite 2.4: | 8.409 |
SQLite 2.4 (nosync): | 0.188 |
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.
+ ++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: | 5.175 |
MySQL: | 2.444 |
SQLite 2.4: | 0.858 |
SQLite 2.4 (nosync): | 0.739 |
-PostgreSQL uses a client-server model. The experiment is unable to measure -CPU used by the server, only the client, so the "user" and "sys" numbers -from PostgreSQL are meaningless. +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.
-+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;
-+-CREATE TABLE t1(f1 int, f2 int, f3 int); -COPY t1 FROM '/home/drh/sqlite/bld/speeddata3.txt'; - -PostgreSQL: real 1.84 -SQLite 1.0: real 3.29 user 0.64 sys 1.60 -SQLite 2.0: real 0.77 user 0.51 sys 0.05 -
PostgreSQL: | 3.773 |
MySQL: | 3.023 |
SQLite 2.4: | 6.281 |
SQLite 2.4 (nosync): | 6.247 |
-The speeddata3.txt data file contains 30000 rows of data. +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.
-+-SELECT max(f2), min(f3), count(*) FROM t1 -WHERE f3<10000 OR f1>=20000; +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: real 1.22 -SQLite 1.0: real 0.80 user 0.67 sys 0.12 -SQLite 2.0: real 0.65 user 0.60 sys 0.05 -
PostgreSQL: | 16.726 |
MySQL: | 5.237 |
SQLite 2.4: | 6.137 |
SQLite 2.4 (nosync): | 6.112 |
-With no indices, a complete scan of the table must be performed -(all 30000 rows) in order to complete this query. +This set of 100 queries uses string comparisons instead of +numerical comparisions. As a result, the speed of SQLite is +compariable to are better then PostgreSQL and MySQL.
-+-CREATE INDEX idx1 ON t1(f1); -CREATE INDEX idx2 ON t1(f2,f3); - -PostgreSQL: real 2.24 -SQLite 1.0: real 5.37 user 1.22 sys 3.10 -SQLite 2.0: real 3.71 user 2.31 sys 1.06 -
+CREATE INDEX i2a ON t2(a);
CREATE INDEX i2b ON t2(b); +
PostgreSQL: | 0.510 |
MySQL: | 0.352 |
SQLite 2.4: | 0.809 |
SQLite 2.4 (nosync): | 0.720 |
-PostgreSQL is fastest at creating new indices. -Note that SQLite 2.0 is faster than SQLite 1.0 but still -spends longer in user-space code. +SQLite is slower at creating new indices. But since creating +new indices is an uncommon operation, this is not seen as a +problem.
-+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;
-+-SELECT max(f2), min(f3), count(*) FROM t1 -WHERE f3<10000 OR f1>=20000; - -PostgreSQL: real 0.19 -SQLite 1.0: real 0.77 user 0.66 sys 0.12 -SQLite 2.0: real 0.62 user 0.62 sys 0.01 -
PostgreSQL: | 5.318 |
MySQL: | 1.555 |
SQLite 2.4: | 1.289 |
SQLite 2.4 (nosync): | 1.273 |
-This is the same query as in Test 2, but now there are indices. -Unfortunately, SQLite is reasonably simple-minded about its querying -and not able to take advantage of the indices. It still does a -linear scan of the entire table. PostgreSQL, on the other hand, -is able to use the indices to make its query over six times faster. +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.
-+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;
-+-SELECT f2, f3 FROM t1 WHERE f1==1; -SELECT f2, f3 FROM t1 WHERE f1==2; -SELECT f2, f3 FROM t1 WHERE f1==3; -... -SELECT f2, f3 FROM t1 WHERE f1==998; -SELECT f2, f3 FROM t1 WHERE f1==999; -SELECT f2, f3 FROM t1 WHERE f1==1000; - -PostgreSQL: real 0.95 -SQLite 1.0: real 15.70 user 0.70 sys 14.41 -SQLite 2.0: real 0.20 user 0.15 sys 0.05 -
PostgreSQL: | 1.828 |
MySQL: | 9.272 |
SQLite 2.4: | 0.915 |
SQLite 2.4 (nosync): | 0.889 |
-This test involves 1000 separate SELECT statements, only the first -and last three of which are show above. SQLite 2.0 is the clear -winner. The miserable showing by SQLite 1.0 is due (it is thought) -to the high overhead of executing gdbm_open 2000 times in -quick succession. +Here is a case where MySQL is over 10 times slower than SQLite. +The reason for this is unclear.
-+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;
-+-UPDATE t1 SET f2=f3, f3=f2 -WHERE f1 BETWEEN 15000 AND 20000; - -PostgreSQL: real 6.56 -SQLite 1.0: real 3.54 user 0.74 sys 1.16 -SQLite 2.0: real 2.70 user 0.70 sys 1.25 -
PostgreSQL: | 28.021 |
MySQL: | 8.565 |
SQLite 2.4: | 10.939 |
SQLite 2.4 (nosync): | 11.199 |
-We have no explanation for why PostgreSQL does poorly here. +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.
-+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;
-- - --CREATE TABLE t2(f1 int, f2 int); -INSERT INTO t2 SELECT f1, f2 FROM t1 WHERE f3<10000; - -PostgreSQL: real 2.05 -SQLite 1.0: real 1.80 user 0.81 sys 0.73 -SQLite 2.0: real 0.69 user 0.58 sys 0.07 -Test 8: Many small INSERTs
- -+-CREATE TABLE t3(f1 int, f2 int, f3 int); -INSERT INTO t3 VALUES(1,1641,1019); -INSERT INTO t3 VALUES(2,984,477); -... -INSERT INTO t3 VALUES(998,1411,1392); -INSERT INTO t3 VALUES(999,1715,526); -INSERT INTO t3 VALUES(1000,1906,1037); - -PostgreSQL: real 5.28 -SQLite 1.0: real 2.20 user 0.21 sys 0.67 -SQLite 2.0: real 10.99 user 0.21 sys 7.02 -
PostgreSQL: | 48.739 |
MySQL: | 7.059 |
SQLite 2.4: | 7.868 |
SQLite 2.4 (nosync): | 6.720 |
-This test involves 1000 separate INSERT statements, only 5 of which -are shown above. SQLite 2.0 does poorly because of its atomic commit -logic. A minimum of two calls to fsync() are required for each -INSERT statement, and that really slows things down. On the other hand, -PostgreSQL also has to support atomic commits and it seems to do so -efficiently. +When updating a text field instead of an integer field, +SQLite is slightly faster than MySQL.
-+-CREATE TABLE t4(f1 int, f2 int, f3 int); -BEGIN TRANSACTION; -INSERT INTO t4 VALUES(1,440,1084); -... -INSERT INTO t4 VALUES(999,1527,423); -INSERT INTO t4 VALUES(1000,74,1865); -COMMIT; - -PostgreSQL: real 0.68 -SQLite 1.0: real 1.72 user 0.09 sys 0.55 -SQLite 2.0: real 0.10 user 0.08 sys 0.02 -
+BEGIN;
INSERT INTO t1 SELECT * FROM t2;
INSERT INTO t2 SELECT * FROM t1;
COMMIT; +
PostgreSQL: | 54.822 |
MySQL: | 1.512 |
SQLite 2.4: | 4.423 |
SQLite 2.4 (nosync): | 2.386 |
-By putting all the inserts inside a single transaction, there -only needs to be a single atomic commit at the very end. This -allows SQLite 2.0 to go (literally) 100 times faster! PostgreSQL -only gets a eight-fold speedup. Perhaps PostgreSQL is limited here by -the IPC overhead. +The poor performance of PostgreSQL in this case appears to be due to its +synchronous behavior. The CPU was mostly idle during the 55 second run.
-+DELETE FROM t2 WHERE c LIKE '%fifty%'; +
PostgreSQL: | 0.734 |
MySQL: | 0.888 |
SQLite 2.4: | 5.405 |
SQLite 2.4 (nosync): | 0.731 |
+-DELETE FROM t1 WHERE f2 NOT BETWEEN 10000 AND 20000; -PostgreSQL: real 7.25 -SQLite 1.0: real 6.98 user 1.66 sys 4.11 -SQLite 2.0: real 5.89 user 1.35 sys 3.11 -
+DELETE FROM t2 WHERE a>10 AND a<20000; +
PostgreSQL: | 2.318 |
MySQL: | 2.600 |
SQLite 2.4: | 1.436 |
SQLite 2.4 (nosync): | 0.775 |
+INSERT INTO t2 SELECT * FROM t1; +
PostgreSQL: | 63.867 |
MySQL: | 1.839 |
SQLite 2.4: | 3.971 |
SQLite 2.4 (nosync): | 1.993 |
-All three database run at about the same speed here. +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.
-+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;
--BEGIN TRANSACTION; -DROP TABLE t1; DROP TABLE t2; -DROP TABLE t3; DROP TABLE t4; -COMMIT; ++
-PostgreSQL: real 0.06 -SQLite 1.0: real 0.03 user 0.00 sys 0.02 -SQLite 2.0: real 3.12 user 0.02 sys 0.31 -+ PostgreSQL: 1.209 + MySQL: 1.031 + SQLite 2.4: 0.298 + SQLite 2.4 (nosync): 0.282
+DROP TABLE t1;
DROP TABLE t2; +
PostgreSQL: | 0.105 |
MySQL: | 0.015 |
SQLite 2.4: | 0.472 |
SQLite 2.4 (nosync): | 0.232 |
-SQLite 2.0 is much slower at dropping tables. This may be because -both SQLite 1.0 and PostgreSQL can drop a table simply by unlinking -or renaming a file, since both store database tables in separate files. -SQLite 2.0, on the other hand, uses a single file for the entire -database, so dropping a table involves moving lots of page of that -file to the free-list, which takes time. +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.
}