From f6dd8cee50e346c726b4ee9525cd1602846ef17d Mon Sep 17 00:00:00 2001 From: Evan Reichard Date: Sun, 1 Dec 2024 20:22:23 -0500 Subject: [PATCH] fix(streaks): incorrect calculation logic --- .drone.yml | 4 +++ database/manager.go | 32 ++++++++++++++++++++- database/models.go | 4 +++ database/query.sql | 12 ++++---- database/query.sql.go | 58 +++++++++++++++++++++------------------ database/schema.sql | 2 ++ database/user_streaks.sql | 46 +++++++++++++++++++++---------- 7 files changed, 109 insertions(+), 49 deletions(-) diff --git a/.drone.yml b/.drone.yml index 42ec2c8..3ad2a9d 100644 --- a/.drone.yml +++ b/.drone.yml @@ -2,6 +2,10 @@ kind: pipeline type: kubernetes name: default +trigger: + branch: + - master + steps: # Unit Tests - name: tests diff --git a/database/manager.go b/database/manager.go index 586d734..be4722f 100644 --- a/database/manager.go +++ b/database/manager.go @@ -44,6 +44,11 @@ func init() { Deterministic: true, Scalar: localTime, }) + sqlite.MustRegisterFunction("LOCAL_DATE", &sqlite.FunctionImpl{ + NArgs: 2, + Deterministic: true, + Scalar: localDate, + }) } // NewMgr Returns an initialized manager @@ -229,5 +234,30 @@ func localTime(ctx *sqlite.FunctionContext, args []driver.Value) (driver.Value, return nil, errors.New("unable to parse time") } - return formattedTime.In(timeZone).Format("2006-01-02 15:04:05.000"), nil + return formattedTime.In(timeZone).Format(time.RFC3339), nil +} + +// localDate is a custom SQL function that is registered as LOCAL_DATE in the init function +func localDate(ctx *sqlite.FunctionContext, args []driver.Value) (driver.Value, error) { + timeStr, ok := args[0].(string) + if !ok { + return nil, errors.New("both arguments to TZTime must be strings") + } + + timeZoneStr, ok := args[1].(string) + if !ok { + return nil, errors.New("both arguments to TZTime must be strings") + } + + timeZone, err := time.LoadLocation(timeZoneStr) + if err != nil { + return nil, errors.New("unable to parse timezone") + } + + formattedTime, err := time.ParseInLocation(time.RFC3339, timeStr, time.UTC) + if err != nil { + return nil, errors.New("unable to parse time") + } + + return formattedTime.In(timeZone).Format("2006-01-02"), nil } diff --git a/database/models.go b/database/models.go index 4bb9963..fdf3a67 100644 --- a/database/models.go +++ b/database/models.go @@ -116,4 +116,8 @@ type UserStreak struct { CurrentStreak int64 `json:"current_streak"` CurrentStreakStartDate string `json:"current_streak_start_date"` CurrentStreakEndDate string `json:"current_streak_end_date"` + LastTimezone string `json:"last_timezone"` + LastSeen string `json:"last_seen"` + LastRecord string `json:"last_record"` + LastCalculated string `json:"last_calculated"` } diff --git a/database/query.sql b/database/query.sql index 6028bd0..b46212f 100644 --- a/database/query.sql +++ b/database/query.sql @@ -67,7 +67,7 @@ WITH filtered_activity AS ( SELECT document_id, device_id, - CAST(STRFTIME('%Y-%m-%d %H:%M:%S', LOCAL_TIME(activity.start_time, users.timezone)) AS TEXT) AS start_time, + LOCAL_TIME(activity.start_time, users.timezone) AS start_time, title, author, duration, @@ -80,7 +80,7 @@ LEFT JOIN users ON users.id = activity.user_id; -- name: GetDailyReadStats :many WITH RECURSIVE last_30_days AS ( - SELECT DATE(LOCAL_TIME(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone)) AS date + SELECT LOCAL_DATE(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone) AS date FROM users WHERE users.id = $user_id UNION ALL SELECT DATE(date, '-1 days') @@ -99,7 +99,7 @@ filtered_activity AS ( activity_days AS ( SELECT SUM(duration) AS seconds_read, - DATE(LOCAL_TIME(start_time, timezone)) AS day + LOCAL_DATE(start_time, timezone) AS day FROM filtered_activity AS activity LEFT JOIN users ON users.id = activity.user_id GROUP BY day @@ -138,8 +138,8 @@ WHERE id = $device_id LIMIT 1; SELECT devices.id, devices.device_name, - CAST(STRFTIME('%Y-%m-%d %H:%M:%S', LOCAL_TIME(devices.created_at, users.timezone)) AS TEXT) AS created_at, - CAST(STRFTIME('%Y-%m-%d %H:%M:%S', LOCAL_TIME(devices.last_synced, users.timezone)) AS TEXT) AS last_synced + LOCAL_TIME(devices.created_at, users.timezone) AS created_at, + LOCAL_TIME(devices.last_synced, users.timezone) AS last_synced FROM devices JOIN users ON users.id = devices.user_id WHERE users.id = $user_id @@ -283,7 +283,7 @@ SELECT ROUND(CAST(progress.percentage AS REAL) * 100, 2) AS percentage, progress.document_id, progress.user_id, - CAST(STRFTIME('%Y-%m-%d %H:%M:%S', LOCAL_TIME(progress.created_at, users.timezone)) AS TEXT) AS created_at + LOCAL_TIME(progress.created_at, users.timezone) AS created_at FROM document_progress AS progress LEFT JOIN users ON progress.user_id = users.id LEFT JOIN devices ON progress.device_id = devices.id diff --git a/database/query.sql.go b/database/query.sql.go index 3ee91bd..5579260 100644 --- a/database/query.sql.go +++ b/database/query.sql.go @@ -193,7 +193,7 @@ WITH filtered_activity AS ( SELECT document_id, device_id, - CAST(STRFTIME('%Y-%m-%d %H:%M:%S', LOCAL_TIME(activity.start_time, users.timezone)) AS TEXT) AS start_time, + LOCAL_TIME(activity.start_time, users.timezone) AS start_time, title, author, duration, @@ -214,15 +214,15 @@ type GetActivityParams struct { } type GetActivityRow struct { - DocumentID string `json:"document_id"` - DeviceID string `json:"device_id"` - StartTime string `json:"start_time"` - Title *string `json:"title"` - Author *string `json:"author"` - Duration int64 `json:"duration"` - StartPercentage float64 `json:"start_percentage"` - EndPercentage float64 `json:"end_percentage"` - ReadPercentage float64 `json:"read_percentage"` + DocumentID string `json:"document_id"` + DeviceID string `json:"device_id"` + StartTime interface{} `json:"start_time"` + Title *string `json:"title"` + Author *string `json:"author"` + Duration int64 `json:"duration"` + StartPercentage float64 `json:"start_percentage"` + EndPercentage float64 `json:"end_percentage"` + ReadPercentage float64 `json:"read_percentage"` } func (q *Queries) GetActivity(ctx context.Context, arg GetActivityParams) ([]GetActivityRow, error) { @@ -266,7 +266,7 @@ func (q *Queries) GetActivity(ctx context.Context, arg GetActivityParams) ([]Get const getDailyReadStats = `-- name: GetDailyReadStats :many WITH RECURSIVE last_30_days AS ( - SELECT DATE(LOCAL_TIME(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone)) AS date + SELECT LOCAL_DATE(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone) AS date FROM users WHERE users.id = ?1 UNION ALL SELECT DATE(date, '-1 days') @@ -285,7 +285,7 @@ filtered_activity AS ( activity_days AS ( SELECT SUM(duration) AS seconds_read, - DATE(LOCAL_TIME(start_time, timezone)) AS day + LOCAL_DATE(start_time, timezone) AS day FROM filtered_activity AS activity LEFT JOIN users ON users.id = activity.user_id GROUP BY day @@ -422,8 +422,8 @@ const getDevices = `-- name: GetDevices :many SELECT devices.id, devices.device_name, - CAST(STRFTIME('%Y-%m-%d %H:%M:%S', LOCAL_TIME(devices.created_at, users.timezone)) AS TEXT) AS created_at, - CAST(STRFTIME('%Y-%m-%d %H:%M:%S', LOCAL_TIME(devices.last_synced, users.timezone)) AS TEXT) AS last_synced + LOCAL_TIME(devices.created_at, users.timezone) AS created_at, + LOCAL_TIME(devices.last_synced, users.timezone) AS last_synced FROM devices JOIN users ON users.id = devices.user_id WHERE users.id = ?1 @@ -431,10 +431,10 @@ ORDER BY devices.last_synced DESC ` type GetDevicesRow struct { - ID string `json:"id"` - DeviceName string `json:"device_name"` - CreatedAt string `json:"created_at"` - LastSynced string `json:"last_synced"` + ID string `json:"id"` + DeviceName string `json:"device_name"` + CreatedAt interface{} `json:"created_at"` + LastSynced interface{} `json:"last_synced"` } func (q *Queries) GetDevices(ctx context.Context, userID string) ([]GetDevicesRow, error) { @@ -902,7 +902,7 @@ SELECT ROUND(CAST(progress.percentage AS REAL) * 100, 2) AS percentage, progress.document_id, progress.user_id, - CAST(STRFTIME('%Y-%m-%d %H:%M:%S', LOCAL_TIME(progress.created_at, users.timezone)) AS TEXT) AS created_at + LOCAL_TIME(progress.created_at, users.timezone) AS created_at FROM document_progress AS progress LEFT JOIN users ON progress.user_id = users.id LEFT JOIN devices ON progress.device_id = devices.id @@ -929,13 +929,13 @@ type GetProgressParams struct { } type GetProgressRow struct { - Title *string `json:"title"` - Author *string `json:"author"` - DeviceName string `json:"device_name"` - Percentage float64 `json:"percentage"` - DocumentID string `json:"document_id"` - UserID string `json:"user_id"` - CreatedAt string `json:"created_at"` + Title *string `json:"title"` + Author *string `json:"author"` + DeviceName string `json:"device_name"` + Percentage float64 `json:"percentage"` + DocumentID string `json:"document_id"` + UserID string `json:"user_id"` + CreatedAt interface{} `json:"created_at"` } func (q *Queries) GetProgress(ctx context.Context, arg GetProgressParams) ([]GetProgressRow, error) { @@ -1078,7 +1078,7 @@ func (q *Queries) GetUserStatistics(ctx context.Context) ([]GetUserStatisticsRow } const getUserStreaks = `-- name: GetUserStreaks :many -SELECT user_id, "window", max_streak, max_streak_start_date, max_streak_end_date, current_streak, current_streak_start_date, current_streak_end_date FROM user_streaks +SELECT user_id, "window", max_streak, max_streak_start_date, max_streak_end_date, current_streak, current_streak_start_date, current_streak_end_date, last_timezone, last_seen, last_record, last_calculated FROM user_streaks WHERE user_id = ?1 ` @@ -1100,6 +1100,10 @@ func (q *Queries) GetUserStreaks(ctx context.Context, userID string) ([]UserStre &i.CurrentStreak, &i.CurrentStreakStartDate, &i.CurrentStreakEndDate, + &i.LastTimezone, + &i.LastSeen, + &i.LastRecord, + &i.LastCalculated, ); err != nil { return nil, err } diff --git a/database/schema.sql b/database/schema.sql index 117e1be..8451df8 100644 --- a/database/schema.sql +++ b/database/schema.sql @@ -161,6 +161,7 @@ CREATE TABLE IF NOT EXISTS user_streaks ( last_timezone TEXT NOT NULL, last_seen TEXT NOT NULL, + last_record TEXT NOT NULL, last_calculated TEXT NOT NULL, UNIQUE(user_id, window) ON CONFLICT REPLACE @@ -171,6 +172,7 @@ CREATE TABLE IF NOT EXISTS user_streaks ( --------------------------------------------------------------- CREATE INDEX IF NOT EXISTS activity_start_time ON activity (start_time); +CREATE INDEX IF NOT EXISTS activity_created_at ON activity (created_at); CREATE INDEX IF NOT EXISTS activity_user_id ON activity (user_id); CREATE INDEX IF NOT EXISTS activity_user_id_document_id ON activity ( user_id, diff --git a/database/user_streaks.sql b/database/user_streaks.sql index bc2854b..eaa3774 100644 --- a/database/user_streaks.sql +++ b/database/user_streaks.sql @@ -1,20 +1,35 @@ -WITH outdated_users AS ( +WITH updated_users AS ( + SELECT a.user_id + 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 AND s.window = 'DAY' + WHERE + a.created_at > COALESCE(s.last_seen, '1970-01-01') + AND LOCAL_DATE(s.last_record, u.timezone) != LOCAL_DATE(a.start_time, u.timezone) + GROUP BY a.user_id +), + +outdated_users AS ( 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 + MAX(a.created_at) AS last_seen, + MAX(a.start_time) AS last_record, + STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now') 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 + LEFT JOIN user_streaks AS s ON a.user_id = s.user_id AND s.window = 'DAY' GROUP BY a.user_id HAVING + -- User Changed Timezones 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') + + -- Users Date Changed + OR LOCAL_DATE(COALESCE(s.last_calculated, '1970-01-01T00:00:00Z'), u.timezone) != + LOCAL_DATE(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), u.timezone) + + -- User Added New Data + OR a.user_id IN updated_users ), document_windows AS ( @@ -22,10 +37,10 @@ document_windows AS ( activity.user_id, users.timezone, DATE( - LOCAL_TIME(activity.start_time, users.timezone), + LOCAL_DATE(activity.start_time, users.timezone), 'weekday 0', '-7 day' ) AS weekly_read, - DATE(LOCAL_TIME(activity.start_time, users.timezone)) AS daily_read + LOCAL_DATE(activity.start_time, users.timezone) AS daily_read FROM activity INNER JOIN outdated_users ON outdated_users.user_id = activity.user_id LEFT JOIN users ON users.id = activity.user_id @@ -109,11 +124,11 @@ current_streak AS ( FROM streaks WHERE CASE WHEN window = "WEEK" THEN - DATE(LOCAL_TIME(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone), 'weekday 0', '-14 day') = current_streak_end_date - OR DATE(LOCAL_TIME(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone), 'weekday 0', '-7 day') = current_streak_end_date + DATE(LOCAL_DATE(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone), 'weekday 0', '-14 day') = current_streak_end_date + OR DATE(LOCAL_DATE(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone), 'weekday 0', '-7 day') = current_streak_end_date WHEN window = "DAY" THEN - DATE(LOCAL_TIME(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone), '-1 day') = current_streak_end_date - OR DATE(LOCAL_TIME(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone)) = current_streak_end_date + DATE(LOCAL_DATE(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone), '-1 day') = current_streak_end_date + OR DATE(LOCAL_DATE(STRFTIME('%Y-%m-%dT%H:%M:%SZ', 'now'), timezone)) = current_streak_end_date END GROUP BY user_id, window ) @@ -130,6 +145,7 @@ SELECT 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_record AS last_record, outdated_users.last_calculated AS last_calculated FROM max_streak JOIN outdated_users ON max_streak.user_id = outdated_users.user_id