db: Add pgsql schema

This commit is contained in:
Χγφτ Kompanion 2025-10-13 07:32:35 +13:00
parent 9c63b6c593
commit d121f2a76d
2 changed files with 101 additions and 34 deletions

5
db/db-init.sql Normal file
View File

@ -0,0 +1,5 @@
INSERT INTO komp.space(name, model, dim) VALUES
('dev_knowledge','mxbai-embed-large',1024),
('pattern_exchange','mxbai-embed-large',1024),
('runtime_memory','mxbai-embed-large',1024)
ON CONFLICT (name) DO NOTHING;

View File

@ -1,43 +1,105 @@
-- Kompanion knowledge store (sqlite)
PRAGMA journal_mode=WAL;
PRAGMA synchronous=NORMAL;
-- Requires: CREATE EXTENSION IF NOT EXISTS vector; CREATE EXTENSION IF NOT EXISTS ltree;
CREATE TABLE IF NOT EXISTS entries (
id INTEGER PRIMARY KEY,
ts TEXT NOT NULL,
aspect TEXT,
tags TEXT,
text TEXT NOT NULL
CREATE SCHEMA IF NOT EXISTS komp;
CREATE EXTENSION IF NOT EXISTS vector;
CREATE EXTENSION IF NOT EXISTS ltree;
CREATE TABLE IF NOT EXISTS komp.source (
id BIGSERIAL PRIMARY KEY,
kind TEXT NOT NULL, -- filesystem|repo|url|note
uri TEXT NOT NULL, -- path or URL
repo TEXT,
ref TEXT,
meta JSONB DEFAULT '{}'::jsonb,
created_at TIMESTAMPTZ DEFAULT now()
);
CREATE VIRTUAL TABLE IF NOT EXISTS entries_fts USING fts5(text, content="entries", content_rowid="id");
CREATE TRIGGER IF NOT EXISTS entries_ai AFTER INSERT ON entries BEGIN
INSERT INTO entries_fts(rowid, text) VALUES (new.id, new.text);
END;
CREATE TRIGGER IF NOT EXISTS entries_ad AFTER DELETE ON entries BEGIN
INSERT INTO entries_fts(entries_fts, rowid, text) VALUES(delete, old.id, old.text);
END;
CREATE TRIGGER IF NOT EXISTS entries_au AFTER UPDATE ON entries BEGIN
INSERT INTO entries_fts(entries_fts, rowid, text) VALUES(delete, old.id, old.text);
INSERT INTO entries_fts(rowid, text) VALUES (new.id, new.text);
END;
CREATE TABLE IF NOT EXISTS komp.chunk (
id BIGSERIAL PRIMARY KEY,
source_id BIGINT REFERENCES komp.source(id) ON DELETE CASCADE,
lineno INT,
text TEXT NOT NULL,
sha256 TEXT NOT NULL,
tokens INT,
created_at TIMESTAMPTZ DEFAULT now()
);
CREATE INDEX IF NOT EXISTS idx_chunk_source ON komp.chunk(source_id);
CREATE TABLE IF NOT EXISTS sources (
id INTEGER PRIMARY KEY,
file TEXT NOT NULL,
sha TEXT,
lineno INTEGER
-- A space is a distinct memory with its own model+dim & policy
CREATE TABLE IF NOT EXISTS komp.space (
id SERIAL PRIMARY KEY,
name TEXT UNIQUE, -- dev_knowledge | pattern_exchange | runtime_memory
model TEXT NOT NULL,
dim INT NOT NULL,
metric TEXT NOT NULL DEFAULT 'cosine'
);
CREATE TABLE IF NOT EXISTS vectors (
id INTEGER PRIMARY KEY,
entry_id INTEGER REFERENCES entries(id) ON DELETE CASCADE,
model TEXT NOT NULL,
dim INTEGER NOT NULL,
vec BLOB NOT NULL
-- Embedding tables per common dimension (add more as needed)
CREATE TABLE IF NOT EXISTS komp.embedding_768 (
id BIGSERIAL PRIMARY KEY,
chunk_id BIGINT REFERENCES komp.chunk(id) ON DELETE CASCADE,
space_id INT REFERENCES komp.space(id) ON DELETE CASCADE,
embedding VECTOR(768) NOT NULL,
created_at TIMESTAMPTZ DEFAULT now(),
UNIQUE(chunk_id, space_id)
);
CREATE INDEX IF NOT EXISTS idx_embed768_space ON komp.embedding_768(space_id);
CREATE INDEX IF NOT EXISTS ivf_embed768 ON komp.embedding_768 USING ivfflat (embedding vector_cosine_ops) WITH (lists=100);
CREATE TABLE IF NOT EXISTS komp.embedding_1024 (
id BIGSERIAL PRIMARY KEY,
chunk_id BIGINT REFERENCES komp.chunk(id) ON DELETE CASCADE,
space_id INT REFERENCES komp.space(id) ON DELETE CASCADE,
embedding VECTOR(1024) NOT NULL,
created_at TIMESTAMPTZ DEFAULT now(),
UNIQUE(chunk_id, space_id)
);
CREATE INDEX IF NOT EXISTS idx_embed1024_space ON komp.embedding_1024(space_id);
CREATE INDEX IF NOT EXISTS ivf_embed1024 ON komp.embedding_1024 USING ivfflat (embedding vector_cosine_ops) WITH (lists=100);
-- Branch hierarchy (Branch Embeddings): path encodes the cluster tree (e.g., physics.quantum.tunneling)
CREATE TABLE IF NOT EXISTS komp.branch (
id BIGSERIAL PRIMARY KEY,
space_id INT REFERENCES komp.space(id) ON DELETE CASCADE,
path LTREE NOT NULL,
label TEXT,
meta JSONB DEFAULT '{}'::jsonb,
UNIQUE(space_id, path)
);
CREATE INDEX IF NOT EXISTS gist_branch_path ON komp.branch USING GIST (path);
-- Centroids per dimension (store only the dim matching the space)
CREATE TABLE IF NOT EXISTS komp.branch_centroid_768 (
branch_id BIGINT PRIMARY KEY REFERENCES komp.branch(id) ON DELETE CASCADE,
embedding VECTOR(768) NOT NULL,
updated_at TIMESTAMPTZ DEFAULT now()
);
CREATE TABLE IF NOT EXISTS komp.branch_centroid_1024 (
branch_id BIGINT PRIMARY KEY REFERENCES komp.branch(id) ON DELETE CASCADE,
embedding VECTOR(1024) NOT NULL,
updated_at TIMESTAMPTZ DEFAULT now()
);
CREATE TABLE IF NOT EXISTS ledger_head (
id INTEGER PRIMARY KEY CHECK (id=1),
head_sha TEXT
-- Soft membership of chunks to branches
CREATE TABLE IF NOT EXISTS komp.chunk_branch (
chunk_id BIGINT REFERENCES komp.chunk(id) ON DELETE CASCADE,
branch_id BIGINT REFERENCES komp.branch(id) ON DELETE CASCADE,
weight REAL NOT NULL CHECK (weight >= 0 AND weight <= 1),
PRIMARY KEY(chunk_id, branch_id)
);
-- Relations between chunks (similarity / cites / derives / contradicts / …)
CREATE TABLE IF NOT EXISTS komp.chunk_edge (
src_chunk_id BIGINT REFERENCES komp.chunk(id) ON DELETE CASCADE,
dst_chunk_id BIGINT REFERENCES komp.chunk(id) ON DELETE CASCADE,
relation TEXT NOT NULL,
weight REAL,
meta JSONB DEFAULT '{}'::jsonb,
PRIMARY KEY(src_chunk_id, dst_chunk_id, relation)
);
CREATE OR REPLACE VIEW komp.latest_sources AS
SELECT s.*, max(c.created_at) AS last_chunk_at
FROM komp.source s LEFT JOIN komp.chunk c ON c.source_id = s.id
GROUP BY s.id;