Tips on Optimizing Your Queries

The next few paragraphs will attempt to give you a few rudimentary rules for speeding up your queries in general, and especially how SQLite is adversely affected by the kinds of SQL behaviors you may have taken for granted in other providers. It is by no means a complete optimization guide. For even more details on optimizing your queries, visit sqlite.org.

The Importance of Transactions

If you are inserting data in SQLite without first starting a transaction: DO NOT PASS GO! Call BeginTransaction() right now, and finish with Commit()! If you think I'm kidding, think again. SQLite's A.C.I.D. design means that every single time you insert any data outside a transaction, an implicit transaction is constructed, the insert made, and the transaction destructed. EVERY TIME. If you're wondering why in the world your inserts are taking 100x longer than you think they should, look no further.

Prepared Statements

Lets have a quick look at the following code and evaluate its performance:

      using (SQLiteCommand mycommand = new SQLiteCommand(myconnection))
      {
        int n;
        
        for (n = 0; n < 100000; n ++)
        {
          mycommand.CommandText = String.Format("INSERT INTO [MyTable] ([MyId]) VALUES({0})", n + 1);
          mycommand.ExecuteNonQuery();
        }
      }

This code seems pretty tight, but if you think it performs well, you're dead wrong. Here's what's wrong with it:

So lets rewrite that code slightly:

      using (SQLiteTransaction mytransaction = myconnection.BeginTransaction())
      {
        using (SQLiteCommand mycommand = new SQLiteCommand(myconnection))
        {
          SQLiteParameter myparam = new SQLiteParameter();
          int n;
        
          mycommand.CommandText = "INSERT INTO [MyTable] ([MyId]) VALUES(?)";
          mycommand.Parameters.Add(myparam);
          
          for (n = 0; n < 100000; n ++)
          {
            myparam.Value = n + 1;
            mycommand.ExecuteNonQuery();
          }
        }
        mytransaction.Commit();
      } 

Now this is a blazing fast insert for any database engine, not just SQLite. The SQL statement is prepared one time -- on the first call to ExecuteNonQuery(). Once prepared, it never needs re-evaluating. Furthermore, we're allocating no memory in the loop and doing a very minimal number of interop transitions. Surround the entire thing with a transaction, and the performance of this insert is so far and away faster than the original that it merits a hands-on-the-hips pirate-like laugh.

Every database engine worth its salt utilizes prepared statements. If you're not coding for this, you're not writing optimized SQL, and that's the bottom line.