CREATE TABLE IF NOT EXISTS accounts ( id SERIAL PRIMARY KEY, account_number TEXT NOT NULL UNIQUE, access_token TEXT UNIQUE, balance_usd DECIMAL(10,2) DEFAULT 0.00, is_active BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT NOW(), activated_at TIMESTAMPTZ, last_billing_date TIMESTAMPTZ DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS payments ( id SERIAL PRIMARY KEY, account_id INT NOT NULL REFERENCES accounts(id) ON DELETE CASCADE, payment_type VARCHAR(20) NOT NULL DEFAULT 'bitcoin', btc_address TEXT, btc_amount DECIMAL(18,8), usd_amount DECIMAL(10,2), confirmations INT DEFAULT 0, tx_hash TEXT, status VARCHAR(20) DEFAULT 'pending', expires_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT NOW(), confirmed_at TIMESTAMPTZ ); CREATE TABLE IF NOT EXISTS crypto_rates ( id SERIAL PRIMARY KEY, currency VARCHAR(10) NOT NULL UNIQUE, usd_rate DECIMAL(18,8) NOT NULL, updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE TABLE IF NOT EXISTS usage_records ( id SERIAL PRIMARY KEY, account_id INT NOT NULL REFERENCES accounts(id) ON DELETE CASCADE, billing_period_start DATE NOT NULL, billing_period_end DATE NOT NULL, max_storage_bytes BIGINT DEFAULT 0, charge_usd DECIMAL(10,2) DEFAULT 0.00, charged_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(account_id, billing_period_start) ); CREATE TABLE IF NOT EXISTS buckets ( id SERIAL PRIMARY KEY, name TEXT NOT NULL UNIQUE, owner_id INT NOT NULL REFERENCES accounts(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_accounts_account_number ON accounts (account_number); CREATE INDEX IF NOT EXISTS idx_accounts_access_token ON accounts (access_token); CREATE INDEX IF NOT EXISTS idx_payments_account_id ON payments (account_id); CREATE INDEX IF NOT EXISTS idx_usage_records_account_id ON usage_records (account_id); CREATE INDEX IF NOT EXISTS idx_buckets_owner_id ON buckets (owner_id); 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();