-- User Notification Preferences -- Allows members to control what email notifications they receive -- Create user notification preferences table CREATE TABLE IF NOT EXISTS user_notification_preferences ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), member_id UUID NOT NULL REFERENCES members(id) ON DELETE CASCADE UNIQUE, -- Event notifications email_event_rsvp_confirmation BOOLEAN DEFAULT true, email_event_reminder BOOLEAN DEFAULT true, email_event_updates BOOLEAN DEFAULT true, email_waitlist_promotion BOOLEAN DEFAULT true, -- Membership notifications email_dues_reminder BOOLEAN DEFAULT true, email_payment_confirmation BOOLEAN DEFAULT true, email_membership_updates BOOLEAN DEFAULT true, -- General notifications email_announcements BOOLEAN DEFAULT true, email_newsletter BOOLEAN DEFAULT true, -- Newsletter frequency (if subscribed) newsletter_frequency TEXT DEFAULT 'monthly' CHECK (newsletter_frequency IN ('weekly', 'monthly', 'quarterly', 'never')), -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); -- Create indexes CREATE INDEX IF NOT EXISTS idx_notification_prefs_member ON user_notification_preferences(member_id); -- Enable RLS ALTER TABLE user_notification_preferences ENABLE ROW LEVEL SECURITY; -- RLS Policies -- Members can view their own preferences CREATE POLICY "Members can view own notification preferences" ON user_notification_preferences FOR SELECT USING (member_id = auth.uid()); -- Members can insert their own preferences CREATE POLICY "Members can insert own notification preferences" ON user_notification_preferences FOR INSERT WITH CHECK (member_id = auth.uid()); -- Members can update their own preferences CREATE POLICY "Members can update own notification preferences" ON user_notification_preferences FOR UPDATE USING (member_id = auth.uid()) WITH CHECK (member_id = auth.uid()); -- Admins can view all preferences (for admin reports) CREATE POLICY "Admins can view all notification preferences" ON user_notification_preferences FOR SELECT USING ( EXISTS ( SELECT 1 FROM members WHERE members.id = auth.uid() AND members.role = 'admin' ) ); -- Function to create default preferences for new members CREATE OR REPLACE FUNCTION create_default_notification_preferences() RETURNS TRIGGER AS $$ BEGIN INSERT INTO user_notification_preferences (member_id) VALUES (NEW.id) ON CONFLICT (member_id) DO NOTHING; RETURN NEW; END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- Trigger to create preferences when a new member is created DROP TRIGGER IF EXISTS on_member_created_create_notification_prefs ON members; CREATE TRIGGER on_member_created_create_notification_prefs AFTER INSERT ON members FOR EACH ROW EXECUTE FUNCTION create_default_notification_preferences(); -- Create default preferences for existing members INSERT INTO user_notification_preferences (member_id) SELECT id FROM members ON CONFLICT (member_id) DO NOTHING; -- Add updated_at trigger CREATE OR REPLACE FUNCTION update_notification_prefs_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; DROP TRIGGER IF EXISTS set_notification_prefs_updated_at ON user_notification_preferences; CREATE TRIGGER set_notification_prefs_updated_at BEFORE UPDATE ON user_notification_preferences FOR EACH ROW EXECUTE FUNCTION update_notification_prefs_updated_at();