From 1dfa6d8b1665b357da2a1c3f8b998d8896a35c42 Mon Sep 17 00:00:00 2001 From: Mike Cao Date: Thu, 24 Sep 2020 23:02:11 -0700 Subject: [PATCH] Refactor query methods. --- lib/db.js | 6 - lib/queries.js | 291 ++++++++++++++++--------------------------------- 2 files changed, 92 insertions(+), 205 deletions(-) diff --git a/lib/db.js b/lib/db.js index e314684e..35948998 100644 --- a/lib/db.js +++ b/lib/db.js @@ -31,9 +31,3 @@ if (process.env.NODE_ENV === 'production') { } export default prisma; - -export async function runQuery(query) { - return query.catch(e => { - throw e; - }); -} diff --git a/lib/queries.js b/lib/queries.js index 684b30d4..9fd61125 100644 --- a/lib/queries.js +++ b/lib/queries.js @@ -1,5 +1,5 @@ import moment from 'moment-timezone'; -import prisma, { runQuery } from 'lib/db'; +import prisma from 'lib/db'; import { subMinutes } from 'date-fns'; import { MYSQL, POSTGRESQL, MYSQL_DATE_FORMATS, POSTGRESQL_DATE_FORMATS } from 'lib/constants'; @@ -15,7 +15,27 @@ export function getDatabase() { return type; } -export function getDateQuery(db, field, unit, timezone) { +export async function runQuery(query) { + return query.catch(e => { + throw e; + }); +} + +export async function rawQuery(query, ...params) { + const db = getDatabase(); + + if (db !== POSTGRESQL && db !== MYSQL) { + return Promise.reject(new Error('Unknown database.')); + } + + const sql = db === MYSQL ? query.replace(/\$[0-9]+/g, '?') : query; + + return prisma.$queryRaw.apply(prisma, [sql, ...params]); +} + +export function getDateQuery(field, unit, timezone) { + const db = getDatabase(); + if (db === POSTGRESQL) { if (timezone) { return `to_char(date_trunc('${unit}', ${field} at time zone '${timezone}'), '${POSTGRESQL_DATE_FORMATS[unit]}')`; @@ -34,6 +54,18 @@ export function getDateQuery(db, field, unit, timezone) { } } +export function getTimestampInterval(field) { + const db = getDatabase(); + + if (db === POSTGRESQL) { + return `floor(extract(epoch from max(${field}) - min(${field})))`; + } + + if (db === MYSQL) { + return `floor(unix_timestamp(max(${field})) - unix_timestamp(min(${field})))`; + } +} + export async function getWebsiteById(website_id) { return runQuery( prisma.website.findOne({ @@ -254,61 +286,27 @@ export async function createAccount(data) { } export function getMetrics(website_id, start_at, end_at) { - const db = getDatabase(); - - if (db === POSTGRESQL) { - return runQuery( - prisma.$queryRaw( - ` + return rawQuery( + ` select sum(t.c) as "pageviews", count(distinct t.session_id) as "uniques", sum(case when t.c = 1 then 1 else 0 end) as "bounces", sum(t.time) as "totaltime" from ( select session_id, - ${getDateQuery(db, 'created_at', 'hour')}, + ${getDateQuery('created_at', 'hour')}, count(*) c, - floor(extract(epoch from max(created_at) - min(created_at))) as "time" + ${getTimestampInterval('created_at')} as "time" from pageview where website_id=$1 and created_at between $2 and $3 group by 1, 2 ) t - `, - website_id, - start_at, - end_at, - ), - ); - } - - if (db === MYSQL) { - return runQuery( - prisma.$queryRaw( - ` - select sum(t.c) as "pageviews", - count(distinct t.session_id) as "uniques", - sum(case when t.c = 1 then 1 else 0 end) as "bounces", - sum(t.time) as "totaltime" - from ( - select session_id, - ${getDateQuery(db, 'created_at', 'hour')}, - count(*) c, - floor(unix_timestamp(max(created_at)) - unix_timestamp(min(created_at))) as "time" - from pageview - where website_id=? - and created_at between ? and ? - group by 1, 2 - ) t - `, - website_id, - start_at, - end_at, - ), - ); - } - - return Promise.reject(new Error('Unknown database.')); + `, + website_id, + start_at, + end_at, + ); } export function getPageviews( @@ -319,176 +317,71 @@ export function getPageviews( unit = 'day', count = '*', ) { - const db = getDatabase(); - - if (db === POSTGRESQL) { - return runQuery( - prisma.$queryRaw( - ` - select ${getDateQuery(db, 'created_at', unit, timezone)} t, - count(${count}) y - from pageview - where website_id=$1 - and created_at between $2 and $3 - group by 1 - order by 1 - `, - website_id, - start_at, - end_at, - ), - ); - } - - if (db === MYSQL) { - return runQuery( - prisma.$queryRaw( - ` - select ${getDateQuery(db, 'created_at', unit, timezone)} t, - count(${count}) y - from pageview - where website_id=? - and created_at between ? and ? - group by 1 - order by 1 - `, - website_id, - start_at, - end_at, - ), - ); - } - - return Promise.reject(new Error('Unknown database.')); + return rawQuery( + ` + select ${getDateQuery('created_at', unit, timezone)} t, + count(${count}) y + from pageview + where website_id=$1 + and created_at between $2 and $3 + group by 1 + order by 1 + `, + website_id, + start_at, + end_at, + ); } export function getRankings(website_id, start_at, end_at, type, table, domain) { - const db = getDatabase(); - const filter = domain ? `and ${type} not like '%${domain}%'` : ''; - if (db === POSTGRESQL) { - return runQuery( - prisma.$queryRaw( - ` - select distinct ${type} x, count(*) y - from ${table} - where website_id=$1 - and created_at between $2 and $3 - ${filter} - group by 1 - order by 2 desc - `, - website_id, - start_at, - end_at, - ), - ); - } - - if (db === MYSQL) { - return runQuery( - prisma.$queryRaw( - ` - select distinct ${type} x, count(*) y - from ${table} - where website_id=? - and created_at between ? and ? - ${filter} - group by 1 - order by 2 desc - `, - website_id, - start_at, - end_at, - ), - ); - } - - return Promise.reject(new Error('Unknown database.')); + return rawQuery( + ` + select distinct ${type} x, count(*) y + from ${table} + where website_id=$1 + and created_at between $2 and $3 + ${filter} + group by 1 + order by 2 desc + `, + website_id, + start_at, + end_at, + ); } export function getActiveVisitors(website_id) { - const db = getDatabase(); const date = subMinutes(new Date(), 5); - if (db === POSTGRESQL) { - return runQuery( - prisma.$queryRaw( - ` + return rawQuery( + ` select count(distinct session_id) x from pageview where website_id=$1 and created_at >= $2 `, - website_id, - date, - ), - ); - } - - if (db === MYSQL) { - return runQuery( - prisma.$queryRaw( - ` - select count(distinct session_id) x - from pageview - where website_id=? - and created_at >= ? - `, - website_id, - date, - ), - ); - } - - return Promise.reject(new Error('Unknown database.')); + website_id, + date, + ); } export function getEvents(website_id, start_at, end_at, timezone = 'utc', unit = 'day') { - const db = getDatabase(); - - if (db === POSTGRESQL) { - return runQuery( - prisma.$queryRaw( - ` - select - event_value x, - ${getDateQuery(db, 'created_at', unit, timezone)} t, - count(*) y - from event - where website_id=$1 - and created_at between $2 and $3 - group by 1, 2 - order by 2 - `, - website_id, - start_at, - end_at, - ), - ); - } - - if (db === MYSQL) { - return runQuery( - prisma.$queryRaw( - ` - select - event_value x, - ${getDateQuery(db, 'created_at', unit, timezone)} t, - count(*) y - from event - where website_id=? - and created_at between ? and ? - group by 1, 2 - order by 2 - `, - website_id, - start_at, - end_at, - ), - ); - } - - return Promise.reject(new Error('Unknown database.')); + return rawQuery( + ` + select + event_value x, + ${getDateQuery('created_at', unit, timezone)} t, + count(*) y + from event + where website_id=$1 + and created_at between $2 and $3 + group by 1, 2 + order by 2 + `, + website_id, + start_at, + end_at, + ); }