riseup-squad18/supabase/APPLY_MIGRATION.sql
2025-12-06 19:13:27 -03:00

338 lines
12 KiB
PL/PgSQL

-- ============================================
-- SCRIPT RÁPIDO PARA SUPABASE DASHBOARD
-- ============================================
-- Execute este SQL no SQL Editor do Supabase Dashboard
-- URL: https://yuanqfswhberkoevtmfr.supabase.co
-- Dashboard > SQL Editor > New Query > Cole este código > Run
-- ============================================
-- 1. CRIAR TABELAS
-- ============================================
-- Conversas entre médicos e pacientes
CREATE TABLE IF NOT EXISTS conversations (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
doctor_id UUID NOT NULL REFERENCES doctors(id) ON DELETE CASCADE,
patient_id UUID NOT NULL REFERENCES patients(id) ON DELETE CASCADE,
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(doctor_id, patient_id)
);
CREATE INDEX IF NOT EXISTS idx_conversations_doctor ON conversations(doctor_id);
CREATE INDEX IF NOT EXISTS idx_conversations_patient ON conversations(patient_id);
-- Mensagens
CREATE TABLE IF NOT EXISTS messages (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
conversation_id UUID NOT NULL REFERENCES conversations(id) ON DELETE CASCADE,
sender_id UUID NOT NULL,
sender_type VARCHAR(10) NOT NULL CHECK (sender_type IN ('doctor', 'patient')),
content TEXT,
message_type VARCHAR(20) NOT NULL DEFAULT 'text' CHECK (message_type IN ('text', 'file', 'image', 'video', 'audio', 'report', 'appointment')),
read_at TIMESTAMPTZ,
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW(),
attachment_name VARCHAR(255),
attachment_url TEXT,
attachment_type VARCHAR(100),
attachment_size INTEGER,
metadata JSONB DEFAULT '{}'::jsonb
);
CREATE INDEX IF NOT EXISTS idx_messages_conversation ON messages(conversation_id);
CREATE INDEX IF NOT EXISTS idx_messages_sender ON messages(sender_id);
CREATE INDEX IF NOT EXISTS idx_messages_created_at ON messages(created_at DESC);
CREATE INDEX IF NOT EXISTS idx_messages_read_at ON messages(read_at);
-- Status online/offline
CREATE TABLE IF NOT EXISTS user_presence (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL,
user_type VARCHAR(10) NOT NULL CHECK (user_type IN ('doctor', 'patient', 'admin', 'secretaria')),
online BOOLEAN DEFAULT false,
last_seen TIMESTAMPTZ DEFAULT NOW(),
metadata JSONB DEFAULT '{}'::jsonb,
UNIQUE(user_id, user_type)
);
CREATE INDEX IF NOT EXISTS idx_user_presence_user ON user_presence(user_id, user_type);
CREATE INDEX IF NOT EXISTS idx_user_presence_online ON user_presence(online);
-- Anexos
CREATE TABLE IF NOT EXISTS message_attachments (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
message_id UUID NOT NULL REFERENCES messages(id) ON DELETE CASCADE,
file_name VARCHAR(255) NOT NULL,
file_url TEXT NOT NULL,
file_type VARCHAR(100) NOT NULL,
file_size INTEGER NOT NULL,
mime_type VARCHAR(100),
thumbnail_url TEXT,
uploaded_by UUID NOT NULL,
created_at TIMESTAMPTZ DEFAULT NOW(),
metadata JSONB DEFAULT '{}'::jsonb
);
CREATE INDEX IF NOT EXISTS idx_attachments_message ON message_attachments(message_id);
CREATE INDEX IF NOT EXISTS idx_attachments_uploader ON message_attachments(uploaded_by);
-- Notificações
CREATE TABLE IF NOT EXISTS message_notifications (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL,
user_type VARCHAR(10) NOT NULL,
message_id UUID NOT NULL REFERENCES messages(id) ON DELETE CASCADE,
read BOOLEAN DEFAULT false,
sent_at TIMESTAMPTZ DEFAULT NOW(),
read_at TIMESTAMPTZ
);
CREATE INDEX IF NOT EXISTS idx_notifications_user ON message_notifications(user_id, user_type);
CREATE INDEX IF NOT EXISTS idx_notifications_read ON message_notifications(read);
-- ============================================
-- 2. CRIAR TRIGGERS
-- ============================================
CREATE OR REPLACE FUNCTION update_conversation_timestamp()
RETURNS TRIGGER AS $$
BEGIN
UPDATE conversations
SET updated_at = NOW()
WHERE id = NEW.conversation_id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS update_conversation_on_message ON messages;
CREATE TRIGGER update_conversation_on_message
AFTER INSERT ON messages
FOR EACH ROW
EXECUTE FUNCTION update_conversation_timestamp();
CREATE OR REPLACE FUNCTION update_last_seen()
RETURNS TRIGGER AS $$
BEGIN
NEW.last_seen = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS update_user_presence_last_seen ON user_presence;
CREATE TRIGGER update_user_presence_last_seen
BEFORE UPDATE ON user_presence
FOR EACH ROW
EXECUTE FUNCTION update_last_seen();
-- ============================================
-- 3. CRIAR FUNÇÕES
-- ============================================
CREATE OR REPLACE FUNCTION get_user_conversations(
p_user_id UUID,
p_user_type VARCHAR
)
RETURNS TABLE (
conversation_id UUID,
other_user_id UUID,
other_user_name TEXT,
other_user_specialty TEXT,
other_user_avatar TEXT,
last_message TEXT,
last_message_time TIMESTAMPTZ,
unread_count BIGINT,
is_online BOOLEAN
) AS $$
BEGIN
IF p_user_type = 'patient' THEN
RETURN QUERY
SELECT
c.id as conversation_id,
d.id as other_user_id,
d.full_name as other_user_name,
d.specialty as other_user_specialty,
NULL::TEXT as other_user_avatar,
(SELECT content FROM messages WHERE conversation_id = c.id ORDER BY created_at DESC LIMIT 1) as last_message,
(SELECT created_at FROM messages WHERE conversation_id = c.id ORDER BY created_at DESC LIMIT 1) as last_message_time,
(SELECT COUNT(*) FROM messages m WHERE m.conversation_id = c.id AND m.sender_type = 'doctor' AND m.read_at IS NULL) as unread_count,
COALESCE((SELECT online FROM user_presence WHERE user_id = d.id AND user_type = 'doctor'), false) as is_online
FROM conversations c
JOIN doctors d ON c.doctor_id = d.id
WHERE c.patient_id = p_user_id
ORDER BY last_message_time DESC NULLS LAST;
ELSE
RETURN QUERY
SELECT
c.id as conversation_id,
p.id as other_user_id,
p.full_name as other_user_name,
NULL::TEXT as other_user_specialty,
NULL::TEXT as other_user_avatar,
(SELECT content FROM messages WHERE conversation_id = c.id ORDER BY created_at DESC LIMIT 1) as last_message,
(SELECT created_at FROM messages WHERE conversation_id = c.id ORDER BY created_at DESC LIMIT 1) as last_message_time,
(SELECT COUNT(*) FROM messages m WHERE m.conversation_id = c.id AND m.sender_type = 'patient' AND m.read_at IS NULL) as unread_count,
COALESCE((SELECT online FROM user_presence WHERE user_id = p.id AND user_type = 'patient'), false) as is_online
FROM conversations c
JOIN patients p ON c.patient_id = p.id
WHERE c.doctor_id = p_user_id
ORDER BY last_message_time DESC NULLS LAST;
END IF;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION get_or_create_conversation(
p_doctor_id UUID,
p_patient_id UUID
)
RETURNS UUID AS $$
DECLARE
v_conversation_id UUID;
BEGIN
SELECT id INTO v_conversation_id
FROM conversations
WHERE doctor_id = p_doctor_id AND patient_id = p_patient_id;
IF v_conversation_id IS NULL THEN
INSERT INTO conversations (doctor_id, patient_id)
VALUES (p_doctor_id, p_patient_id)
RETURNING id INTO v_conversation_id;
END IF;
RETURN v_conversation_id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION mark_messages_as_read(
p_conversation_id UUID,
p_user_id UUID,
p_user_type VARCHAR
)
RETURNS INTEGER AS $$
DECLARE
v_updated_count INTEGER;
BEGIN
UPDATE messages
SET read_at = NOW()
WHERE conversation_id = p_conversation_id
AND sender_id != p_user_id
AND sender_type != p_user_type
AND read_at IS NULL;
GET DIAGNOSTICS v_updated_count = ROW_COUNT;
RETURN v_updated_count;
END;
$$ LANGUAGE plpgsql;
-- ============================================
-- 4. HABILITAR RLS
-- ============================================
ALTER TABLE conversations ENABLE ROW LEVEL SECURITY;
ALTER TABLE messages ENABLE ROW LEVEL SECURITY;
ALTER TABLE user_presence ENABLE ROW LEVEL SECURITY;
ALTER TABLE message_attachments ENABLE ROW LEVEL SECURITY;
ALTER TABLE message_notifications ENABLE ROW LEVEL SECURITY;
-- ============================================
-- 5. CRIAR POLÍTICAS RLS
-- ============================================
-- Políticas para conversations
DROP POLICY IF EXISTS "Users can view their own conversations" ON conversations;
CREATE POLICY "Users can view their own conversations"
ON conversations FOR SELECT
USING (
doctor_id IN (SELECT id FROM doctors WHERE user_id = auth.uid())
OR patient_id IN (SELECT id FROM patients WHERE user_id = auth.uid())
);
DROP POLICY IF EXISTS "Users can create conversations" ON conversations;
CREATE POLICY "Users can create conversations"
ON conversations FOR INSERT
WITH CHECK (
doctor_id IN (SELECT id FROM doctors WHERE user_id = auth.uid())
OR patient_id IN (SELECT id FROM patients WHERE user_id = auth.uid())
);
-- Políticas para messages
DROP POLICY IF EXISTS "Users can view messages in their conversations" ON messages;
CREATE POLICY "Users can view messages in their conversations"
ON messages FOR SELECT
USING (
conversation_id IN (
SELECT id FROM conversations
WHERE doctor_id IN (SELECT id FROM doctors WHERE user_id = auth.uid())
OR patient_id IN (SELECT id FROM patients WHERE user_id = auth.uid())
)
);
DROP POLICY IF EXISTS "Users can send messages in their conversations" ON messages;
CREATE POLICY "Users can send messages in their conversations"
ON messages FOR INSERT
WITH CHECK (
conversation_id IN (
SELECT id FROM conversations
WHERE doctor_id IN (SELECT id FROM doctors WHERE user_id = auth.uid())
OR patient_id IN (SELECT id FROM patients WHERE user_id = auth.uid())
)
);
DROP POLICY IF EXISTS "Users can update their own messages" ON messages;
CREATE POLICY "Users can update their own messages"
ON messages FOR UPDATE
USING (
sender_id = auth.uid()
OR conversation_id IN (
SELECT id FROM conversations
WHERE doctor_id IN (SELECT id FROM doctors WHERE user_id = auth.uid())
OR patient_id IN (SELECT id FROM patients WHERE user_id = auth.uid())
)
);
-- Políticas para user_presence
DROP POLICY IF EXISTS "Everyone can view presence" ON user_presence;
CREATE POLICY "Everyone can view presence"
ON user_presence FOR SELECT
USING (true);
DROP POLICY IF EXISTS "Users can update their own presence" ON user_presence;
CREATE POLICY "Users can update their own presence"
ON user_presence FOR ALL
USING (user_id = auth.uid());
-- Políticas para attachments
DROP POLICY IF EXISTS "Users can view attachments in their conversations" ON message_attachments;
CREATE POLICY "Users can view attachments in their conversations"
ON message_attachments FOR SELECT
USING (
message_id IN (
SELECT m.id FROM messages m
JOIN conversations c ON m.conversation_id = c.id
WHERE c.doctor_id IN (SELECT id FROM doctors WHERE user_id = auth.uid())
OR c.patient_id IN (SELECT id FROM patients WHERE user_id = auth.uid())
)
);
DROP POLICY IF EXISTS "Users can upload attachments" ON message_attachments;
CREATE POLICY "Users can upload attachments"
ON message_attachments FOR INSERT
WITH CHECK (uploaded_by = auth.uid());
-- ============================================
-- 6. HABILITAR REALTIME
-- ============================================
ALTER PUBLICATION supabase_realtime ADD TABLE conversations;
ALTER PUBLICATION supabase_realtime ADD TABLE messages;
ALTER PUBLICATION supabase_realtime ADD TABLE user_presence;
ALTER PUBLICATION supabase_realtime ADD TABLE message_attachments;
-- ============================================
-- ✅ CONCLUÍDO!
-- ============================================
-- Próximos passos:
-- 1. Criar bucket 'message-files' no Storage
-- 2. Configurar políticas de storage (ver SETUP_STORAGE.md)
-- 3. Testar o sistema de mensagens