Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
8 changes: 8 additions & 0 deletions typescript/packages/common-memory/README.md
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,14 @@ deno task start
It will print out service URL endpoint and `file:` URL for the directory where
memory will be persisted in `.sqlite` files.

## Database Migrations

You can upgrade database to latest version by running following command from the package root

```sh
deno task migrate ./path/to/db.sqlite
```

## Data Model

Memory records are represented as a discrete facts in the shape of
Expand Down
6 changes: 5 additions & 1 deletion typescript/packages/common-memory/deno.json
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,11 @@
"name": "@commontools/memory",
"tasks": {
"start": "deno run --allow-read --allow-write --allow-net --allow-ffi --allow-env deno.ts",
"test": "deno test --allow-read --allow-write --allow-net --allow-ffi --allow-env --no-check"
"test": "deno test --allow-read --allow-write --allow-net --allow-ffi --allow-env --no-check",
"migrate": {
"description": "Performs database migration",
"command": "deno run -A ./migrate.ts"
}
},
"test": {
"include": [
Expand Down
92 changes: 92 additions & 0 deletions typescript/packages/common-memory/migrate.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,92 @@
import {
Database,
SqliteError,
Transaction as DBTransaction,
} from "jsr:@db/sqlite";

const MIGRATIONS = new URL("./migrations/", import.meta.url);

class Migration {
constructor(
public db: Database,
public id: number,
public name: string,
public url: URL,
) {}

execute() {
const content = Deno.readFileSync(this.url);
this.db.exec(new TextDecoder().decode(content));
}

migrate() {
this.execute();
this.db.run(
`INSERT INTO migration (id, title) VALUES (:id, :title)`,
{ id: this.id, title: this.name },
);
}
}

const migrations = (db: Database): Migration[] => {
const migrations = Deno.readDirSync(MIGRATIONS).flatMap(
({ name, isFile }) => {
const id = parseInt(name.slice(0, name.indexOf("-")));
if (!isFile || isNaN(id)) {
return [];
} else {
return [new Migration(db, id, name, new URL(name, MIGRATIONS))];
}
},
);

return [...migrations].sort((left, right) => left.id - right.id);
};

const current = (db: Database) =>
db.prepare(
`SELECT * FROM migration ORDER BY id DESC LIMIT 1;`,
).get() as { id: number; title: string; time: string };

export const migrate = (db: Database) => {
const [setup, ...updates] = migrations(db);
// First we run the setup
setup.execute();
const { time, id, title } = current(db);

console.log(
`🔎 DB was last migrated on ${time} to version ${id} via ${title}`,
);

try {
let migration = null;
for (migration of updates) {
if (migration.id > id) {
console.log(`⏭️ Migrating to ${migration.id} using ${migration.name}`);
migration.migrate();
} else {
migration = null;
}
}

if (migration) {
console.log(`🏁 DB was successfully migrated to version ${migration.id}`);
} else {
console.log(`✅ DB is already at latest version ${id}`);
}
} catch (reason) {
console.error(`💥 Migration failed`, reason);
}
};
export const main = (database: string) => {
const path = Deno.realPathSync(database);
console.log(`💾 Loading ${path}`);
const db = new Database(path, {
create: false,
unsafeConcurrency: true,
});

return db.transaction(migrate)(db);
};

main(...Deno.args as [string]);
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
CREATE TABLE IF NOT EXISTS migration (
id INTEGER PRIMARY KEY NOT NULL,
title TEXT NOT NULL,
time TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL
);

INSERT OR IGNORE INTO migration (id, title)
VALUES (0, '000-setup-migrations.sql');
Original file line number Diff line number Diff line change
@@ -0,0 +1,89 @@
-- Drop indexes
DROP INDEX memory_the;
DROP INDEX memory_of;
DROP INDEX IF EXISTS fact_since;

-- -- Drop views
DROP VIEW state;
DROP VIEW IF EXISTS maybe_datum;

-- Archive all tables
ALTER TABLE datum RENAME TO datum_archive;
ALTER TABLE fact RENAME TO fact_archive;
ALTER TABLE memory RENAME TO memory_archive;

-- Create table for storing JSON data.
-- ⚠️ We need make this NOT NULL because SQLite does not uphold uniqueness on NULL
CREATE TABLE datum (
this TEXT NOT NULL PRIMARY KEY, -- Merkle reference for this JSON
source JSON -- Source for this JSON
);

CREATE TABLE fact (
this TEXT NOT NULL PRIMARY KEY, -- Merkle reference for { the, of, is, cause }
the TEXT NOT NULL, -- Kind of a fact e.g. "application/json"
of TEXT NOT NULL, -- Entity identifier fact is about
'is' TEXT, -- Value entity is claimed to have
cause TEXT, -- Causal reference to prior fact
since INTEGER NOT NULL, -- Lamport clock since when this fact was in effect
FOREIGN KEY('is') REFERENCES datum(this)
);

CREATE TABLE memory (
the TEXT NOT NULL, -- Kind of a fact e.g. "application/json"
of TEXT NOT NULL, -- Entity identifier fact is about
fact TEXT NOT NULL, -- Link to the fact,
FOREIGN KEY(fact) REFERENCES fact(this),
PRIMARY KEY (the, of) -- Ensure that we have only one fact per entity
);

-- Create indexes
CREATE INDEX memory_the ON memory (the); -- Index to filter by "the" field
CREATE INDEX memory_of ON memory (of); -- Index to query by "of" field
CREATE INDEX fact_since ON fact (since); -- Index to query by "since" field

-- Migrate data
INSERT INTO datum (this, source)
SELECT this, source
FROM datum_archive;

-- Insert `NULL` value if not exists already
INSERT INTO datum (this, source) VALUES ('undefined', NULL);

-- Not sure why but without this complicated query we run into
-- foreign key constraint while this seems to avoid it yet copy same
-- amount of rows.
INSERT INTO fact (this, the, of, 'is', cause, since)
SELECT fa.this, fa.the, fa.of, fa.'is', fa.cause, fa.since
FROM fact_archive fa
LEFT JOIN datum d ON fa.'is' = d.this
WHERE fa.'is' IS NULL OR d.this IS NOT NULL;


INSERT INTO memory (the, of, fact)
SELECT ma.the, ma.of, ma.fact
FROM memory_archive ma
LEFT JOIN fact f ON ma.fact = f.this
WHERE f.this IS NOT NULL; -- Include only rows with valid 'fact' references


-- Create new 'state' view
CREATE VIEW state AS
SELECT
memory.the AS the,
memory.of AS of,
datum.source AS 'is',
fact.cause AS cause,
memory.fact AS fact,
datum.this AS proof,
fact.since AS since
FROM
memory
JOIN
fact ON memory.fact = fact.this
JOIN
datum ON datum.this = COALESCE(fact.'is', 'undefined');

DROP TABLE memory_archive;
DROP TABLE fact_archive;
DROP TABLE datum_archive;
53 changes: 33 additions & 20 deletions typescript/packages/common-memory/space.ts
Original file line number Diff line number Diff line change
Expand Up @@ -44,23 +44,25 @@ export const PREPARE = `
BEGIN TRANSACTION;

-- Create table for storing JSON data.
-- ⚠️ We need make this NOT NULL because SQLite does not uphold uniqueness on NULL
CREATE TABLE IF NOT EXISTS datum (
this TEXT PRIMARY KEY, -- Merkle reference for this JSON
source JSON NOT NULL -- Source for this JSON
this TEXT NOT NULL PRIMARY KEY, -- Merkle reference for this JSON
source JSON -- Source for this JSON
);

CREATE VIEW IF NOT EXISTS maybe_datum AS
SELECT * FROM datum
UNION ALL
SELECT NULL AS this, NULL AS source;
-- We create special record to represent undefined which does not exist in JSON.
-- This allows us to join fact with datum table and cover retractions where
-- fact.is is set to NULL
INSERT OR IGNORE INTO datum (this, source) VALUES ('undefined', NULL);


CREATE TABLE IF NOT EXISTS fact (
this TEXT PRIMARY KEY, -- Merkle reference for { the, of, is, cause }
the TEXT NOT NULL, -- Kind of a fact e.g. "application/json"
of TEXT NOT NULL, -- Entity identifier fact is about
'is' TEXT, -- Value entity is claimed to have
cause TEXT, -- Causal reference to prior fact
since INTEGER NOT NULL, -- Lamport clock since when this fact was in effect
this TEXT NOT NULL PRIMARY KEY, -- Merkle reference for { the, of, is, cause }
the TEXT NOT NULL, -- Kind of a fact e.g. "application/json"
of TEXT NOT NULL, -- Entity identifier fact is about
'is' TEXT, -- Value entity is claimed to have
cause TEXT, -- Causal reference to prior fact
since INTEGER NOT NULL, -- Lamport clock since when this fact was in effect
FOREIGN KEY('is') REFERENCES datum(this)
);

Expand All @@ -74,22 +76,33 @@ CREATE TABLE IF NOT EXISTS memory (

CREATE INDEX IF NOT EXISTS memory_the ON memory (the); -- Index to filter by "the" field
CREATE INDEX IF NOT EXISTS memory_of ON memory (of); -- Index to query by "of" field
CREATE INDEX IF NOT EXISTS fact_since ON fact (since); -- Index to query by "since" field

-- Create the updated 'state' view
CREATE VIEW IF NOT EXISTS state AS
SELECT
memory.the as the,
memory.of as of,
maybe_datum.source as 'is',
fact.cause as cause,
memory.fact as fact,
maybe_datum.this as proof,
fact.since as since
memory.the AS the,
memory.of AS of,
datum.source AS 'is',
fact.cause AS cause,
memory.fact AS fact,
datum.this AS proof,
fact.since AS since
FROM
memory
-- We use inner join because we memory.fact can not be NULL and as foreign
-- key into fact.this which is also primary key. This guarantees that we will
-- not have any memory record with corresponding fact record
JOIN
fact ON memory.fact = fact.this
-- We use inner join here because fact.is || 'undefined' is guaranteed to have
-- corresponding record in datum through a foreign key constraint and inner
-- joins are generally more efficient that left joins.
-- ⚠️ Also note that we use COALESCE operator to use 'undefined' in case where
-- there fact.is NULL (retractions), which is important because SQLite never
-- matches over fact.is = NULL.
JOIN
maybe_datum ON fact.'is' = maybe_datum.this OR (fact.'is' IS NULL AND maybe_datum.this IS NULL);
datum ON datum.this = COALESCE(fact.'is', 'undefined');

COMMIT;
`;
Expand Down