Fix: Исправление определения недели на границе года (ISOYEAR)

- Заменен EXTRACT(YEAR) на EXTRACT(ISOYEAR) в materialized view для корректной работы на границе года
- Обновлена миграция 001_create_schema.sql для использования ISOYEAR
- Создана миграция 006_fix_weekly_report_mv_structure.sql для исправления структуры view (LEFT JOIN)
- Добавлен endpoint /admin/recreate-mv для пересоздания materialized view
- Обновлена документация миграций в README.md
- Обновлены зависимости Go (go.mod, go.sum)
This commit is contained in:
poignatov
2025-12-29 20:58:34 +03:00
parent 4f8a793377
commit 8d79a8f692
6 changed files with 151 additions and 8 deletions

View File

@@ -73,9 +73,10 @@ FROM
LEFT JOIN
(
-- 1. Предварительная агрегация: суммируем score по неделям
-- Используем ISOYEAR для корректной работы на границе года
SELECT
n.project_id,
EXTRACT(YEAR FROM e.created_date)::INTEGER AS report_year,
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
@@ -101,5 +102,5 @@ COMMENT ON TABLE projects IS 'Projects table storing project information with pr
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';
COMMENT ON MATERIALIZED VIEW weekly_report_mv IS 'Materialized view aggregating weekly scores by project using ISOYEAR for correct week calculations at year boundaries';

View File

@@ -0,0 +1,46 @@
-- Migration: Fix weekly_report_mv structure to include all projects via LEFT JOIN
-- This ensures the view structure matches the code in main.go
-- Date: 2024-12-29
--
-- Issue: Migration 005 created the view without LEFT JOIN to projects table,
-- which means projects without data were not included in the view.
-- This migration fixes the structure to match main.go implementation.
-- Drop existing materialized view
DROP MATERIALIZED VIEW IF EXISTS weekly_report_mv;
-- Recreate materialized view with correct structure (LEFT JOIN with projects)
-- This ensures all projects are included, even if they have no data for a given week
CREATE MATERIALIZED VIEW weekly_report_mv AS
SELECT
p.id AS project_id,
agg.report_year,
agg.report_week,
COALESCE(agg.total_score, 0.0000) AS total_score
FROM
projects p
LEFT JOIN
(
SELECT
n.project_id,
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
) agg
ON p.id = agg.project_id
ORDER BY
p.id, agg.report_year, agg.report_week
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 at year boundaries. Includes all projects via LEFT JOIN.';

View File

@@ -57,6 +57,33 @@ docker-compose exec db psql -U playeng -d playeng -f /migrations/001_create_sche
- `report_week` (INTEGER)
- `total_score` (NUMERIC)
## Миграции
### Порядок применения миграций
1. **001_create_schema.sql** - Создание базовой структуры (таблицы, индексы, materialized view)
2. **002_add_dictionaries.sql** - Добавление таблиц для словарей
3. **003_remove_words_unique_constraint.sql** - Удаление уникального ограничения на words.name
4. **004_add_config_dictionaries.sql** - Добавление связи между конфигурациями и словарями
5. **005_fix_weekly_report_mv.sql** - Исправление использования ISOYEAR вместо YEAR для корректной работы на границе года
6. **006_fix_weekly_report_mv_structure.sql** - Исправление структуры view (добавление LEFT JOIN для включения всех проектов)
### Применение миграций
Для существующей базы данных применяйте миграции последовательно:
```bash
psql -U playeng -d playeng -f migrations/005_fix_weekly_report_mv.sql
psql -U playeng -d playeng -f migrations/006_fix_weekly_report_mv_structure.sql
```
Или через docker-compose:
```bash
docker-compose exec db psql -U playeng -d playeng -f /migrations/005_fix_weekly_report_mv.sql
docker-compose exec db psql -U playeng -d playeng -f /migrations/006_fix_weekly_report_mv_structure.sql
```
## Обновление Materialized View
После изменения данных в таблицах `nodes` или `entries`, необходимо обновить materialized view: