Skip to content
This repository has been archived by the owner on Apr 26, 2024. It is now read-only.

Commit

Permalink
Notes on boolean columns in database schemas (#10164)
Browse files Browse the repository at this point in the history
  • Loading branch information
richvdh committed Jun 11, 2021
1 parent 29966a2 commit 13577aa
Show file tree
Hide file tree
Showing 2 changed files with 43 additions and 0 deletions.
1 change: 1 addition & 0 deletions changelog.d/10164.misc
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
Add some developer documentation about boolean columns in database schemas.
42 changes: 42 additions & 0 deletions docs/development/database_schema.md
Original file line number Diff line number Diff line change
Expand Up @@ -93,3 +93,45 @@ Ensure postgres is installed, then run:

NB at the time of writing, this script predates the split into separate `state`/`main`
databases so will require updates to handle that correctly.

## Boolean columns

Boolean columns require special treatment, since SQLite treats booleans the
same as integers.

There are three separate aspects to this:

* Any new boolean column must be added to the `BOOLEAN_COLUMNS` list in
`scripts/synapse_port_db`. This tells the port script to cast the integer
value from SQLite to a boolean before writing the value to the postgres
database.

* Before SQLite 3.23, `TRUE` and `FALSE` were not recognised as constants by
SQLite, and the `IS [NOT] TRUE`/`IS [NOT] FALSE` operators were not
supported. This makes it necessary to avoid using `TRUE` and `FALSE`
constants in SQL commands.

For example, to insert a `TRUE` value into the database, write:

```python
txn.execute("INSERT INTO tbl(col) VALUES (?)", (True, ))
```

* Default values for new boolean columns present a particular
difficulty. Generally it is best to create separate schema files for
Postgres and SQLite. For example:

```sql
# in 00delta.sql.postgres:
ALTER TABLE tbl ADD COLUMN col BOOLEAN DEFAULT FALSE;
```

```sql
# in 00delta.sql.sqlite:
ALTER TABLE tbl ADD COLUMN col BOOLEAN DEFAULT 0;
```

Note that there is a particularly insidious failure mode here: the Postgres
flavour will be accepted by SQLite 3.22, but will give a column whose
default value is the **string** `"FALSE"` - which, when cast back to a boolean
in Python, evaluates to `True`.

0 comments on commit 13577aa

Please sign in to comment.