mirror of
https://github.com/lucasrcsantana/story-generator.git
synced 2025-12-17 05:47:52 +00:00
229 lines
9.3 KiB
PL/PgSQL
229 lines
9.3 KiB
PL/PgSQL
-- Criação do sistema de redações (Essays)
|
|
-- Tipos de texto (Narrativo, Dissertativo, etc)
|
|
CREATE TABLE public.essay_types (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
slug TEXT NOT NULL UNIQUE,
|
|
title TEXT NOT NULL,
|
|
description TEXT NOT NULL,
|
|
icon TEXT NOT NULL,
|
|
active BOOLEAN DEFAULT true,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
|
|
);
|
|
|
|
-- Gêneros textuais (Artigo de opinião, Carta argumentativa, etc)
|
|
CREATE TABLE public.essay_genres (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
type_id UUID NOT NULL REFERENCES public.essay_types(id),
|
|
slug TEXT NOT NULL UNIQUE,
|
|
title TEXT NOT NULL,
|
|
description TEXT NOT NULL,
|
|
icon TEXT NOT NULL,
|
|
requirements JSONB NOT NULL DEFAULT '{}',
|
|
active BOOLEAN DEFAULT true,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
|
|
);
|
|
|
|
-- Redações dos alunos
|
|
CREATE TABLE public.student_essays (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
student_id UUID NOT NULL REFERENCES public.students(id),
|
|
type_id UUID NOT NULL REFERENCES public.essay_types(id),
|
|
genre_id UUID NOT NULL REFERENCES public.essay_genres(id),
|
|
title TEXT NOT NULL,
|
|
content TEXT NOT NULL,
|
|
status TEXT NOT NULL DEFAULT 'draft',
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
|
|
CONSTRAINT status_check CHECK (status IN ('draft', 'submitted', 'analyzed'))
|
|
);
|
|
|
|
-- Análises das redações
|
|
CREATE TABLE public.essay_analyses (
|
|
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
|
|
);
|
|
|
|
-- Feedback das análises
|
|
CREATE TABLE public.essay_analysis_feedback (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
analysis_id UUID NOT NULL REFERENCES public.essay_analyses(id) ON DELETE CASCADE,
|
|
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
|
|
);
|
|
|
|
-- Pontos fortes das análises
|
|
CREATE TABLE public.essay_analysis_strengths (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
analysis_id UUID NOT NULL REFERENCES public.essay_analyses(id) ON DELETE CASCADE,
|
|
strength TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
|
|
);
|
|
|
|
-- Pontos a melhorar das análises
|
|
CREATE TABLE public.essay_analysis_improvements (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
analysis_id UUID NOT NULL REFERENCES public.essay_analyses(id) ON DELETE CASCADE,
|
|
improvement TEXT NOT NULL,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL
|
|
);
|
|
|
|
-- Notas por critério das análises
|
|
CREATE TABLE public.essay_analysis_scores (
|
|
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
|
analysis_id UUID NOT NULL REFERENCES public.essay_analyses(id) ON DELETE CASCADE,
|
|
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
|
|
);
|
|
|
|
-- Índices para melhor performance
|
|
CREATE INDEX idx_student_essays_student_id ON public.student_essays(student_id);
|
|
CREATE INDEX idx_student_essays_status ON public.student_essays(status);
|
|
CREATE INDEX idx_essay_genres_type_id ON public.essay_genres(type_id);
|
|
CREATE INDEX idx_essay_analyses_essay_id ON public.essay_analyses(essay_id);
|
|
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);
|
|
|
|
-- Triggers para updated_at
|
|
CREATE OR REPLACE FUNCTION public.handle_updated_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = now();
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER essay_types_updated_at
|
|
BEFORE UPDATE ON public.essay_types
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE public.handle_updated_at();
|
|
|
|
CREATE TRIGGER essay_genres_updated_at
|
|
BEFORE UPDATE ON public.essay_genres
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE public.handle_updated_at();
|
|
|
|
CREATE TRIGGER student_essays_updated_at
|
|
BEFORE UPDATE ON public.student_essays
|
|
FOR EACH ROW
|
|
EXECUTE PROCEDURE public.handle_updated_at();
|
|
|
|
-- Políticas RLS
|
|
ALTER TABLE public.essay_types ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.essay_genres ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.student_essays ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE public.essay_analyses ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Políticas para essay_types (visível para todos)
|
|
CREATE POLICY "Tipos de redação visíveis para todos"
|
|
ON public.essay_types FOR SELECT
|
|
USING (active = true);
|
|
|
|
-- Políticas para essay_genres (visível para todos)
|
|
CREATE POLICY "Gêneros textuais visíveis para todos"
|
|
ON public.essay_genres FOR SELECT
|
|
USING (active = true);
|
|
|
|
-- Políticas para student_essays
|
|
CREATE POLICY "Alunos podem ver suas próprias redações"
|
|
ON public.student_essays FOR SELECT
|
|
USING (student_id = auth.uid());
|
|
|
|
CREATE POLICY "Alunos podem criar suas próprias redações"
|
|
ON public.student_essays FOR INSERT
|
|
WITH CHECK (student_id = auth.uid());
|
|
|
|
CREATE POLICY "Alunos podem atualizar suas próprias redações"
|
|
ON public.student_essays FOR UPDATE
|
|
USING (student_id = auth.uid())
|
|
WITH CHECK (student_id = auth.uid());
|
|
|
|
CREATE POLICY "Alunos podem deletar suas próprias redações"
|
|
ON public.student_essays FOR DELETE
|
|
USING (student_id = auth.uid());
|
|
|
|
-- Políticas para essay_analyses
|
|
CREATE POLICY "Edge Function pode inserir análises"
|
|
ON public.essay_analyses FOR INSERT
|
|
WITH CHECK (
|
|
-- A função de análise roda com a service_role, então permitimos
|
|
(auth.jwt() ->> 'role' = 'service_role') OR
|
|
-- Permitir inserção se o essay_id pertence ao usuário atual
|
|
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 FOR SELECT
|
|
USING (
|
|
EXISTS (
|
|
SELECT 1
|
|
FROM public.student_essays
|
|
WHERE id = essay_id
|
|
AND student_id = auth.uid()
|
|
)
|
|
);
|
|
|
|
-- Função para verificar se uma redação pertence ao aluno
|
|
CREATE OR REPLACE FUNCTION public.check_essay_ownership(essay_id UUID)
|
|
RETURNS BOOLEAN AS $$
|
|
BEGIN
|
|
RETURN EXISTS (
|
|
SELECT 1
|
|
FROM public.student_essays
|
|
WHERE id = essay_id
|
|
AND student_id = auth.uid()
|
|
);
|
|
END;
|
|
$$ language plpgsql security definer;
|
|
|
|
-- Comentários nas tabelas
|
|
COMMENT ON TABLE public.essay_types IS 'Tipos de texto (Narrativo, Dissertativo, etc)';
|
|
COMMENT ON TABLE public.essay_genres IS 'Gêneros textuais relacionados a cada tipo de texto';
|
|
COMMENT ON TABLE public.student_essays IS 'Redações escritas pelos alunos';
|
|
COMMENT ON TABLE public.essay_analyses IS 'Análises e feedbacks das redações dos alunos';
|
|
|
|
-- Dados iniciais
|
|
INSERT INTO public.essay_types (slug, title, description, icon) VALUES
|
|
('narrative', 'Narrativo', 'Textos que contam uma história com personagens, tempo e espaço definidos', '📖'),
|
|
('dissertation', 'Dissertativo', 'Textos que apresentam uma análise e discussão de um tema', '📝'),
|
|
('descriptive', 'Descritivo', 'Textos que descrevem detalhadamente um objeto, pessoa, lugar ou situação', '🎨');
|
|
|
|
INSERT INTO public.essay_genres (type_id, slug, title, description, icon, requirements) VALUES
|
|
((SELECT id FROM public.essay_types WHERE slug = 'dissertation'),
|
|
'opinion-article',
|
|
'Artigo de Opinião',
|
|
'Texto que apresenta um ponto de vista sobre um tema atual',
|
|
'📰',
|
|
'{"min_words": 300, "max_words": 600, "required_sections": ["introduction", "development", "conclusion"]}'
|
|
),
|
|
((SELECT id FROM public.essay_types WHERE slug = 'narrative'),
|
|
'short-story',
|
|
'Conto',
|
|
'História curta com poucos personagens e um único conflito',
|
|
'📚',
|
|
'{"min_words": 200, "max_words": 1000, "required_elements": ["characters", "setting", "conflict", "resolution"]}'
|
|
),
|
|
((SELECT id FROM public.essay_types WHERE slug = 'descriptive'),
|
|
'character-description',
|
|
'Descrição de Personagem',
|
|
'Texto que descreve características físicas e psicológicas de um personagem',
|
|
'👤',
|
|
'{"min_words": 150, "max_words": 400, "required_aspects": ["physical", "psychological", "habits"]}'
|
|
); |