story-generator/supabase/migrations/20240320000004_recreate_phonics_tables.sql
Lucas Santana 350a66bb9e
Some checks are pending
Docker Build and Push / build (push) Waiting to run
feat: implementa sistema de exercícios f��nicos
- Cria estrutura completa de banco de dados para exerc��cios f��nicos

- Implementa tabelas para categorias, tipos, exerc��cios e palavras

- Adiciona sistema de progresso e conquistas do estudante

- Configura pol��ticas de seguran��a RLS para prote����o dos dados

- Otimiza performance com ��ndices e relacionamentos apropriados

BREAKING CHANGE: Nova estrutura de banco de dados para exerc��cios f��nicos
2025-01-17 20:59:50 -03:00

175 lines
6.6 KiB
SQL

-- Primeiro, dropar todas as tabelas na ordem correta (inversa das dependências)
DROP TABLE IF EXISTS student_phonics_achievements;
DROP TABLE IF EXISTS phonics_achievements;
DROP TABLE IF EXISTS achievement_types;
DROP TABLE IF EXISTS student_phonics_attempt_answers;
DROP TABLE IF EXISTS student_phonics_attempts;
DROP TABLE IF EXISTS student_phonics_progress;
DROP TABLE IF EXISTS phonics_exercise_media;
DROP TABLE IF EXISTS media_types;
DROP TABLE IF EXISTS phonics_exercise_words;
DROP TABLE IF EXISTS phonics_words;
DROP TABLE IF EXISTS phonics_exercises;
DROP TABLE IF EXISTS phonics_exercise_types;
DROP TABLE IF EXISTS phonics_exercise_categories;
-- Dropar os índices (não é necessário pois eles são dropados junto com as tabelas)
-- DROP INDEX IF EXISTS idx_exercises_category;
-- DROP INDEX IF EXISTS idx_exercises_type;
-- DROP INDEX IF EXISTS idx_exercise_words;
-- DROP INDEX IF EXISTS idx_student_progress;
-- DROP INDEX IF EXISTS idx_student_attempts;
-- DROP INDEX IF EXISTS idx_attempt_answers;
-- DROP INDEX IF EXISTS idx_student_achievements;
-- Recriar as tabelas na ordem correta
-- Tabela de categorias de exercícios
CREATE TABLE phonics_exercise_categories (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(255) NOT NULL,
description TEXT,
level INTEGER NOT NULL,
order_index INTEGER NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de tipos de exercícios
CREATE TABLE phonics_exercise_types (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(50) NOT NULL, -- (rima, aliteração, segmentação, etc)
description TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de exercícios
CREATE TABLE phonics_exercises (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
category_id UUID REFERENCES phonics_exercise_categories(id),
type_id UUID REFERENCES phonics_exercise_types(id),
title VARCHAR(255) NOT NULL,
description TEXT,
difficulty_level INTEGER NOT NULL, -- (1-5)
estimated_time_seconds INTEGER,
instructions TEXT NOT NULL,
points INTEGER DEFAULT 10,
is_active BOOLEAN DEFAULT true,
required_score FLOAT DEFAULT 0.7, -- Pontuação mínima para passar (70%)
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de palavras
CREATE TABLE phonics_words (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
word VARCHAR(255) NOT NULL,
phonetic_transcription VARCHAR(255),
syllables_count INTEGER NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de relação exercício-palavras
CREATE TABLE phonics_exercise_words (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
exercise_id UUID REFERENCES phonics_exercises(id),
word_id UUID REFERENCES phonics_words(id),
is_correct_answer BOOLEAN DEFAULT false,
order_index INTEGER,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
UNIQUE(exercise_id, word_id)
);
-- Tabela de tipos de mídia
CREATE TABLE media_types (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(50) NOT NULL, -- (image, sound, animation)
description TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de recursos de mídia
CREATE TABLE phonics_exercise_media (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
exercise_id UUID REFERENCES phonics_exercises(id),
media_type_id UUID REFERENCES media_types(id),
url TEXT NOT NULL,
alt_text TEXT,
order_index INTEGER,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de progresso do estudante
CREATE TABLE student_phonics_progress (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
student_id UUID REFERENCES auth.users(id),
exercise_id UUID REFERENCES phonics_exercises(id),
attempts INTEGER DEFAULT 0,
best_score FLOAT DEFAULT 0,
last_score FLOAT DEFAULT 0,
completed BOOLEAN DEFAULT false,
completed_at TIMESTAMP WITH TIME ZONE,
stars INTEGER DEFAULT 0, -- (1-3 estrelas)
xp_earned INTEGER DEFAULT 0,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
UNIQUE(student_id, exercise_id)
);
-- Tabela de tentativas
CREATE TABLE student_phonics_attempts (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
student_id UUID REFERENCES auth.users(id),
exercise_id UUID REFERENCES phonics_exercises(id),
score FLOAT NOT NULL,
time_spent_seconds INTEGER,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de respostas das tentativas
CREATE TABLE student_phonics_attempt_answers (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
attempt_id UUID REFERENCES student_phonics_attempts(id),
word_id UUID REFERENCES phonics_words(id),
is_correct BOOLEAN NOT NULL,
answer_text TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de tipos de conquistas
CREATE TABLE achievement_types (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(50) NOT NULL, -- (streak, completion, mastery)
description TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de conquistas
CREATE TABLE phonics_achievements (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
type_id UUID REFERENCES achievement_types(id),
name VARCHAR(255) NOT NULL,
description TEXT,
points INTEGER DEFAULT 0,
icon_url TEXT,
required_count INTEGER DEFAULT 1,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Tabela de conquistas do estudante
CREATE TABLE student_phonics_achievements (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
student_id UUID REFERENCES auth.users(id),
achievement_id UUID REFERENCES phonics_achievements(id),
earned_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
UNIQUE(student_id, achievement_id)
);
-- Recriar os índices
CREATE INDEX idx_exercises_category ON phonics_exercises(category_id);
CREATE INDEX idx_exercises_type ON phonics_exercises(type_id);
CREATE INDEX idx_exercise_words ON phonics_exercise_words(exercise_id, word_id);
CREATE INDEX idx_student_progress ON student_phonics_progress(student_id, exercise_id);
CREATE INDEX idx_student_attempts ON student_phonics_attempts(student_id, exercise_id);
CREATE INDEX idx_attempt_answers ON student_phonics_attempt_answers(attempt_id);
CREATE INDEX idx_student_achievements ON student_phonics_achievements(student_id);