|
| 1 | +# Counting SQLite virtual machine operations |
| 2 | + |
| 3 | +When SQLite executes a query, it does so by executing a sequence of virtual machine operations. |
| 4 | + |
| 5 | +There are mechanisms for cancelling a query after a specific number of these operations, to protect against long-running queries. |
| 6 | + |
| 7 | +To work with those mechanisms, it's useful to get a feel for how many operations different queries execute. |
| 8 | + |
| 9 | +Thanks to [tips on the SQLite forum](https://sqlite.org/forum/forumpost/dfb178d58c185ee4) I now know how to count these operations using the `sqlite3` command line tool, using `.stats vmstats` to turn on display of that number after each query: |
| 10 | + |
| 11 | +``` |
| 12 | +% sqlite3 fixtures.db |
| 13 | +SQLite version 3.36.0 2021-06-18 18:58:49 |
| 14 | +Enter ".help" for usage hints. |
| 15 | +sqlite> .stats vmstep |
| 16 | +sqlite> select * from facetable; |
| 17 | +1|2019-01-14 08:00:00|1|1|CA|1|Mission|["tag1", "tag2"]|[{"foo": "bar"}]|one |
| 18 | +2|2019-01-14 08:00:00|1|1|CA|1|Dogpatch|["tag1", "tag3"]|[]|two |
| 19 | +3|2019-01-14 08:00:00|1|1|CA|1|SOMA|[]|[]| |
| 20 | +4|2019-01-14 08:00:00|1|1|CA|1|Tenderloin|[]|[]| |
| 21 | +5|2019-01-15 08:00:00|1|1|CA|1|Bernal Heights|[]|[]| |
| 22 | +6|2019-01-15 08:00:00|1|1|CA|1|Hayes Valley|[]|[]| |
| 23 | +7|2019-01-15 08:00:00|1|1|CA|2|Hollywood|[]|[]| |
| 24 | +8|2019-01-15 08:00:00|1|1|CA|2|Downtown|[]|[]| |
| 25 | +9|2019-01-16 08:00:00|1|1|CA|2|Los Feliz|[]|[]| |
| 26 | +10|2019-01-16 08:00:00|1|1|CA|2|Koreatown|[]|[]| |
| 27 | +11|2019-01-16 08:00:00|1|1|MI|3|Downtown|[]|[]| |
| 28 | +12|2019-01-17 08:00:00|1|1|MI|3|Greektown|[]|[]| |
| 29 | +13|2019-01-17 08:00:00|1|1|MI|3|Corktown|[]|[]| |
| 30 | +14|2019-01-17 08:00:00|1|1|MI|3|Mexicantown|[]|[]| |
| 31 | +15|2019-01-17 08:00:00|2|0|MC|4|Arcadia Planitia|[]|[]| |
| 32 | +VM-steps: 187 |
| 33 | +sqlite> select * from facetable limit 3; |
| 34 | +1|2019-01-14 08:00:00|1|1|CA|1|Mission|["tag1", "tag2"]|[{"foo": "bar"}]|one |
| 35 | +2|2019-01-14 08:00:00|1|1|CA|1|Dogpatch|["tag1", "tag3"]|[]|two |
| 36 | +3|2019-01-14 08:00:00|1|1|CA|1|SOMA|[]|[]| |
| 37 | +VM-steps: 46 |
| 38 | +``` |
| 39 | +Using `.stats on` shows a more detailed group of statistics about the query: |
| 40 | +``` |
| 41 | +sqlite> .stats on |
| 42 | +sqlite> select * from facetable limit 3; |
| 43 | +1|2019-01-14 08:00:00|1|1|CA|1|Mission|["tag1", "tag2"]|[{"foo": "bar"}]|one |
| 44 | +2|2019-01-14 08:00:00|1|1|CA|1|Dogpatch|["tag1", "tag3"]|[]|two |
| 45 | +3|2019-01-14 08:00:00|1|1|CA|1|SOMA|[]|[]| |
| 46 | +Memory Used: 195520 (max 195776) bytes |
| 47 | +Number of Outstanding Allocations: 525 (max 526) |
| 48 | +Number of Pcache Overflow Bytes: 5696 (max 5696) bytes |
| 49 | +Largest Allocation: 122400 bytes |
| 50 | +Largest Pcache Allocation: 4104 bytes |
| 51 | +Lookaside Slots Used: 94 (max 122) |
| 52 | +Successful lookaside attempts: 431 |
| 53 | +Lookaside failures due to size: 4 |
| 54 | +Lookaside failures due to OOM: 0 |
| 55 | +Pager Heap Usage: 23008 bytes |
| 56 | +Page cache hits: 6 |
| 57 | +Page cache misses: 4 |
| 58 | +Page cache writes: 0 |
| 59 | +Page cache spills: 0 |
| 60 | +Schema Heap Usage: 25216 bytes |
| 61 | +Statement Heap/Lookaside Usage: 15504 bytes |
| 62 | +Fullscan Steps: 2 |
| 63 | +Sort Operations: 0 |
| 64 | +Autoindex Inserts: 0 |
| 65 | +Virtual Machine Steps: 46 |
| 66 | +Reprepare operations: 0 |
| 67 | +Number of times run: 1 |
| 68 | +Memory used by prepared stmt: 15504 |
| 69 | +``` |
| 70 | +There is also a `sqlite_stmt` virtual table ([documented here](https://sqlite.org/stmt.html)) which can be enabled using a loadable module, but I have not yet managed to get this to compile and load into the Python `sqlite3` environment. |
| 71 | + |
| 72 | +## Cancelling queries after a specified number of opcodes |
| 73 | + |
| 74 | +You can set an upper limit on the number of opcodes in the `sqlite3` command line using `.progress 100 --limit 1`, as [described here](https://sqlite.org/forum/forumpost/4a669c7b50f9a64c): |
| 75 | + |
| 76 | +``` |
| 77 | +sqlite> .progress 100 --limit 1 |
| 78 | +sqlite> select * from facetable limit 3; |
| 79 | +1|2019-01-14 08:00:00|1|1|CA|1|Mission|["tag1", "tag2"]|[{"foo": "bar"}]|one |
| 80 | +2|2019-01-14 08:00:00|1|1|CA|1|Dogpatch|["tag1", "tag3"]|[]|two |
| 81 | +3|2019-01-14 08:00:00|1|1|CA|1|SOMA|[]|[]| |
| 82 | +sqlite> select * from facetable; |
| 83 | +1|2019-01-14 08:00:00|1|1|CA|1|Mission|["tag1", "tag2"]|[{"foo": "bar"}]|one |
| 84 | +2|2019-01-14 08:00:00|1|1|CA|1|Dogpatch|["tag1", "tag3"]|[]|two |
| 85 | +3|2019-01-14 08:00:00|1|1|CA|1|SOMA|[]|[]| |
| 86 | +4|2019-01-14 08:00:00|1|1|CA|1|Tenderloin|[]|[]| |
| 87 | +5|2019-01-15 08:00:00|1|1|CA|1|Bernal Heights|[]|[]| |
| 88 | +6|2019-01-15 08:00:00|1|1|CA|1|Hayes Valley|[]|[]| |
| 89 | +7|2019-01-15 08:00:00|1|1|CA|2|Hollywood|[]|[]| |
| 90 | +Progress limit reached (1) |
| 91 | +Error: interrupted |
| 92 | +``` |
| 93 | +In Python code this can be achieved like so: |
| 94 | + |
| 95 | +```python |
| 96 | +conn.set_progress_handler(lambda: 1, 100) |
| 97 | +``` |
| 98 | +This sets a progress handler which will be called after every 100 opcodes - but by returning `1` the handler causes the query to be cancelled: |
| 99 | +```pycon |
| 100 | +>>> import sqlite3 |
| 101 | +>>> conn = sqlite3.connect("fixtures.db") |
| 102 | +>>> conn.set_progress_handler(lambda: 1, 200) |
| 103 | +>>> conn.execute("select * from facetable limit 3").rows() |
| 104 | +# Outputs rows |
| 105 | +>>> conn.execute("select * from facetable").fetchall() |
| 106 | +Traceback (most recent call last): |
| 107 | + File "<stdin>", line 1, in <module> |
| 108 | +sqlite3.OperationalError: interrupted |
| 109 | +``` |
| 110 | +This didn't exactly work how I expected - I had to change the number from 100 to 200 and I'm not sure why. But it illustrates the principle. |
0 commit comments