mirror of
https://github.com/umami-software/umami.git
synced 2026-02-07 22:27:16 +01:00
Allow filtering on session fields.
This commit is contained in:
parent
edd1645bab
commit
fb2dc9f5ab
19 changed files with 275 additions and 211 deletions
239
lib/queries.js
239
lib/queries.js
|
|
@ -21,24 +21,6 @@ export function getDatabase() {
|
|||
return type;
|
||||
}
|
||||
|
||||
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.$queryRawUnsafe.apply(prisma, [sql, ...params]);
|
||||
}
|
||||
|
||||
export function getDateQuery(field, unit, timezone) {
|
||||
const db = getDatabase();
|
||||
|
||||
|
|
@ -72,6 +54,79 @@ export function getTimestampInterval(field) {
|
|||
}
|
||||
}
|
||||
|
||||
export function getFilterQuery(table, filters = {}, params = []) {
|
||||
const query = Object.keys(filters).reduce((arr, key) => {
|
||||
const value = filters[key];
|
||||
|
||||
if (value === undefined) {
|
||||
return arr;
|
||||
}
|
||||
|
||||
switch (key) {
|
||||
case 'url':
|
||||
if (table === 'session' || table === 'pageview') {
|
||||
arr.push(`and ${table}.${key}=$${params.length + 1}`);
|
||||
params.push(decodeURIComponent(value));
|
||||
}
|
||||
break;
|
||||
|
||||
case 'os':
|
||||
case 'browser':
|
||||
case 'device':
|
||||
case 'country':
|
||||
if (table === 'session') {
|
||||
arr.push(`and ${table}.${key}=$${params.length + 1}`);
|
||||
params.push(decodeURIComponent(value));
|
||||
}
|
||||
break;
|
||||
|
||||
case 'event_type':
|
||||
if (table === 'event') {
|
||||
arr.push(`and ${table}.${key}=$${params.length + 1}`);
|
||||
params.push(decodeURIComponent(value));
|
||||
}
|
||||
break;
|
||||
|
||||
case 'referrer':
|
||||
if (table === 'pageview') {
|
||||
arr.push(`and ${table}.referrer like $${params.length + 1}`);
|
||||
params.push(`%${decodeURIComponent(value)}%`);
|
||||
}
|
||||
break;
|
||||
|
||||
case 'domain':
|
||||
if (table === 'pageview') {
|
||||
arr.push(`and ${table}.referrer not like $${params.length + 1}`);
|
||||
arr.push(`and ${table}.referrer not like '/%'`);
|
||||
params.push(`%://${value}/%`);
|
||||
}
|
||||
break;
|
||||
}
|
||||
|
||||
return arr;
|
||||
}, []);
|
||||
|
||||
return query.join('\n');
|
||||
}
|
||||
|
||||
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 runQuery(prisma.$queryRawUnsafe.apply(prisma, [sql, ...params]));
|
||||
}
|
||||
|
||||
export async function getWebsiteById(website_id) {
|
||||
return runQuery(
|
||||
prisma.website.findUnique({
|
||||
|
|
@ -344,19 +399,12 @@ export async function getEvents(websites, start_at) {
|
|||
|
||||
export function getWebsiteStats(website_id, start_at, end_at, filters = {}) {
|
||||
const params = [website_id, start_at, end_at];
|
||||
const { url, referrer } = filters;
|
||||
let urlFilter = '';
|
||||
let refFilter = '';
|
||||
const { url, referrer, os, browser, device, country } = filters;
|
||||
|
||||
if (url) {
|
||||
urlFilter = `and url=$${params.length + 1}`;
|
||||
params.push(decodeURIComponent(url));
|
||||
}
|
||||
|
||||
if (referrer) {
|
||||
refFilter = `and referrer like $${params.length + 1}`;
|
||||
params.push(`%${decodeURIComponent(referrer)}%`);
|
||||
}
|
||||
const joinSession =
|
||||
os || browser || device || country
|
||||
? 'inner join session on session.session_id = pageview.session_id'
|
||||
: '';
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -365,15 +413,16 @@ export function getWebsiteStats(website_id, start_at, end_at, filters = {}) {
|
|||
sum(case when t.c = 1 then 1 else 0 end) as "bounces",
|
||||
sum(t.time) as "totaltime"
|
||||
from (
|
||||
select session_id,
|
||||
${getDateQuery('created_at', 'hour')},
|
||||
select pageview.session_id,
|
||||
${getDateQuery('pageview.created_at', 'hour')},
|
||||
count(*) c,
|
||||
${getTimestampInterval('created_at')} as "time"
|
||||
${getTimestampInterval('pageview.created_at')} as "time"
|
||||
from pageview
|
||||
where website_id=$1
|
||||
and created_at between $2 and $3
|
||||
${urlFilter}
|
||||
${refFilter}
|
||||
${joinSession}
|
||||
where pageview.website_id=$1
|
||||
and pageview.created_at between $2 and $3
|
||||
${getFilterQuery('pageview', { url, referrer }, params)}
|
||||
${getFilterQuery('session', { os, browser, device, country }, params)}
|
||||
group by 1, 2
|
||||
) t
|
||||
`,
|
||||
|
|
@ -391,30 +440,22 @@ export function getPageviewStats(
|
|||
filters = {},
|
||||
) {
|
||||
const params = [website_id, start_at, end_at];
|
||||
const { url, referrer } = filters;
|
||||
|
||||
let urlFilter = '';
|
||||
let refFilter = '';
|
||||
|
||||
if (url) {
|
||||
urlFilter = `and url=$${params.length + 1}`;
|
||||
params.push(decodeURIComponent(url));
|
||||
}
|
||||
|
||||
if (referrer) {
|
||||
refFilter = `and referrer like $${params.length + 1}`;
|
||||
params.push(`%${decodeURIComponent(referrer)}%`);
|
||||
}
|
||||
const { url, referrer, os, browser, device, country } = filters;
|
||||
const joinSession =
|
||||
os || browser || device || country
|
||||
? 'inner join session on session.session_id = pageview.session_id'
|
||||
: '';
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
select ${getDateQuery('created_at', unit, timezone)} t,
|
||||
select ${getDateQuery('pageview.created_at', unit, timezone)} t,
|
||||
count(${count}) y
|
||||
from pageview
|
||||
where website_id=$1
|
||||
and created_at between $2 and $3
|
||||
${urlFilter}
|
||||
${refFilter}
|
||||
${joinSession}
|
||||
where pageview.website_id=$1
|
||||
and pageview.created_at between $2 and $3
|
||||
${getFilterQuery('pageview', { url, referrer }, params)}
|
||||
${getFilterQuery('session', { os, browser, device, country }, params)}
|
||||
group by 1
|
||||
order by 1
|
||||
`,
|
||||
|
|
@ -424,32 +465,24 @@ export function getPageviewStats(
|
|||
|
||||
export function getSessionMetrics(website_id, start_at, end_at, field, filters = {}) {
|
||||
const params = [website_id, start_at, end_at];
|
||||
const { url, referrer } = filters;
|
||||
|
||||
let urlFilter = '';
|
||||
let refFilter = '';
|
||||
|
||||
if (url) {
|
||||
urlFilter = `and url=$${params.length + 1}`;
|
||||
params.push(decodeURIComponent(url));
|
||||
}
|
||||
|
||||
if (referrer) {
|
||||
refFilter = `and referrer like $${params.length + 1}`;
|
||||
params.push(`%${decodeURIComponent(referrer)}%`);
|
||||
}
|
||||
const { url, referrer, os, browser, device, country } = filters;
|
||||
const joinSession =
|
||||
os || browser || device || country
|
||||
? 'inner join session on session.session_id = pageview.session_id'
|
||||
: '';
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
select ${field} x, count(*) y
|
||||
from session
|
||||
where session_id in (
|
||||
select session_id
|
||||
from session as x
|
||||
where x.session_id in (
|
||||
select pageview.session_id
|
||||
from pageview
|
||||
where website_id=$1
|
||||
and created_at between $2 and $3
|
||||
${urlFilter}
|
||||
${refFilter}
|
||||
${joinSession}
|
||||
where pageview.website_id=$1
|
||||
and pageview.created_at between $2 and $3
|
||||
${getFilterQuery('pageview', { url, referrer }, params)}
|
||||
${getFilterQuery('session', { os, browser, device, country }, params)}
|
||||
)
|
||||
group by 1
|
||||
order by 2 desc
|
||||
|
|
@ -460,36 +493,21 @@ export function getSessionMetrics(website_id, start_at, end_at, field, filters =
|
|||
|
||||
export function getPageviewMetrics(website_id, start_at, end_at, field, table, filters = {}) {
|
||||
const params = [website_id, start_at, end_at];
|
||||
const { domain, url, referrer } = filters;
|
||||
|
||||
let domainFilter = '';
|
||||
let urlFilter = '';
|
||||
let refFilter = '';
|
||||
|
||||
if (domain) {
|
||||
domainFilter = `and referrer not like $${params.length + 1} and referrer not like '/%'`;
|
||||
params.push(`%://${domain}/%`);
|
||||
}
|
||||
|
||||
if (url) {
|
||||
urlFilter = `and url=$${params.length + 1}`;
|
||||
params.push(decodeURIComponent(url));
|
||||
}
|
||||
|
||||
if (referrer && table !== 'event') {
|
||||
refFilter = `and referrer like $${params.length + 1}`;
|
||||
params.push(`%${decodeURIComponent(referrer)}%`);
|
||||
}
|
||||
const { domain, url, referrer, os, browser, device, country } = filters;
|
||||
const joinSession =
|
||||
(os || browser || device || country) && table === 'pageview'
|
||||
? 'inner join session on session.session_id = pageview.session_id'
|
||||
: '';
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
select ${field} x, count(*) y
|
||||
from ${table}
|
||||
where website_id=$1
|
||||
and created_at between $2 and $3
|
||||
${domainFilter}
|
||||
${urlFilter}
|
||||
${refFilter}
|
||||
${joinSession}
|
||||
where ${table}.website_id=$1
|
||||
and ${table}.created_at between $2 and $3
|
||||
${getFilterQuery(table, { domain, url, referrer }, params)}
|
||||
${joinSession && getFilterQuery('session', { os, browser, device, country }, params)}
|
||||
group by 1
|
||||
order by 2 desc
|
||||
`,
|
||||
|
|
@ -521,20 +539,6 @@ export function getEventMetrics(
|
|||
filters = {},
|
||||
) {
|
||||
const params = [website_id, start_at, end_at];
|
||||
const { url, event_type } = filters;
|
||||
|
||||
let urlFilter = '';
|
||||
let eventTypeFilter = '';
|
||||
|
||||
if (url) {
|
||||
urlFilter = `and url=$${params.length + 1}`;
|
||||
params.push(decodeURIComponent(url));
|
||||
}
|
||||
|
||||
if (event_type) {
|
||||
eventTypeFilter = `and event_type=$${params.length + 1}`;
|
||||
params.push(event_type);
|
||||
}
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -545,8 +549,7 @@ export function getEventMetrics(
|
|||
from event
|
||||
where website_id=$1
|
||||
and created_at between $2 and $3
|
||||
${urlFilter}
|
||||
${eventTypeFilter}
|
||||
${getFilterQuery('event', filters, params)}
|
||||
group by 1, 2
|
||||
order by 2
|
||||
`,
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue