This commit is contained in:
@@ -61,14 +61,23 @@ type DocumentProgress struct {
|
||||
}
|
||||
|
||||
type DocumentUserStatistic struct {
|
||||
DocumentID string `json:"document_id"`
|
||||
UserID string `json:"user_id"`
|
||||
LastRead string `json:"last_read"`
|
||||
TotalTimeSeconds int64 `json:"total_time_seconds"`
|
||||
ReadPercentage float64 `json:"read_percentage"`
|
||||
Percentage float64 `json:"percentage"`
|
||||
WordsRead int64 `json:"words_read"`
|
||||
Wpm float64 `json:"wpm"`
|
||||
DocumentID string `json:"document_id"`
|
||||
UserID string `json:"user_id"`
|
||||
Percentage float64 `json:"percentage"`
|
||||
LastRead string `json:"last_read"`
|
||||
ReadPercentage float64 `json:"read_percentage"`
|
||||
TotalTimeSeconds int64 `json:"total_time_seconds"`
|
||||
TotalWordsRead int64 `json:"total_words_read"`
|
||||
TotalWpm float64 `json:"total_wpm"`
|
||||
YearlyTimeSeconds int64 `json:"yearly_time_seconds"`
|
||||
YearlyWordsRead int64 `json:"yearly_words_read"`
|
||||
YearlyWpm float64 `json:"yearly_wpm"`
|
||||
MonthlyTimeSeconds int64 `json:"monthly_time_seconds"`
|
||||
MonthlyWordsRead int64 `json:"monthly_words_read"`
|
||||
MonthlyWpm float64 `json:"monthly_wpm"`
|
||||
WeeklyTimeSeconds int64 `json:"weekly_time_seconds"`
|
||||
WeeklyWordsRead int64 `json:"weekly_words_read"`
|
||||
WeeklyWpm float64 `json:"weekly_wpm"`
|
||||
}
|
||||
|
||||
type Metadatum struct {
|
||||
@@ -104,14 +113,23 @@ type UserStreak struct {
|
||||
}
|
||||
|
||||
type ViewDocumentUserStatistic struct {
|
||||
DocumentID string `json:"document_id"`
|
||||
UserID string `json:"user_id"`
|
||||
LastRead interface{} `json:"last_read"`
|
||||
TotalTimeSeconds sql.NullFloat64 `json:"total_time_seconds"`
|
||||
ReadPercentage sql.NullFloat64 `json:"read_percentage"`
|
||||
Percentage float64 `json:"percentage"`
|
||||
WordsRead interface{} `json:"words_read"`
|
||||
Wpm int64 `json:"wpm"`
|
||||
DocumentID string `json:"document_id"`
|
||||
UserID string `json:"user_id"`
|
||||
Percentage float64 `json:"percentage"`
|
||||
LastRead interface{} `json:"last_read"`
|
||||
ReadPercentage sql.NullFloat64 `json:"read_percentage"`
|
||||
TotalTimeSeconds sql.NullFloat64 `json:"total_time_seconds"`
|
||||
TotalWordsRead interface{} `json:"total_words_read"`
|
||||
TotalWpm int64 `json:"total_wpm"`
|
||||
YearlyTimeSeconds sql.NullFloat64 `json:"yearly_time_seconds"`
|
||||
YearlyWordsRead interface{} `json:"yearly_words_read"`
|
||||
YearlyWpm interface{} `json:"yearly_wpm"`
|
||||
MonthlyTimeSeconds sql.NullFloat64 `json:"monthly_time_seconds"`
|
||||
MonthlyWordsRead interface{} `json:"monthly_words_read"`
|
||||
MonthlyWpm interface{} `json:"monthly_wpm"`
|
||||
WeeklyTimeSeconds sql.NullFloat64 `json:"weekly_time_seconds"`
|
||||
WeeklyWordsRead interface{} `json:"weekly_words_read"`
|
||||
WeeklyWpm interface{} `json:"weekly_wpm"`
|
||||
}
|
||||
|
||||
type ViewUserStreak struct {
|
||||
|
||||
@@ -171,7 +171,7 @@ SELECT
|
||||
docs.filepath,
|
||||
docs.words,
|
||||
|
||||
CAST(COALESCE(dus.wpm, 0.0) AS INTEGER) AS wpm,
|
||||
CAST(COALESCE(dus.total_wpm, 0.0) AS INTEGER) AS wpm,
|
||||
COALESCE(dus.read_percentage, 0) AS read_percentage,
|
||||
COALESCE(dus.total_time_seconds, 0) AS total_time_seconds,
|
||||
STRFTIME('%Y-%m-%d %H:%M:%S', COALESCE(dus.last_read, "1970-01-01"), users.time_offset)
|
||||
@@ -223,7 +223,7 @@ SELECT
|
||||
docs.filepath,
|
||||
docs.words,
|
||||
|
||||
CAST(COALESCE(dus.wpm, 0.0) AS INTEGER) AS wpm,
|
||||
CAST(COALESCE(dus.total_wpm, 0.0) AS INTEGER) AS wpm,
|
||||
COALESCE(dus.read_percentage, 0) AS read_percentage,
|
||||
COALESCE(dus.total_time_seconds, 0) AS total_time_seconds,
|
||||
STRFTIME('%Y-%m-%d %H:%M:%S', COALESCE(dus.last_read, "1970-01-01"), users.time_offset)
|
||||
@@ -308,17 +308,34 @@ WHERE user_id = $user_id;
|
||||
-- name: GetUsers :many
|
||||
SELECT * FROM users;
|
||||
|
||||
-- name: GetWPMLeaderboard :many
|
||||
-- name: GetUserStatistics :many
|
||||
SELECT
|
||||
user_id,
|
||||
CAST(SUM(words_read) AS INTEGER) AS total_words_read,
|
||||
|
||||
CAST(SUM(total_words_read) AS INTEGER) AS total_words_read,
|
||||
CAST(SUM(total_time_seconds) AS INTEGER) AS total_seconds,
|
||||
ROUND(CAST(SUM(words_read) AS REAL) / (SUM(total_time_seconds) / 60.0), 2)
|
||||
AS wpm
|
||||
ROUND(CAST(SUM(total_words_read) AS REAL) / (SUM(total_time_seconds) / 60.0), 2)
|
||||
AS total_wpm,
|
||||
|
||||
CAST(SUM(yearly_words_read) AS INTEGER) AS yearly_words_read,
|
||||
CAST(SUM(yearly_time_seconds) AS INTEGER) AS yearly_seconds,
|
||||
ROUND(CAST(SUM(yearly_words_read) AS REAL) / (SUM(yearly_time_seconds) / 60.0), 2)
|
||||
AS yearly_wpm,
|
||||
|
||||
CAST(SUM(monthly_words_read) AS INTEGER) AS monthly_words_read,
|
||||
CAST(SUM(monthly_time_seconds) AS INTEGER) AS monthly_seconds,
|
||||
ROUND(CAST(SUM(monthly_words_read) AS REAL) / (SUM(monthly_time_seconds) / 60.0), 2)
|
||||
AS monthly_wpm,
|
||||
|
||||
CAST(SUM(weekly_words_read) AS INTEGER) AS weekly_words_read,
|
||||
CAST(SUM(weekly_time_seconds) AS INTEGER) AS weekly_seconds,
|
||||
ROUND(CAST(SUM(weekly_words_read) AS REAL) / (SUM(weekly_time_seconds) / 60.0), 2)
|
||||
AS weekly_wpm
|
||||
|
||||
FROM document_user_statistics
|
||||
WHERE words_read > 0
|
||||
WHERE total_words_read > 0
|
||||
GROUP BY user_id
|
||||
ORDER BY wpm DESC;
|
||||
ORDER BY total_wpm DESC;
|
||||
|
||||
-- name: GetWantedDocuments :many
|
||||
SELECT
|
||||
|
||||
@@ -534,7 +534,7 @@ SELECT
|
||||
docs.filepath,
|
||||
docs.words,
|
||||
|
||||
CAST(COALESCE(dus.wpm, 0.0) AS INTEGER) AS wpm,
|
||||
CAST(COALESCE(dus.total_wpm, 0.0) AS INTEGER) AS wpm,
|
||||
COALESCE(dus.read_percentage, 0) AS read_percentage,
|
||||
COALESCE(dus.total_time_seconds, 0) AS total_time_seconds,
|
||||
STRFTIME('%Y-%m-%d %H:%M:%S', COALESCE(dus.last_read, "1970-01-01"), users.time_offset)
|
||||
@@ -688,7 +688,7 @@ SELECT
|
||||
docs.filepath,
|
||||
docs.words,
|
||||
|
||||
CAST(COALESCE(dus.wpm, 0.0) AS INTEGER) AS wpm,
|
||||
CAST(COALESCE(dus.total_wpm, 0.0) AS INTEGER) AS wpm,
|
||||
COALESCE(dus.read_percentage, 0) AS read_percentage,
|
||||
COALESCE(dus.total_time_seconds, 0) AS total_time_seconds,
|
||||
STRFTIME('%Y-%m-%d %H:%M:%S', COALESCE(dus.last_read, "1970-01-01"), users.time_offset)
|
||||
@@ -971,6 +971,89 @@ func (q *Queries) GetUser(ctx context.Context, userID string) (User, error) {
|
||||
return i, err
|
||||
}
|
||||
|
||||
const getUserStatistics = `-- name: GetUserStatistics :many
|
||||
SELECT
|
||||
user_id,
|
||||
|
||||
CAST(SUM(total_words_read) AS INTEGER) AS total_words_read,
|
||||
CAST(SUM(total_time_seconds) AS INTEGER) AS total_seconds,
|
||||
ROUND(CAST(SUM(total_words_read) AS REAL) / (SUM(total_time_seconds) / 60.0), 2)
|
||||
AS total_wpm,
|
||||
|
||||
CAST(SUM(yearly_words_read) AS INTEGER) AS yearly_words_read,
|
||||
CAST(SUM(yearly_time_seconds) AS INTEGER) AS yearly_seconds,
|
||||
ROUND(CAST(SUM(yearly_words_read) AS REAL) / (SUM(yearly_time_seconds) / 60.0), 2)
|
||||
AS yearly_wpm,
|
||||
|
||||
CAST(SUM(monthly_words_read) AS INTEGER) AS monthly_words_read,
|
||||
CAST(SUM(monthly_time_seconds) AS INTEGER) AS monthly_seconds,
|
||||
ROUND(CAST(SUM(monthly_words_read) AS REAL) / (SUM(monthly_time_seconds) / 60.0), 2)
|
||||
AS monthly_wpm,
|
||||
|
||||
CAST(SUM(weekly_words_read) AS INTEGER) AS weekly_words_read,
|
||||
CAST(SUM(weekly_time_seconds) AS INTEGER) AS weekly_seconds,
|
||||
ROUND(CAST(SUM(weekly_words_read) AS REAL) / (SUM(weekly_time_seconds) / 60.0), 2)
|
||||
AS weekly_wpm
|
||||
|
||||
FROM document_user_statistics
|
||||
WHERE total_words_read > 0
|
||||
GROUP BY user_id
|
||||
ORDER BY total_wpm DESC
|
||||
`
|
||||
|
||||
type GetUserStatisticsRow struct {
|
||||
UserID string `json:"user_id"`
|
||||
TotalWordsRead int64 `json:"total_words_read"`
|
||||
TotalSeconds int64 `json:"total_seconds"`
|
||||
TotalWpm float64 `json:"total_wpm"`
|
||||
YearlyWordsRead int64 `json:"yearly_words_read"`
|
||||
YearlySeconds int64 `json:"yearly_seconds"`
|
||||
YearlyWpm float64 `json:"yearly_wpm"`
|
||||
MonthlyWordsRead int64 `json:"monthly_words_read"`
|
||||
MonthlySeconds int64 `json:"monthly_seconds"`
|
||||
MonthlyWpm float64 `json:"monthly_wpm"`
|
||||
WeeklyWordsRead int64 `json:"weekly_words_read"`
|
||||
WeeklySeconds int64 `json:"weekly_seconds"`
|
||||
WeeklyWpm float64 `json:"weekly_wpm"`
|
||||
}
|
||||
|
||||
func (q *Queries) GetUserStatistics(ctx context.Context) ([]GetUserStatisticsRow, error) {
|
||||
rows, err := q.db.QueryContext(ctx, getUserStatistics)
|
||||
if err != nil {
|
||||
return nil, err
|
||||
}
|
||||
defer rows.Close()
|
||||
var items []GetUserStatisticsRow
|
||||
for rows.Next() {
|
||||
var i GetUserStatisticsRow
|
||||
if err := rows.Scan(
|
||||
&i.UserID,
|
||||
&i.TotalWordsRead,
|
||||
&i.TotalSeconds,
|
||||
&i.TotalWpm,
|
||||
&i.YearlyWordsRead,
|
||||
&i.YearlySeconds,
|
||||
&i.YearlyWpm,
|
||||
&i.MonthlyWordsRead,
|
||||
&i.MonthlySeconds,
|
||||
&i.MonthlyWpm,
|
||||
&i.WeeklyWordsRead,
|
||||
&i.WeeklySeconds,
|
||||
&i.WeeklyWpm,
|
||||
); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
items = append(items, i)
|
||||
}
|
||||
if err := rows.Close(); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
if err := rows.Err(); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
return items, nil
|
||||
}
|
||||
|
||||
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
|
||||
WHERE user_id = ?1
|
||||
@@ -1041,54 +1124,6 @@ func (q *Queries) GetUsers(ctx context.Context) ([]User, error) {
|
||||
return items, nil
|
||||
}
|
||||
|
||||
const getWPMLeaderboard = `-- name: GetWPMLeaderboard :many
|
||||
SELECT
|
||||
user_id,
|
||||
CAST(SUM(words_read) AS INTEGER) AS total_words_read,
|
||||
CAST(SUM(total_time_seconds) AS INTEGER) AS total_seconds,
|
||||
ROUND(CAST(SUM(words_read) AS REAL) / (SUM(total_time_seconds) / 60.0), 2)
|
||||
AS wpm
|
||||
FROM document_user_statistics
|
||||
WHERE words_read > 0
|
||||
GROUP BY user_id
|
||||
ORDER BY wpm DESC
|
||||
`
|
||||
|
||||
type GetWPMLeaderboardRow struct {
|
||||
UserID string `json:"user_id"`
|
||||
TotalWordsRead int64 `json:"total_words_read"`
|
||||
TotalSeconds int64 `json:"total_seconds"`
|
||||
Wpm float64 `json:"wpm"`
|
||||
}
|
||||
|
||||
func (q *Queries) GetWPMLeaderboard(ctx context.Context) ([]GetWPMLeaderboardRow, error) {
|
||||
rows, err := q.db.QueryContext(ctx, getWPMLeaderboard)
|
||||
if err != nil {
|
||||
return nil, err
|
||||
}
|
||||
defer rows.Close()
|
||||
var items []GetWPMLeaderboardRow
|
||||
for rows.Next() {
|
||||
var i GetWPMLeaderboardRow
|
||||
if err := rows.Scan(
|
||||
&i.UserID,
|
||||
&i.TotalWordsRead,
|
||||
&i.TotalSeconds,
|
||||
&i.Wpm,
|
||||
); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
items = append(items, i)
|
||||
}
|
||||
if err := rows.Close(); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
if err := rows.Err(); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
return items, nil
|
||||
}
|
||||
|
||||
const getWantedDocuments = `-- name: GetWantedDocuments :many
|
||||
SELECT
|
||||
CAST(value AS TEXT) AS id,
|
||||
|
||||
@@ -128,15 +128,29 @@ CREATE TEMPORARY TABLE IF NOT EXISTS user_streaks (
|
||||
current_streak_end_date TEXT NOT NULL
|
||||
);
|
||||
|
||||
-- Temporary Document User Statistics Table (Cached from View)
|
||||
CREATE TEMPORARY TABLE IF NOT EXISTS document_user_statistics (
|
||||
document_id TEXT NOT NULL,
|
||||
user_id TEXT NOT NULL,
|
||||
last_read TEXT NOT NULL,
|
||||
total_time_seconds INTEGER NOT NULL,
|
||||
read_percentage REAL NOT NULL,
|
||||
percentage REAL NOT NULL,
|
||||
words_read INTEGER NOT NULL,
|
||||
wpm REAL NOT NULL,
|
||||
last_read TEXT NOT NULL,
|
||||
read_percentage REAL NOT NULL,
|
||||
|
||||
total_time_seconds INTEGER NOT NULL,
|
||||
total_words_read INTEGER NOT NULL,
|
||||
total_wpm REAL NOT NULL,
|
||||
|
||||
yearly_time_seconds INTEGER NOT NULL,
|
||||
yearly_words_read INTEGER NOT NULL,
|
||||
yearly_wpm REAL NOT NULL,
|
||||
|
||||
monthly_time_seconds INTEGER NOT NULL,
|
||||
monthly_words_read INTEGER NOT NULL,
|
||||
monthly_wpm REAL NOT NULL,
|
||||
|
||||
weekly_time_seconds INTEGER NOT NULL,
|
||||
weekly_words_read INTEGER NOT NULL,
|
||||
weekly_wpm REAL NOT NULL,
|
||||
|
||||
UNIQUE(document_id, user_id) ON CONFLICT REPLACE
|
||||
);
|
||||
@@ -177,7 +191,6 @@ WITH document_windows AS (
|
||||
LEFT JOIN users ON users.id = activity.user_id
|
||||
GROUP BY activity.user_id, weekly_read, daily_read
|
||||
),
|
||||
|
||||
weekly_partitions AS (
|
||||
SELECT
|
||||
user_id,
|
||||
@@ -190,7 +203,6 @@ weekly_partitions AS (
|
||||
FROM document_windows
|
||||
GROUP BY user_id, weekly_read
|
||||
),
|
||||
|
||||
daily_partitions AS (
|
||||
SELECT
|
||||
user_id,
|
||||
@@ -203,7 +215,6 @@ daily_partitions AS (
|
||||
FROM document_windows
|
||||
GROUP BY user_id, daily_read
|
||||
),
|
||||
|
||||
streaks AS (
|
||||
SELECT
|
||||
COUNT(*) AS streak,
|
||||
@@ -327,8 +338,8 @@ current_progress AS (
|
||||
WHERE
|
||||
dp.user_id = iga.user_id
|
||||
AND dp.document_id = iga.document_id
|
||||
ORDER BY created_at DESC
|
||||
LIMIT 1
|
||||
ORDER BY created_at DESC
|
||||
LIMIT 1
|
||||
), end_percentage) AS percentage
|
||||
FROM intermediate_ga AS iga
|
||||
GROUP BY user_id, document_id
|
||||
@@ -338,25 +349,121 @@ current_progress AS (
|
||||
SELECT
|
||||
ga.document_id,
|
||||
ga.user_id,
|
||||
MAX(start_time) AS last_read,
|
||||
SUM(duration) AS total_time_seconds,
|
||||
SUM(read_percentage) AS read_percentage,
|
||||
cp.percentage,
|
||||
MAX(start_time) AS last_read,
|
||||
SUM(read_percentage) AS read_percentage,
|
||||
|
||||
-- All Time WPM
|
||||
SUM(duration) AS total_time_seconds,
|
||||
(CAST(COALESCE(d.words, 0.0) AS REAL) * SUM(read_percentage))
|
||||
AS words_read,
|
||||
AS total_words_read,
|
||||
(CAST(COALESCE(d.words, 0.0) AS REAL) * SUM(read_percentage))
|
||||
/ (SUM(duration) / 60.0) AS total_wpm,
|
||||
|
||||
-- Yearly WPM
|
||||
SUM(CASE WHEN start_time >= DATE('now', '-1 year') THEN duration ELSE 0 END)
|
||||
AS yearly_time_seconds,
|
||||
(
|
||||
CAST(COALESCE(d.words, 0.0) AS REAL)
|
||||
* SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-1 year') THEN read_percentage
|
||||
ELSE 0
|
||||
END
|
||||
)
|
||||
)
|
||||
AS yearly_words_read,
|
||||
COALESCE((
|
||||
CAST(COALESCE(d.words, 0.0) AS REAL)
|
||||
* SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-1 year') THEN read_percentage
|
||||
END
|
||||
)
|
||||
)
|
||||
/ (
|
||||
SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-1 year') THEN duration
|
||||
END
|
||||
)
|
||||
/ 60.0
|
||||
), 0.0)
|
||||
AS yearly_wpm,
|
||||
|
||||
-- Monthly WPM
|
||||
SUM(
|
||||
CASE WHEN start_time >= DATE('now', '-1 month') THEN duration ELSE 0 END
|
||||
)
|
||||
AS monthly_time_seconds,
|
||||
(
|
||||
CAST(COALESCE(d.words, 0.0) AS REAL)
|
||||
* SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-1 month') THEN read_percentage
|
||||
ELSE 0
|
||||
END
|
||||
)
|
||||
)
|
||||
AS monthly_words_read,
|
||||
COALESCE((
|
||||
CAST(COALESCE(d.words, 0.0) AS REAL)
|
||||
* SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-1 month') THEN read_percentage
|
||||
END
|
||||
)
|
||||
)
|
||||
/ (
|
||||
SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-1 month') THEN duration
|
||||
END
|
||||
)
|
||||
/ 60.0
|
||||
), 0.0)
|
||||
AS monthly_wpm,
|
||||
|
||||
-- Weekly WPM
|
||||
SUM(CASE WHEN start_time >= DATE('now', '-7 days') THEN duration ELSE 0 END)
|
||||
AS weekly_time_seconds,
|
||||
(
|
||||
CAST(COALESCE(d.words, 0.0) AS REAL)
|
||||
* SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-7 days') THEN read_percentage
|
||||
ELSE 0
|
||||
END
|
||||
)
|
||||
)
|
||||
AS weekly_words_read,
|
||||
COALESCE((
|
||||
CAST(COALESCE(d.words, 0.0) AS REAL)
|
||||
* SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-7 days') THEN read_percentage
|
||||
END
|
||||
)
|
||||
)
|
||||
/ (
|
||||
SUM(
|
||||
CASE
|
||||
WHEN start_time >= DATE('now', '-7 days') THEN duration
|
||||
END
|
||||
)
|
||||
/ 60.0
|
||||
), 0.0)
|
||||
AS weekly_wpm
|
||||
|
||||
(CAST(COALESCE(d.words, 0.0) AS REAL) * SUM(read_percentage))
|
||||
/ (SUM(duration) / 60.0) AS wpm
|
||||
FROM grouped_activity AS ga
|
||||
INNER JOIN
|
||||
current_progress AS cp
|
||||
ON ga.user_id = cp.user_id AND ga.document_id = cp.document_id
|
||||
INNER JOIN
|
||||
documents AS d
|
||||
ON d.id = ga.document_id
|
||||
ON ga.document_id = d.id
|
||||
GROUP BY ga.document_id, ga.user_id
|
||||
ORDER BY wpm DESC;
|
||||
ORDER BY total_wpm DESC;
|
||||
|
||||
---------------------------------------------------------------
|
||||
------------------ Populate Temporary Tables ------------------
|
||||
|
||||
Reference in New Issue
Block a user