- backend/app/main.py: grove/ -> project/ in SPA route check - frontend/vite.config.ts: /grove -> /project proxy - helm/orchard/templates/NOTES.txt: Updated API examples - migrations/001_initial.sql: Updated table/column names
161 lines
5.5 KiB
PL/PgSQL
161 lines
5.5 KiB
PL/PgSQL
-- Orchard Database Schema
|
|
-- Content-Addressable Storage System
|
|
|
|
-- Projects (top-level organizational containers)
|
|
CREATE TABLE IF NOT EXISTS projects (
|
|
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_projects_name ON projects(name);
|
|
CREATE INDEX idx_projects_created_by ON projects(created_by);
|
|
|
|
-- Packages (collections within projects)
|
|
CREATE TABLE IF NOT EXISTS packages (
|
|
id UUID PRIMARY KEY,
|
|
project_id UUID NOT NULL REFERENCES projects(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(project_id, name)
|
|
);
|
|
|
|
CREATE INDEX idx_packages_project_id ON packages(project_id);
|
|
CREATE INDEX idx_packages_name ON packages(name);
|
|
|
|
-- Artifacts (Content-Addressable)
|
|
CREATE TABLE IF NOT EXISTS artifacts (
|
|
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_artifacts_created_at ON artifacts(created_at);
|
|
CREATE INDEX idx_artifacts_created_by ON artifacts(created_by);
|
|
|
|
-- Tags (Aliases pointing to artifacts)
|
|
CREATE TABLE IF NOT EXISTS tags (
|
|
id UUID PRIMARY KEY,
|
|
package_id UUID NOT NULL REFERENCES packages(id) ON DELETE CASCADE,
|
|
name VARCHAR(255) NOT NULL,
|
|
artifact_id VARCHAR(64) NOT NULL REFERENCES artifacts(id),
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
created_by VARCHAR(255) NOT NULL,
|
|
UNIQUE(package_id, name)
|
|
);
|
|
|
|
CREATE INDEX idx_tags_package_id ON tags(package_id);
|
|
CREATE INDEX idx_tags_artifact_id ON tags(artifact_id);
|
|
|
|
-- Tag History (for rollback capability)
|
|
CREATE TABLE IF NOT EXISTS tag_history (
|
|
id UUID PRIMARY KEY,
|
|
tag_id UUID NOT NULL REFERENCES tags(id) ON DELETE CASCADE,
|
|
old_artifact_id VARCHAR(64) REFERENCES artifacts(id),
|
|
new_artifact_id VARCHAR(64) NOT NULL REFERENCES artifacts(id),
|
|
changed_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
changed_by VARCHAR(255) NOT NULL
|
|
);
|
|
|
|
CREATE INDEX idx_tag_history_tag_id ON tag_history(tag_id);
|
|
|
|
-- Uploads (upload event records)
|
|
CREATE TABLE IF NOT EXISTS uploads (
|
|
id UUID PRIMARY KEY,
|
|
artifact_id VARCHAR(64) NOT NULL REFERENCES artifacts(id),
|
|
package_id UUID NOT NULL REFERENCES packages(id),
|
|
original_name VARCHAR(1024),
|
|
uploaded_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
uploaded_by VARCHAR(255) NOT NULL,
|
|
source_ip VARCHAR(45)
|
|
);
|
|
|
|
CREATE INDEX idx_uploads_artifact_id ON uploads(artifact_id);
|
|
CREATE INDEX idx_uploads_package_id ON uploads(package_id);
|
|
CREATE INDEX idx_uploads_uploaded_at ON uploads(uploaded_at);
|
|
|
|
-- Consumers (Dependency tracking)
|
|
CREATE TABLE IF NOT EXISTS consumers (
|
|
id UUID PRIMARY KEY,
|
|
package_id UUID NOT NULL REFERENCES packages(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(package_id, project_url)
|
|
);
|
|
|
|
CREATE INDEX idx_consumers_package_id ON consumers(package_id);
|
|
CREATE INDEX idx_consumers_last_access ON consumers(last_access);
|
|
|
|
-- Access Permissions
|
|
CREATE TABLE IF NOT EXISTS access_permissions (
|
|
id UUID PRIMARY KEY,
|
|
project_id UUID NOT NULL REFERENCES projects(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(project_id, user_id)
|
|
);
|
|
|
|
CREATE INDEX idx_access_permissions_project_id ON access_permissions(project_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 tag history on changes
|
|
CREATE OR REPLACE FUNCTION track_tag_changes()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'UPDATE' AND OLD.artifact_id != NEW.artifact_id THEN
|
|
INSERT INTO tag_history (id, tag_id, old_artifact_id, new_artifact_id, changed_at, changed_by)
|
|
VALUES (gen_random_uuid(), NEW.id, OLD.artifact_id, NEW.artifact_id, NOW(), NEW.created_by);
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER tag_changes_trigger
|
|
AFTER UPDATE ON tags
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION track_tag_changes();
|