245 lines
6.1 KiB
TypeScript
245 lines
6.1 KiB
TypeScript
import { DateTime } from 'luxon'
|
|
import { BaseModel, column } from '@adonisjs/lucid/orm'
|
|
import db from '@adonisjs/lucid/services/db'
|
|
import redis from '@adonisjs/redis/services/main'
|
|
|
|
export default class Replay extends BaseModel {
|
|
public static async updateReplayStats() {
|
|
let results = await db.rawQuery(`
|
|
SELECT
|
|
u.display_name,
|
|
u.sessions,
|
|
u.total_time_seconds,
|
|
u.total_time_readable,
|
|
u.average_session_time_readable,
|
|
u.average_time_seconds,
|
|
r.id AS last_session_id,
|
|
r.finished_at AS last_session_time,
|
|
o.id AS oldest_session_id,
|
|
o.finished_at AS oldest_session_time
|
|
|
|
FROM (
|
|
-- Aggregate sessions in the last 30 days
|
|
SELECT
|
|
"user" ->> 'display_name' AS display_name,
|
|
COUNT(duration) AS sessions,
|
|
SUM(duration) AS total_time_seconds,
|
|
AVG(duration) AS average_time_seconds,
|
|
CONCAT(
|
|
FLOOR(SUM(duration) / 86400), 'd ',
|
|
FLOOR(MOD(SUM(duration), 86400) / 3600), 'h ',
|
|
FLOOR(MOD(SUM(duration), 3600) / 60), 'm'
|
|
) AS total_time_readable,
|
|
CONCAT(
|
|
FLOOR(COUNT(duration) / 86400), 'd ',
|
|
FLOOR(MOD(COUNT(duration), 86400) / 3600), 'h ',
|
|
FLOOR(MOD(COUNT(duration), 3600) / 60), 'm'
|
|
) AS average_session_time_readable
|
|
FROM
|
|
replays
|
|
WHERE
|
|
finished_at >= NOW() - INTERVAL '30 days'
|
|
AND "user" ->> 'display_name' LIKE '%@%'
|
|
AND "user" ->> 'display_name' !~ 'e2etesting|@paragontruss.com'
|
|
|
|
GROUP BY
|
|
"user" ->> 'display_name'
|
|
) u
|
|
|
|
-- LATERAL JOIN to get latest session (either within 30d or fallback to latest overall)
|
|
JOIN LATERAL (
|
|
SELECT id, finished_at
|
|
FROM replays
|
|
WHERE "user" ->> 'display_name' = u.display_name
|
|
AND "user" ->> 'display_name' LIKE '%@%'
|
|
AND "user" ->> 'display_name' !~ 'e2etesting|@paragontruss.com'
|
|
ORDER BY
|
|
CASE WHEN finished_at >= NOW() - INTERVAL '30 days' THEN 0 ELSE 1 END,
|
|
finished_at DESC
|
|
LIMIT 1
|
|
) r ON true
|
|
|
|
-- LATERAL JOIN to get the oldest session
|
|
JOIN LATERAL (
|
|
SELECT id, finished_at
|
|
FROM replays
|
|
WHERE "user" ->> 'display_name' = u.display_name
|
|
AND "user" ->> 'display_name' LIKE '%@%'
|
|
AND "user" ->> 'display_name' !~ 'e2etesting|@paragontruss.com'
|
|
ORDER BY finished_at ASC
|
|
LIMIT 1
|
|
) o ON true
|
|
|
|
ORDER BY
|
|
u.total_time_seconds DESC;
|
|
|
|
`)
|
|
const updatedVersion = await redis.incr('replays:stats:latest_version')
|
|
results.version = updatedVersion
|
|
results.updatedAt = Date.now()
|
|
await redis.set(`replays:stats:version:${updatedVersion}:results`, JSON.stringify(results))
|
|
return results
|
|
}
|
|
@column({ isPrimary: true })
|
|
declare id: string
|
|
|
|
@column()
|
|
declare project_id: string
|
|
|
|
@column({
|
|
prepare: (value) => {
|
|
// The values from sentry are just arrays so convert them to json
|
|
return JSON.stringify(value)
|
|
},
|
|
})
|
|
declare trace_ids: string[]
|
|
|
|
@column({
|
|
prepare: (value) => {
|
|
return JSON.stringify(value)
|
|
},
|
|
})
|
|
declare error_ids: string[]
|
|
|
|
@column()
|
|
declare environment: string | null
|
|
|
|
@column({
|
|
prepare: (value) => {
|
|
// The values from sentry are just arrays so convert them to json
|
|
return JSON.stringify(value)
|
|
},
|
|
})
|
|
declare tags: string[]
|
|
|
|
@column()
|
|
declare user: string[]
|
|
|
|
@column()
|
|
declare sdk: any
|
|
|
|
@column()
|
|
declare os: any
|
|
|
|
@column()
|
|
declare browser: any
|
|
|
|
@column()
|
|
declare device: any
|
|
|
|
@column()
|
|
declare ota_updates: any
|
|
|
|
@column()
|
|
declare is_archived: boolean | null
|
|
|
|
@column({
|
|
prepare: (value) => {
|
|
// The values from sentry are just arrays so convert them to json
|
|
return JSON.stringify(value)
|
|
},
|
|
})
|
|
declare urls: any
|
|
|
|
@column({
|
|
prepare: (value) => {
|
|
// The values from sentry are just arrays so convert them to json
|
|
return JSON.stringify(value)
|
|
},
|
|
})
|
|
declare clicks: any
|
|
|
|
@column()
|
|
declare count_dead_clicks: number | null
|
|
|
|
@column()
|
|
declare count_rage_clicks: number | null
|
|
|
|
@column()
|
|
declare count_errors: number | null
|
|
|
|
@column()
|
|
declare duration: number | null
|
|
|
|
@column.dateTime()
|
|
declare finished_at: DateTime | null
|
|
|
|
@column.dateTime({ serializeAs: 'started_at' })
|
|
declare started_at: DateTime | null
|
|
|
|
@column()
|
|
declare activity: number | null
|
|
|
|
@column()
|
|
declare count_urls: number | null
|
|
|
|
@column()
|
|
declare replay_type: string
|
|
|
|
@column()
|
|
declare count_segments: number | null
|
|
|
|
@column()
|
|
declare platform: string | null
|
|
|
|
@column({
|
|
prepare: (value) => {
|
|
// The values from sentry are just arrays so convert them to json
|
|
return JSON.stringify(value)
|
|
},
|
|
})
|
|
declare releases: any
|
|
|
|
@column()
|
|
declare dist: string | null
|
|
|
|
@column()
|
|
declare count_warnings: number | null
|
|
|
|
@column()
|
|
declare count_infos: number | null
|
|
|
|
@column()
|
|
declare has_viewed: boolean
|
|
|
|
@column.dateTime({ autoCreate: true })
|
|
declare created_at: DateTime
|
|
|
|
@column.dateTime({ autoCreate: true, autoUpdate: true })
|
|
declare updated_at: DateTime
|
|
|
|
public static allowedFields = [
|
|
'id',
|
|
'project_id',
|
|
'trace_ids',
|
|
'error_ids',
|
|
'environment',
|
|
'tags',
|
|
'user',
|
|
'sdk',
|
|
'os',
|
|
'browser',
|
|
'device',
|
|
'ota_updates',
|
|
'is_archived',
|
|
'urls',
|
|
'clicks',
|
|
'count_dead_clicks',
|
|
'count_rage_clicks',
|
|
'count_errors',
|
|
'duration',
|
|
'finished_at',
|
|
'started_at',
|
|
'activity',
|
|
'count_urls',
|
|
'replay_type',
|
|
'count_segments',
|
|
'platform',
|
|
'releases',
|
|
'dist',
|
|
'count_warnings',
|
|
'count_infos',
|
|
'has_viewed',
|
|
]
|
|
}
|