71 lines
2.4 KiB
PL/PgSQL
71 lines
2.4 KiB
PL/PgSQL
CREATE TABLE IF NOT EXISTS users (
|
|
id SERIAL PRIMARY KEY,
|
|
username TEXT NOT NULL UNIQUE,
|
|
email TEXT NOT NULL UNIQUE,
|
|
api_key TEXT UNIQUE,
|
|
storage_limit_bytes BIGINT DEFAULT 1073741824,
|
|
created_at TIMESTAMPTZ DEFAULT NOW()
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS buckets (
|
|
id SERIAL PRIMARY KEY,
|
|
name TEXT NOT NULL UNIQUE,
|
|
owner_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
storage_used_bytes BIGINT DEFAULT 0,
|
|
created_at TIMESTAMPTZ DEFAULT NOW()
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS objects (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
bucket_id INT NOT NULL REFERENCES buckets(id) ON DELETE CASCADE,
|
|
key TEXT NOT NULL,
|
|
size_bytes BIGINT NOT NULL,
|
|
content_type TEXT,
|
|
last_modified TIMESTAMPTZ DEFAULT NOW(),
|
|
version_id TEXT UNIQUE,
|
|
md5_checksum TEXT,
|
|
custom_metadata JSONB DEFAULT '{}',
|
|
UNIQUE (bucket_id, key)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS bucket_policies (
|
|
id SERIAL PRIMARY KEY,
|
|
bucket_id INT NOT NULL REFERENCES buckets(id) ON DELETE CASCADE UNIQUE,
|
|
policy JSONB NOT NULL,
|
|
updated_at TIMESTAMPTZ DEFAULT NOW()
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_buckets_owner_id ON buckets (owner_id);
|
|
CREATE INDEX IF NOT EXISTS idx_users_api_key ON users (api_key);
|
|
CREATE INDEX IF NOT EXISTS idx_bucket_policies_bucket_id ON bucket_policies (bucket_id);
|
|
CREATE INDEX IF NOT EXISTS idx_objects_bucket_id_key ON objects (bucket_id, key);
|
|
CREATE INDEX IF NOT EXISTS idx_objects_bucket_id_last_modified ON objects (bucket_id, last_modified DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_objects_custom_metadata_gin ON objects USING GIN (custom_metadata);
|
|
|
|
CREATE OR REPLACE FUNCTION update_bucket_storage() RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'INSERT' THEN
|
|
UPDATE buckets
|
|
SET storage_used_bytes = storage_used_bytes + NEW.size_bytes
|
|
WHERE id = NEW.bucket_id;
|
|
RETURN NEW;
|
|
ELSIF TG_OP = 'DELETE' THEN
|
|
UPDATE buckets
|
|
SET storage_used_bytes = storage_used_bytes - OLD.size_bytes
|
|
WHERE id = OLD.bucket_id;
|
|
RETURN OLD;
|
|
ELSIF TG_OP = 'UPDATE' THEN
|
|
UPDATE buckets
|
|
SET storage_used_bytes = storage_used_bytes + NEW.size_bytes - OLD.size_bytes
|
|
WHERE id = NEW.bucket_id;
|
|
RETURN NEW;
|
|
END IF;
|
|
RETURN NULL;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE TRIGGER update_bucket_storage_trigger
|
|
AFTER INSERT OR UPDATE OR DELETE ON objects
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_bucket_storage();
|