metal-kompanion/sql/pg/001_init.sql

87 lines
3.3 KiB
PL/PgSQL

-- Enable pgvector (requires extension installed)
CREATE EXTENSION IF NOT EXISTS vector;
-- Namespaces: unique logical scope (e.g., 'project:metal', 'thread:abc')
CREATE TABLE IF NOT EXISTS namespaces (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name TEXT NOT NULL UNIQUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
-- Users (optional link)
CREATE TABLE IF NOT EXISTS users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
external_id TEXT UNIQUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
-- Threads (within a namespace)
CREATE TABLE IF NOT EXISTS threads (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
namespace_id UUID NOT NULL REFERENCES namespaces(id) ON DELETE CASCADE,
external_id TEXT,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE INDEX IF NOT EXISTS threads_ns_idx ON threads(namespace_id);
-- Memory items: logical notes/contexts (JSONB content + normalized text)
CREATE TABLE IF NOT EXISTS memory_items (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
namespace_id UUID NOT NULL REFERENCES namespaces(id) ON DELETE CASCADE,
thread_id UUID REFERENCES threads(id) ON DELETE SET NULL,
user_id UUID REFERENCES users(id) ON DELETE SET NULL,
key TEXT,
content JSONB NOT NULL,
text TEXT,
tags TEXT[] DEFAULT '{}',
metadata JSONB DEFAULT '{}'::jsonb,
revision INTEGER NOT NULL DEFAULT 1,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT now(),
expires_at TIMESTAMPTZ,
deleted_at TIMESTAMPTZ
);
CREATE INDEX IF NOT EXISTS mem_items_ns_idx ON memory_items(namespace_id, thread_id, created_at DESC);
CREATE INDEX IF NOT EXISTS mem_items_tags_gin ON memory_items USING GIN(tags);
CREATE INDEX IF NOT EXISTS mem_items_meta_gin ON memory_items USING GIN(metadata);
-- Chunks: embedding units derived from items
CREATE TABLE IF NOT EXISTS memory_chunks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
item_id UUID NOT NULL REFERENCES memory_items(id) ON DELETE CASCADE,
ord INTEGER NOT NULL,
text TEXT NOT NULL,
metadata JSONB DEFAULT '{}'::jsonb,
created_at TIMESTAMPTZ NOT NULL DEFAULT now()
);
CREATE INDEX IF NOT EXISTS chunks_item_idx ON memory_chunks(item_id, ord);
-- Embeddings: one per chunk (per model)
CREATE TABLE IF NOT EXISTS embeddings (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
chunk_id UUID NOT NULL REFERENCES memory_chunks(id) ON DELETE CASCADE,
model TEXT NOT NULL,
dim INTEGER NOT NULL,
vector VECTOR(1536) NOT NULL, -- adjust dim per model
normalized BOOLEAN DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
UNIQUE(chunk_id, model)
);
CREATE INDEX IF NOT EXISTS embeddings_model_dim ON embeddings(model, dim);
-- For ivfflat you must first create a HNSW/IVFFLAT index; pgvector uses different syntax depending on version
CREATE INDEX IF NOT EXISTS embeddings_vector_ivfflat ON embeddings USING ivfflat (vector) WITH (lists = 100);
-- Helper upsert function for memory_items revision bump
CREATE OR REPLACE FUNCTION bump_revision() RETURNS trigger AS $$
BEGIN
NEW.revision := COALESCE(OLD.revision, 0) + 1;
NEW.updated_at := now();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS trg_bump_revision ON memory_items;
CREATE TRIGGER trg_bump_revision
BEFORE UPDATE ON memory_items
FOR EACH ROW EXECUTE FUNCTION bump_revision();