Refactor query methods.

This commit is contained in:
Mike Cao 2020-09-24 23:02:11 -07:00
parent ee8859d86c
commit 1dfa6d8b16
2 changed files with 92 additions and 205 deletions

View File

@ -31,9 +31,3 @@ if (process.env.NODE_ENV === 'production') {
} }
export default prisma; export default prisma;
export async function runQuery(query) {
return query.catch(e => {
throw e;
});
}

View File

@ -1,5 +1,5 @@
import moment from 'moment-timezone'; import moment from 'moment-timezone';
import prisma, { runQuery } from 'lib/db'; import prisma from 'lib/db';
import { subMinutes } from 'date-fns'; import { subMinutes } from 'date-fns';
import { MYSQL, POSTGRESQL, MYSQL_DATE_FORMATS, POSTGRESQL_DATE_FORMATS } from 'lib/constants'; import { MYSQL, POSTGRESQL, MYSQL_DATE_FORMATS, POSTGRESQL_DATE_FORMATS } from 'lib/constants';
@ -15,7 +15,27 @@ export function getDatabase() {
return type; 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 (db === POSTGRESQL) {
if (timezone) { if (timezone) {
return `to_char(date_trunc('${unit}', ${field} at time zone '${timezone}'), '${POSTGRESQL_DATE_FORMATS[unit]}')`; 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) { export async function getWebsiteById(website_id) {
return runQuery( return runQuery(
prisma.website.findOne({ prisma.website.findOne({
@ -254,61 +286,27 @@ export async function createAccount(data) {
} }
export function getMetrics(website_id, start_at, end_at) { export function getMetrics(website_id, start_at, end_at) {
const db = getDatabase(); return rawQuery(
`
if (db === POSTGRESQL) {
return runQuery(
prisma.$queryRaw(
`
select sum(t.c) as "pageviews", select sum(t.c) as "pageviews",
count(distinct t.session_id) as "uniques", count(distinct t.session_id) as "uniques",
sum(case when t.c = 1 then 1 else 0 end) as "bounces", sum(case when t.c = 1 then 1 else 0 end) as "bounces",
sum(t.time) as "totaltime" sum(t.time) as "totaltime"
from ( from (
select session_id, select session_id,
${getDateQuery(db, 'created_at', 'hour')}, ${getDateQuery('created_at', 'hour')},
count(*) c, count(*) c,
floor(extract(epoch from max(created_at) - min(created_at))) as "time" ${getTimestampInterval('created_at')} as "time"
from pageview from pageview
where website_id=$1 where website_id=$1
and created_at between $2 and $3 and created_at between $2 and $3
group by 1, 2 group by 1, 2
) t ) t
`, `,
website_id, website_id,
start_at, start_at,
end_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.'));
} }
export function getPageviews( export function getPageviews(
@ -319,176 +317,71 @@ export function getPageviews(
unit = 'day', unit = 'day',
count = '*', count = '*',
) { ) {
const db = getDatabase(); return rawQuery(
`
if (db === POSTGRESQL) { select ${getDateQuery('created_at', unit, timezone)} t,
return runQuery( count(${count}) y
prisma.$queryRaw( from pageview
` where website_id=$1
select ${getDateQuery(db, 'created_at', unit, timezone)} t, and created_at between $2 and $3
count(${count}) y group by 1
from pageview order by 1
where website_id=$1 `,
and created_at between $2 and $3 website_id,
group by 1 start_at,
order by 1 end_at,
`, );
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.'));
} }
export function getRankings(website_id, start_at, end_at, type, table, domain) { export function getRankings(website_id, start_at, end_at, type, table, domain) {
const db = getDatabase();
const filter = domain ? `and ${type} not like '%${domain}%'` : ''; const filter = domain ? `and ${type} not like '%${domain}%'` : '';
if (db === POSTGRESQL) { return rawQuery(
return runQuery( `
prisma.$queryRaw( select distinct ${type} x, count(*) y
` from ${table}
select distinct ${type} x, count(*) y where website_id=$1
from ${table} and created_at between $2 and $3
where website_id=$1 ${filter}
and created_at between $2 and $3 group by 1
${filter} order by 2 desc
group by 1 `,
order by 2 desc website_id,
`, start_at,
website_id, end_at,
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.'));
} }
export function getActiveVisitors(website_id) { export function getActiveVisitors(website_id) {
const db = getDatabase();
const date = subMinutes(new Date(), 5); const date = subMinutes(new Date(), 5);
if (db === POSTGRESQL) { return rawQuery(
return runQuery( `
prisma.$queryRaw(
`
select count(distinct session_id) x select count(distinct session_id) x
from pageview from pageview
where website_id=$1 where website_id=$1
and created_at >= $2 and created_at >= $2
`, `,
website_id, website_id,
date, 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.'));
} }
export function getEvents(website_id, start_at, end_at, timezone = 'utc', unit = 'day') { export function getEvents(website_id, start_at, end_at, timezone = 'utc', unit = 'day') {
const db = getDatabase(); return rawQuery(
`
if (db === POSTGRESQL) { select
return runQuery( event_value x,
prisma.$queryRaw( ${getDateQuery('created_at', unit, timezone)} t,
` count(*) y
select from event
event_value x, where website_id=$1
${getDateQuery(db, 'created_at', unit, timezone)} t, and created_at between $2 and $3
count(*) y group by 1, 2
from event order by 2
where website_id=$1 `,
and created_at between $2 and $3 website_id,
group by 1, 2 start_at,
order by 2 end_at,
`, );
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.'));
} }