-- Invitation system for invite-only registration -- Supports both platform-level and community-level invitations CREATE TABLE invitations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Invitation code (unique, URL-safe) code VARCHAR(64) UNIQUE NOT NULL, -- Who created this invitation created_by UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, -- Optional: specific email this invite is for email VARCHAR(255), -- Optional: community-specific invite community_id UUID REFERENCES communities(id) ON DELETE CASCADE, -- Invitation metadata max_uses INTEGER DEFAULT 1, uses_count INTEGER DEFAULT 0, -- Expiration expires_at TIMESTAMPTZ, -- Status is_active BOOLEAN DEFAULT TRUE, -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), -- Constraint: can't exceed max uses CONSTRAINT valid_uses CHECK (uses_count <= max_uses OR max_uses IS NULL) ); -- Track invitation usage CREATE TABLE invitation_uses ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), invitation_id UUID NOT NULL REFERENCES invitations(id) ON DELETE CASCADE, user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, used_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(invitation_id, user_id) ); -- Add invitation reference to users table ALTER TABLE users ADD COLUMN IF NOT EXISTS invited_by UUID REFERENCES invitations(id); -- Indexes CREATE INDEX idx_invitations_code ON invitations(code); CREATE INDEX idx_invitations_created_by ON invitations(created_by); CREATE INDEX idx_invitations_community ON invitations(community_id); CREATE INDEX idx_invitations_email ON invitations(email); CREATE INDEX idx_invitations_active ON invitations(is_active) WHERE is_active = TRUE; -- Function to generate secure invitation code CREATE OR REPLACE FUNCTION generate_invitation_code() RETURNS VARCHAR(64) AS $$ DECLARE chars TEXT := 'ABCDEFGHJKLMNPQRSTUVWXYZabcdefghjkmnpqrstuvwxyz23456789'; result VARCHAR(64) := ''; i INTEGER; BEGIN FOR i IN 1..16 LOOP result := result || substr(chars, floor(random() * length(chars) + 1)::integer, 1); END LOOP; RETURN result; END; $$ LANGUAGE plpgsql; -- Function to validate and use an invitation CREATE OR REPLACE FUNCTION use_invitation( p_code VARCHAR(64), p_user_id UUID, p_email VARCHAR(255) DEFAULT NULL ) RETURNS TABLE( success BOOLEAN, invitation_id UUID, community_id UUID, error_message TEXT ) AS $$ DECLARE v_invite invitations%ROWTYPE; BEGIN -- Find the invitation SELECT * INTO v_invite FROM invitations WHERE code = p_code AND is_active = TRUE FOR UPDATE; IF NOT FOUND THEN RETURN QUERY SELECT FALSE, NULL::UUID, NULL::UUID, 'Invalid invitation code'::TEXT; RETURN; END IF; -- Check expiration IF v_invite.expires_at IS NOT NULL AND v_invite.expires_at < NOW() THEN UPDATE invitations SET is_active = FALSE WHERE id = v_invite.id; RETURN QUERY SELECT FALSE, NULL::UUID, NULL::UUID, 'Invitation has expired'::TEXT; RETURN; END IF; -- Check max uses IF v_invite.max_uses IS NOT NULL AND v_invite.uses_count >= v_invite.max_uses THEN UPDATE invitations SET is_active = FALSE WHERE id = v_invite.id; RETURN QUERY SELECT FALSE, NULL::UUID, NULL::UUID, 'Invitation has reached maximum uses'::TEXT; RETURN; END IF; -- Check email restriction IF v_invite.email IS NOT NULL AND v_invite.email != p_email THEN RETURN QUERY SELECT FALSE, NULL::UUID, NULL::UUID, 'This invitation is for a specific email address'::TEXT; RETURN; END IF; -- Record the use INSERT INTO invitation_uses (invitation_id, user_id) VALUES (v_invite.id, p_user_id); -- Increment uses count UPDATE invitations SET uses_count = uses_count + 1, is_active = CASE WHEN max_uses IS NOT NULL AND uses_count + 1 >= max_uses THEN FALSE ELSE is_active END WHERE id = v_invite.id; -- Update user's invited_by UPDATE users SET invited_by = v_invite.id WHERE id = p_user_id; RETURN QUERY SELECT TRUE, v_invite.id, v_invite.community_id, NULL::TEXT; END; $$ LANGUAGE plpgsql;