73 lines
3.2 KiB
PL/PgSQL
73 lines
3.2 KiB
PL/PgSQL
-- 000010_notification_preferences.up.sql
|
|
-- User notification preferences for granular control
|
|
|
|
CREATE TABLE IF NOT EXISTS notification_preferences (
|
|
user_id UUID PRIMARY KEY REFERENCES profiles(id) ON DELETE CASCADE,
|
|
|
|
-- Push notification toggles
|
|
push_enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_likes BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_comments BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_replies BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_mentions BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_follows BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_follow_requests BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_messages BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_saves BOOLEAN NOT NULL DEFAULT TRUE,
|
|
push_beacons BOOLEAN NOT NULL DEFAULT TRUE,
|
|
|
|
-- Email notification toggles (for future use)
|
|
email_enabled BOOLEAN NOT NULL DEFAULT FALSE,
|
|
email_digest_frequency TEXT NOT NULL DEFAULT 'never', -- 'never', 'daily', 'weekly'
|
|
|
|
-- Quiet hours (UTC)
|
|
quiet_hours_enabled BOOLEAN NOT NULL DEFAULT FALSE,
|
|
quiet_hours_start TIME, -- e.g., '22:00:00'
|
|
quiet_hours_end TIME, -- e.g., '08:00:00'
|
|
|
|
-- Badge settings
|
|
show_badge_count BOOLEAN NOT NULL DEFAULT TRUE,
|
|
|
|
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Add unread count cache to profiles for badge display
|
|
ALTER TABLE profiles ADD COLUMN IF NOT EXISTS unread_notification_count INTEGER NOT NULL DEFAULT 0;
|
|
|
|
-- Add group_key for notification batching/grouping
|
|
ALTER TABLE notifications ADD COLUMN IF NOT EXISTS group_key TEXT;
|
|
ALTER TABLE notifications ADD COLUMN IF NOT EXISTS priority TEXT NOT NULL DEFAULT 'normal'; -- 'low', 'normal', 'high', 'urgent'
|
|
|
|
-- Create indexes for efficient querying
|
|
CREATE INDEX IF NOT EXISTS idx_notifications_user_unread ON notifications(user_id, is_read) WHERE is_read = FALSE;
|
|
CREATE INDEX IF NOT EXISTS idx_notifications_group_key ON notifications(group_key) WHERE group_key IS NOT NULL;
|
|
CREATE INDEX IF NOT EXISTS idx_fcm_tokens_user ON user_fcm_tokens(user_id);
|
|
|
|
-- Function to update unread count on notification insert
|
|
CREATE OR REPLACE FUNCTION update_unread_notification_count()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
IF TG_OP = 'INSERT' THEN
|
|
UPDATE profiles SET unread_notification_count = unread_notification_count + 1 WHERE id = NEW.user_id;
|
|
ELSIF TG_OP = 'UPDATE' AND OLD.is_read = FALSE AND NEW.is_read = TRUE THEN
|
|
UPDATE profiles SET unread_notification_count = GREATEST(0, unread_notification_count - 1) WHERE id = NEW.user_id;
|
|
ELSIF TG_OP = 'DELETE' AND OLD.is_read = FALSE THEN
|
|
UPDATE profiles SET unread_notification_count = GREATEST(0, unread_notification_count - 1) WHERE id = OLD.user_id;
|
|
END IF;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Create trigger for automatic badge count updates
|
|
DROP TRIGGER IF EXISTS notification_count_trigger ON notifications;
|
|
CREATE TRIGGER notification_count_trigger
|
|
AFTER INSERT OR UPDATE OR DELETE ON notifications
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_unread_notification_count();
|
|
|
|
-- Initialize notification preferences for existing users
|
|
INSERT INTO notification_preferences (user_id)
|
|
SELECT id FROM profiles
|
|
ON CONFLICT (user_id) DO NOTHING;
|