347 lines
18 KiB
SQL
347 lines
18 KiB
SQL
-- ============================================
|
|
-- TABELAS COMPLEMENTARES PARA OS 36 ENDPOINTS
|
|
-- ============================================
|
|
|
|
-- Tabela de preferências do usuário (MÓDULO 1 + 11)
|
|
CREATE TABLE IF NOT EXISTS public.user_preferences (
|
|
user_id uuid PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE,
|
|
dark_mode boolean DEFAULT false,
|
|
high_contrast boolean DEFAULT false,
|
|
font_size text DEFAULT 'medium' CHECK (font_size IN ('small', 'medium', 'large', 'extra-large')),
|
|
dyslexia_font boolean DEFAULT false,
|
|
notifications_enabled boolean DEFAULT true,
|
|
language text DEFAULT 'pt-BR',
|
|
timezone text DEFAULT 'America/Sao_Paulo',
|
|
created_at timestamptz DEFAULT now(),
|
|
updated_at timestamptz DEFAULT now()
|
|
);
|
|
|
|
-- Tabela de disponibilidade de médicos (MÓDULO 2.2)
|
|
CREATE TABLE IF NOT EXISTS public.doctor_availability (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
doctor_id uuid NOT NULL,
|
|
external_doctor_id uuid, -- ID do médico no Supabase externo
|
|
day_of_week int NOT NULL CHECK (day_of_week BETWEEN 0 AND 6), -- 0=Domingo, 6=Sábado
|
|
start_time time NOT NULL,
|
|
end_time time NOT NULL,
|
|
slot_duration_minutes int DEFAULT 30,
|
|
is_active boolean DEFAULT true,
|
|
created_at timestamptz DEFAULT now(),
|
|
updated_at timestamptz DEFAULT now()
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_doctor_availability_doctor ON public.doctor_availability(doctor_id);
|
|
CREATE INDEX IF NOT EXISTS idx_doctor_availability_external ON public.doctor_availability(external_doctor_id);
|
|
|
|
-- Tabela de exceções de agenda (MÓDULO 2.3)
|
|
CREATE TABLE IF NOT EXISTS public.availability_exceptions (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
doctor_id uuid NOT NULL,
|
|
external_doctor_id uuid,
|
|
exception_date date NOT NULL,
|
|
start_time time,
|
|
end_time time,
|
|
reason text,
|
|
type text CHECK (type IN ('unavailable', 'special_hours', 'holiday')) DEFAULT 'unavailable',
|
|
created_at timestamptz DEFAULT now(),
|
|
updated_at timestamptz DEFAULT now()
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_availability_exceptions_doctor ON public.availability_exceptions(doctor_id);
|
|
CREATE INDEX IF NOT EXISTS idx_availability_exceptions_date ON public.availability_exceptions(exception_date);
|
|
|
|
-- Tabela de estatísticas do médico (MÓDULO 7)
|
|
CREATE TABLE IF NOT EXISTS public.doctor_stats (
|
|
doctor_id uuid PRIMARY KEY,
|
|
external_doctor_id uuid,
|
|
total_appointments int DEFAULT 0,
|
|
completed_appointments int DEFAULT 0,
|
|
no_show_count int DEFAULT 0,
|
|
average_delay_minutes int DEFAULT 0,
|
|
occupancy_rate decimal(5,2) DEFAULT 0,
|
|
satisfaction_score decimal(3,2),
|
|
last_calculated_at timestamptz DEFAULT now(),
|
|
created_at timestamptz DEFAULT now(),
|
|
updated_at timestamptz DEFAULT now()
|
|
);
|
|
|
|
-- Tabela de histórico detalhado do paciente (MÓDULO 8)
|
|
CREATE TABLE IF NOT EXISTS public.patient_extended_history (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
patient_id uuid NOT NULL,
|
|
external_patient_id uuid,
|
|
visit_date timestamptz NOT NULL,
|
|
doctor_id uuid,
|
|
external_doctor_id uuid,
|
|
diagnosis text,
|
|
treatment text,
|
|
medications jsonb,
|
|
allergies jsonb,
|
|
vital_signs jsonb,
|
|
notes text,
|
|
attachments jsonb,
|
|
created_at timestamptz DEFAULT now(),
|
|
updated_at timestamptz DEFAULT now()
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_patient_history_patient ON public.patient_extended_history(patient_id);
|
|
CREATE INDEX IF NOT EXISTS idx_patient_history_external ON public.patient_extended_history(external_patient_id);
|
|
CREATE INDEX IF NOT EXISTS idx_patient_history_date ON public.patient_extended_history(visit_date);
|
|
|
|
-- Tabela de preferências do paciente (MÓDULO 8)
|
|
CREATE TABLE IF NOT EXISTS public.patient_preferences (
|
|
patient_id uuid PRIMARY KEY,
|
|
external_patient_id uuid,
|
|
preferred_days jsonb, -- ["monday", "wednesday"]
|
|
preferred_times jsonb, -- ["morning", "afternoon"]
|
|
preferred_doctors uuid[],
|
|
appointment_reminder_minutes int DEFAULT 60,
|
|
communication_method text DEFAULT 'sms' CHECK (communication_method IN ('sms', 'email', 'whatsapp', 'all')),
|
|
created_at timestamptz DEFAULT now(),
|
|
updated_at timestamptz DEFAULT now()
|
|
);
|
|
|
|
-- Tabela de ações auditadas (MÓDULO 13)
|
|
CREATE TABLE IF NOT EXISTS public.audit_actions (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id uuid,
|
|
external_user_id uuid,
|
|
action_type text NOT NULL,
|
|
entity_type text NOT NULL,
|
|
entity_id uuid,
|
|
old_data jsonb,
|
|
new_data jsonb,
|
|
ip_address inet,
|
|
user_agent text,
|
|
timestamp timestamptz DEFAULT now()
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_audit_actions_user ON public.audit_actions(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_audit_actions_external ON public.audit_actions(external_user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_audit_actions_timestamp ON public.audit_actions(timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_audit_actions_entity ON public.audit_actions(entity_type, entity_id);
|
|
|
|
-- Tabela de subscriptions de notificações (MÓDULO 5)
|
|
CREATE TABLE IF NOT EXISTS public.notification_subscriptions (
|
|
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id uuid NOT NULL,
|
|
external_user_id uuid,
|
|
channel text NOT NULL CHECK (channel IN ('sms', 'email', 'whatsapp', 'push')),
|
|
is_subscribed boolean DEFAULT true,
|
|
preferences jsonb, -- {appointment_reminders: true, newsletters: false, etc}
|
|
created_at timestamptz DEFAULT now(),
|
|
updated_at timestamptz DEFAULT now(),
|
|
UNIQUE(user_id, channel)
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_notification_subs_user ON public.notification_subscriptions(user_id);
|
|
|
|
-- Tabela de hashes de relatórios (MÓDULO 6 - integridade)
|
|
CREATE TABLE IF NOT EXISTS public.report_integrity (
|
|
report_id uuid PRIMARY KEY,
|
|
external_report_id uuid,
|
|
content_hash text NOT NULL,
|
|
algorithm text DEFAULT 'SHA256',
|
|
generated_at timestamptz DEFAULT now(),
|
|
verified_at timestamptz
|
|
);
|
|
|
|
-- Tabela de cache de analytics (MÓDULO 10)
|
|
CREATE TABLE IF NOT EXISTS public.analytics_cache (
|
|
cache_key text PRIMARY KEY,
|
|
data jsonb NOT NULL,
|
|
expires_at timestamptz NOT NULL,
|
|
created_at timestamptz DEFAULT now()
|
|
);
|
|
|
|
-- Adicionar coluna expires_at se não existir (para compatibilidade com kpi_cache existente)
|
|
DO $$
|
|
BEGIN
|
|
IF NOT EXISTS (SELECT 1 FROM information_schema.columns
|
|
WHERE table_schema = 'public'
|
|
AND table_name = 'analytics_cache'
|
|
AND column_name = 'expires_at') THEN
|
|
ALTER TABLE public.analytics_cache ADD COLUMN expires_at timestamptz NOT NULL DEFAULT (now() + interval '1 hour');
|
|
END IF;
|
|
END $$;
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_analytics_cache_expires ON public.analytics_cache(expires_at);
|
|
|
|
-- ============================================
|
|
-- RLS POLICIES (Service role tem acesso total)
|
|
-- ============================================
|
|
|
|
-- Habilitar RLS apenas se a tabela existir
|
|
DO $$
|
|
BEGIN
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'user_preferences') THEN
|
|
ALTER TABLE public.user_preferences ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'doctor_availability') THEN
|
|
ALTER TABLE public.doctor_availability ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'availability_exceptions') THEN
|
|
ALTER TABLE public.availability_exceptions ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'doctor_stats') THEN
|
|
ALTER TABLE public.doctor_stats ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'patient_extended_history') THEN
|
|
ALTER TABLE public.patient_extended_history ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'patient_preferences') THEN
|
|
ALTER TABLE public.patient_preferences ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'audit_actions') THEN
|
|
ALTER TABLE public.audit_actions ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'notification_subscriptions') THEN
|
|
ALTER TABLE public.notification_subscriptions ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'report_integrity') THEN
|
|
ALTER TABLE public.report_integrity ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'analytics_cache') THEN
|
|
ALTER TABLE public.analytics_cache ENABLE ROW LEVEL SECURITY;
|
|
END IF;
|
|
END $$;
|
|
|
|
-- Policies para user_preferences
|
|
DROP POLICY IF EXISTS "Service role full access user_preferences" ON public.user_preferences;
|
|
DROP POLICY IF EXISTS "Users manage own preferences" ON public.user_preferences;
|
|
CREATE POLICY "Service role full access user_preferences" ON public.user_preferences FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Users manage own preferences" ON public.user_preferences FOR ALL TO authenticated USING (user_id = auth.uid());
|
|
|
|
-- Policies para doctor_availability
|
|
DROP POLICY IF EXISTS "Service role full access doctor_availability" ON public.doctor_availability;
|
|
DROP POLICY IF EXISTS "Doctors manage own availability" ON public.doctor_availability;
|
|
DROP POLICY IF EXISTS "Staff view all availability" ON public.doctor_availability;
|
|
|
|
CREATE POLICY "Service role full access doctor_availability" ON public.doctor_availability FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Doctors manage own availability" ON public.doctor_availability FOR ALL TO authenticated USING (doctor_id = auth.uid());
|
|
CREATE POLICY "Staff view all availability" ON public.doctor_availability FOR SELECT TO authenticated USING (true);
|
|
|
|
-- Policies para availability_exceptions
|
|
DROP POLICY IF EXISTS "Service role full access exceptions" ON public.availability_exceptions;
|
|
DROP POLICY IF EXISTS "Doctors manage own exceptions" ON public.availability_exceptions;
|
|
DROP POLICY IF EXISTS "Staff view all exceptions" ON public.availability_exceptions;
|
|
|
|
CREATE POLICY "Service role full access exceptions" ON public.availability_exceptions FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Doctors manage own exceptions" ON public.availability_exceptions FOR ALL TO authenticated USING (doctor_id = auth.uid());
|
|
CREATE POLICY "Staff view all exceptions" ON public.availability_exceptions FOR SELECT TO authenticated USING (true);
|
|
|
|
-- Policies para doctor_stats
|
|
DROP POLICY IF EXISTS "Service role full access doctor_stats" ON public.doctor_stats;
|
|
DROP POLICY IF EXISTS "Doctors view own stats" ON public.doctor_stats;
|
|
DROP POLICY IF EXISTS "Admins view all stats" ON public.doctor_stats;
|
|
|
|
CREATE POLICY "Service role full access doctor_stats" ON public.doctor_stats FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Doctors view own stats" ON public.doctor_stats FOR SELECT TO authenticated USING (doctor_id = auth.uid());
|
|
CREATE POLICY "Admins view all stats" ON public.doctor_stats FOR SELECT TO authenticated
|
|
USING (EXISTS (SELECT 1 FROM auth.users WHERE auth.users.id = auth.uid() AND auth.users.raw_user_meta_data->>'role' = 'admin'));
|
|
|
|
-- Policies para patient_extended_history
|
|
DROP POLICY IF EXISTS "Service role full access patient_history" ON public.patient_extended_history;
|
|
DROP POLICY IF EXISTS "Patients view own history" ON public.patient_extended_history;
|
|
DROP POLICY IF EXISTS "Doctors view patient history" ON public.patient_extended_history;
|
|
|
|
CREATE POLICY "Service role full access patient_history" ON public.patient_extended_history FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Patients view own history" ON public.patient_extended_history FOR SELECT TO authenticated USING (patient_id = auth.uid());
|
|
CREATE POLICY "Doctors view patient history" ON public.patient_extended_history FOR SELECT TO authenticated
|
|
USING (EXISTS (SELECT 1 FROM auth.users WHERE auth.users.id = auth.uid() AND auth.users.raw_user_meta_data->>'role' IN ('doctor', 'admin')));
|
|
|
|
-- Policies para patient_preferences
|
|
DROP POLICY IF EXISTS "Service role full access patient_prefs" ON public.patient_preferences;
|
|
DROP POLICY IF EXISTS "Patients manage own preferences" ON public.patient_preferences;
|
|
|
|
CREATE POLICY "Service role full access patient_prefs" ON public.patient_preferences FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Patients manage own preferences" ON public.patient_preferences FOR ALL TO authenticated USING (patient_id = auth.uid());
|
|
|
|
-- Policies para audit_actions
|
|
DROP POLICY IF EXISTS "Service role full access audit" ON public.audit_actions;
|
|
DROP POLICY IF EXISTS "Admins view all audit" ON public.audit_actions;
|
|
|
|
CREATE POLICY "Service role full access audit" ON public.audit_actions FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Admins view all audit" ON public.audit_actions FOR SELECT TO authenticated
|
|
USING (EXISTS (SELECT 1 FROM auth.users WHERE auth.users.id = auth.uid() AND auth.users.raw_user_meta_data->>'role' = 'admin'));
|
|
|
|
-- Policies para notification_subscriptions
|
|
DROP POLICY IF EXISTS "Service role full access notif_subs" ON public.notification_subscriptions;
|
|
DROP POLICY IF EXISTS "Users manage own subscriptions" ON public.notification_subscriptions;
|
|
|
|
CREATE POLICY "Service role full access notif_subs" ON public.notification_subscriptions FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Users manage own subscriptions" ON public.notification_subscriptions FOR ALL TO authenticated USING (user_id = auth.uid());
|
|
|
|
-- Policies para report_integrity
|
|
DROP POLICY IF EXISTS "Service role full access report_integrity" ON public.report_integrity;
|
|
DROP POLICY IF EXISTS "Staff view report integrity" ON public.report_integrity;
|
|
|
|
CREATE POLICY "Service role full access report_integrity" ON public.report_integrity FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Staff view report integrity" ON public.report_integrity FOR SELECT TO authenticated
|
|
USING (EXISTS (SELECT 1 FROM auth.users WHERE auth.users.id = auth.uid() AND auth.users.raw_user_meta_data->>'role' IN ('doctor', 'admin', 'secretary')));
|
|
|
|
-- Policies para analytics_cache
|
|
DROP POLICY IF EXISTS "Service role full access analytics_cache" ON public.analytics_cache;
|
|
DROP POLICY IF EXISTS "Staff view analytics" ON public.analytics_cache;
|
|
|
|
CREATE POLICY "Service role full access analytics_cache" ON public.analytics_cache FOR ALL TO service_role USING (true);
|
|
CREATE POLICY "Staff view analytics" ON public.analytics_cache FOR SELECT TO authenticated
|
|
USING (EXISTS (SELECT 1 FROM auth.users WHERE auth.users.id = auth.uid() AND auth.users.raw_user_meta_data->>'role' IN ('doctor', 'admin', 'secretary')));
|
|
|
|
-- ============================================
|
|
-- TRIGGERS
|
|
-- ============================================
|
|
|
|
-- Criar triggers apenas se as tabelas existirem
|
|
DO $$
|
|
BEGIN
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'user_preferences') THEN
|
|
DROP TRIGGER IF EXISTS update_user_preferences_updated_at ON public.user_preferences;
|
|
CREATE TRIGGER update_user_preferences_updated_at
|
|
BEFORE UPDATE ON public.user_preferences
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
|
|
END IF;
|
|
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'doctor_availability') THEN
|
|
DROP TRIGGER IF EXISTS update_doctor_availability_updated_at ON public.doctor_availability;
|
|
CREATE TRIGGER update_doctor_availability_updated_at
|
|
BEFORE UPDATE ON public.doctor_availability
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
|
|
END IF;
|
|
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'availability_exceptions') THEN
|
|
DROP TRIGGER IF EXISTS update_availability_exceptions_updated_at ON public.availability_exceptions;
|
|
CREATE TRIGGER update_availability_exceptions_updated_at
|
|
BEFORE UPDATE ON public.availability_exceptions
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
|
|
END IF;
|
|
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'doctor_stats') THEN
|
|
DROP TRIGGER IF EXISTS update_doctor_stats_updated_at ON public.doctor_stats;
|
|
CREATE TRIGGER update_doctor_stats_updated_at
|
|
BEFORE UPDATE ON public.doctor_stats
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
|
|
END IF;
|
|
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'patient_extended_history') THEN
|
|
DROP TRIGGER IF EXISTS update_patient_history_updated_at ON public.patient_extended_history;
|
|
CREATE TRIGGER update_patient_history_updated_at
|
|
BEFORE UPDATE ON public.patient_extended_history
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
|
|
END IF;
|
|
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'patient_preferences') THEN
|
|
DROP TRIGGER IF EXISTS update_patient_preferences_updated_at ON public.patient_preferences;
|
|
CREATE TRIGGER update_patient_preferences_updated_at
|
|
BEFORE UPDATE ON public.patient_preferences
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
|
|
END IF;
|
|
|
|
IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = 'public' AND table_name = 'notification_subscriptions') THEN
|
|
DROP TRIGGER IF EXISTS update_notification_subscriptions_updated_at ON public.notification_subscriptions;
|
|
CREATE TRIGGER update_notification_subscriptions_updated_at
|
|
BEFORE UPDATE ON public.notification_subscriptions
|
|
FOR EACH ROW EXECUTE FUNCTION public.update_updated_at_column();
|
|
END IF;
|
|
END $$;
|