├── .github └── workflows │ ├── publish.yml │ └── test.yml ├── .gitignore ├── LICENSE ├── README.md ├── setup.py ├── sqlite_history ├── __init__.py ├── __main__.py ├── cli.py └── sql.py └── tests └── test_sqlite_history.py /.github/workflows/publish.yml: -------------------------------------------------------------------------------- 1 | name: Publish Python Package 2 | 3 | on: 4 | release: 5 | types: [created] 6 | 7 | permissions: 8 | contents: read 9 | 10 | jobs: 11 | test: 12 | runs-on: ubuntu-latest 13 | strategy: 14 | matrix: 15 | python-version: ["3.7", "3.8", "3.9", "3.10", "3.11"] 16 | steps: 17 | - uses: actions/checkout@v3 18 | - name: Set up Python ${{ matrix.python-version }} 19 | uses: actions/setup-python@v4 20 | with: 21 | python-version: ${{ matrix.python-version }} 22 | cache: pip 23 | cache-dependency-path: setup.py 24 | - name: Install dependencies 25 | run: | 26 | pip install '.[test]' 27 | - name: Run tests 28 | run: | 29 | pytest 30 | cog --check README.md 31 | deploy: 32 | runs-on: ubuntu-latest 33 | needs: [test] 34 | steps: 35 | - uses: actions/checkout@v3 36 | - name: Set up Python 37 | uses: actions/setup-python@v4 38 | with: 39 | python-version: "3.11" 40 | cache: pip 41 | cache-dependency-path: setup.py 42 | - name: Install dependencies 43 | run: | 44 | pip install setuptools wheel twine build 45 | - name: Publish 46 | env: 47 | TWINE_USERNAME: __token__ 48 | TWINE_PASSWORD: ${{ secrets.PYPI_TOKEN }} 49 | run: | 50 | python -m build 51 | twine upload dist/* 52 | 53 | -------------------------------------------------------------------------------- /.github/workflows/test.yml: -------------------------------------------------------------------------------- 1 | name: Test 2 | 3 | on: [push, pull_request] 4 | 5 | permissions: 6 | contents: read 7 | 8 | jobs: 9 | test: 10 | runs-on: ubuntu-latest 11 | strategy: 12 | matrix: 13 | python-version: ["3.7", "3.8", "3.9", "3.10", "3.11"] 14 | steps: 15 | - uses: actions/checkout@v3 16 | - name: Set up Python ${{ matrix.python-version }} 17 | uses: actions/setup-python@v4 18 | with: 19 | python-version: ${{ matrix.python-version }} 20 | cache: pip 21 | cache-dependency-path: setup.py 22 | - name: Install dependencies 23 | run: | 24 | pip install '.[test]' 25 | - name: Run tests 26 | run: | 27 | pytest 28 | cog --check README.md 29 | 30 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | .venv 2 | __pycache__/ 3 | *.py[cod] 4 | *$py.class 5 | venv 6 | .eggs 7 | .pytest_cache 8 | *.egg-info 9 | .DS_Store 10 | dist 11 | build 12 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | APPENDIX: How to apply the Apache License to your work. 179 | 180 | To apply the Apache License to your work, attach the following 181 | boilerplate notice, with the fields enclosed by brackets "[]" 182 | replaced with your own identifying information. (Don't include 183 | the brackets!) The text should be enclosed in the appropriate 184 | comment syntax for the file format. We also recommend that a 185 | file or class name and description of purpose be included on the 186 | same "printed page" as the copyright notice for easier 187 | identification within third-party archives. 188 | 189 | Copyright [yyyy] [name of copyright owner] 190 | 191 | Licensed under the Apache License, Version 2.0 (the "License"); 192 | you may not use this file except in compliance with the License. 193 | You may obtain a copy of the License at 194 | 195 | http://www.apache.org/licenses/LICENSE-2.0 196 | 197 | Unless required by applicable law or agreed to in writing, software 198 | distributed under the License is distributed on an "AS IS" BASIS, 199 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 200 | See the License for the specific language governing permissions and 201 | limitations under the License. 202 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # sqlite-history 2 | 3 | [![PyPI](https://img.shields.io/pypi/v/sqlite-history.svg)](https://pypi.org/project/sqlite-history/) 4 | [![Tests](https://github.com/simonw/sqlite-history/workflows/Test/badge.svg)](https://github.com/simonw/sqlite-history/actions?query=workflow%3ATest) 5 | [![Changelog](https://img.shields.io/github/v/release/simonw/sqlite-history?include_prereleases&label=changelog)](https://github.com/simonw/sqlite-history/releases) 6 | [![License](https://img.shields.io/badge/license-Apache%202.0-blue.svg)](https://github.com/simonw/sqlite-history/blob/main/LICENSE) 7 | 8 | Track changes to SQLite tables using triggers 9 | 10 | For more on this project: [sqlite-history: tracking changes to SQLite tables using triggers](https://simonwillison.net/2023/Apr/15/sqlite-history/) 11 | 12 | ## Installation 13 | 14 | Install this library using `pip`: 15 | 16 | pip install sqlite-history 17 | 18 | ## Usage 19 | 20 | This library can be used to configure triggers on a SQLite database such that any inserts, updates or deletes against a table will have their changes recorded in a separate table. 21 | 22 | You can enable history tracking for a table using the `configure_history()` function: 23 | 24 | import sqlite_history 25 | import sqlite3 26 | 27 | conn = sqlite3.connect("data.db") 28 | conn.execute("CREATE TABLE table1 (id INTEGER PRIMARY KEY, name TEXT)") 29 | sqlite_history.configure_history(conn, "table1") 30 | 31 | Or you can use the CLI interface, available via `python -m sqlite_history`: 32 | 33 | python -m sqlite_history data.db table1 [table2 table3 ...] 34 | 35 | Use `--all` to configure it for all tables: 36 | 37 | python -m sqlite_history data.db --all 38 | 39 | ## How this works 40 | 41 | Given a table with the following schema: 42 | 43 | 57 | ```sql 58 | CREATE TABLE people ( 59 | id INTEGER PRIMARY KEY, 60 | name TEXT, 61 | age INTEGER, 62 | weight REAL 63 | ); 64 | ``` 65 | 66 | 67 | This library will create a new table called `_people_history` with the following schema: 68 | 69 | 80 | ```sql 81 | CREATE TABLE _people_history ( 82 | _rowid INTEGER, 83 | id INTEGER, 84 | name TEXT, 85 | age INTEGER, 86 | weight REAL, 87 | _version INTEGER, 88 | _updated INTEGER, 89 | _mask INTEGER 90 | ); 91 | CREATE INDEX idx_people_history_rowid ON _people_history (_rowid); 92 | ``` 93 | 94 | The `_rowid` column references the `rowid` of the row in the original table that is being tracked. If a row has been updated multiple times there will be multiple rows with the same `_rowid` in this table. 95 | 96 | The `id`, `name`, `age` and `weight` columns represent the new values assigned to the row when it was updated. These can also be `null`, which might represent no change or might represent the value being set to `null` (hence the `_mask` column). 97 | 98 | The `_version` column is a monotonically increasing integer that is incremented each time a row is updated. 99 | 100 | The `_updated` column is a timestamp showing when the change was recorded. This is stored in milliseconds since the Unix epoch - to convert that to a human-readable UTC date you can use `strftime('%Y-%m-%d %H:%M:%S', _updated / 1000, 'unixepoch')` in your SQL queries. 101 | 102 | The `_mask` column is a bit mask that indicates which columns changed in an update. The bit mask is calculated by adding together the following values: 103 | 104 | 1: id 105 | 2: name 106 | 4: age 107 | 8: weight 108 | 109 | Tables with different schemas will have different `_mask` values. 110 | 111 | A `_mask` of `-1` indicates that the row was deleted. 112 | 113 | The following triggers are created to populate the `_people_history` table: 114 | 120 | ```sql 121 | CREATE TRIGGER people_insert_history 122 | AFTER INSERT ON people 123 | BEGIN 124 | INSERT INTO _people_history (_rowid, id, name, age, weight, _version, _updated, _mask) 125 | VALUES (new.rowid, new.id, new.name, new.age, new.weight, 1, cast((julianday('now') - 2440587.5) * 86400 * 1000 as integer), 15); 126 | END; 127 | 128 | CREATE TRIGGER people_update_history 129 | AFTER UPDATE ON people 130 | FOR EACH ROW 131 | BEGIN 132 | INSERT INTO _people_history (_rowid, id, name, age, weight, _version, _updated, _mask) 133 | SELECT old.rowid, 134 | CASE WHEN old.id != new.id then new.id else null end, 135 | CASE WHEN old.name != new.name then new.name else null end, 136 | CASE WHEN old.age != new.age then new.age else null end, 137 | CASE WHEN old.weight != new.weight then new.weight else null end, 138 | (SELECT MAX(_version) FROM _people_history WHERE _rowid = old.rowid) + 1, 139 | cast((julianday('now') - 2440587.5) * 86400 * 1000 as integer), 140 | (CASE WHEN old.id != new.id then 1 else 0 end) + (CASE WHEN old.name != new.name then 2 else 0 end) + (CASE WHEN old.age != new.age then 4 else 0 end) + (CASE WHEN old.weight != new.weight then 8 else 0 end) 141 | WHERE old.id != new.id or old.name != new.name or old.age != new.age or old.weight != new.weight; 142 | END; 143 | 144 | CREATE TRIGGER people_delete_history 145 | AFTER DELETE ON people 146 | BEGIN 147 | INSERT INTO _people_history (_rowid, id, name, age, weight, _version, _updated, _mask) 148 | VALUES ( 149 | old.rowid, 150 | old.id, old.name, old.age, old.weight, 151 | (SELECT COALESCE(MAX(_version), 0) from _people_history WHERE _rowid = old.rowid) + 1, 152 | cast((julianday('now') - 2440587.5) * 86400 * 1000 as integer), 153 | -1 154 | ); 155 | END; 156 | ``` 157 | 158 | 159 | ## Development 160 | 161 | To contribute to this library, first checkout the code. Then create a new virtual environment: 162 | 163 | cd sqlite-history 164 | python -m venv venv 165 | source venv/bin/activate 166 | 167 | Now install the dependencies and test dependencies: 168 | 169 | pip install -e '.[test]' 170 | 171 | To run the tests: 172 | 173 | pytest 174 | -------------------------------------------------------------------------------- /setup.py: -------------------------------------------------------------------------------- 1 | from setuptools import setup 2 | import os 3 | 4 | VERSION = "0.1" 5 | 6 | 7 | def get_long_description(): 8 | with open( 9 | os.path.join(os.path.dirname(os.path.abspath(__file__)), "README.md"), 10 | encoding="utf8", 11 | ) as fp: 12 | return fp.read() 13 | 14 | 15 | setup( 16 | name="sqlite-history", 17 | description="Track changes to SQLite tables using triggers", 18 | long_description=get_long_description(), 19 | long_description_content_type="text/markdown", 20 | author="Simon Willison", 21 | url="https://github.com/simonw/sqlite-history", 22 | project_urls={ 23 | "Issues": "https://github.com/simonw/sqlite-history/issues", 24 | "CI": "https://github.com/simonw/sqlite-history/actions", 25 | "Changelog": "https://github.com/simonw/sqlite-history/releases", 26 | }, 27 | license="Apache License, Version 2.0", 28 | version=VERSION, 29 | packages=["sqlite_history"], 30 | install_requires=[], 31 | extras_require={"test": ["pytest", "sqlite-utils", "cogapp"]}, 32 | python_requires=">=3.7", 33 | ) 34 | -------------------------------------------------------------------------------- /sqlite_history/__init__.py: -------------------------------------------------------------------------------- 1 | from .sql import backfill_sql, history_table_sql, triggers_sql, table_columns_and_types 2 | 3 | 4 | def configure_history(db, table): 5 | """Configure history triggers for a table in a database.""" 6 | # Get the table schema 7 | columns_and_types = table_columns_and_types(db, table) 8 | columns = [r[0] for r in columns_and_types] 9 | with db: 10 | db.executescript(history_table_sql(table, columns_and_types)) 11 | # Create the triggers 12 | db.executescript(triggers_sql(table, columns)) 13 | # Backfill the history table 14 | db.execute(backfill_sql(table, columns)) 15 | -------------------------------------------------------------------------------- /sqlite_history/__main__.py: -------------------------------------------------------------------------------- 1 | from .cli import run 2 | 3 | if __name__ == "__main__": 4 | run() 5 | -------------------------------------------------------------------------------- /sqlite_history/cli.py: -------------------------------------------------------------------------------- 1 | import argparse 2 | import sqlite3 3 | import os 4 | from . import configure_history 5 | 6 | 7 | def configure_triggers(database_path, tables): 8 | db = sqlite3.connect(database_path) 9 | for table in tables: 10 | if table.startswith("_") and table.endswith("_history"): 11 | continue 12 | # Does a history table exist already? 13 | history_table_name = f"_{table}_history" 14 | cursor = db.execute( 15 | f"SELECT name FROM sqlite_master WHERE type='table' AND name='{history_table_name}';" 16 | ) 17 | if cursor.fetchone(): 18 | print(f"History table {history_table_name} already exists - skipping.") 19 | continue 20 | configure_history(db, table) 21 | 22 | 23 | def all_regular_tables(database_path): 24 | """'Regular' excludes FTS and related tables.""" 25 | conn = sqlite3.connect(database_path) 26 | cursor = conn.cursor() 27 | hidden_tables = [ 28 | r[0] 29 | for r in ( 30 | cursor.execute( 31 | """ 32 | SELECT NAME FROM sqlite_master 33 | WHERE type = 'table' 34 | AND ( 35 | sql LIKE '%VIRTUAL TABLE%USING FTS%' 36 | ) OR name IN ('sqlite_stat1', 'sqlite_stat2', 'sqlite_stat3', 'sqlite_stat4') 37 | """ 38 | ) 39 | ).fetchall() 40 | ] 41 | hidden_tables_copy = hidden_tables[:] 42 | regular_tables = [] 43 | for row in cursor.execute( 44 | "SELECT name FROM sqlite_master WHERE type='table';" 45 | ).fetchall(): 46 | table_name = row[0] 47 | should_be_hidden = any( 48 | table_name.startswith(hidden_table) for hidden_table in hidden_tables_copy 49 | ) 50 | if not should_be_hidden: 51 | regular_tables.append(table_name) 52 | return regular_tables 53 | 54 | 55 | def run(test_args=None): 56 | parser = argparse.ArgumentParser( 57 | description="Configure sqlite-history triggers for one or more tables." 58 | ) 59 | 60 | parser.add_argument("database_path", help="Path to the SQLite database file.") 61 | parser.add_argument( 62 | "tables", nargs="*", help="One or more table names to configure." 63 | ) 64 | parser.add_argument( 65 | "--all", action="store_true", help="Configure for all tables in the database." 66 | ) 67 | 68 | if test_args: 69 | args = parser.parse_args(test_args) 70 | else: 71 | args = parser.parse_args() 72 | 73 | if args.all: 74 | args.tables = all_regular_tables(args.database_path) 75 | elif len(args.tables) == 0: 76 | parser.error( 77 | "No tables provided. Please provide table names or use --all flag." 78 | ) 79 | 80 | # Error if database_path doesn't exist 81 | if not os.path.exists(args.database_path): 82 | parser.error("Database file does not exist.") 83 | 84 | # Error if any of the tables don't exist 85 | all_table_names = all_regular_tables(args.database_path) 86 | missing_tables = [table for table in args.tables if table not in all_table_names] 87 | if missing_tables: 88 | parser.error("The following tables do not exist: " + ", ".join(missing_tables)) 89 | 90 | configure_triggers(args.database_path, args.tables) 91 | -------------------------------------------------------------------------------- /sqlite_history/sql.py: -------------------------------------------------------------------------------- 1 | import re 2 | 3 | 4 | def history_table_sql(table, columns_and_types): 5 | """Return SQL for history table for a table and its columns.""" 6 | if isinstance(columns_and_types, dict): 7 | columns_and_types = dict.items() 8 | column_names = ",\n".join( 9 | " {name} {type}".format(name=escape_sqlite(name), type=type) 10 | for name, type in columns_and_types 11 | ) 12 | return """ 13 | CREATE TABLE _{table}_history ( 14 | _rowid INTEGER, 15 | {column_names}, 16 | _version INTEGER, 17 | _updated INTEGER, 18 | _mask INTEGER 19 | ); 20 | CREATE INDEX idx_{table}_history_rowid ON _{table}_history (_rowid); 21 | """.format( 22 | table=table, column_names=column_names 23 | ) 24 | 25 | 26 | def triggers_sql(table, columns): 27 | """Return SQL for triggers for a table and its columns.""" 28 | column_names = ", ".join(escape_sqlite(column) for column in columns) 29 | new_column_values = ", ".join("new." + escape_sqlite(column) for column in columns) 30 | old_column_values = ", ".join("old." + escape_sqlite(column) for column in columns) 31 | # mask is a bit mask of all columns, so len(columns) 32 | mask = 2 ** len(columns) - 1 33 | insert_trigger = """ 34 | CREATE TRIGGER {table}_insert_history 35 | AFTER INSERT ON {table} 36 | BEGIN 37 | INSERT INTO _{table}_history (_rowid, {column_names}, _version, _updated, _mask) 38 | VALUES (new.rowid, {new_column_values}, 1, cast((julianday('now') - 2440587.5) * 86400 * 1000 as integer), {mask}); 39 | END; 40 | """.format( 41 | table=table, 42 | column_names=column_names, 43 | new_column_values=new_column_values, 44 | mask=mask, 45 | ) 46 | update_columns = [] 47 | for column in columns: 48 | update_columns.append( 49 | """ 50 | CASE WHEN old.{column} != new.{column} then new.{column} else null end""".format( 51 | column=escape_sqlite(column) 52 | ) 53 | ) 54 | update_columns_sql = ", ".join(update_columns) 55 | mask_sql = " + ".join( 56 | """(CASE WHEN old.{column} != new.{column} then {base} else 0 end)""".format( 57 | column=escape_sqlite(column), 58 | base=2**idx, 59 | ) 60 | for idx, column in enumerate(columns) 61 | ) 62 | where_sql = " or ".join( 63 | "old.{column} != new.{column}".format(column=escape_sqlite(column)) 64 | for column in columns 65 | ) 66 | update_trigger = """ 67 | CREATE TRIGGER {table}_update_history 68 | AFTER UPDATE ON {table} 69 | FOR EACH ROW 70 | BEGIN 71 | INSERT INTO _{table}_history (_rowid, {column_names}, _version, _updated, _mask) 72 | SELECT old.rowid, {update_columns_sql}, 73 | (SELECT MAX(_version) FROM _{table}_history WHERE _rowid = old.rowid) + 1, 74 | cast((julianday('now') - 2440587.5) * 86400 * 1000 as integer), 75 | {mask_sql} 76 | WHERE {where_sql}; 77 | END; 78 | """.format( 79 | table=table, 80 | column_names=column_names, 81 | update_columns_sql=update_columns_sql, 82 | mask_sql=mask_sql, 83 | where_sql=where_sql, 84 | ) 85 | delete_trigger = """ 86 | CREATE TRIGGER {table}_delete_history 87 | AFTER DELETE ON {table} 88 | BEGIN 89 | INSERT INTO _{table}_history (_rowid, {column_names}, _version, _updated, _mask) 90 | VALUES ( 91 | old.rowid, 92 | {old_column_values}, 93 | (SELECT COALESCE(MAX(_version), 0) from _{table}_history WHERE _rowid = old.rowid) + 1, 94 | cast((julianday('now') - 2440587.5) * 86400 * 1000 as integer), 95 | -1 96 | ); 97 | END; 98 | """.format( 99 | table=table, column_names=column_names, old_column_values=old_column_values 100 | ) 101 | return insert_trigger + update_trigger + delete_trigger 102 | 103 | 104 | def backfill_sql(table, columns): 105 | column_names = ", ".join(escape_sqlite(column) for column in columns) 106 | sql = """ 107 | INSERT INTO _{table}_history (_rowid, {column_names}, _version, _updated, _mask) 108 | SELECT rowid, {column_names}, 1, cast((julianday('now') - 2440587.5) * 86400 * 1000 as integer), {mask} 109 | FROM {table}; 110 | """.format( 111 | table=table, column_names=column_names, mask=2 ** len(columns) - 1 112 | ) 113 | return sql 114 | 115 | 116 | def table_columns_and_types(db, table): 117 | cursor = db.execute(f"PRAGMA table_info([{table}]);") 118 | columns_and_types = [] 119 | for row in cursor.fetchall(): 120 | columns_and_types.append((row[1], row[2])) 121 | return columns_and_types 122 | 123 | 124 | # From https://www.sqlite.org/lang_keywords.html 125 | reserved_words = set( 126 | ( 127 | "abort action add after all alter analyze and as asc attach autoincrement " 128 | "before begin between by cascade case cast check collate column commit " 129 | "conflict constraint create cross current_date current_time " 130 | "current_timestamp database default deferrable deferred delete desc detach " 131 | "distinct drop each else end escape except exclusive exists explain fail " 132 | "for foreign from full glob group having if ignore immediate in index " 133 | "indexed initially inner insert instead intersect into is isnull join key " 134 | "left like limit match natural no not notnull null of offset on or order " 135 | "outer plan pragma primary query raise recursive references regexp reindex " 136 | "release rename replace restrict right rollback row savepoint select set " 137 | "table temp temporary then to transaction trigger union unique update using " 138 | "vacuum values view virtual when where with without" 139 | ).split() 140 | ) 141 | 142 | _boring_keyword_re = re.compile(r"^[a-zA-Z_][a-zA-Z0-9_]*$") 143 | 144 | 145 | def escape_sqlite(s): 146 | if _boring_keyword_re.match(s) and (s.lower() not in reserved_words): 147 | return s 148 | else: 149 | return f"[{s}]" 150 | -------------------------------------------------------------------------------- /tests/test_sqlite_history.py: -------------------------------------------------------------------------------- 1 | import sqlite_utils 2 | from sqlite_history.sql import history_table_sql, triggers_sql 3 | from sqlite_history.cli import run 4 | from unittest.mock import ANY 5 | 6 | 7 | def test_create_history_table(): 8 | db = sqlite_utils.Database(memory=True) 9 | db["test"].create({"id": int, "name": str}, pk="id") 10 | db.executescript(history_table_sql("test", (("id", "integer"), ("name", "text")))) 11 | assert db["_test_history"].schema == ( 12 | "CREATE TABLE _test_history (\n" 13 | " _rowid INTEGER,\n" 14 | " id integer,\n" 15 | " name text,\n" 16 | " _version INTEGER,\n" 17 | " _updated INTEGER,\n" 18 | " _mask INTEGER\n" 19 | ")" 20 | ) 21 | 22 | 23 | def test_triggers(): 24 | db = sqlite_utils.Database(memory=True) 25 | db["test"].create({"id": int, "name": str, "order": int}, pk="id") 26 | db.executescript(history_table_sql("test", (("id", "integer"), ("name", "text")))) 27 | db.executescript(triggers_sql("test", ["id", "name"])) 28 | db["test"].insert({"id": 1, "name": "Alice"}) 29 | db["test"].insert({"id": 2, "name": "Bob"}) 30 | db["test"].update(1, {"name": "Alice Smith"}) 31 | assert list(db["test"].rows) == [ 32 | {"id": 1, "name": "Alice Smith", "order": None}, 33 | {"id": 2, "name": "Bob", "order": None}, 34 | ] 35 | assert list(db["_test_history"].rows) == [ 36 | { 37 | "_rowid": 1, 38 | "id": 1, 39 | "name": "Alice", 40 | "_version": 1, 41 | "_updated": ANY, 42 | "_mask": 3, 43 | }, 44 | { 45 | "_rowid": 2, 46 | "id": 2, 47 | "name": "Bob", 48 | "_version": 1, 49 | "_updated": ANY, 50 | "_mask": 3, 51 | }, 52 | { 53 | "_rowid": 1, 54 | "id": None, 55 | "name": "Alice Smith", 56 | "_version": 2, 57 | "_updated": ANY, 58 | "_mask": 2, 59 | }, 60 | ] 61 | 62 | 63 | def test_triggers_delete(): 64 | db = sqlite_utils.Database(memory=True) 65 | db["test"].create({"id": int, "name": str}, pk="id") 66 | db.executescript(history_table_sql("test", (("id", "integer"), ("name", "text")))) 67 | db.executescript(triggers_sql("test", ["id", "name"])) 68 | db["test"].insert({"id": 1, "name": "Alice"}) 69 | db["test"].insert({"id": 2, "name": "Bob"}) 70 | db["test"].update(1, {"name": "Alice Smith"}) 71 | db["test"].delete(1) 72 | assert list(db["test"].rows) == [ 73 | {"id": 2, "name": "Bob"}, 74 | ] 75 | assert list(db["_test_history"].rows) == [ 76 | { 77 | "_rowid": 1, 78 | "id": 1, 79 | "name": "Alice", 80 | "_version": 1, 81 | "_updated": ANY, 82 | "_mask": 3, 83 | }, 84 | { 85 | "_rowid": 2, 86 | "id": 2, 87 | "name": "Bob", 88 | "_version": 1, 89 | "_updated": ANY, 90 | "_mask": 3, 91 | }, 92 | { 93 | "_rowid": 1, 94 | "id": None, 95 | "name": "Alice Smith", 96 | "_version": 2, 97 | "_updated": ANY, 98 | "_mask": 2, 99 | }, 100 | { 101 | "_rowid": 1, 102 | "id": 1, 103 | "name": "Alice Smith", 104 | "_version": 3, 105 | "_updated": ANY, 106 | "_mask": -1, 107 | }, 108 | ] 109 | 110 | 111 | def test_cli(tmpdir): 112 | test = tmpdir / "test.db" 113 | db = sqlite_utils.Database(str(test)) 114 | db["test"].insert({"id": 1, "name": "Alice", "order": 1}) 115 | db["test"].enable_fts(("name",), create_triggers=True) 116 | assert set(db.table_names()) == { 117 | "test", 118 | "test_fts", 119 | "test_fts_docsize", 120 | "test_fts_idx", 121 | "test_fts_data", 122 | "test_fts_config", 123 | } 124 | run([str(test), "--all"]) 125 | assert set(db.table_names()) == { 126 | "test", 127 | "test_fts", 128 | "test_fts_docsize", 129 | "test_fts_idx", 130 | "test_fts_data", 131 | "test_fts_config", 132 | "_test_history", 133 | } 134 | --------------------------------------------------------------------------------