perf(db): incremental user streaks cache
All checks were successful
continuous-integration/drone/push Build is passing

This commit is contained in:
Evan Reichard 2024-12-01 18:58:46 -05:00
parent 841b29c425
commit a193f97d29
3 changed files with 47 additions and 36 deletions

View File

@ -29,7 +29,7 @@ type DBManager struct {
var ddl string var ddl string
//go:embed user_streaks.sql //go:embed user_streaks.sql
var user_streaks_view string var user_streaks string
//go:embed document_user_statistics.sql //go:embed document_user_statistics.sql
var document_user_statistics string var document_user_statistics string
@ -107,12 +107,6 @@ func (dbm *DBManager) init() error {
return err return err
} }
// Execute views
if _, err := dbm.DB.Exec(user_streaks_view, nil); err != nil {
log.Panicf("Error executing views: %v", err)
return err
}
// Update settings // Update settings
err = dbm.updateSettings() err = dbm.updateSettings()
if err != nil { if err != nil {
@ -147,11 +141,7 @@ func (dbm *DBManager) Reload() error {
// CacheTempTables clears existing statistics and recalculates // CacheTempTables clears existing statistics and recalculates
func (dbm *DBManager) CacheTempTables() error { func (dbm *DBManager) CacheTempTables() error {
start := time.Now() start := time.Now()
user_streaks_sql := ` if _, err := dbm.DB.ExecContext(dbm.Ctx, user_streaks); err != nil {
DELETE FROM user_streaks;
INSERT INTO user_streaks SELECT * FROM view_user_streaks;
`
if _, err := dbm.DB.ExecContext(dbm.Ctx, user_streaks_sql); err != nil {
return err return err
} }
log.Debug("Cached 'user_streaks' in: ", time.Since(start)) log.Debug("Cached 'user_streaks' in: ", time.Since(start))

View File

@ -146,12 +146,8 @@ CREATE TABLE IF NOT EXISTS document_user_statistics (
UNIQUE(document_id, user_id) ON CONFLICT REPLACE UNIQUE(document_id, user_id) ON CONFLICT REPLACE
); );
--------------------------------------------------------------- -- User Streaks Table
----------------------- Temporary Tables ---------------------- CREATE TABLE IF NOT EXISTS user_streaks (
---------------------------------------------------------------
-- Temporary User Streaks Table (Cached from View)
CREATE TEMPORARY TABLE IF NOT EXISTS user_streaks (
user_id TEXT NOT NULL, user_id TEXT NOT NULL,
window TEXT NOT NULL, window TEXT NOT NULL,
@ -161,7 +157,13 @@ CREATE TEMPORARY TABLE IF NOT EXISTS user_streaks (
current_streak INTEGER NOT NULL, current_streak INTEGER NOT NULL,
current_streak_start_date TEXT NOT NULL, current_streak_start_date TEXT NOT NULL,
current_streak_end_date TEXT NOT NULL current_streak_end_date TEXT NOT NULL,
last_timezone TEXT NOT NULL,
last_seen TEXT NOT NULL,
last_calculated TEXT NOT NULL,
UNIQUE(user_id, window) ON CONFLICT REPLACE
); );
--------------------------------------------------------------- ---------------------------------------------------------------
@ -175,8 +177,6 @@ CREATE INDEX IF NOT EXISTS activity_user_id_document_id ON activity (
document_id document_id
); );
DROP VIEW IF EXISTS view_user_streaks;
--------------------------------------------------------------- ---------------------------------------------------------------
--------------------------- Triggers -------------------------- --------------------------- Triggers --------------------------
--------------------------------------------------------------- ---------------------------------------------------------------

View File

@ -1,14 +1,23 @@
--------------------------------------------------------------- WITH outdated_users AS (
---------------------------- Views ---------------------------- SELECT
--------------------------------------------------------------- a.user_id,
u.timezone AS last_timezone,
DATE(LOCAL_TIME(MAX(a.created_at), u.timezone)) AS last_seen,
DATE(LOCAL_TIME(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), u.timezone))
AS last_calculated
FROM activity AS a
LEFT JOIN users AS u ON u.id = a.user_id
LEFT JOIN user_streaks AS s ON a.user_id = s.user_id
GROUP BY a.user_id
HAVING
s.last_timezone != u.timezone
OR DATE(LOCAL_TIME(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), u.timezone))
!= COALESCE(s.last_calculated, '1970-01-01')
OR DATE(LOCAL_TIME(MAX(a.created_at), u.timezone))
!= COALESCE(s.last_seen, '1970-01-01')
),
-------------------------------- document_windows AS (
--------- User Streaks ---------
--------------------------------
CREATE VIEW view_user_streaks AS
WITH document_windows AS (
SELECT SELECT
activity.user_id, activity.user_id,
users.timezone, users.timezone,
@ -18,33 +27,37 @@ WITH document_windows AS (
) AS weekly_read, ) AS weekly_read,
DATE(LOCAL_TIME(activity.start_time, users.timezone)) AS daily_read DATE(LOCAL_TIME(activity.start_time, users.timezone)) AS daily_read
FROM activity FROM activity
INNER JOIN outdated_users ON outdated_users.user_id = activity.user_id
LEFT JOIN users ON users.id = activity.user_id LEFT JOIN users ON users.id = activity.user_id
GROUP BY activity.user_id, weekly_read, daily_read GROUP BY activity.user_id, weekly_read, daily_read
), ),
weekly_partitions AS ( weekly_partitions AS (
SELECT SELECT
user_id, user_id,
timezone, timezone,
'WEEK' AS "window", 'WEEK' AS "window",
weekly_read AS read_window, weekly_read AS read_window,
row_number() OVER ( ROW_NUMBER() OVER (
PARTITION BY user_id ORDER BY weekly_read DESC PARTITION BY user_id ORDER BY weekly_read DESC
) AS seqnum ) AS seqnum
FROM document_windows FROM document_windows
GROUP BY user_id, weekly_read GROUP BY user_id, weekly_read
), ),
daily_partitions AS ( daily_partitions AS (
SELECT SELECT
user_id, user_id,
timezone, timezone,
'DAY' AS "window", 'DAY' AS "window",
daily_read AS read_window, daily_read AS read_window,
row_number() OVER ( ROW_NUMBER() OVER (
PARTITION BY user_id ORDER BY daily_read DESC PARTITION BY user_id ORDER BY daily_read DESC
) AS seqnum ) AS seqnum
FROM document_windows FROM document_windows
GROUP BY user_id, daily_read GROUP BY user_id, daily_read
), ),
streaks AS ( streaks AS (
SELECT SELECT
COUNT(*) AS streak, COUNT(*) AS streak,
@ -74,6 +87,7 @@ streaks AS (
user_id, user_id,
DATE(read_window, '+' || (seqnum * 7) || ' day') DATE(read_window, '+' || (seqnum * 7) || ' day')
), ),
max_streak AS ( max_streak AS (
SELECT SELECT
MAX(streak) AS max_streak, MAX(streak) AS max_streak,
@ -84,6 +98,7 @@ max_streak AS (
FROM streaks FROM streaks
GROUP BY user_id, window GROUP BY user_id, window
), ),
current_streak AS ( current_streak AS (
SELECT SELECT
streak AS current_streak, streak AS current_streak,
@ -102,16 +117,22 @@ current_streak AS (
END END
GROUP BY user_id, window GROUP BY user_id, window
) )
INSERT INTO user_streaks
SELECT SELECT
max_streak.user_id, max_streak.user_id,
max_streak.window, max_streak.window,
IFNULL(max_streak, 0) AS max_streak, IFNULL(max_streak, 0) AS max_streak,
IFNULL(max_streak_start_date, "N/A") AS max_streak_start_date, IFNULL(max_streak_start_date, "N/A") AS max_streak_start_date,
IFNULL(max_streak_end_date, "N/A") AS max_streak_end_date, IFNULL(max_streak_end_date, "N/A") AS max_streak_end_date,
IFNULL(current_streak, 0) AS current_streak, IFNULL(current_streak.current_streak, 0) AS current_streak,
IFNULL(current_streak_start_date, "N/A") AS current_streak_start_date, IFNULL(current_streak.current_streak_start_date, "N/A") AS current_streak_start_date,
IFNULL(current_streak_end_date, "N/A") AS current_streak_end_date IFNULL(current_streak.current_streak_end_date, "N/A") AS current_streak_end_date,
outdated_users.last_timezone AS last_timezone,
outdated_users.last_seen AS last_seen,
outdated_users.last_calculated AS last_calculated
FROM max_streak FROM max_streak
JOIN outdated_users ON max_streak.user_id = outdated_users.user_id
LEFT JOIN current_streak ON LEFT JOIN current_streak ON
current_streak.user_id = max_streak.user_id current_streak.user_id = max_streak.user_id
AND current_streak.window = max_streak.window; AND current_streak.window = max_streak.window;