-- Likwid Initial Schema -- Modular Governance Platform -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Users table (civic identity) CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), username VARCHAR(50) UNIQUE NOT NULL, email VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, display_name VARCHAR(100), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), is_active BOOLEAN NOT NULL DEFAULT TRUE ); -- Communities (supports multi-community mode) CREATE TABLE communities ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(100) UNIQUE NOT NULL, slug VARCHAR(100) UNIQUE NOT NULL, description TEXT, settings JSONB NOT NULL DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), is_active BOOLEAN NOT NULL DEFAULT TRUE ); -- Community membership CREATE TABLE community_members ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, role VARCHAR(50) NOT NULL DEFAULT 'member', joined_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(user_id, community_id) ); -- Voting identities (separate from civic identity for anonymity) CREATE TABLE voting_identities ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, pseudonym VARCHAR(100) NOT NULL, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(user_id, community_id), UNIQUE(pseudonym, community_id) ); -- Plugins registry CREATE TABLE plugins ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(100) UNIQUE NOT NULL, version VARCHAR(20) NOT NULL, description TEXT, is_core BOOLEAN NOT NULL DEFAULT FALSE, is_active BOOLEAN NOT NULL DEFAULT TRUE, settings_schema JSONB, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Plugin activation per community CREATE TABLE community_plugins ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, plugin_id UUID NOT NULL REFERENCES plugins(id) ON DELETE CASCADE, settings JSONB NOT NULL DEFAULT '{}', is_active BOOLEAN NOT NULL DEFAULT TRUE, activated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(community_id, plugin_id) ); -- Moderation log (immutable, non-deactivatable per spec) CREATE TABLE moderation_log ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), community_id UUID NOT NULL REFERENCES communities(id) ON DELETE CASCADE, moderator_id UUID REFERENCES users(id), target_user_id UUID REFERENCES users(id), action_type VARCHAR(50) NOT NULL, reason TEXT NOT NULL, details JSONB, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); -- Create indexes CREATE INDEX idx_community_members_user ON community_members(user_id); CREATE INDEX idx_community_members_community ON community_members(community_id); CREATE INDEX idx_voting_identities_user ON voting_identities(user_id); CREATE INDEX idx_moderation_log_community ON moderation_log(community_id); CREATE INDEX idx_moderation_log_created ON moderation_log(created_at); -- Updated_at trigger function CREATE OR REPLACE FUNCTION update_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Apply trigger to tables with updated_at CREATE TRIGGER users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at(); CREATE TRIGGER communities_updated_at BEFORE UPDATE ON communities FOR EACH ROW EXECUTE FUNCTION update_updated_at();