- Embed migrations/001_initial.sql into the binary - Run migrations automatically when connecting to database - Uses CREATE TABLE IF NOT EXISTS for idempotent execution
161 lines
5.4 KiB
PL/PgSQL
161 lines
5.4 KiB
PL/PgSQL
-- Orchard Database Schema
|
|
-- Content-Addressable Storage System
|
|
|
|
-- Groves (Projects)
|
|
CREATE TABLE IF NOT EXISTS groves (
|
|
id UUID PRIMARY KEY,
|
|
name VARCHAR(255) UNIQUE NOT NULL,
|
|
description TEXT,
|
|
is_public BOOLEAN DEFAULT true,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
created_by VARCHAR(255) NOT NULL
|
|
);
|
|
|
|
CREATE INDEX idx_groves_name ON groves(name);
|
|
CREATE INDEX idx_groves_created_by ON groves(created_by);
|
|
|
|
-- Trees (Packages)
|
|
CREATE TABLE IF NOT EXISTS trees (
|
|
id UUID PRIMARY KEY,
|
|
grove_id UUID NOT NULL REFERENCES groves(id) ON DELETE CASCADE,
|
|
name VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
UNIQUE(grove_id, name)
|
|
);
|
|
|
|
CREATE INDEX idx_trees_grove_id ON trees(grove_id);
|
|
CREATE INDEX idx_trees_name ON trees(name);
|
|
|
|
-- Fruits (Content-Addressable Artifacts)
|
|
CREATE TABLE IF NOT EXISTS fruits (
|
|
id VARCHAR(64) PRIMARY KEY, -- SHA256 hash
|
|
size BIGINT NOT NULL,
|
|
content_type VARCHAR(255),
|
|
original_name VARCHAR(1024),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
created_by VARCHAR(255) NOT NULL,
|
|
ref_count INTEGER DEFAULT 1,
|
|
s3_key VARCHAR(1024) NOT NULL
|
|
);
|
|
|
|
CREATE INDEX idx_fruits_created_at ON fruits(created_at);
|
|
CREATE INDEX idx_fruits_created_by ON fruits(created_by);
|
|
|
|
-- Grafts (Aliases/Tags)
|
|
CREATE TABLE IF NOT EXISTS grafts (
|
|
id UUID PRIMARY KEY,
|
|
tree_id UUID NOT NULL REFERENCES trees(id) ON DELETE CASCADE,
|
|
name VARCHAR(255) NOT NULL,
|
|
fruit_id VARCHAR(64) NOT NULL REFERENCES fruits(id),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
created_by VARCHAR(255) NOT NULL,
|
|
UNIQUE(tree_id, name)
|
|
);
|
|
|
|
CREATE INDEX idx_grafts_tree_id ON grafts(tree_id);
|
|
CREATE INDEX idx_grafts_fruit_id ON grafts(fruit_id);
|
|
|
|
-- Graft History (for rollback capability)
|
|
CREATE TABLE IF NOT EXISTS graft_history (
|
|
id UUID PRIMARY KEY,
|
|
graft_id UUID NOT NULL REFERENCES grafts(id) ON DELETE CASCADE,
|
|
old_fruit_id VARCHAR(64) REFERENCES fruits(id),
|
|
new_fruit_id VARCHAR(64) NOT NULL REFERENCES fruits(id),
|
|
changed_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
changed_by VARCHAR(255) NOT NULL
|
|
);
|
|
|
|
CREATE INDEX idx_graft_history_graft_id ON graft_history(graft_id);
|
|
|
|
-- Harvests (Upload events)
|
|
CREATE TABLE IF NOT EXISTS harvests (
|
|
id UUID PRIMARY KEY,
|
|
fruit_id VARCHAR(64) NOT NULL REFERENCES fruits(id),
|
|
tree_id UUID NOT NULL REFERENCES trees(id),
|
|
original_name VARCHAR(1024),
|
|
harvested_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
harvested_by VARCHAR(255) NOT NULL,
|
|
source_ip VARCHAR(45)
|
|
);
|
|
|
|
CREATE INDEX idx_harvests_fruit_id ON harvests(fruit_id);
|
|
CREATE INDEX idx_harvests_tree_id ON harvests(tree_id);
|
|
CREATE INDEX idx_harvests_harvested_at ON harvests(harvested_at);
|
|
|
|
-- Consumers (Dependency tracking)
|
|
CREATE TABLE IF NOT EXISTS consumers (
|
|
id UUID PRIMARY KEY,
|
|
tree_id UUID NOT NULL REFERENCES trees(id) ON DELETE CASCADE,
|
|
project_url VARCHAR(2048) NOT NULL,
|
|
last_access TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
UNIQUE(tree_id, project_url)
|
|
);
|
|
|
|
CREATE INDEX idx_consumers_tree_id ON consumers(tree_id);
|
|
CREATE INDEX idx_consumers_last_access ON consumers(last_access);
|
|
|
|
-- Access Permissions
|
|
CREATE TABLE IF NOT EXISTS access_permissions (
|
|
id UUID PRIMARY KEY,
|
|
grove_id UUID NOT NULL REFERENCES groves(id) ON DELETE CASCADE,
|
|
user_id VARCHAR(255) NOT NULL,
|
|
level VARCHAR(20) NOT NULL CHECK (level IN ('read', 'write', 'admin')),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
expires_at TIMESTAMP WITH TIME ZONE,
|
|
UNIQUE(grove_id, user_id)
|
|
);
|
|
|
|
CREATE INDEX idx_access_permissions_grove_id ON access_permissions(grove_id);
|
|
CREATE INDEX idx_access_permissions_user_id ON access_permissions(user_id);
|
|
|
|
-- API Keys
|
|
CREATE TABLE IF NOT EXISTS api_keys (
|
|
id UUID PRIMARY KEY,
|
|
key_hash VARCHAR(64) NOT NULL UNIQUE,
|
|
name VARCHAR(255) NOT NULL,
|
|
user_id VARCHAR(255) NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
expires_at TIMESTAMP WITH TIME ZONE,
|
|
last_used TIMESTAMP WITH TIME ZONE
|
|
);
|
|
|
|
CREATE INDEX idx_api_keys_user_id ON api_keys(user_id);
|
|
CREATE INDEX idx_api_keys_key_hash ON api_keys(key_hash);
|
|
|
|
-- Audit Logs (Immutable)
|
|
CREATE TABLE IF NOT EXISTS audit_logs (
|
|
id UUID PRIMARY KEY,
|
|
action VARCHAR(100) NOT NULL,
|
|
resource VARCHAR(1024) NOT NULL,
|
|
user_id VARCHAR(255) NOT NULL,
|
|
details JSONB,
|
|
timestamp TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
source_ip VARCHAR(45)
|
|
);
|
|
|
|
CREATE INDEX idx_audit_logs_action ON audit_logs(action);
|
|
CREATE INDEX idx_audit_logs_resource ON audit_logs(resource);
|
|
CREATE INDEX idx_audit_logs_user_id ON audit_logs(user_id);
|
|
CREATE INDEX idx_audit_logs_timestamp ON audit_logs(timestamp);
|
|
|
|
-- Trigger to update graft history on changes
|
|
CREATE OR REPLACE FUNCTION track_graft_changes()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'UPDATE' AND OLD.fruit_id != NEW.fruit_id THEN
|
|
INSERT INTO graft_history (id, graft_id, old_fruit_id, new_fruit_id, changed_at, changed_by)
|
|
VALUES (gen_random_uuid(), NEW.id, OLD.fruit_id, NEW.fruit_id, NOW(), NEW.created_by);
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER graft_changes_trigger
|
|
AFTER UPDATE ON grafts
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION track_graft_changes();
|