rspace-online/modules/vote/db/schema.sql

83 lines
2.9 KiB
SQL

-- rVote module schema
CREATE SCHEMA IF NOT EXISTS rvote;
-- Users (lightweight, DID-based)
CREATE TABLE IF NOT EXISTS rvote.users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
did TEXT UNIQUE NOT NULL,
username TEXT,
created_at TIMESTAMPTZ DEFAULT NOW()
);
-- Voting spaces
CREATE TABLE IF NOT EXISTS rvote.spaces (
slug TEXT PRIMARY KEY,
name TEXT NOT NULL,
description TEXT,
owner_did TEXT NOT NULL,
visibility TEXT DEFAULT 'public_read' CHECK (visibility IN ('public','public_read','authenticated','members_only')),
promotion_threshold INTEGER DEFAULT 100,
voting_period_days INTEGER DEFAULT 7,
credits_per_day INTEGER DEFAULT 10,
max_credits INTEGER DEFAULT 500,
starting_credits INTEGER DEFAULT 50,
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW()
);
-- Space membership
CREATE TABLE IF NOT EXISTS rvote.space_members (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES rvote.users(id) ON DELETE CASCADE,
space_slug TEXT NOT NULL REFERENCES rvote.spaces(slug) ON DELETE CASCADE,
role TEXT DEFAULT 'MEMBER' CHECK (role IN ('ADMIN','MEMBER')),
credits INTEGER DEFAULT 50,
last_credit_at TIMESTAMPTZ DEFAULT NOW(),
joined_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(user_id, space_slug)
);
-- Proposals
CREATE TABLE IF NOT EXISTS rvote.proposals (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
space_slug TEXT NOT NULL REFERENCES rvote.spaces(slug) ON DELETE CASCADE,
author_id UUID NOT NULL REFERENCES rvote.users(id),
title TEXT NOT NULL,
description TEXT,
status TEXT DEFAULT 'RANKING' CHECK (status IN ('RANKING','VOTING','PASSED','FAILED','ARCHIVED')),
score REAL DEFAULT 0,
voting_ends_at TIMESTAMPTZ,
final_yes INTEGER DEFAULT 0,
final_no INTEGER DEFAULT 0,
final_abstain INTEGER DEFAULT 0,
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW()
);
-- Conviction votes (ranking phase)
CREATE TABLE IF NOT EXISTS rvote.votes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES rvote.users(id) ON DELETE CASCADE,
proposal_id UUID NOT NULL REFERENCES rvote.proposals(id) ON DELETE CASCADE,
weight INTEGER NOT NULL DEFAULT 1,
credit_cost INTEGER NOT NULL DEFAULT 1,
created_at TIMESTAMPTZ DEFAULT NOW(),
decays_at TIMESTAMPTZ,
UNIQUE(user_id, proposal_id)
);
-- Final votes (binary phase)
CREATE TABLE IF NOT EXISTS rvote.final_votes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES rvote.users(id) ON DELETE CASCADE,
proposal_id UUID NOT NULL REFERENCES rvote.proposals(id) ON DELETE CASCADE,
vote TEXT NOT NULL CHECK (vote IN ('YES','NO','ABSTAIN')),
created_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(user_id, proposal_id)
);
-- Indexes
CREATE INDEX IF NOT EXISTS idx_proposals_space ON rvote.proposals(space_slug, status);
CREATE INDEX IF NOT EXISTS idx_votes_proposal ON rvote.votes(proposal_id);
CREATE INDEX IF NOT EXISTS idx_members_space ON rvote.space_members(space_slug);