Skip to content

Commit edddb29

Browse files
authored
fix: remove maybe_datum view (#517)
* fix: remove maybe_datum view * fix: query performance * chore: add clarifying comments * feat: improve db migrations tool * chore: run migration as single transaction
1 parent 1e4cddd commit edddb29

File tree

6 files changed

+235
-21
lines changed

6 files changed

+235
-21
lines changed

typescript/packages/common-memory/README.md

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -17,6 +17,14 @@ deno task start
1717
It will print out service URL endpoint and `file:` URL for the directory where
1818
memory will be persisted in `.sqlite` files.
1919

20+
## Database Migrations
21+
22+
You can upgrade database to latest version by running following command from the package root
23+
24+
```sh
25+
deno task migrate ./path/to/db.sqlite
26+
```
27+
2028
## Data Model
2129

2230
Memory records are represented as a discrete facts in the shape of

typescript/packages/common-memory/deno.json

Lines changed: 5 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2,7 +2,11 @@
22
"name": "@commontools/memory",
33
"tasks": {
44
"start": "deno run --allow-read --allow-write --allow-net --allow-ffi --allow-env deno.ts",
5-
"test": "deno test --allow-read --allow-write --allow-net --allow-ffi --allow-env --no-check"
5+
"test": "deno test --allow-read --allow-write --allow-net --allow-ffi --allow-env --no-check",
6+
"migrate": {
7+
"description": "Performs database migration",
8+
"command": "deno run -A ./migrate.ts"
9+
}
610
},
711
"test": {
812
"include": [
Lines changed: 92 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,92 @@
1+
import {
2+
Database,
3+
SqliteError,
4+
Transaction as DBTransaction,
5+
} from "jsr:@db/sqlite";
6+
7+
const MIGRATIONS = new URL("./migrations/", import.meta.url);
8+
9+
class Migration {
10+
constructor(
11+
public db: Database,
12+
public id: number,
13+
public name: string,
14+
public url: URL,
15+
) {}
16+
17+
execute() {
18+
const content = Deno.readFileSync(this.url);
19+
this.db.exec(new TextDecoder().decode(content));
20+
}
21+
22+
migrate() {
23+
this.execute();
24+
this.db.run(
25+
`INSERT INTO migration (id, title) VALUES (:id, :title)`,
26+
{ id: this.id, title: this.name },
27+
);
28+
}
29+
}
30+
31+
const migrations = (db: Database): Migration[] => {
32+
const migrations = Deno.readDirSync(MIGRATIONS).flatMap(
33+
({ name, isFile }) => {
34+
const id = parseInt(name.slice(0, name.indexOf("-")));
35+
if (!isFile || isNaN(id)) {
36+
return [];
37+
} else {
38+
return [new Migration(db, id, name, new URL(name, MIGRATIONS))];
39+
}
40+
},
41+
);
42+
43+
return [...migrations].sort((left, right) => left.id - right.id);
44+
};
45+
46+
const current = (db: Database) =>
47+
db.prepare(
48+
`SELECT * FROM migration ORDER BY id DESC LIMIT 1;`,
49+
).get() as { id: number; title: string; time: string };
50+
51+
export const migrate = (db: Database) => {
52+
const [setup, ...updates] = migrations(db);
53+
// First we run the setup
54+
setup.execute();
55+
const { time, id, title } = current(db);
56+
57+
console.log(
58+
`🔎 DB was last migrated on ${time} to version ${id} via ${title}`,
59+
);
60+
61+
try {
62+
let migration = null;
63+
for (migration of updates) {
64+
if (migration.id > id) {
65+
console.log(`⏭️ Migrating to ${migration.id} using ${migration.name}`);
66+
migration.migrate();
67+
} else {
68+
migration = null;
69+
}
70+
}
71+
72+
if (migration) {
73+
console.log(`🏁 DB was successfully migrated to version ${migration.id}`);
74+
} else {
75+
console.log(`✅ DB is already at latest version ${id}`);
76+
}
77+
} catch (reason) {
78+
console.error(`💥 Migration failed`, reason);
79+
}
80+
};
81+
export const main = (database: string) => {
82+
const path = Deno.realPathSync(database);
83+
console.log(`💾 Loading ${path}`);
84+
const db = new Database(path, {
85+
create: false,
86+
unsafeConcurrency: true,
87+
});
88+
89+
return db.transaction(migrate)(db);
90+
};
91+
92+
main(...Deno.args as [string]);
Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
CREATE TABLE IF NOT EXISTS migration (
2+
id INTEGER PRIMARY KEY NOT NULL,
3+
title TEXT NOT NULL,
4+
time TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL
5+
);
6+
7+
INSERT OR IGNORE INTO migration (id, title)
8+
VALUES (0, '000-setup-migrations.sql');
Lines changed: 89 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,89 @@
1+
-- Drop indexes
2+
DROP INDEX memory_the;
3+
DROP INDEX memory_of;
4+
DROP INDEX IF EXISTS fact_since;
5+
6+
-- -- Drop views
7+
DROP VIEW state;
8+
DROP VIEW IF EXISTS maybe_datum;
9+
10+
-- Archive all tables
11+
ALTER TABLE datum RENAME TO datum_archive;
12+
ALTER TABLE fact RENAME TO fact_archive;
13+
ALTER TABLE memory RENAME TO memory_archive;
14+
15+
-- Create table for storing JSON data.
16+
-- ⚠️ We need make this NOT NULL because SQLite does not uphold uniqueness on NULL
17+
CREATE TABLE datum (
18+
this TEXT NOT NULL PRIMARY KEY, -- Merkle reference for this JSON
19+
source JSON -- Source for this JSON
20+
);
21+
22+
CREATE TABLE fact (
23+
this TEXT NOT NULL PRIMARY KEY, -- Merkle reference for { the, of, is, cause }
24+
the TEXT NOT NULL, -- Kind of a fact e.g. "application/json"
25+
of TEXT NOT NULL, -- Entity identifier fact is about
26+
'is' TEXT, -- Value entity is claimed to have
27+
cause TEXT, -- Causal reference to prior fact
28+
since INTEGER NOT NULL, -- Lamport clock since when this fact was in effect
29+
FOREIGN KEY('is') REFERENCES datum(this)
30+
);
31+
32+
CREATE TABLE memory (
33+
the TEXT NOT NULL, -- Kind of a fact e.g. "application/json"
34+
of TEXT NOT NULL, -- Entity identifier fact is about
35+
fact TEXT NOT NULL, -- Link to the fact,
36+
FOREIGN KEY(fact) REFERENCES fact(this),
37+
PRIMARY KEY (the, of) -- Ensure that we have only one fact per entity
38+
);
39+
40+
-- Create indexes
41+
CREATE INDEX memory_the ON memory (the); -- Index to filter by "the" field
42+
CREATE INDEX memory_of ON memory (of); -- Index to query by "of" field
43+
CREATE INDEX fact_since ON fact (since); -- Index to query by "since" field
44+
45+
-- Migrate data
46+
INSERT INTO datum (this, source)
47+
SELECT this, source
48+
FROM datum_archive;
49+
50+
-- Insert `NULL` value if not exists already
51+
INSERT INTO datum (this, source) VALUES ('undefined', NULL);
52+
53+
-- Not sure why but without this complicated query we run into
54+
-- foreign key constraint while this seems to avoid it yet copy same
55+
-- amount of rows.
56+
INSERT INTO fact (this, the, of, 'is', cause, since)
57+
SELECT fa.this, fa.the, fa.of, fa.'is', fa.cause, fa.since
58+
FROM fact_archive fa
59+
LEFT JOIN datum d ON fa.'is' = d.this
60+
WHERE fa.'is' IS NULL OR d.this IS NOT NULL;
61+
62+
63+
INSERT INTO memory (the, of, fact)
64+
SELECT ma.the, ma.of, ma.fact
65+
FROM memory_archive ma
66+
LEFT JOIN fact f ON ma.fact = f.this
67+
WHERE f.this IS NOT NULL; -- Include only rows with valid 'fact' references
68+
69+
70+
-- Create new 'state' view
71+
CREATE VIEW state AS
72+
SELECT
73+
memory.the AS the,
74+
memory.of AS of,
75+
datum.source AS 'is',
76+
fact.cause AS cause,
77+
memory.fact AS fact,
78+
datum.this AS proof,
79+
fact.since AS since
80+
FROM
81+
memory
82+
JOIN
83+
fact ON memory.fact = fact.this
84+
JOIN
85+
datum ON datum.this = COALESCE(fact.'is', 'undefined');
86+
87+
DROP TABLE memory_archive;
88+
DROP TABLE fact_archive;
89+
DROP TABLE datum_archive;

typescript/packages/common-memory/space.ts

Lines changed: 33 additions & 20 deletions
Original file line numberDiff line numberDiff line change
@@ -44,23 +44,25 @@ export const PREPARE = `
4444
BEGIN TRANSACTION;
4545
4646
-- Create table for storing JSON data.
47+
-- ⚠️ We need make this NOT NULL because SQLite does not uphold uniqueness on NULL
4748
CREATE TABLE IF NOT EXISTS datum (
48-
this TEXT PRIMARY KEY, -- Merkle reference for this JSON
49-
source JSON NOT NULL -- Source for this JSON
49+
this TEXT NOT NULL PRIMARY KEY, -- Merkle reference for this JSON
50+
source JSON -- Source for this JSON
5051
);
5152
52-
CREATE VIEW IF NOT EXISTS maybe_datum AS
53-
SELECT * FROM datum
54-
UNION ALL
55-
SELECT NULL AS this, NULL AS source;
53+
-- We create special record to represent undefined which does not exist in JSON.
54+
-- This allows us to join fact with datum table and cover retractions where
55+
-- fact.is is set to NULL
56+
INSERT OR IGNORE INTO datum (this, source) VALUES ('undefined', NULL);
57+
5658
5759
CREATE TABLE IF NOT EXISTS fact (
58-
this TEXT PRIMARY KEY, -- Merkle reference for { the, of, is, cause }
59-
the TEXT NOT NULL, -- Kind of a fact e.g. "application/json"
60-
of TEXT NOT NULL, -- Entity identifier fact is about
61-
'is' TEXT, -- Value entity is claimed to have
62-
cause TEXT, -- Causal reference to prior fact
63-
since INTEGER NOT NULL, -- Lamport clock since when this fact was in effect
60+
this TEXT NOT NULL PRIMARY KEY, -- Merkle reference for { the, of, is, cause }
61+
the TEXT NOT NULL, -- Kind of a fact e.g. "application/json"
62+
of TEXT NOT NULL, -- Entity identifier fact is about
63+
'is' TEXT, -- Value entity is claimed to have
64+
cause TEXT, -- Causal reference to prior fact
65+
since INTEGER NOT NULL, -- Lamport clock since when this fact was in effect
6466
FOREIGN KEY('is') REFERENCES datum(this)
6567
);
6668
@@ -74,22 +76,33 @@ CREATE TABLE IF NOT EXISTS memory (
7476
7577
CREATE INDEX IF NOT EXISTS memory_the ON memory (the); -- Index to filter by "the" field
7678
CREATE INDEX IF NOT EXISTS memory_of ON memory (of); -- Index to query by "of" field
79+
CREATE INDEX IF NOT EXISTS fact_since ON fact (since); -- Index to query by "since" field
7780
81+
-- Create the updated 'state' view
7882
CREATE VIEW IF NOT EXISTS state AS
7983
SELECT
80-
memory.the as the,
81-
memory.of as of,
82-
maybe_datum.source as 'is',
83-
fact.cause as cause,
84-
memory.fact as fact,
85-
maybe_datum.this as proof,
86-
fact.since as since
84+
memory.the AS the,
85+
memory.of AS of,
86+
datum.source AS 'is',
87+
fact.cause AS cause,
88+
memory.fact AS fact,
89+
datum.this AS proof,
90+
fact.since AS since
8791
FROM
8892
memory
93+
-- We use inner join because we memory.fact can not be NULL and as foreign
94+
-- key into fact.this which is also primary key. This guarantees that we will
95+
-- not have any memory record with corresponding fact record
8996
JOIN
9097
fact ON memory.fact = fact.this
98+
-- We use inner join here because fact.is || 'undefined' is guaranteed to have
99+
-- corresponding record in datum through a foreign key constraint and inner
100+
-- joins are generally more efficient that left joins.
101+
-- ⚠️ Also note that we use COALESCE operator to use 'undefined' in case where
102+
-- there fact.is NULL (retractions), which is important because SQLite never
103+
-- matches over fact.is = NULL.
91104
JOIN
92-
maybe_datum ON fact.'is' = maybe_datum.this OR (fact.'is' IS NULL AND maybe_datum.this IS NULL);
105+
datum ON datum.this = COALESCE(fact.'is', 'undefined');
93106
94107
COMMIT;
95108
`;

0 commit comments

Comments
 (0)