Finalize sql query and add webhook endpoint
This commit is contained in:
@ -13,3 +13,4 @@ SENTRY_ORG=
|
||||
REDIS_HOST=sentry-redis-1
|
||||
REDIS_PORT=6379
|
||||
REDIS_PASSWORD=
|
||||
WEBHOOK_URL=
|
@ -6,9 +6,7 @@ const SENTRY_TOKEN = env.get('SENTRY_TOKEN')
|
||||
const SENTRY_ORG = env.get('SENTRY_ORG')
|
||||
let recordsUpdated = 0
|
||||
import redis from '@adonisjs/redis/services/main'
|
||||
import { DateTime } from 'luxon'
|
||||
|
||||
const thirtyDaysAgo = DateTime.now().minus({ days: 30 }).toSQL()
|
||||
|
||||
interface ApiResponse<T> {
|
||||
data: T;
|
||||
@ -24,22 +22,72 @@ interface SentryPagination {
|
||||
export default class ReplaysController {
|
||||
|
||||
public async search({ response }: HttpContext) {
|
||||
console.log('thir', thirtyDaysAgo)
|
||||
let results = await db.rawQuery(`SELECT
|
||||
"user" ->> 'display_name' AS user_email,
|
||||
SUM(duration) AS duration,
|
||||
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
|
||||
|
||||
FROM (
|
||||
-- Aggregate sessions in the last 30 days
|
||||
SELECT
|
||||
"user" ->> 'display_name' AS display_name,
|
||||
COUNT(duration) AS sessions,
|
||||
AVG(duration) AS avg_duration
|
||||
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 >= ?
|
||||
finished_at >= NOW() - INTERVAL '30 days'
|
||||
GROUP BY
|
||||
user_email
|
||||
"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
|
||||
ORDER BY
|
||||
SUM(duration) desc`, [thirtyDaysAgo]
|
||||
CASE WHEN finished_at >= NOW() - INTERVAL '30 days' THEN 0 ELSE 1 END,
|
||||
finished_at DESC
|
||||
LIMIT 1
|
||||
) r ON true
|
||||
|
||||
ORDER BY
|
||||
u.total_time_seconds DESC;`
|
||||
)
|
||||
response.json(results)
|
||||
try {
|
||||
|
||||
await fetch(env.get('WEBHOOK_URL'),
|
||||
{
|
||||
headers:
|
||||
{
|
||||
'content-type': 'application/json'
|
||||
},
|
||||
method: 'POST',
|
||||
body: JSON.stringify(results.rows)
|
||||
}
|
||||
)
|
||||
} catch(e) {
|
||||
console.error('error sending webhook data', e)
|
||||
}
|
||||
response.json(results.rows)
|
||||
}
|
||||
public async list({ request, inertia }: HttpContext) {
|
||||
const page = request.input('page', 1)
|
||||
|
@ -33,4 +33,6 @@ export default await Env.create(new URL('../', import.meta.url), {
|
||||
PG_HOST: Env.schema.string(),
|
||||
PG_USER: Env.schema.string(),
|
||||
PG_PASSWORD: Env.schema.string(),
|
||||
|
||||
WEBHOOK_URL: Env.schema.string()
|
||||
})
|
||||
|
Reference in New Issue
Block a user