-- ============================================================================ -- User FCM Tokens for Push Notifications -- ============================================================================ CREATE TABLE IF NOT EXISTS user_fcm_tokens ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES profiles(id) ON DELETE CASCADE, token TEXT NOT NULL UNIQUE, device_type TEXT NOT NULL, last_updated TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_user_fcm_tokens_user_id ON user_fcm_tokens(user_id); ALTER TABLE user_fcm_tokens ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS user_fcm_tokens_select ON user_fcm_tokens; CREATE POLICY user_fcm_tokens_select ON user_fcm_tokens FOR SELECT USING (auth.uid() = user_id); DROP POLICY IF EXISTS user_fcm_tokens_insert ON user_fcm_tokens; CREATE POLICY user_fcm_tokens_insert ON user_fcm_tokens FOR INSERT WITH CHECK (auth.uid() = user_id); DROP POLICY IF EXISTS user_fcm_tokens_update ON user_fcm_tokens; CREATE POLICY user_fcm_tokens_update ON user_fcm_tokens FOR UPDATE USING (auth.uid() = user_id); DROP POLICY IF EXISTS user_fcm_tokens_delete ON user_fcm_tokens; CREATE POLICY user_fcm_tokens_delete ON user_fcm_tokens FOR DELETE USING (auth.uid() = user_id); CREATE OR REPLACE FUNCTION set_user_fcm_tokens_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.last_updated = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; DROP TRIGGER IF EXISTS trg_user_fcm_tokens_updated_at ON user_fcm_tokens; CREATE TRIGGER trg_user_fcm_tokens_updated_at BEFORE UPDATE ON user_fcm_tokens FOR EACH ROW EXECUTE FUNCTION set_user_fcm_tokens_updated_at(); -- Function to clean up stale FCM tokens (not updated in 30 days) CREATE OR REPLACE FUNCTION cleanup_stale_fcm_tokens() RETURNS INTEGER LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE deleted_count INTEGER; BEGIN DELETE FROM user_fcm_tokens WHERE last_updated < NOW() - INTERVAL '30 days'; GET DIAGNOSTICS deleted_count = ROW_COUNT; RETURN deleted_count; END; $$;