Initial commit
This commit is contained in:
105
play-life-backend/migrations/001_create_schema.sql
Normal file
105
play-life-backend/migrations/001_create_schema.sql
Normal file
@@ -0,0 +1,105 @@
|
||||
-- Migration: Create database schema for play-life project
|
||||
-- This script creates all tables and materialized views needed for the project
|
||||
|
||||
-- ============================================
|
||||
-- Table: projects
|
||||
-- ============================================
|
||||
CREATE TABLE IF NOT EXISTS projects (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
priority SMALLINT,
|
||||
CONSTRAINT unique_project_name UNIQUE (name)
|
||||
);
|
||||
|
||||
-- ============================================
|
||||
-- Table: entries
|
||||
-- ============================================
|
||||
-- This table stores entries with creation dates
|
||||
-- Used in weekly_report_mv for grouping by week
|
||||
CREATE TABLE IF NOT EXISTS entries (
|
||||
id SERIAL PRIMARY KEY,
|
||||
text TEXT NOT NULL,
|
||||
created_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- ============================================
|
||||
-- Table: nodes
|
||||
-- ============================================
|
||||
-- This table stores nodes linked to projects and entries
|
||||
-- Contains score information used in weekly reports
|
||||
CREATE TABLE IF NOT EXISTS nodes (
|
||||
id SERIAL PRIMARY KEY,
|
||||
project_id INTEGER NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
|
||||
entry_id INTEGER NOT NULL REFERENCES entries(id) ON DELETE CASCADE,
|
||||
score NUMERIC(8,4)
|
||||
);
|
||||
|
||||
-- Create index on project_id for better join performance
|
||||
CREATE INDEX IF NOT EXISTS idx_nodes_project_id ON nodes(project_id);
|
||||
-- Create index on entry_id for better join performance
|
||||
CREATE INDEX IF NOT EXISTS idx_nodes_entry_id ON nodes(entry_id);
|
||||
|
||||
-- ============================================
|
||||
-- Table: weekly_goals
|
||||
-- ============================================
|
||||
-- This table stores weekly goals for projects
|
||||
CREATE TABLE IF NOT EXISTS weekly_goals (
|
||||
id SERIAL PRIMARY KEY,
|
||||
project_id INTEGER NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
|
||||
goal_year INTEGER NOT NULL,
|
||||
goal_week INTEGER NOT NULL,
|
||||
min_goal_score NUMERIC(10,4) NOT NULL DEFAULT 0,
|
||||
max_goal_score NUMERIC(10,4),
|
||||
actual_score NUMERIC(10,4) DEFAULT 0,
|
||||
priority SMALLINT,
|
||||
CONSTRAINT weekly_goals_project_id_goal_year_goal_week_key UNIQUE (project_id, goal_year, goal_week)
|
||||
);
|
||||
|
||||
-- Create index on project_id for better join performance
|
||||
CREATE INDEX IF NOT EXISTS idx_weekly_goals_project_id ON weekly_goals(project_id);
|
||||
|
||||
-- ============================================
|
||||
-- Materialized View: weekly_report_mv
|
||||
-- ============================================
|
||||
CREATE MATERIALIZED VIEW IF NOT EXISTS weekly_report_mv AS
|
||||
SELECT
|
||||
p.id AS project_id,
|
||||
agg.report_year,
|
||||
agg.report_week,
|
||||
-- Используем COALESCE для установки total_score в 0.0000, если нет данных (NULL)
|
||||
COALESCE(agg.total_score, 0.0000) AS total_score
|
||||
FROM
|
||||
projects p
|
||||
LEFT JOIN
|
||||
(
|
||||
-- 1. Предварительная агрегация: суммируем score по неделям
|
||||
SELECT
|
||||
n.project_id,
|
||||
EXTRACT(YEAR FROM e.created_date)::INTEGER AS report_year,
|
||||
EXTRACT(WEEK FROM e.created_date)::INTEGER AS report_week,
|
||||
SUM(n.score) AS total_score
|
||||
FROM
|
||||
nodes n
|
||||
JOIN
|
||||
entries e ON n.entry_id = e.id
|
||||
GROUP BY
|
||||
1, 2, 3
|
||||
) agg
|
||||
-- 2. Присоединяем агрегированные данные ко ВСЕМ проектам
|
||||
ON p.id = agg.project_id
|
||||
ORDER BY
|
||||
p.id, agg.report_year, agg.report_week;
|
||||
|
||||
-- Create index on materialized view for better query performance
|
||||
CREATE INDEX IF NOT EXISTS idx_weekly_report_mv_project_year_week
|
||||
ON weekly_report_mv(project_id, report_year, report_week);
|
||||
|
||||
-- ============================================
|
||||
-- Comments for documentation
|
||||
-- ============================================
|
||||
COMMENT ON TABLE projects IS 'Projects table storing project information with priority';
|
||||
COMMENT ON TABLE entries IS 'Entries table storing entry creation timestamps';
|
||||
COMMENT ON TABLE nodes IS 'Nodes table linking projects, entries and storing scores';
|
||||
COMMENT ON TABLE weekly_goals IS 'Weekly goals for projects';
|
||||
COMMENT ON MATERIALIZED VIEW weekly_report_mv IS 'Materialized view aggregating weekly scores by project';
|
||||
|
||||
53
play-life-backend/migrations/002_add_dictionaries.sql
Normal file
53
play-life-backend/migrations/002_add_dictionaries.sql
Normal file
@@ -0,0 +1,53 @@
|
||||
-- Migration: Add dictionaries table and dictionary_id to words
|
||||
-- This script creates the dictionaries table and adds dictionary_id field to words table
|
||||
|
||||
-- ============================================
|
||||
-- Table: dictionaries
|
||||
-- ============================================
|
||||
CREATE TABLE IF NOT EXISTS dictionaries (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL
|
||||
);
|
||||
|
||||
-- Insert default dictionary "Все слова" with id = 0
|
||||
-- Note: PostgreSQL SERIAL starts from 1, so we need to use a workaround
|
||||
-- First, set the sequence to allow inserting 0, then insert, then reset sequence
|
||||
DO $$
|
||||
BEGIN
|
||||
-- Set sequence to -1 so next value will be 0
|
||||
PERFORM setval('dictionaries_id_seq', -1, false);
|
||||
|
||||
-- Insert the default dictionary with id = 0
|
||||
INSERT INTO dictionaries (id, name)
|
||||
VALUES (0, 'Все слова')
|
||||
ON CONFLICT (id) DO NOTHING;
|
||||
|
||||
-- Set the sequence to start from 1 (so next auto-increment will be 1)
|
||||
PERFORM setval('dictionaries_id_seq', 1, false);
|
||||
END $$;
|
||||
|
||||
-- ============================================
|
||||
-- Alter words table: Add dictionary_id column
|
||||
-- ============================================
|
||||
ALTER TABLE words
|
||||
ADD COLUMN IF NOT EXISTS dictionary_id INTEGER DEFAULT 0 REFERENCES dictionaries(id);
|
||||
|
||||
-- Update all existing words to have dictionary_id = 0
|
||||
UPDATE words
|
||||
SET dictionary_id = 0
|
||||
WHERE dictionary_id IS NULL;
|
||||
|
||||
-- Make dictionary_id NOT NULL after setting default values
|
||||
ALTER TABLE words
|
||||
ALTER COLUMN dictionary_id SET NOT NULL,
|
||||
ALTER COLUMN dictionary_id SET DEFAULT 0;
|
||||
|
||||
-- Create index on dictionary_id for better join performance
|
||||
CREATE INDEX IF NOT EXISTS idx_words_dictionary_id ON words(dictionary_id);
|
||||
|
||||
-- ============================================
|
||||
-- Comments for documentation
|
||||
-- ============================================
|
||||
COMMENT ON TABLE dictionaries IS 'Dictionaries table storing dictionary information';
|
||||
COMMENT ON COLUMN words.dictionary_id IS 'Reference to dictionary. Default is 0 (Все слова)';
|
||||
|
||||
@@ -0,0 +1,11 @@
|
||||
-- Migration: Remove UNIQUE constraint from words.name
|
||||
-- This script removes the unique constraint on the name column in the words table
|
||||
|
||||
-- Drop the unique constraint on words.name if it exists
|
||||
ALTER TABLE words
|
||||
DROP CONSTRAINT IF EXISTS words_name_key;
|
||||
|
||||
-- Also try to drop constraint if it was created with different name
|
||||
ALTER TABLE words
|
||||
DROP CONSTRAINT IF EXISTS words_name_unique;
|
||||
|
||||
21
play-life-backend/migrations/004_add_config_dictionaries.sql
Normal file
21
play-life-backend/migrations/004_add_config_dictionaries.sql
Normal file
@@ -0,0 +1,21 @@
|
||||
-- Migration: Add config_dictionaries table (many-to-many relationship)
|
||||
-- This script creates the config_dictionaries table linking configs and dictionaries
|
||||
|
||||
-- ============================================
|
||||
-- Table: config_dictionaries
|
||||
-- ============================================
|
||||
CREATE TABLE IF NOT EXISTS config_dictionaries (
|
||||
config_id INTEGER NOT NULL REFERENCES configs(id) ON DELETE CASCADE,
|
||||
dictionary_id INTEGER NOT NULL REFERENCES dictionaries(id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (config_id, dictionary_id)
|
||||
);
|
||||
|
||||
-- Create indexes for better query performance
|
||||
CREATE INDEX IF NOT EXISTS idx_config_dictionaries_config_id ON config_dictionaries(config_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_config_dictionaries_dictionary_id ON config_dictionaries(dictionary_id);
|
||||
|
||||
-- ============================================
|
||||
-- Comments for documentation
|
||||
-- ============================================
|
||||
COMMENT ON TABLE config_dictionaries IS 'Many-to-many relationship table linking configs and dictionaries. If no dictionaries are selected for a config, all dictionaries will be used.';
|
||||
|
||||
29
play-life-backend/migrations/005_fix_weekly_report_mv.sql
Normal file
29
play-life-backend/migrations/005_fix_weekly_report_mv.sql
Normal file
@@ -0,0 +1,29 @@
|
||||
-- Migration: Fix weekly_report_mv to use ISOYEAR instead of YEAR
|
||||
-- This fixes incorrect week calculations at year boundaries
|
||||
-- Date: 2024
|
||||
|
||||
-- Drop existing materialized view
|
||||
DROP MATERIALIZED VIEW IF EXISTS weekly_report_mv;
|
||||
|
||||
-- Recreate materialized view with ISOYEAR
|
||||
CREATE MATERIALIZED VIEW weekly_report_mv AS
|
||||
SELECT
|
||||
n.project_id,
|
||||
-- 🔑 ГЛАВНОЕ ИСПРАВЛЕНИЕ: Используем ISOYEAR
|
||||
EXTRACT(ISOYEAR FROM e.created_date)::INTEGER AS report_year,
|
||||
EXTRACT(WEEK FROM e.created_date)::INTEGER AS report_week,
|
||||
SUM(n.score) AS total_score
|
||||
FROM
|
||||
nodes n
|
||||
JOIN
|
||||
entries e ON n.entry_id = e.id
|
||||
GROUP BY
|
||||
1, 2, 3
|
||||
WITH DATA;
|
||||
|
||||
-- Recreate index
|
||||
CREATE INDEX IF NOT EXISTS idx_weekly_report_mv_project_year_week
|
||||
ON weekly_report_mv(project_id, report_year, report_week);
|
||||
|
||||
COMMENT ON MATERIALIZED VIEW weekly_report_mv IS 'Materialized view aggregating weekly scores by project using ISOYEAR for correct week calculations';
|
||||
|
||||
81
play-life-backend/migrations/README.md
Normal file
81
play-life-backend/migrations/README.md
Normal file
@@ -0,0 +1,81 @@
|
||||
# Database Migrations
|
||||
|
||||
Этот каталог содержит SQL миграции для создания структуры базы данных проекта play-life.
|
||||
|
||||
## Использование
|
||||
|
||||
### Создание базы данных с нуля
|
||||
|
||||
Выполните миграцию для создания всех таблиц и представлений:
|
||||
|
||||
```bash
|
||||
psql -U your_user -d your_database -f 001_create_schema.sql
|
||||
```
|
||||
|
||||
Или через docker-compose:
|
||||
|
||||
```bash
|
||||
docker-compose exec db psql -U playeng -d playeng -f /migrations/001_create_schema.sql
|
||||
```
|
||||
|
||||
## Структура базы данных
|
||||
|
||||
### Таблицы
|
||||
|
||||
1. **projects** - Проекты
|
||||
- `id` (SERIAL PRIMARY KEY)
|
||||
- `name` (VARCHAR(255) NOT NULL, UNIQUE)
|
||||
- `priority` (SMALLINT)
|
||||
|
||||
2. **entries** - Записи с текстом и датами создания
|
||||
- `id` (SERIAL PRIMARY KEY)
|
||||
- `text` (TEXT NOT NULL)
|
||||
- `created_date` (TIMESTAMP WITH TIME ZONE NOT NULL, DEFAULT CURRENT_TIMESTAMP)
|
||||
|
||||
3. **nodes** - Узлы, связывающие проекты и записи
|
||||
- `id` (SERIAL PRIMARY KEY)
|
||||
- `project_id` (INTEGER NOT NULL, FK -> projects.id ON DELETE CASCADE)
|
||||
- `entry_id` (INTEGER NOT NULL, FK -> entries.id ON DELETE CASCADE)
|
||||
- `score` (NUMERIC(8,4))
|
||||
|
||||
4. **weekly_goals** - Недельные цели для проектов
|
||||
- `id` (SERIAL PRIMARY KEY)
|
||||
- `project_id` (INTEGER NOT NULL, FK -> projects.id ON DELETE CASCADE)
|
||||
- `goal_year` (INTEGER NOT NULL)
|
||||
- `goal_week` (INTEGER NOT NULL)
|
||||
- `min_goal_score` (NUMERIC(10,4) NOT NULL, DEFAULT 0)
|
||||
- `max_goal_score` (NUMERIC(10,4))
|
||||
- `actual_score` (NUMERIC(10,4), DEFAULT 0)
|
||||
- `priority` (SMALLINT)
|
||||
- UNIQUE CONSTRAINT: `(project_id, goal_year, goal_week)`
|
||||
|
||||
### Materialized View
|
||||
|
||||
- **weekly_report_mv** - Агрегированные данные по неделям для каждого проекта
|
||||
- `project_id` (INTEGER)
|
||||
- `report_year` (INTEGER)
|
||||
- `report_week` (INTEGER)
|
||||
- `total_score` (NUMERIC)
|
||||
|
||||
## Обновление Materialized View
|
||||
|
||||
После изменения данных в таблицах `nodes` или `entries`, необходимо обновить materialized view:
|
||||
|
||||
```sql
|
||||
REFRESH MATERIALIZED VIEW weekly_report_mv;
|
||||
```
|
||||
|
||||
## Связи между таблицами
|
||||
|
||||
- `nodes.project_id` → `projects.id` (ON DELETE CASCADE)
|
||||
- `nodes.entry_id` → `entries.id` (ON DELETE CASCADE)
|
||||
- `weekly_goals.project_id` → `projects.id` (ON DELETE CASCADE)
|
||||
|
||||
## Индексы
|
||||
|
||||
Созданы индексы для оптимизации запросов:
|
||||
- `idx_nodes_project_id` на `nodes(project_id)`
|
||||
- `idx_nodes_entry_id` на `nodes(entry_id)`
|
||||
- `idx_weekly_goals_project_id` на `weekly_goals(project_id)`
|
||||
- `idx_weekly_report_mv_project_year_week` на `weekly_report_mv(project_id, report_year, report_week)`
|
||||
|
||||
Reference in New Issue
Block a user