Fix schema and add migration for incorrect subscriber count (null) in materialized view.

This commit is contained in:
Kailash Nadh 2024-12-04 23:06:49 +05:30
parent 5c0de6ef0b
commit 63712285aa
3 changed files with 38 additions and 2 deletions

View file

@ -40,6 +40,7 @@ var migList = []migFunc{
{"v3.0.0", migrations.V3_0_0},
{"v4.0.0", migrations.V4_0_0},
{"v4.1.0", migrations.V4_1_0},
{"v5.0.0", migrations.V5_0_0},
}
// upgrade upgrades the database to the current version by running SQL migration files

View file

@ -0,0 +1,35 @@
package migrations
import (
"log"
"github.com/jmoiron/sqlx"
"github.com/knadh/koanf/v2"
"github.com/knadh/stuffbin"
)
// V5_0_0 performs the DB migrations.
func V5_0_0(db *sqlx.DB, fs stuffbin.FileSystem, ko *koanf.Koanf, lo *log.Logger) error {
lo.Println("IMPORTANT: this upgrade might take a while if you have a large database. Please be patient ...")
if _, err := db.Exec(`
-- Create a new temp materialized view with the fixed query (removing COUNT(*) that returns 1 for NULLs)
CREATE MATERIALIZED VIEW IF NOT EXISTS mat_list_subscriber_stats_v5_0_0 AS
SELECT NOW() AS updated_at, lists.id AS list_id, subscriber_lists.status, COUNT(subscriber_lists.status) AS subscriber_count FROM lists
LEFT JOIN subscriber_lists ON (subscriber_lists.list_id = lists.id)
GROUP BY lists.id, subscriber_lists.status
UNION ALL
SELECT NOW() AS updated_at, 0 AS list_id, NULL AS status, COUNT(id) AS subscriber_count FROM subscribers;
-- Drop the old view and index.
DROP INDEX IF EXISTS mat_list_subscriber_stats_idx;
DROP MATERIALIZED VIEW IF EXISTS mat_list_subscriber_stats;
-- Rename the temp view and create an index.
ALTER MATERIALIZED VIEW mat_list_subscriber_stats_v5_0_0 RENAME TO mat_list_subscriber_stats;
CREATE UNIQUE INDEX IF NOT EXISTS mat_list_subscriber_stats_idx ON mat_list_subscriber_stats (list_id, status);
`); err != nil {
return err
}
return nil
}

View file

@ -422,9 +422,9 @@ DROP INDEX IF EXISTS mat_dashboard_charts_idx; CREATE UNIQUE INDEX mat_dashboard
-- subscriber counts stats for lists
DROP MATERIALIZED VIEW IF EXISTS mat_list_subscriber_stats;
CREATE MATERIALIZED VIEW mat_list_subscriber_stats AS
SELECT NOW() AS updated_at, lists.id AS list_id, subscriber_lists.status, COUNT(*) AS subscriber_count FROM lists
SELECT NOW() AS updated_at, lists.id AS list_id, subscriber_lists.status, COUNT(subscriber_lists.status) AS subscriber_count FROM lists
LEFT JOIN subscriber_lists ON (subscriber_lists.list_id = lists.id)
GROUP BY lists.id, subscriber_lists.status
UNION ALL
SELECT NOW() AS updated_at, 0 AS list_id, NULL AS status, COUNT(*) AS subscriber_count FROM subscribers;
SELECT NOW() AS updated_at, 0 AS list_id, NULL AS status, COUNT(id) AS subscriber_count FROM subscribers;
DROP INDEX IF EXISTS mat_list_subscriber_stats_idx; CREATE UNIQUE INDEX mat_list_subscriber_stats_idx ON mat_list_subscriber_stats (list_id, status);