Add support for MySQL.

This commit is contained in:
Mike Cao 2020-08-11 20:05:40 -07:00
parent e309376150
commit a248f35db2
9 changed files with 302 additions and 102 deletions

View File

@ -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;
}
@ -109,5 +111,7 @@ export function getDateArray(data, startDate, endDate, unit) {
arr.push({ t, y });
}
console.log({ unit, arr });
return arr;
}

View File

@ -1,5 +1,6 @@
import { PrismaClient } from '@prisma/client';
import chalk from 'chalk';
import { getMetricsQuery, getPageviewsQuery, getRankingsQuery } from 'lib/queries';
const options = {
log: [
@ -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(
@ -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 });
}

View File

@ -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) =>
@ -17,10 +18,12 @@ 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;
@ -28,10 +31,12 @@ export const useSession = use(async (req, res, 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;

141
lib/queries.js Normal file
View File

@ -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([]);
}

View File

@ -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);
}

View File

@ -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 });
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}`);
}
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;

View File

@ -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];

94
sql/schema.mysql.sql Normal file
View File

@ -0,0 +1,94 @@
create table account (
user_id int unsigned not null auto_increment primary key,
username varchar(255) unique not null,
password varchar(60) not null,
is_admin bool not null default false,
created_at timestamp default current_timestamp,
updated_at timestamp default current_timestamp
) ENGINE=InnoDB;
create table website (
website_id int unsigned not null auto_increment primary key,
website_uuid varchar(36) unique not null,
user_id int unsigned not null,
name varchar(100) not null,
domain varchar(500),
created_at timestamp default current_timestamp,
foreign key (user_id) references account(user_id) on delete cascade
) ENGINE=InnoDB;
create table session (
session_id int unsigned not null auto_increment primary key,
session_uuid varchar(36) unique not null,
website_id int unsigned not null references website(website_id) on delete cascade,
created_at timestamp default current_timestamp,
hostname varchar(100),
browser varchar(20),
os varchar(20),
device varchar(20),
screen varchar(11),
language varchar(35),
country char(2),
foreign key (website_id) references website(website_id) on delete cascade
) ENGINE=InnoDB;
create table pageview (
view_id int unsigned not null auto_increment primary key,
website_id int unsigned not null,
session_id int unsigned not null,
created_at timestamp default current_timestamp,
url varchar(500) not null,
referrer varchar(500),
foreign key (website_id) references website(website_id) on delete cascade,
foreign key (session_id) references session(session_id) on delete cascade
) ENGINE=InnoDB;
create table event (
event_id int unsigned not null auto_increment primary key,
website_id int unsigned not null,
session_id int unsigned not null,
created_at timestamp default current_timestamp,
url varchar(500) not null,
event_type varchar(50) not null,
event_value varchar(50) not null,
foreign key (website_id) references website(website_id) on delete cascade,
foreign key (session_id) references session(session_id) on delete cascade
) ENGINE=InnoDB;
create index session_created_at_idx on session(created_at);
create index session_website_id_idx on session(website_id);
create index pageview_created_at_idx on pageview(created_at);
create index pageview_website_id_idx on pageview(website_id);
create index pageview_session_id_idx on pageview(session_id);
create index event_created_at_idx on event(created_at);
create index event_website_id_idx on event(website_id);
create index event_session_id_idx on event(session_id);
drop function if exists date_trunc;
create function date_trunc(
in_granularity enum('minute', 'hour', 'day', 'month', 'year'),
in_datetime datetime(6)
)
returns datetime(6)
deterministic
begin
if (in_granularity = 'minute') then
return DATE_FORMAT(in_datetime, '%Y-%m-%d %H:%i:00.0000');
end if;
if (in_granularity = 'hour') then
return DATE_FORMAT(in_datetime, '%Y-%m-%d %H:00:00.0000');
end if;
if (in_granularity = 'day') then
return DATE_FORMAT(in_datetime, '%Y-%m-%d 00:00:00.0000');
end if;
if (in_granularity = 'month') then
return DATE_FORMAT(in_datetime, '%Y-%m-01 00:00:00.0000');
end if;
if (in_granularity = 'year') then
return DATE_FORMAT(in_datetime, '%Y-01-01 00:00:00.0000');
end if;
end;
insert into account (username, password, is_admin) values ('admin', '$2a$10$BXHPV7APlV1I6WrKJt1igeJAyVsvbhMTaTAi3nHkUJFGPsYmfZq3y', true);

View File

@ -49,15 +49,15 @@ create table event (
event_value varchar(50) not null
);
create index on account(username);
create index session_created_at_idx on session(created_at);
create index session_website_id_idx on session(website_id);
create index on session(created_at);
create index on session(website_id);
create index pageview_created_at_idx on pageview(created_at);
create index pageview_website_id_idx on pageview(website_id);
create index pageview_session_id_idx on pageview(session_id);
create index on pageview(created_at);
create index on pageview(website_id);
create index on pageview(session_id);
create index event_created_at_idx on event(created_at);
create index event_website_id_idx on event(website_id);
create index event_session_id_idx on event(session_id);
create index on event(created_at);
create index on event(website_id);
create index on event(session_id);
insert into account (username, password, is_admin) values ('admin', '$2a$10$BXHPV7APlV1I6WrKJt1igeJAyVsvbhMTaTAi3nHkUJFGPsYmfZq3y', true);