2020-08-12 05:05:40 +02:00
|
|
|
import moment from 'moment-timezone';
|
2020-08-12 07:24:41 +02:00
|
|
|
import prisma, { runQuery } from 'lib/db';
|
2020-08-18 09:51:32 +02:00
|
|
|
import { subMinutes } from 'date-fns';
|
2020-08-12 05:05:40 +02:00
|
|
|
|
|
|
|
const POSTGRESQL = 'postgresql';
|
|
|
|
const MYSQL = 'mysql';
|
|
|
|
|
2020-08-28 08:45:37 +02:00
|
|
|
const DATE_FORMATS = {
|
|
|
|
minute: '%Y-%m-%d %H:%i:00',
|
|
|
|
hour: '%Y-%m-%d %H:00:00',
|
|
|
|
day: '%Y-%m-%d',
|
|
|
|
month: '%Y-%m-01',
|
|
|
|
year: '%Y-01-01',
|
|
|
|
};
|
|
|
|
|
2020-08-12 05:05:40 +02:00
|
|
|
export function getDatabase() {
|
2020-08-27 02:50:47 +02:00
|
|
|
return process.env.DATABASE_TYPE || process.env.DATABASE_URL.split(':')[0];
|
2020-08-12 05:05:40 +02:00
|
|
|
}
|
|
|
|
|
2020-08-28 08:45:37 +02:00
|
|
|
export function getDateQuery(field, unit, timezone) {
|
|
|
|
if (timezone) {
|
|
|
|
const tz = moment.tz(timezone).format('Z');
|
|
|
|
|
|
|
|
return `DATE_FORMAT(convert_tz(${field},'+00:00','${tz}'), '${DATE_FORMATS[unit]}')`;
|
|
|
|
}
|
|
|
|
|
|
|
|
return `DATE_FORMAT(${field}, '${DATE_FORMATS[unit]}')`;
|
|
|
|
}
|
|
|
|
|
2020-08-12 07:24:41 +02:00
|
|
|
export async function getWebsiteById(website_id) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.website.findOne({
|
|
|
|
where: {
|
|
|
|
website_id,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function getWebsiteByUuid(website_uuid) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.website.findOne({
|
|
|
|
where: {
|
|
|
|
website_uuid,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
2020-08-15 10:17:15 +02:00
|
|
|
export async function getWebsiteByShareId(share_id) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.website.findOne({
|
|
|
|
where: {
|
|
|
|
share_id,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
2020-08-12 07:24:41 +02:00
|
|
|
export async function getUserWebsites(user_id) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.website.findMany({
|
|
|
|
where: {
|
|
|
|
user_id,
|
|
|
|
},
|
|
|
|
orderBy: {
|
|
|
|
name: 'asc',
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function createWebsite(user_id, data) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.website.create({
|
|
|
|
data: {
|
|
|
|
account: {
|
|
|
|
connect: {
|
|
|
|
user_id,
|
|
|
|
},
|
|
|
|
},
|
|
|
|
...data,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function updateWebsite(website_id, data) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.website.update({
|
|
|
|
where: {
|
|
|
|
website_id,
|
|
|
|
},
|
|
|
|
data,
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function deleteWebsite(website_id) {
|
|
|
|
return runQuery(
|
|
|
|
/* Prisma bug, does not cascade on non-nullable foreign keys
|
|
|
|
prisma.website.delete({
|
|
|
|
where: {
|
|
|
|
website_id,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
*/
|
|
|
|
prisma.$queryRaw`delete from website where website_id=${website_id}`,
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function createSession(website_id, data) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.session.create({
|
|
|
|
data: {
|
|
|
|
website: {
|
|
|
|
connect: {
|
|
|
|
website_id,
|
|
|
|
},
|
|
|
|
},
|
|
|
|
...data,
|
|
|
|
},
|
|
|
|
select: {
|
|
|
|
session_id: true,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function getSessionById(session_id) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.session.findOne({
|
|
|
|
where: {
|
|
|
|
session_id,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function getSessionByUuid(session_uuid) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.session.findOne({
|
|
|
|
where: {
|
|
|
|
session_uuid,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function savePageView(website_id, session_id, url, referrer) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.pageview.create({
|
|
|
|
data: {
|
|
|
|
website: {
|
|
|
|
connect: {
|
|
|
|
website_id,
|
|
|
|
},
|
|
|
|
},
|
|
|
|
session: {
|
|
|
|
connect: {
|
|
|
|
session_id,
|
|
|
|
},
|
|
|
|
},
|
|
|
|
url,
|
|
|
|
referrer,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function saveEvent(website_id, session_id, url, event_type, event_value) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.event.create({
|
|
|
|
data: {
|
|
|
|
website: {
|
|
|
|
connect: {
|
|
|
|
website_id,
|
|
|
|
},
|
|
|
|
},
|
|
|
|
session: {
|
|
|
|
connect: {
|
|
|
|
session_id,
|
|
|
|
},
|
|
|
|
},
|
|
|
|
url,
|
|
|
|
event_type,
|
|
|
|
event_value,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function getAccounts() {
|
|
|
|
return runQuery(prisma.account.findMany());
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function getAccountById(user_id) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.account.findOne({
|
|
|
|
where: {
|
|
|
|
user_id,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function getAccountByUsername(username) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.account.findOne({
|
|
|
|
where: {
|
|
|
|
username,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function updateAccount(user_id, data) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.account.update({
|
|
|
|
where: {
|
|
|
|
user_id,
|
|
|
|
},
|
|
|
|
data,
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function deleteAccount(user_id) {
|
|
|
|
return runQuery(
|
|
|
|
/* Prisma bug, does not cascade on non-nullable foreign keys
|
|
|
|
prisma.account.delete({
|
|
|
|
where: {
|
|
|
|
user_id,
|
|
|
|
},
|
|
|
|
}),
|
|
|
|
*/
|
|
|
|
prisma.$queryRaw`delete from account where user_id=${user_id}`,
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export async function createAccount(data) {
|
|
|
|
return runQuery(
|
|
|
|
prisma.account.create({
|
|
|
|
data,
|
|
|
|
}),
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
export function getMetrics(website_id, start_at, end_at) {
|
2020-08-12 05:05:40 +02:00
|
|
|
const db = getDatabase();
|
|
|
|
|
|
|
|
if (db === POSTGRESQL) {
|
|
|
|
return prisma.$queryRaw(
|
|
|
|
`
|
|
|
|
select sum(t.c) as "pageviews",
|
|
|
|
count(distinct t.session_id) as "uniques",
|
2020-08-24 19:52:47 +02:00
|
|
|
sum(case when t.c = 1 then 1 else 0 end) as "bounces",
|
2020-08-12 05:05:40 +02:00
|
|
|
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",
|
2020-08-24 19:52:47 +02:00
|
|
|
sum(case when t.c = 1 then 1 else 0 end) as "bounces",
|
2020-08-12 05:05:40 +02:00
|
|
|
sum(t.time) as "totaltime"
|
|
|
|
from (
|
|
|
|
select session_id,
|
2020-08-28 08:45:37 +02:00
|
|
|
${getDateQuery('created_at', 'hour')},
|
2020-08-12 05:05:40 +02:00
|
|
|
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({});
|
|
|
|
}
|
|
|
|
|
2020-08-12 07:24:41 +02:00
|
|
|
export function getPageviews(
|
|
|
|
website_id,
|
|
|
|
start_at,
|
|
|
|
end_at,
|
|
|
|
timezone = 'utc',
|
|
|
|
unit = 'day',
|
|
|
|
count = '*',
|
|
|
|
) {
|
2020-08-12 05:05:40 +02:00
|
|
|
const db = getDatabase();
|
|
|
|
|
|
|
|
if (db === POSTGRESQL) {
|
|
|
|
return prisma.$queryRaw(
|
|
|
|
`
|
|
|
|
select date_trunc('${unit}', created_at at time zone '${timezone}') t,
|
2020-08-28 08:45:37 +02:00
|
|
|
count(${count}) y
|
2020-08-12 05:05:40 +02:00
|
|
|
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 prisma.$queryRaw(
|
|
|
|
`
|
2020-08-28 08:45:37 +02:00
|
|
|
select ${getDateQuery('created_at', unit, timezone)} t,
|
|
|
|
count(${count}) y
|
2020-08-12 05:05:40 +02:00
|
|
|
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([]);
|
|
|
|
}
|
|
|
|
|
2020-08-29 06:34:20 +02:00
|
|
|
export function getRankings(website_id, start_at, end_at, type, table, domain) {
|
2020-08-12 05:05:40 +02:00
|
|
|
const db = getDatabase();
|
|
|
|
|
2020-08-29 06:34:20 +02:00
|
|
|
const filter = domain ? `and ${type} not like '%${domain}%'` : '';
|
|
|
|
|
2020-08-12 05:05:40 +02:00
|
|
|
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
|
2020-08-29 06:34:20 +02:00
|
|
|
${filter}
|
2020-08-12 05:05:40 +02:00
|
|
|
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 ?
|
2020-08-29 06:34:20 +02:00
|
|
|
${filter}
|
2020-08-12 05:05:40 +02:00
|
|
|
group by 1
|
|
|
|
order by 2 desc
|
|
|
|
`,
|
|
|
|
website_id,
|
|
|
|
start_at,
|
|
|
|
end_at,
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
return Promise.resolve([]);
|
|
|
|
}
|
2020-08-18 09:51:32 +02:00
|
|
|
|
|
|
|
export function getActiveVisitors(website_id) {
|
2020-08-19 03:33:59 +02:00
|
|
|
const db = getDatabase();
|
|
|
|
const date = subMinutes(new Date(), 5);
|
|
|
|
|
|
|
|
if (db === POSTGRESQL) {
|
|
|
|
return prisma.$queryRaw(
|
|
|
|
`
|
2020-08-18 09:51:32 +02:00
|
|
|
select count(distinct session_id) x
|
|
|
|
from pageview
|
|
|
|
where website_id=$1
|
|
|
|
and created_at >= $2
|
|
|
|
`,
|
2020-08-19 03:33:59 +02:00
|
|
|
website_id,
|
|
|
|
date,
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
if (db === MYSQL) {
|
|
|
|
return prisma.$queryRaw(
|
|
|
|
`
|
|
|
|
select count(distinct session_id) x
|
|
|
|
from pageview
|
|
|
|
where website_id=?
|
|
|
|
and created_at >= ?
|
|
|
|
`,
|
|
|
|
website_id,
|
|
|
|
date,
|
|
|
|
);
|
|
|
|
}
|
|
|
|
|
|
|
|
return Promise.resolve([]);
|
2020-08-18 09:51:32 +02:00
|
|
|
}
|
2020-08-25 08:49:14 +02:00
|
|
|
|
2020-08-27 12:42:24 +02:00
|
|
|
export function getEvents(website_id, start_at, end_at, timezone = 'utc', unit = 'day') {
|
|
|
|
const db = getDatabase();
|
|
|
|
|
|
|
|
if (db === POSTGRESQL) {
|
|
|
|
return prisma.$queryRaw(
|
|
|
|
`
|
|
|
|
select
|
|
|
|
event_value x,
|
|
|
|
date_trunc('${unit}', created_at at time zone '${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 prisma.$queryRaw(
|
|
|
|
`
|
|
|
|
select
|
|
|
|
event_value x,
|
2020-08-28 08:45:37 +02:00
|
|
|
${getDateQuery('created_at', unit, timezone)} t,
|
2020-08-27 12:42:24 +02:00
|
|
|
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.resolve([]);
|
|
|
|
}
|