Files
play-life/play-life-backend/migrations/006_fix_weekly_report_mv_structure.sql
poignatov 8d79a8f692 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)
2025-12-29 20:58:34 +03:00

47 lines
1.6 KiB
SQL

-- 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.';