SQLite

Check-in [9f5b241cb2]
Login

Many hyperlinks are disabled.
Use anonymous login to enable hyperlinks.

Overview
Comment:Preparing for the 2.4.0 release. (CVS 426)
Downloads: Tarball | ZIP archive
Timelines: family | ancestors | descendants | both | trunk
Files: files | file ages | folders
SHA1: 9f5b241cb2fc89f66d3762b4b4978b8e114caf53
User & Date: drh 2002-03-11 02:06:13.000
Context
2002-03-11
02:15
Version 2.4.0 (CVS 443) (check-in: d3f66b44e5 user: drh tags: trunk)
02:06
Preparing for the 2.4.0 release. (CVS 426) (check-in: 9f5b241cb2 user: drh tags: trunk)
2002-03-10
21:21
Bug fix: updates within a transaction would fail if there was existed a temporary table. (CVS 425) (check-in: 02cc2d60b2 user: drh tags: trunk)
Changes
Unified Diff Ignore Whitespace Patch
Changes to VERSION.
1
2.4.0-beta2
|
1
2.4.0
Changes to src/md5.c.
26
27
28
29
30
31
32

33
34
35
36
37
38
39
 * To compute the message digest of a chunk of bytes, declare an
 * MD5Context structure, pass it to MD5Init, call MD5Update as
 * needed on buffers full of bytes, and then call MD5Final, which
 * will fill a supplied 16-byte array with the digest.
 */
#include <tcl.h>
#include <string.h>


/*
 * If compiled on a machine that doesn't have a 32-bit integer,
 * you just set "uint32" to the appropriate datatype for an
 * unsigned 32-bit integer.  For example:
 *
 *       cc -Duint32='unsigned long' md5.c







>







26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
 * To compute the message digest of a chunk of bytes, declare an
 * MD5Context structure, pass it to MD5Init, call MD5Update as
 * needed on buffers full of bytes, and then call MD5Final, which
 * will fill a supplied 16-byte array with the digest.
 */
#include <tcl.h>
#include <string.h>
#include "sqlite.h"

/*
 * If compiled on a machine that doesn't have a 32-bit integer,
 * you just set "uint32" to the appropriate datatype for an
 * unsigned 32-bit integer.  For example:
 *
 *       cc -Duint32='unsigned long' md5.c
346
347
348
349
350
351
352
































** Register the two TCL commands above with the TCL interpreter.
*/
int Md5_Init(Tcl_Interp *interp){
  Tcl_CreateCommand(interp, "md5", md5_cmd, 0, 0);
  Tcl_CreateCommand(interp, "md5file", md5file_cmd, 0, 0);
  return TCL_OK;
}







































>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
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
** Register the two TCL commands above with the TCL interpreter.
*/
int Md5_Init(Tcl_Interp *interp){
  Tcl_CreateCommand(interp, "md5", md5_cmd, 0, 0);
  Tcl_CreateCommand(interp, "md5file", md5file_cmd, 0, 0);
  return TCL_OK;
}

/*
** During testing, the special md5sum() aggregate function is available.
** inside SQLite.  The following routines implement that function.
*/
static void md5step(sqlite_func *context, int argc, const char **argv){
  MD5Context *p;
  int i;
  if( argc<1 ) return;
  p = sqlite_aggregate_context(context, sizeof(*p));
  if( p==0 ) return;
  if( sqlite_aggregate_count(context)==1 ){
    MD5Init(p);
  }
  for(i=0; i<argc; i++){
    if( argv[i] ){
      MD5Update(p, (unsigned char*)argv[i], strlen(argv[i]));
    }
  }
}
static void md5finalize(sqlite_func *context){
  MD5Context *p;
  unsigned char digest[16];
  char zBuf[33];
  p = sqlite_aggregate_context(context, sizeof(*p));
  MD5Final(digest,p);
  DigestToBase16(digest, zBuf);
  sqlite_set_result_string(context, zBuf, strlen(zBuf));
}
void Md5_Register(sqlite *db){
  sqlite_create_aggregate(db, "md5sum", -1, md5step, md5finalize, 0);
}
Changes to src/tclsqlite.c.
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
/*
** 2001 September 15
**
** The author disclaims copyright to this source code.  In place of
** a legal notice, here is a blessing:
**
**    May you do good and not evil.
**    May you find forgiveness for yourself and forgive others.
**    May you share freely, never taking more than you give.
**
*************************************************************************
** A TCL Interface to SQLite
**
** $Id: tclsqlite.c,v 1.29 2002/01/16 21:00:27 drh Exp $
*/
#ifndef NO_TCL     /* Omit this whole file if TCL is unavailable */

#include "sqlite.h"
#include "tcl.h"
#include <stdlib.h>
#include <string.h>













|







1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
/*
** 2001 September 15
**
** The author disclaims copyright to this source code.  In place of
** a legal notice, here is a blessing:
**
**    May you do good and not evil.
**    May you find forgiveness for yourself and forgive others.
**    May you share freely, never taking more than you give.
**
*************************************************************************
** A TCL Interface to SQLite
**
** $Id: tclsqlite.c,v 1.30 2002/03/11 02:06:13 drh Exp $
*/
#ifndef NO_TCL     /* Omit this whole file if TCL is unavailable */

#include "sqlite.h"
#include "tcl.h"
#include <stdlib.h>
#include <string.h>
527
528
529
530
531
532
533






534
535
536
537
538
539
540
  if( p->db==0 ){
    Tcl_SetResult(interp, zErrMsg, TCL_VOLATILE);
    Tcl_Free((char*)p);
    free(zErrMsg);
    return TCL_ERROR;
  }
  Tcl_CreateObjCommand(interp, argv[1], DbObjCmd, (char*)p, DbDeleteCmd);






  return TCL_OK;
}

/*
** Provide a dummy Tcl_InitStubs if we are using this as a static
** library.
*/







>
>
>
>
>
>







527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
  if( p->db==0 ){
    Tcl_SetResult(interp, zErrMsg, TCL_VOLATILE);
    Tcl_Free((char*)p);
    free(zErrMsg);
    return TCL_ERROR;
  }
  Tcl_CreateObjCommand(interp, argv[1], DbObjCmd, (char*)p, DbDeleteCmd);
#ifdef SQLITE_TEST
  {
     extern void Md5_Register(sqlite*);
     Md5_Register(p->db);
  }
#endif  
  return TCL_OK;
}

/*
** Provide a dummy Tcl_InitStubs if we are using this as a static
** library.
*/
Changes to src/test1.c.
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
**    May you share freely, never taking more than you give.
**
*************************************************************************
** Code for testing the printf() interface to SQLite.  This code
** is not included in the SQLite library.  It is used for automated
** testing of the SQLite library.
**
** $Id: test1.c,v 1.6 2002/01/16 21:00:27 drh Exp $
*/
#include "sqliteInt.h"
#include "tcl.h"
#include <stdlib.h>
#include <string.h>

/*







|







9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
**    May you share freely, never taking more than you give.
**
*************************************************************************
** Code for testing the printf() interface to SQLite.  This code
** is not included in the SQLite library.  It is used for automated
** testing of the SQLite library.
**
** $Id: test1.c,v 1.7 2002/03/11 02:06:13 drh Exp $
*/
#include "sqliteInt.h"
#include "tcl.h"
#include <stdlib.h>
#include <string.h>

/*
319
320
321
322
323
324
325

















326
327
328
329
330
331
332
){
  char zBuf[200];
  sprintf(zBuf, "%d %d %d", sqlite_nMalloc, sqlite_nFree, sqlite_iMallocFail);
  Tcl_AppendResult(interp, zBuf, 0);
  return TCL_OK;
}
#endif


















/*
** Register commands with the TCL interpreter.
*/
int Sqlitetest1_Init(Tcl_Interp *interp){
  extern int sqlite_search_count;
  Tcl_CreateCommand(interp, "sqlite_mprintf_int", sqlite_mprintf_int, 0, 0);







>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>







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
){
  char zBuf[200];
  sprintf(zBuf, "%d %d %d", sqlite_nMalloc, sqlite_nFree, sqlite_iMallocFail);
  Tcl_AppendResult(interp, zBuf, 0);
  return TCL_OK;
}
#endif

/*
** Usage:  sqlite_abort
**
** Shutdown the process immediately.  This is not a clean shutdown.
** This command is used to test the recoverability of a database in
** the event of a program crash.
*/
static int sqlite_abort(
  void *NotUsed,
  Tcl_Interp *interp,    /* The TCL interpreter that invoked this command */
  int argc,              /* Number of arguments */
  char **argv            /* Text of each argument */
){
  assert( interp==0 );   /* This will always fail */
  return TCL_OK;
}

/*
** Register commands with the TCL interpreter.
*/
int Sqlitetest1_Init(Tcl_Interp *interp){
  extern int sqlite_search_count;
  Tcl_CreateCommand(interp, "sqlite_mprintf_int", sqlite_mprintf_int, 0, 0);
340
341
342
343
344
345
346

347
348
  Tcl_CreateCommand(interp, "sqlite_close", sqlite_test_close, 0, 0);
  Tcl_LinkVar(interp, "sqlite_search_count", 
      (char*)&sqlite_search_count, TCL_LINK_INT);
#ifdef MEMORY_DEBUG
  Tcl_CreateCommand(interp, "sqlite_malloc_fail", sqlite_malloc_fail, 0, 0);
  Tcl_CreateCommand(interp, "sqlite_malloc_stat", sqlite_malloc_stat, 0, 0);
#endif

  return TCL_OK;
}







>


357
358
359
360
361
362
363
364
365
366
  Tcl_CreateCommand(interp, "sqlite_close", sqlite_test_close, 0, 0);
  Tcl_LinkVar(interp, "sqlite_search_count", 
      (char*)&sqlite_search_count, TCL_LINK_INT);
#ifdef MEMORY_DEBUG
  Tcl_CreateCommand(interp, "sqlite_malloc_fail", sqlite_malloc_fail, 0, 0);
  Tcl_CreateCommand(interp, "sqlite_malloc_stat", sqlite_malloc_stat, 0, 0);
#endif
  Tcl_CreateCommand(interp, "sqlite_abort", sqlite_abort, 0, 0);
  return TCL_OK;
}
Changes to test/trans.test.
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
# 2001 September 15
#
# The author disclaims copyright to this source code.  In place of
# a legal notice, here is a blessing:
#
#    May you do good and not evil.
#    May you find forgiveness for yourself and forgive others.
#    May you share freely, never taking more than you give.
#
#***********************************************************************
# This file implements regression tests for SQLite library.  The
# focus of this script is database locks.
#
# $Id: trans.test,v 1.10 2002/01/10 14:31:49 drh Exp $


set testdir [file dirname $argv0]
source $testdir/tester.tcl


# Create several tables to work with.













|







1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
# 2001 September 15
#
# The author disclaims copyright to this source code.  In place of
# a legal notice, here is a blessing:
#
#    May you do good and not evil.
#    May you find forgiveness for yourself and forgive others.
#    May you share freely, never taking more than you give.
#
#***********************************************************************
# This file implements regression tests for SQLite library.  The
# focus of this script is database locks.
#
# $Id: trans.test,v 1.11 2002/03/11 02:06:14 drh Exp $


set testdir [file dirname $argv0]
source $testdir/tester.tcl


# Create several tables to work with.
660
661
662
663
664
665
666




































































































































667
} {4 -5 -6 1 -2 -3}
do_test trans-6.39 {
  execsql {
    SELECT * FROM t1 WHERE c<1;
  }
} {1 -2 -3 4 -5 -6}





































































































































finish_test







>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>

660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
} {4 -5 -6 1 -2 -3}
do_test trans-6.39 {
  execsql {
    SELECT * FROM t1 WHERE c<1;
  }
} {1 -2 -3 4 -5 -6}

# Test to make sure rollback restores the database back to its original
# state.
#
do_test trans-7.1 {
  execsql {BEGIN}
  for {set i 0} {$i<1000} {incr i} {
    set r1 [expr {rand()}]
    set r2 [expr {rand()}]
    set r3 [expr {rand()}]
    execsql "INSERT INTO t2 VALUES($r1,$r2,$r3)"
  }
  execsql {COMMIT}
  set ::checksum [execsql {SELECT md5sum(x,y,z) FROM t2}]
  set ::checksum2 [
    execsql {SELECT md5sum(type,name,tbl_name,rootpage,sql) FROM sqlite_master}
  ]
  execsql {SELECT count(*) FROM t2}
} {1001}
do_test trans-7.2 {
  execsql {SELECT md5sum(x,y,z) FROM t2}
} $checksum
do_test trans-7.2.1 {
  execsql {SELECT md5sum(type,name,tbl_name,rootpage,sql) FROM sqlite_master}
} $checksum2
do_test trans-7.3 {
  execsql {
    BEGIN;
    DELETE FROM t2;
    ROLLBACK;
    SELECT md5sum(x,y,z) FROM t2;
  }
} $checksum
do_test trans-7.4 {
  execsql {
    BEGIN;
    INSERT INTO t2 SELECT * FROM t2;
    ROLLBACK;
    SELECT md5sum(x,y,z) FROM t2;
  }
} $checksum
do_test trans-7.5 {
  execsql {
    BEGIN;
    DELETE FROM t2;
    ROLLBACK;
    SELECT md5sum(x,y,z) FROM t2;
  }
} $checksum
do_test trans-7.6 {
  execsql {
    BEGIN;
    INSERT INTO t2 SELECT * FROM t2;
    ROLLBACK;
    SELECT md5sum(x,y,z) FROM t2;
  }
} $checksum
do_test trans-7.7 {
  execsql {
    BEGIN;
    CREATE TABLE t3 AS SELECT * FROM t2;
    INSERT INTO t2 SELECT * FROM t3;
    ROLLBACK;
    SELECT md5sum(x,y,z) FROM t2;
  }
} $checksum
do_test trans-7.8 {
  execsql {SELECT md5sum(type,name,tbl_name,rootpage,sql) FROM sqlite_master}
} $checksum2
do_test trans-7.9 {
  execsql {
    BEGIN;
    CREATE TEMP TABLE t3 AS SELECT * FROM t2;
    INSERT INTO t2 SELECT * FROM t3;
    ROLLBACK;
    SELECT md5sum(x,y,z) FROM t2;
  }
} $checksum
do_test trans-7.10 {
  execsql {SELECT md5sum(type,name,tbl_name,rootpage,sql) FROM sqlite_master}
} $checksum2
do_test trans-7.11 {
  execsql {
    BEGIN;
    CREATE TEMP TABLE t3 AS SELECT * FROM t2;
    INSERT INTO t2 SELECT * FROM t3;
    DROP INDEX i2x;
    DROP INDEX i2y;
    CREATE INDEX i3a ON t3(x);
    ROLLBACK;
    SELECT md5sum(x,y,z) FROM t2;
  }
} $checksum
do_test trans-7.12 {
  execsql {SELECT md5sum(type,name,tbl_name,rootpage,sql) FROM sqlite_master}
} $checksum2
do_test trans-7.13 {
  execsql {
    BEGIN;
    DROP TABLE t2;
    ROLLBACK;
    SELECT md5sum(x,y,z) FROM t2;
  }
} $checksum
do_test trans-7.14 {
  execsql {SELECT md5sum(type,name,tbl_name,rootpage,sql) FROM sqlite_master}
} $checksum2

# Arrange for another process to begin modifying the database but abort
# and die in the middle of the modification.  Then have this process read
# the database.  This process should detect the journal file and roll it
# back.  Verify that this happens correctly.
#
set fd [open test.tcl w]
puts $fd {
  sqlite db test.db
  db eval {
    BEGIN;
    CREATE TABLE t3 AS SELECT * FROM t2;
    DELETE FROM t2;
  }
  sqlite_abort
}
close $fd
do_test trans-8.1 {
  catch {exec [info nameofexec] test.tcl}
  execsql {SELECT md5sum(x,y,z) FROM t2}
} $checksum
do_test trans-8.2 {
  execsql {SELECT md5sum(type,name,tbl_name,rootpage,sql) FROM sqlite_master}
} $checksum2

   
finish_test
Changes to www/changes.tcl.
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27


proc chng {date desc} {
  puts "<DT><B>$date</B></DT>"
  puts "<DD><P><UL>$desc</UL></P></DD>"
}

chng {2002 Mar * (2.4.0)} {
<li>Change the name of the sanity_check PRAGMA to <b>integrity_check</b>
    and make it available in all compiles.</li>
<li>SELECT min() or max() of an indexed column with no WHERE or GROUP BY
    clause is handled as a special case which avoids a complete table scan.</li>
<li>Automatically generated ROWIDs are now sequential.</li>
<li>Do not allow dot-commands of the command-line shell to occur in the
    middle of a real SQL command.</li>







|







13
14
15
16
17
18
19
20
21
22
23
24
25
26
27


proc chng {date desc} {
  puts "<DT><B>$date</B></DT>"
  puts "<DD><P><UL>$desc</UL></P></DD>"
}

chng {2002 Mar 10 (2.4.0)} {
<li>Change the name of the sanity_check PRAGMA to <b>integrity_check</b>
    and make it available in all compiles.</li>
<li>SELECT min() or max() of an indexed column with no WHERE or GROUP BY
    clause is handled as a special case which avoids a complete table scan.</li>
<li>Automatically generated ROWIDs are now sequential.</li>
<li>Do not allow dot-commands of the command-line shell to occur in the
    middle of a real SQL command.</li>
36
37
38
39
40
41
42


43
44
45
46
47
48
49
    contain real data (free pages) are not journalled and are not
    written from memory back to the disk when they change.  This does not 
    impact database integrity, since the
    pages contain no real data, but it does make large INSERT operations
    about 2.5 times faster and large DELETEs about 5 times faster.</li>
<li>Made the CACHE_SIZE pragma persistent</li>
<li>Added the SYNCHRONOUS pragma</li>


}

chng {2002 Feb 18 (2.3.3)} {
<li>Allow identifiers to be quoted in square brackets, for compatibility
    with MS-Access.</li>
<li>Added support for sub-queries in the FROM clause of a SELECT.</li>
<li>More efficient implementation of sqliteFileExists() under Windows.







>
>







36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
    contain real data (free pages) are not journalled and are not
    written from memory back to the disk when they change.  This does not 
    impact database integrity, since the
    pages contain no real data, but it does make large INSERT operations
    about 2.5 times faster and large DELETEs about 5 times faster.</li>
<li>Made the CACHE_SIZE pragma persistent</li>
<li>Added the SYNCHRONOUS pragma</li>
<li>Fixed a bug that was causing updates to fail inside of transactions when
    the database contained a temporary table.</li>
}

chng {2002 Feb 18 (2.3.3)} {
<li>Allow identifiers to be quoted in square brackets, for compatibility
    with MS-Access.</li>
<li>Added support for sub-queries in the FROM clause of a SELECT.</li>
<li>More efficient implementation of sqliteFileExists() under Windows.
Changes to www/formatchng.tcl.
1
2
3
4
5
6
7
8
9
10
11
#
# Run this Tcl script to generate the formatchng.html file.
#
set rcsid {$Id: formatchng.tcl,v 1.3 2002/03/04 02:26:17 drh Exp $ }

puts {<html>
<head>
  <title>File Format Changes in SQLite</title>
</head>
<body bgcolor=white>
<h1 align=center>



|







1
2
3
4
5
6
7
8
9
10
11
#
# Run this Tcl script to generate the formatchng.html file.
#
set rcsid {$Id: formatchng.tcl,v 1.4 2002/03/11 02:06:14 drh Exp $ }

puts {<html>
<head>
  <title>File Format Changes in SQLite</title>
</head>
<body bgcolor=white>
<h1 align=center>
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
  that are stored in the SQLITE_MASTER table.  If you create a database that
  contains this new syntax, then try to read that database using version 2.2.5
  or earlier, the parser will not understand the new syntax and you will get
  an error.  Otherwise, databases for 2.2.x and 2.3.x are interchangeable.</td>
</tr>
<tr>
  <td valign="top">2.3.3 to 2.4.0</td>
  <td valign="top">2002-Mar-?</td>
  <td>Beginning with version 2.4.0, SQLite added support for views. 
  Information about views is stored in the SQLITE_MASTER table.  If an older
  version of SQLite attempts to read a database that contains VIEW information
  in the SQLITE_MASTER table, the parser will not understand the new syntax
  and you will get an error.  Also, the
  way SQLite keeps track of unused disk blocks in the database file
  changed slightly.







|







89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
  that are stored in the SQLITE_MASTER table.  If you create a database that
  contains this new syntax, then try to read that database using version 2.2.5
  or earlier, the parser will not understand the new syntax and you will get
  an error.  Otherwise, databases for 2.2.x and 2.3.x are interchangeable.</td>
</tr>
<tr>
  <td valign="top">2.3.3 to 2.4.0</td>
  <td valign="top">2002-Mar-10</td>
  <td>Beginning with version 2.4.0, SQLite added support for views. 
  Information about views is stored in the SQLITE_MASTER table.  If an older
  version of SQLite attempts to read a database that contains VIEW information
  in the SQLITE_MASTER table, the parser will not understand the new syntax
  and you will get an error.  Also, the
  way SQLite keeps track of unused disk blocks in the database file
  changed slightly.
Changes to www/lang.tcl.
1
2
3
4
5
6
7
8
9
10
11
#
# Run this Tcl script to generate the sqlite.html file.
#
set rcsid {$Id: lang.tcl,v 1.27 2002/03/04 02:26:17 drh Exp $}

puts {<html>
<head>
  <title>Query Language Understood By SQLite</title>
</head>
<body bgcolor=white>
<h1 align=center>



|







1
2
3
4
5
6
7
8
9
10
11
#
# Run this Tcl script to generate the sqlite.html file.
#
set rcsid {$Id: lang.tcl,v 1.28 2002/03/11 02:06:14 drh Exp $}

puts {<html>
<head>
  <title>Query Language Understood By SQLite</title>
</head>
<body bgcolor=white>
<h1 align=center>
813
814
815
816
817
818
819

820
821
822
823
824
825
826





827
828
829
830
831
832

































833
834
835
836
837
838
839
The pragma command is experimental and specific pragma statements may
removed or added in future releases of SQLite.  Use this command
with caution.</p>

<p>The current implementation supports the following pragmas:</p>

<ul>

<li><p><b>PRAGMA cache_size = </b><i>Number-of-pages</i><b>;</b></p>
    <p>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
    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.</p></li>






<li><p><b>PRAGMA count_changes = ON;
       <br>PRAGMA count_changes = OFF;</b></p>
    <p>When on, the COUNT_CHANGES pragma causes the callback function to
    be invoked once for each DELETE, INSERT, or UPDATE operation.  The
    argument is the number of rows that were changed.</p>


































<li><p><b>PRAGMA empty_result_callbacks = ON;
       <br>PRAGMA empty_result_callbacks = OFF;</b></p>
    <p>When on, the EMPTY_RESULT_CALLBACKS pragma causes the callback
    function to be invoked once for each query that has an empty result
    set.  The third "<b>argv</b>" parameter to the callback is set to NULL
    because there is no data to report.  But the second "<b>argc</b>" and







>
|
|
|
|


|
>
>
>
>
>






>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>
>







813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
The pragma command is experimental and specific pragma statements may
removed or added in future releases of SQLite.  Use this command
with caution.</p>

<p>The current implementation supports the following pragmas:</p>

<ul>
<li><p><b>PRAGMA cache_size;
       <br>PRAGMA cache_size = </b><i>Number-of-pages</i><b>;</b></p>
    <p>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.</p>
    <p>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 <b>default_cache_size</b> pragma to check the cache size permanently
    </p></li>

<li><p><b>PRAGMA count_changes = ON;
       <br>PRAGMA count_changes = OFF;</b></p>
    <p>When on, the COUNT_CHANGES pragma causes the callback function to
    be invoked once for each DELETE, INSERT, or UPDATE operation.  The
    argument is the number of rows that were changed.</p>

<li><p><b>PRAGMA default_cache_size;
       <br>PRAGMA default_cache_size = </b><i>Number-of-pages</i><b>;</b></p>
    <p>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 <b>cache_size</b> 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.</p></li>

<li><p><b>PRAGMA default_synchronous;
       <br>PRAGMA default_synchronous = ON;
       <br>PRAGMA default_synchronous = OFF;</b></p>
    <p>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 <b>fsync()</b> 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.
    </p>
    <p>This pragma changes the synchronous mode persistently.  Once changed,
    the mode stays as set even if the database is closed and reopened.  The
    <b>synchronous</b> pragma does the same thing but only applies the setting
    to the current session.</p>

<li><p><b>PRAGMA empty_result_callbacks = ON;
       <br>PRAGMA empty_result_callbacks = OFF;</b></p>
    <p>When on, the EMPTY_RESULT_CALLBACKS pragma causes the callback
    function to be invoked once for each query that has an empty result
    set.  The third "<b>argv</b>" parameter to the callback is set to NULL
    because there is no data to report.  But the second "<b>argc</b>" and
868
869
870
871
872
873
874










875
876
877
878
879
880
881

<li><p><b>PRAGMA integrity_check;</b></p>
    <p>The command does an integrity check of the entire database.  It
    looks for out-of-order records, missing pages, and malformed records.
    If any problems are found, then a single string is returned which is
    a description of all problems.  If everything is in order, "ok" is
    returned.</p>











<li><p><b>PRAGMA table_info(</b><i>table-name</i><b>);</b></p>
    <p>For each column in the named table, invoke the callback function
    once with information about that column, including the column name,
    data type, whether or not the column can be NULL, and the default
    value for the column.</p>








>
>
>
>
>
>
>
>
>
>







907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930

<li><p><b>PRAGMA integrity_check;</b></p>
    <p>The command does an integrity check of the entire database.  It
    looks for out-of-order records, missing pages, and malformed records.
    If any problems are found, then a single string is returned which is
    a description of all problems.  If everything is in order, "ok" is
    returned.</p>

<li><p><b>PRAGMA synchronous;
       <br>PRAGMA synchronous = ON;
       <br>PRAGMA synchronous = OFF;</b></p>
    <p>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 <b>default_synchronous</b> pragma.</p>
    </li>

<li><p><b>PRAGMA table_info(</b><i>table-name</i><b>);</b></p>
    <p>For each column in the named table, invoke the callback function
    once with information about that column, including the column name,
    data type, whether or not the column can be NULL, and the default
    value for the column.</p>

Changes to www/speed.tcl.
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
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79

80
81
82
83
84



85








86
87
88
89
90
91
92

93
94
95
96
97
98
99






100



101
102
103
104
105
106
107



108
109
110
111
112
113

114
115




116

117

118
119
120
121
122
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
#
# 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 $ }

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 are run to measure the relative performance of
SQLite version 1.0 and 2.0 and PostgreSQL version 6.4.
The following are general
conclusions drawn from these experiments:
</p>

<ul>
<li><p>
  SQLite 2.0 is significantly faster than both SQLite 1.0 and 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 <b>INSERT</b> statements 
  within a transaction.
</p></li>
<li><p>
  PostgreSQL performs better on complex queries, possibly due to having
  a more sophisticated query optimizer.
</p></li>
<li><p>
  SQLite 2.0 is significantly slower than both SQLite 1.0 and PostgreSQL
  on <b>DROP TABLE</b> statements and on doing lots of small <b>INSERT</b>

  statements that are not grouped into a single transaction.

</p></li>
</ul>

<h2>Test Environment</h2>

<p>
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.
</p>

<p>
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.
</p>

<p>
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.
</p>

<p>
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.
</p>

<p>
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:

</p>

<p>
<ol>
<li> "<b>Real</b>" or wall-clock time. </li>



<li> "<b>User</b>" time, the time spent executing user-level code. </li>








<li> "<b>Sys</b>" or system time, the time spent in the operating system. </li>
</ol>
</p>

<p>
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.
</p>

<h2>Test 1: CREATE TABLE</h2>

<blockquote><pre>
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
</pre></blockquote>

<p>



The speeddata3.txt data file contains 30000 rows of data.
</p>

<h2>Test 2: SELECT</h2>

<blockquote><pre>

SELECT max(f2), min(f3), count(*) FROM t1
WHERE f3<10000 OR f1>=20000;






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
</pre></blockquote>

<p>
With no indices, a complete scan of the table must be performed
(all 30000 rows) in order to complete this query.




</p>

<h2>Test 3: CREATE INDEX</h2>





<blockquote><pre>
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
</pre></blockquote>

<p>




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.
</p>

<h2>Test 4: SELECT using an index</h2>


<blockquote><pre>
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
</pre></blockquote>

<p>
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.
</p>

<h2>Test 5: SELECT a single record</h2>
















<blockquote><pre>
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
</pre></blockquote>

<p>
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 <b>gdbm_open</b> 2000 times in
quick succession.
</p>

<h2>Test 6: UPDATE</h2>

<blockquote><pre>

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
</pre></blockquote>

<p>

We have no explanation for why PostgreSQL does poorly here.
</p>

<h2>Test 7: INSERT from a SELECT</h2>

<blockquote><pre>

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
</pre></blockquote>





<h2>Test 8: Many small INSERTs</h2>


<blockquote><pre>
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
</pre></blockquote>

<p>
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 <b>fsync()</b> 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.
</p>











<h2>Test 9: Many small INSERTs within a TRANSACTION</h2>






<blockquote><pre>







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

</pre></blockquote>

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



</p>

<h2>Test 10: DELETE</h2>


<blockquote><pre>
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
</pre></blockquote>

<p>
All three database run at about the same speed here.



</p>

<h2>Test 11: DROP TABLE</h2>

<blockquote><pre>
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

</pre></blockquote>








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

</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>}



|
















|
|






|

<
<
<


<
<
<
<
|
<
>
|
>






|
|
|



|
|
|
<
|
<
<
<
|
<
|



|
|
|
<
|




|
|
>



<
|
>
>
>
|
>
>
>
>
>
>
>
>
|
<
<
|
<
|
<
>
|


|
<
|
|
>
>
>
>
>
>
|
>
>
>
|
<
<
|
|

<
>
>
>
|
|

|
<
|
>
|
|
>
>
>
>

>
|
>
|
|
|


<
<
>
>
>
>


|
>
>
>
>
|
|
|
|

>
|
>
|
|
|


>
>
>
>
|
<
>
|


<

>
|
|
|
>
>
>
>
>

>
|
>
|
|
|


|
|
<
|
<


|
>
>
>
>
>
>
>
>

>
>
>
>
>
>
>
|
|
|
|
|
|
|
|

>
|
>
|
|
|


|
|
|
<
<


<
|
|
>
|
|
>
>
>
>

>
|
>
|
|
|


>
|


<
|
|
>
|
>
>
>
>
>
|
>
|
|
|
|
|

|
>
>
>
|

>
|
<
<
|
>
>
|
<
<
<
>
>
>

>
|
>
|
|
|


<
>
|
<
<
<
<

>
>
>
>
>
>
>
>
>
>

<
>
>
>
>

>
|
>
>
>
>
>
>
>
|
<
<
<
<
<
<

<
<
<
>
|
|
<
<
<
>
|
<
<
>
>
>
|

<

>
|
|
>
>
>
>
|
<
<
<
|


<
>
>
>


<
|
|
|
|
>
>
|
>
|

>
|
>
|
>
>
|
>
|
>
>
>
>
>
>
>


|
<
|
<
<
<
>










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
65
66
67
68
69
70
71

72
73
74
75
76
77
78
79
80
81
82
83
84
85


86

87

88
89
90
91
92

93
94
95
96
97
98
99
100
101
102
103
104
105


106
107
108

109
110
111
112
113
114
115

116
117
118
119
120
121
122
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
#
# Run this Tcl script to generate the speed.html file.
#
set rcsid {$Id: speed.tcl,v 1.6 2002/03/11 02:06:14 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.4.0, PostgreSQL, and MySQL
The following are general
conclusions drawn from these experiments:
</p>

<ul>
<li><p>
  SQLite 2.4.0 is significantly faster than PostgreSQL
  for most common operations.



</p></li>
<li><p>




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

<p>
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.
</p>

<p>
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.
</p>

<p>
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 <b>tools/speedtest.tcl</b>.
</p>

<p>

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 <b>fsync()</b> 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.
</p>

<h2>Test 1: 1000 INSERTs</h2>

<blockquote>
CREATE TABLE t1(a INTEGER, b INTEGER, c VARCHAR(100));<br>
INSERT INTO t1 VALUES(1,13153,'thirteen thousand one hundred fifty three');<br>
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">&nbsp;&nbsp;&nbsp;4.027</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;0.113</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;8.409</td></tr>


<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;0.188</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">&nbsp;&nbsp;&nbsp;5.175</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;2.444</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;0.858</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;0.739</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>
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>
SELECT count(*), avg(b) FROM t2 WHERE b>=200 AND b<1200;<br>
<i>... 94 lines omitted</i><br>
SELECT count(*), avg(b) FROM t2 WHERE b>=9700 AND b<10700;<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>

</blockquote><table border=0 cellpadding=0 cellspacing=0>
<tr><td>PostgreSQL:</td><td align="right">&nbsp;&nbsp;&nbsp;3.773</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;3.023</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;6.281</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;6.247</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 half the speed of
PostgreSQL and MySQL.  This is because SQLite stores all data as strings
and must therefore call <b>strtod()</b> 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.
</p>



<h2>Test 4: 100 SELECTs on a string comparison</h2>
<blockquote>
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%one%';<br>
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%two%';<br>
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%three%';<br>
<i>... 94 lines omitted</i><br>
SELECT count(*), avg(b) FROM t2 WHERE c LIKE '%ninety eight%';<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>

</blockquote><table border=0 cellpadding=0 cellspacing=0>
<tr><td>PostgreSQL:</td><td align="right">&nbsp;&nbsp;&nbsp;16.726</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;5.237</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;6.137</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;6.112</td></tr>
</table>

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

</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">&nbsp;&nbsp;&nbsp;0.510</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;0.352</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;0.809</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;0.720</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">&nbsp;&nbsp;&nbsp;5.318</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;1.555</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;1.289</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;1.273</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 half as fast, 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">&nbsp;&nbsp;&nbsp;1.828</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;9.272</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;0.915</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;0.889</td></tr>
</table>

<p>
Here is a case where MySQL is over 10 times slower than SQLite.
The reason for this is unclear.
</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">&nbsp;&nbsp;&nbsp;28.021</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;8.565</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;10.939</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;11.199</td></tr>
</table>

<p>
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.
</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">&nbsp;&nbsp;&nbsp;48.739</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;7.059</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;7.868</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;6.720</td></tr>
</table>

<p>

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




</p>

<h2>Test 10: INSERTs from a SELECT</h2>
<blockquote>
BEGIN;<br>INSERT INTO t1 SELECT * FROM t2;<br>INSERT INTO t2 SELECT * FROM t1;<br>COMMIT;
</blockquote><table border=0 cellpadding=0 cellspacing=0>
<tr><td>PostgreSQL:</td><td align="right">&nbsp;&nbsp;&nbsp;54.822</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;1.512</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;4.423</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;2.386</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 during the 55 second run.
</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">&nbsp;&nbsp;&nbsp;0.734</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;0.888</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;5.405</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;0.731</td></tr>
</table>











<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">&nbsp;&nbsp;&nbsp;2.318</td></tr>


<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;2.600</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;1.436</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;0.775</td></tr>
</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">&nbsp;&nbsp;&nbsp;63.867</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;1.839</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;3.971</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;1.993</td></tr>



</table>

<p>

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.
</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>... 2997 lines omitted</i><br>
INSERT INTO t1 VALUES(2999,37835,'thirty seven thousand eight hundred thirty five');<br>
INSERT INTO t1 VALUES(3000,97817,'ninety seven thousand eight hundred seventeen');<br>
COMMIT;<br>

</blockquote><table border=0 cellpadding=0 cellspacing=0>
<tr><td>PostgreSQL:</td><td align="right">&nbsp;&nbsp;&nbsp;1.209</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;1.031</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;0.298</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;0.282</td></tr>
</table>

<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">&nbsp;&nbsp;&nbsp;0.105</td></tr>
<tr><td>MySQL:</td><td align="right">&nbsp;&nbsp;&nbsp;0.015</td></tr>
<tr><td>SQLite 2.4:</td><td align="right">&nbsp;&nbsp;&nbsp;0.472</td></tr>
<tr><td>SQLite 2.4 (nosync):</td><td align="right">&nbsp;&nbsp;&nbsp;0.232</td></tr>
</table>

<p>
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.
</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>}