CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS pgcrypto; CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email TEXT NOT NULL UNIQUE, display_name TEXT NOT NULL, password_hash TEXT NOT NULL, role TEXT NOT NULL DEFAULT 'user' CHECK (role IN ('user','admin')), created_at TIMESTAMPTZ NOT NULL DEFAULT now() ); CREATE TABLE products ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL, price_cents INT NOT NULL CHECK (price_cents >= 0), active BOOLEAN NOT NULL DEFAULT TRUE, created_at TIMESTAMPTZ NOT NULL DEFAULT now() ); CREATE TABLE ledger ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id), amount_cents INT NOT NULL, kind TEXT NOT NULL CHECK (kind IN ('topup','purchase','adjustment')), ref_id UUID, created_at TIMESTAMPTZ NOT NULL DEFAULT now() ); CREATE TABLE orders ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id), total_cents INT NOT NULL CHECK (total_cents >= 0), created_at TIMESTAMPTZ NOT NULL DEFAULT now() ); CREATE TABLE order_items ( order_id UUID NOT NULL REFERENCES orders(id) ON DELETE CASCADE, product_id UUID NOT NULL REFERENCES products(id), qty INT NOT NULL CHECK (qty > 0), price_cents INT NOT NULL CHECK (price_cents >= 0), PRIMARY KEY (order_id, product_id) ); CREATE TABLE inventory_movements ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), product_id UUID NOT NULL REFERENCES products(id), qty INT NOT NULL, reason TEXT NOT NULL CHECK (reason IN ('purchase','consumption','correction')), note TEXT, created_by UUID REFERENCES users(id), created_at TIMESTAMPTZ NOT NULL DEFAULT now() ); CREATE VIEW user_balances AS SELECT user_id, COALESCE(SUM(amount_cents),0) AS balance_cents FROM ledger GROUP BY user_id; CREATE VIEW product_stock AS SELECT p.id AS product_id, COALESCE(SUM(m.qty),0) AS stock FROM products p LEFT JOIN inventory_movements m ON m.product_id = p.id GROUP BY p.id;