story-generator/supabase/migrations/20240327000001_normalize_essay_analyses.sql

165 lines
6.0 KiB
SQL

-- Primeiro, vamos criar as novas tabelas normalizadas
CREATE TABLE public.essay_analysis_feedback (
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
analysis_id UUID NOT NULL,
structure_feedback TEXT NOT NULL,
content_feedback TEXT NOT NULL,
language_feedback TEXT NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
);
CREATE TABLE public.essay_analysis_strengths (
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
analysis_id UUID NOT NULL,
strength TEXT NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
);
CREATE TABLE public.essay_analysis_improvements (
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
analysis_id UUID NOT NULL,
improvement TEXT NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
);
CREATE TABLE public.essay_analysis_scores (
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
analysis_id UUID NOT NULL,
adequacy INTEGER NOT NULL CHECK (adequacy >= 0 AND adequacy <= 100),
coherence INTEGER NOT NULL CHECK (coherence >= 0 AND coherence <= 100),
cohesion INTEGER NOT NULL CHECK (cohesion >= 0 AND cohesion <= 100),
vocabulary INTEGER NOT NULL CHECK (vocabulary >= 0 AND vocabulary <= 100),
grammar INTEGER NOT NULL CHECK (grammar >= 0 AND grammar <= 100),
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
);
-- Criar nova versão da tabela essay_analyses sem os campos JSONB e arrays
CREATE TABLE public.essay_analyses_new (
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
essay_id UUID NOT NULL REFERENCES public.student_essays(id),
overall_score INTEGER NOT NULL CHECK (overall_score >= 0 AND overall_score <= 100),
suggestions TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
);
-- Migrar dados da tabela antiga para as novas tabelas
INSERT INTO public.essay_analyses_new (id, essay_id, overall_score, suggestions, created_at)
SELECT id, essay_id, overall_score, suggestions, created_at
FROM public.essay_analyses;
-- Adicionar chaves estrangeiras nas tabelas de normalização
ALTER TABLE public.essay_analysis_feedback
ADD CONSTRAINT fk_analysis_feedback
FOREIGN KEY (analysis_id)
REFERENCES public.essay_analyses_new(id)
ON DELETE CASCADE;
ALTER TABLE public.essay_analysis_strengths
ADD CONSTRAINT fk_analysis_strengths
FOREIGN KEY (analysis_id)
REFERENCES public.essay_analyses_new(id)
ON DELETE CASCADE;
ALTER TABLE public.essay_analysis_improvements
ADD CONSTRAINT fk_analysis_improvements
FOREIGN KEY (analysis_id)
REFERENCES public.essay_analyses_new(id)
ON DELETE CASCADE;
ALTER TABLE public.essay_analysis_scores
ADD CONSTRAINT fk_analysis_scores
FOREIGN KEY (analysis_id)
REFERENCES public.essay_analyses_new(id)
ON DELETE CASCADE;
-- Criar índices para melhor performance
CREATE INDEX idx_essay_analysis_feedback_analysis_id ON public.essay_analysis_feedback(analysis_id);
CREATE INDEX idx_essay_analysis_strengths_analysis_id ON public.essay_analysis_strengths(analysis_id);
CREATE INDEX idx_essay_analysis_improvements_analysis_id ON public.essay_analysis_improvements(analysis_id);
CREATE INDEX idx_essay_analysis_scores_analysis_id ON public.essay_analysis_scores(analysis_id);
-- Aplicar políticas RLS nas novas tabelas
ALTER TABLE public.essay_analyses_new ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.essay_analysis_feedback ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.essay_analysis_strengths ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.essay_analysis_improvements ENABLE ROW LEVEL SECURITY;
ALTER TABLE public.essay_analysis_scores ENABLE ROW LEVEL SECURITY;
-- Políticas para essay_analyses_new
CREATE POLICY "Edge Function pode inserir análises"
ON public.essay_analyses_new FOR INSERT
WITH CHECK (
(auth.jwt() ->> 'role' = 'service_role') OR
EXISTS (
SELECT 1
FROM public.student_essays
WHERE id = essay_id
AND student_id = auth.uid()
)
);
CREATE POLICY "Alunos podem ver análises de suas próprias redações"
ON public.essay_analyses_new FOR SELECT
USING (
EXISTS (
SELECT 1
FROM public.student_essays
WHERE id = essay_id
AND student_id = auth.uid()
)
);
-- Políticas para tabelas relacionadas
CREATE POLICY "Acesso vinculado à análise principal - feedback"
ON public.essay_analysis_feedback FOR ALL
USING (
EXISTS (
SELECT 1
FROM public.essay_analyses_new a
JOIN public.student_essays e ON e.id = a.essay_id
WHERE a.id = analysis_id
AND e.student_id = auth.uid()
)
);
CREATE POLICY "Acesso vinculado à análise principal - strengths"
ON public.essay_analysis_strengths FOR ALL
USING (
EXISTS (
SELECT 1
FROM public.essay_analyses_new a
JOIN public.student_essays e ON e.id = a.essay_id
WHERE a.id = analysis_id
AND e.student_id = auth.uid()
)
);
CREATE POLICY "Acesso vinculado à análise principal - improvements"
ON public.essay_analysis_improvements FOR ALL
USING (
EXISTS (
SELECT 1
FROM public.essay_analyses_new a
JOIN public.student_essays e ON e.id = a.essay_id
WHERE a.id = analysis_id
AND e.student_id = auth.uid()
)
);
CREATE POLICY "Acesso vinculado à análise principal - scores"
ON public.essay_analysis_scores FOR ALL
USING (
EXISTS (
SELECT 1
FROM public.essay_analyses_new a
JOIN public.student_essays e ON e.id = a.essay_id
WHERE a.id = analysis_id
AND e.student_id = auth.uid()
)
);
-- Dropar a tabela antiga
DROP TABLE public.essay_analyses;
-- Renomear a nova tabela
ALTER TABLE public.essay_analyses_new RENAME TO essay_analyses;