Skip to content

Commit

Permalink
Add support for MySQL.
Browse files Browse the repository at this point in the history
  • Loading branch information
mikecao committed Aug 12, 2020
1 parent e309376 commit a248f35
Show file tree
Hide file tree
Showing 9 changed files with 303 additions and 103 deletions.
6 changes: 5 additions & 1 deletion lib/date.js
Original file line number Diff line number Diff line change
Expand Up @@ -97,7 +97,9 @@ export function getDateArray(data, startDate, endDate, unit) {
const n = diff(endDate, startDate) + 1;

function findData(t) {
const x = data.find(e => new Date(e.t).getTime() === normalize(new Date(t)).getTime());
const x = data.find(e => {
return getLocalTime(new Date(e.t)).getTime() === normalize(new Date(t)).getTime();
});

return x?.y || 0;
}
Expand All @@ -109,5 +111,7 @@ export function getDateArray(data, startDate, endDate, unit) {
arr.push({ t, y });
}

console.log({ unit, arr });

return arr;
}
53 changes: 4 additions & 49 deletions lib/db.js
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
import { PrismaClient } from '@prisma/client';
import chalk from 'chalk';
import { getMetricsQuery, getPageviewsQuery, getRankingsQuery } from 'lib/queries';

const options = {
log: [
Expand Down Expand Up @@ -236,21 +237,7 @@ export async function getPageviews(website_id, start_at, end_at) {
}

export async function getRankings(website_id, start_at, end_at, type, table) {
return runQuery(
prisma.queryRaw(
`
select distinct "${type}" x, count(*) y
from "${table}"
where website_id=$1
and created_at between $2 and $3
group by 1
order by 2 desc
`,
website_id,
start_at,
end_at,
),
);
return getRankingsQuery(prisma, { website_id, start_at, end_at, type, table });
}

export async function getPageviewData(
Expand All @@ -262,42 +249,10 @@ export async function getPageviewData(
count = '*',
) {
return runQuery(
prisma.queryRaw(
`
select date_trunc('${unit}', created_at at time zone '${timezone}') at time zone '${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,
),
getPageviewsQuery(prisma, { website_id, start_at, end_at, timezone, unit, count }),
);
}

export async function getMetrics(website_id, start_at, end_at) {
return runQuery(
prisma.queryRaw(
`
select sum(t.c) as "pageviews",
count(distinct t.session_id) as "uniques",
sum(case when t.c = 1 then t.c else 0 end) as "bounces",
sum(t.time) as "totaltime"
from (
select session_id,
date_trunc('hour', created_at),
count(*) c,
floor(extract(epoch from max(created_at) - min(created_at))) as "time"
from pageview
where website_id=${website_id}
and created_at between '${start_at}' and '${end_at}'
group by 1, 2
) t;
`,
),
);
return getMetricsQuery(prisma, { website_id, start_at, end_at });
}
13 changes: 9 additions & 4 deletions lib/middleware.js
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
import cors from 'cors';
import { verifySession } from './session';
import { verifyAuthToken } from './auth';
import { unauthorized, badRequest, serverError } from './response';

export function use(middleware) {
return (req, res) =>
Expand All @@ -17,21 +18,25 @@ export function use(middleware) {
export const useCors = use(cors());

export const useSession = use(async (req, res, next) => {
const session = await verifySession(req);
const session = await verifySession(req).catch(e => {
return serverError(res, e.message);
});

if (!session) {
return res.status(400).end();
return badRequest(res);
}

req.session = session;
next();
});

export const useAuth = use(async (req, res, next) => {
const token = await verifyAuthToken(req);
const token = await verifyAuthToken(req).catch(e => {
return serverError(res, e.message);
});

if (!token) {
return res.status(401).end();
return unauthorized(res);
}

req.auth = token;
Expand Down
141 changes: 141 additions & 0 deletions lib/queries.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,141 @@
import moment from 'moment-timezone';

const POSTGRESQL = 'postgresql';
const MYSQL = 'mysql';

export function getDatabase() {
return process.env.DATABASE_URL.split(':')[0];
}

export function getMetricsQuery(prisma, { website_id, start_at, end_at }) {
const db = getDatabase();

if (db === POSTGRESQL) {
return prisma.$queryRaw(
`
select sum(t.c) as "pageviews",
count(distinct t.session_id) as "uniques",
sum(case when t.c = 1 then t.c else 0 end) as "bounces",
sum(t.time) as "totaltime"
from (
select session_id,
date_trunc('hour', created_at),
count(*) c,
floor(extract(epoch from max(created_at) - min(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 prisma.$queryRaw(
`
select sum(t.c) as "pageviews",
count(distinct t.session_id) as "uniques",
sum(case when t.c = 1 then t.c else 0 end) as "bounces",
sum(t.time) as "totaltime"
from (
select session_id,
date_trunc('hour', created_at),
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.resolve({});
}

export function getPageviewsQuery(prisma, { website_id, start_at, end_at, unit, timezone, count }) {
const db = getDatabase();

if (db === POSTGRESQL) {
return prisma.$queryRaw(
`
select date_trunc('${unit}', created_at at time zone '${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) {
const tz = moment.tz(timezone).format('Z');
return prisma.$queryRaw(
`
select date_trunc('${unit}', convert_tz(created_at,'+00:00','${tz}')) 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.resolve([]);
}

export function getRankingsQuery(prisma, { website_id, start_at, end_at, type, table }) {
const db = getDatabase();

if (db === POSTGRESQL) {
return prisma.$queryRaw(
`
select distinct ${type} x, count(*) y
from ${table}
where website_id=$1
and created_at between $2 and $3
group by 1
order by 2 desc
`,
website_id,
start_at,
end_at,
);
}

if (db === MYSQL) {
return prisma.$queryRaw(
`
select distinct ${type} x, count(*) y
from ${table}
where website_id=?
and created_at between ? and ?
group by 1
order by 2 desc
`,
website_id,
start_at,
end_at,
);
}

return Promise.resolve([]);
}
4 changes: 4 additions & 0 deletions lib/response.js
Original file line number Diff line number Diff line change
Expand Up @@ -23,3 +23,7 @@ export function forbidden(res, msg) {
export function methodNotAllowed(res, msg) {
res.status(405).end(msg);
}

export function serverError(res, msg) {
res.status(500).end(msg);
}
71 changes: 36 additions & 35 deletions lib/session.js
Original file line number Diff line number Diff line change
Expand Up @@ -10,46 +10,47 @@ export async function verifySession(req) {
}

const { website: website_uuid, hostname, screen, language, session } = payload;

const token = await parseToken(session);

if (!token || !isValidId(website_uuid) || token.website_uuid !== website_uuid) {
if (!isValidId(website_uuid)) {
throw new Error(`Invalid website: ${website_uuid}`);
}

if (!token || token.website_uuid !== website_uuid) {
const { userAgent, browser, os, ip, country, device } = await getClientInfo(req, payload);

if (website_uuid) {
const website = await getWebsite({ website_uuid });

if (website) {
const { website_id } = website;
const session_uuid = uuid(website_id, hostname, ip, userAgent, os);

let session = await getSession({ session_uuid });

if (!session) {
session = await createSession(website_id, {
session_uuid,
hostname,
browser,
os,
screen,
language,
country,
device,
});
}

const { session_id } = session;

return {
website_id,
website_uuid,
session_id,
session_uuid,
};
} else {
throw new Error(`Invalid website: ${website_uuid}`);
}
const website = await getWebsite({ website_uuid });

if (!website) {
throw new Error(`Website not found: ${website_uuid}`);
}

const { website_id } = website;
const session_uuid = uuid(website_id, hostname, ip, userAgent, os);

let session = await getSession({ session_uuid });

if (!session) {
session = await createSession(website_id, {
session_uuid,
hostname,
browser,
os,
screen,
language,
country,
device,
});
}

const { session_id } = session;

return {
website_id,
website_uuid,
session_id,
session_uuid,
};
}

return token;
Expand Down
6 changes: 1 addition & 5 deletions pages/api/website/[id]/metrics.js
Original file line number Diff line number Diff line change
Expand Up @@ -7,11 +7,7 @@ export default async (req, res) => {

const { id, start_at, end_at } = req.query;

const metrics = await getMetrics(
+id,
new Date(+start_at).toISOString(),
new Date(+end_at).toISOString(),
);
const metrics = await getMetrics(+id, new Date(+start_at), new Date(+end_at));

const stats = Object.keys(metrics[0]).reduce((obj, key) => {
obj[key] = +metrics[0][key];
Expand Down
Loading

0 comments on commit a248f35

Please sign in to comment.