From 4bd3ef8e129b7924d927b21695ae8bbddb41fd0f Mon Sep 17 00:00:00 2001 From: Mike Cao Date: Mon, 24 Jul 2023 23:06:16 -0700 Subject: [PATCH] Refactored queries. --- lib/clickhouse.ts | 58 +-------- lib/db.js | 4 + lib/kafka.ts | 2 +- lib/prisma.ts | 83 +++---------- lib/sql.ts | 9 -- .../analytics/eventData/getEventDataEvents.ts | 115 ++++++++++-------- .../analytics/eventData/getEventDataFields.ts | 103 ++++++++-------- .../analytics/eventData/getEventDataUsage.ts | 20 ++- queries/analytics/eventData/saveEventData.ts | 2 +- queries/analytics/events/getEventMetrics.ts | 37 +++--- queries/analytics/events/getEventUsage.ts | 22 ++-- queries/analytics/events/getEvents.ts | 6 +- .../analytics/pageviews/getPageviewMetrics.ts | 44 ++++--- .../analytics/pageviews/getPageviewStats.ts | 58 +++++---- queries/analytics/reports/getFunnel.ts | 10 +- .../analytics/sessions/getSessionMetrics.ts | 33 ++--- queries/analytics/sessions/getSessions.ts | 6 +- queries/analytics/stats/getActiveVisitors.ts | 27 ++-- queries/analytics/stats/getWebsiteStats.ts | 99 ++++++++------- 19 files changed, 330 insertions(+), 408 deletions(-) diff --git a/lib/clickhouse.ts b/lib/clickhouse.ts index 166c0daa..10722fff 100644 --- a/lib/clickhouse.ts +++ b/lib/clickhouse.ts @@ -2,7 +2,6 @@ import { ClickHouse } from 'clickhouse'; import dateFormat from 'dateformat'; import debug from 'debug'; import { CLICKHOUSE } from 'lib/db'; -import { getDynamicDataType } from './dynamicData'; import { WebsiteMetricFilter } from './types'; import { FILTER_COLUMNS } from './constants'; @@ -62,45 +61,6 @@ function getDateFormat(date) { return `'${dateFormat(date, 'UTC:yyyy-mm-dd HH:MM:ss')}'`; } -function getEventDataFilterQuery( - filters: { - eventKey?: string; - eventValue?: string | number | boolean | Date; - }[] = [], - params: any, -) { - const query = filters.reduce((ac, cv, i) => { - const type = getDynamicDataType(cv.eventValue); - - let value = cv.eventValue; - - ac.push(`and (event_key = {eventKey${i}:String}`); - - switch (type) { - case 'number': - ac.push(`and number_value = {eventValue${i}:UInt64})`); - break; - case 'string': - ac.push(`and string_value = {eventValue${i}:String})`); - break; - case 'boolean': - ac.push(`and string_value = {eventValue${i}:String})`); - value = cv ? 'true' : 'false'; - break; - case 'date': - ac.push(`and date_value = {eventValue${i}:DateTime('UTC')})`); - break; - } - - params[`eventKey${i}`] = cv.eventKey; - params[`eventValue${i}`] = value; - - return ac; - }, []); - - return query.join('\n'); -} - function getFilterQuery(filters = {}, params = {}) { const query = Object.keys(filters).reduce((arr, key) => { const filter = filters[key]; @@ -146,22 +106,7 @@ function parseFilters(filters: WebsiteMetricFilter = {}, params: any = {}) { }; } -function formatField(field, type, value) { - switch (type) { - case 'date': - return getDateFormat(value); - default: - return field; - } -} - -async function rawQuery(sql, params = {}): Promise { - const query = sql.replaceAll(/\{\{\w+:\w+}}/g, token => { - const [, field, type] = token.match(/\{\{(\w+):(\w+)}}/); - - return formatField(field, type, params[field]); - }); - +async function rawQuery(query: string, params: object = {}): Promise { if (process.env.LOG_QUERY) { log('QUERY:\n', query); log('PARAMETERS:\n', params); @@ -202,7 +147,6 @@ export default { getDateFormat, getFilterQuery, getFunnelQuery, - getEventDataFilterQuery, parseFilters, findUnique, findFirst, diff --git a/lib/db.js b/lib/db.js index 19e46a3d..750cdec0 100644 --- a/lib/db.js +++ b/lib/db.js @@ -35,3 +35,7 @@ export async function runQuery(queries) { return queries[CLICKHOUSE](); } } + +export function notImplemented() { + throw new Error('Not implemented.'); +} diff --git a/lib/kafka.ts b/lib/kafka.ts index 8f5bb87f..10326888 100644 --- a/lib/kafka.ts +++ b/lib/kafka.ts @@ -61,7 +61,7 @@ async function getProducer(): Promise { return producer; } -function getDateFormat(date, format?): string { +function getDateFormat(date: Date, format?: string): string { return dateFormat(date, format ? format : 'UTC:yyyy-mm-dd HH:MM:ss'); } diff --git a/lib/prisma.ts b/lib/prisma.ts index 875f5897..d2749ed7 100644 --- a/lib/prisma.ts +++ b/lib/prisma.ts @@ -1,7 +1,6 @@ import prisma from '@umami/prisma-client'; import moment from 'moment-timezone'; import { MYSQL, POSTGRESQL, getDatabaseType } from 'lib/db'; -import { getDynamicDataType } from './dynamicData'; import { FILTER_COLUMNS } from './constants'; const MYSQL_DATE_FORMATS = { @@ -20,20 +19,8 @@ const POSTGRESQL_DATE_FORMATS = { year: 'YYYY-01-01', }; -function toUuid(): string { - const db = getDatabaseType(process.env.DATABASE_URL); - - if (db === POSTGRESQL) { - return '::uuid'; - } - - if (db === MYSQL) { - return ''; - } -} - function getAddMinutesQuery(field: string, minutes: number) { - const db = getDatabaseType(process.env.DATABASE_URL); + const db = getDatabaseType(); if (db === POSTGRESQL) { return `${field} + interval '${minutes} minute'`; @@ -45,7 +32,7 @@ function getAddMinutesQuery(field: string, minutes: number) { } function getDateQuery(field: string, unit: string, timezone?: string): string { - const db = getDatabaseType(process.env.DATABASE_URL); + const db = getDatabaseType(); if (db === POSTGRESQL) { if (timezone) { @@ -65,8 +52,8 @@ function getDateQuery(field: string, unit: string, timezone?: string): string { } } -function getTimestampInterval(field: string): string { - const db = getDatabaseType(process.env.DATABASE_URL); +function getTimestampIntervalQuery(field: string): string { + const db = getDatabaseType(); if (db === POSTGRESQL) { return `floor(extract(epoch from max(${field}) - min(${field})))`; @@ -77,47 +64,6 @@ function getTimestampInterval(field: string): string { } } -function getEventDataFilterQuery( - filters: { - eventKey?: string; - eventValue?: string | number | boolean | Date; - }[], - params: any[], -) { - const query = filters.reduce((ac, cv) => { - const type = getDynamicDataType(cv.eventValue); - - let value = cv.eventValue; - - ac.push(`and (event_key = $${params.length + 1}`); - params.push(cv.eventKey); - - switch (type) { - case 'number': - ac.push(`and number_value = $${params.length + 1})`); - params.push(value); - break; - case 'string': - ac.push(`and string_value = $${params.length + 1})`); - params.push(decodeURIComponent(cv.eventValue as string)); - break; - case 'boolean': - ac.push(`and string_value = $${params.length + 1})`); - params.push(decodeURIComponent(cv.eventValue as string)); - value = cv ? 'true' : 'false'; - break; - case 'date': - ac.push(`and date_value = $${params.length + 1})`); - params.push(cv.eventValue); - break; - } - - return ac; - }, []); - - return query.join('\n'); -} - function getFilterQuery(filters = {}, params = []): string { const query = Object.keys(filters).reduce((arr, key) => { const filter = filters[key]; @@ -163,7 +109,7 @@ function getFunnelQuery( and l0.referrer_path = $${i + initParamLength} and l0.url_path = $${levelNumber + initParamLength} and created_at between $2 and $3 - and website_id = $1${toUuid()} + and website_id = $1 )`; } @@ -197,27 +143,32 @@ function parseFilters( }; } -async function rawQuery(query: string, params: never[] = []): Promise { - const db = getDatabaseType(process.env.DATABASE_URL); +async function rawQuery(sql: string, data: object): Promise { + const db = getDatabaseType(); + const params = []; if (db !== POSTGRESQL && db !== MYSQL) { return Promise.reject(new Error('Unknown database.')); } - const sql = db === MYSQL ? query.replace(/\$[0-9]+/g, '?') : query; + const query = sql?.replaceAll(/\{\{(\w+)(::\w+)?}}/g, (...args) => { + const [, name, type] = args; - return prisma.rawQuery(sql, params); + params.push(data[name]); + + return db === MYSQL ? '?' : `$${params.length}${type ?? ''}`; + }); + + return prisma.rawQuery(query, params); } export default { ...prisma, getAddMinutesQuery, getDateQuery, - getTimestampInterval, + getTimestampIntervalQuery, getFilterQuery, getFunnelQuery, - getEventDataFilterQuery, - toUuid, parseFilters, rawQuery, }; diff --git a/lib/sql.ts b/lib/sql.ts index 325a88ed..e69de29b 100644 --- a/lib/sql.ts +++ b/lib/sql.ts @@ -1,9 +0,0 @@ -export function buildSql(query: string, parameters: object) { - const params = { ...parameters }; - - const sql = query.replaceAll(/\$[\w_]+/g, name => { - return name; - }); - - return { sql, params }; -} diff --git a/queries/analytics/eventData/getEventDataEvents.ts b/queries/analytics/eventData/getEventDataEvents.ts index bb57f70e..0c6f4782 100644 --- a/queries/analytics/eventData/getEventDataEvents.ts +++ b/queries/analytics/eventData/getEventDataEvents.ts @@ -1,4 +1,3 @@ -import { buildSql } from 'lib/sql'; import prisma from 'lib/prisma'; import clickhouse from 'lib/clickhouse'; import { CLICKHOUSE, PRISMA, runQuery } from 'lib/db'; @@ -26,47 +25,52 @@ async function relationalQuery( endDate: Date, filters: { field?: string; event?: string }, ) { - const { toUuid, rawQuery } = prisma; + const { rawQuery } = prisma; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); const { field, event } = filters; - if (field) { - if (event) { - return rawQuery( - `select ed.event_key as field, - ed.string_value as value, - count(ed.*) as total - from event_data as ed - inner join website_event as we - on we.event_id = ed.website_event_id - where ed.website_id = $1${toUuid()} - and ed.event_key = $2 - and ed.created_at >= $3 - and ed.created_at between $4 and $5 - and we.event_name = $6 - group by ed.event_key, ed.string_value - order by 3 desc, 2 desc, 1 asc - `, - [websiteId, field, resetDate, startDate, endDate, event] as any, - ); - } - + if (event) { return rawQuery( - `select event_key as field, - string_value as value, - count(*) as total - from event_data - where website_id = $1${toUuid()} - and event_key = $2 - and created_at >= $3 - and created_at between $4 and $5 - group by event_key, string_value - order by 3 desc, 2 desc, 1 asc + ` + select + we.event_name as event, + ed.event_key as field, + ed.string_value as value, + count(ed.*) as total + from event_data as ed + inner join website_event as we + on we.event_id = ed.website_event_id + where ed.website_id = {{websiteId:uuid}} + and ed.event_key = {{field}} + and ed.created_at >= {{resetDate}} + and ed.created_at between {{startDate}} and {{endDate}} + and we.event_name = {{event}} + group by ed.event_key, ed.string_value + order by 3 desc, 2 desc, 1 asc `, - [websiteId, field, resetDate, startDate, endDate] as any, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } + return rawQuery( + ` + select + we.event_name as event, + ed.event_key as field, + ed.string_value as value, + count(ed.*) as total + from event_data as ed + inner join website_event as we + on we.event_id = ed.website_event_id + where ed.website_id = {{websiteId::uuid}} + and ed.event_key = {{field}} + and ed.created_at >= {{resetDate}} + and ed.created_at between {{startDate}} and {{endDate}} + group by we.event_name, ed.event_key, ed.string_value + order by 3 desc, 2 desc, 1 asc + `, + { websiteId, field, resetDate, startDate, endDate }, + ); } async function clickhouseQuery( @@ -82,12 +86,13 @@ async function clickhouseQuery( if (event) { return rawQuery( - `select - event_name as event, - event_key as field, - data_type as type, - string_value as value, - count(*) as total + ` + select + event_name as event, + event_key as field, + data_type as type, + string_value as value, + count(*) as total from event_data where website_id = {websiteId:UUID} and created_at >= {resetDate:DateTime} @@ -95,24 +100,26 @@ async function clickhouseQuery( and event_name = {event:String} group by event_key, data_type, string_value, event_name order by 1 asc, 2 asc, 3 asc, 4 desc - limit 100`, - { websiteId, resetDate, startDate, endDate, event }, + limit 100 + `, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } return rawQuery( - `select - event_name as event, - event_key as field, - data_type as type, - count(*) as total - from event_data - where website_id = {websiteId:UUID} - and created_at >= {resetDate:DateTime} - and created_at between {startDate:DateTime} and {endDate:DateTime} - group by event_key, data_type, event_name - order by 1 asc, 2 asc - limit 100 + ` + select + event_name as event, + event_key as field, + data_type as type, + count(*) as total + from event_data + where website_id = {websiteId:UUID} + and created_at >= {resetDate:DateTime} + and created_at between {startDate:DateTime} and {endDate:DateTime} + group by event_key, data_type, event_name + order by 1 asc, 2 asc + limit 100 `, { websiteId, resetDate, startDate, endDate }, ); diff --git a/queries/analytics/eventData/getEventDataFields.ts b/queries/analytics/eventData/getEventDataFields.ts index d53e87a2..e7eb3814 100644 --- a/queries/analytics/eventData/getEventDataFields.ts +++ b/queries/analytics/eventData/getEventDataFields.ts @@ -15,82 +15,87 @@ export async function getEventDataFields( } async function relationalQuery(websiteId: string, startDate: Date, endDate: Date, field: string) { - const { toUuid, rawQuery } = prisma; + const { rawQuery } = prisma; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); if (field) { return rawQuery( - `select event_key as field, - string_value as value, - count(*) as total - from event_data - where website_id = $1${toUuid()} - and event_key = $2 - and created_at >= $3 - and created_at between $4 and $5 - group by event_key, string_value - order by 3 desc, 2 desc, 1 asc - limit 100 + ` + select + event_key as field, + string_value as value, + count(*) as total + from event_data + where website_id = {{websiteId::uuid}} + and event_key = {{field}} + and created_at >= {{resetDate}} + and created_at between {{startDate}} and {{endDate}} + group by event_key, string_value + order by 3 desc, 2 desc, 1 asc + limit 100 `, - [websiteId, field, resetDate, startDate, endDate] as any, + { websiteId, field, resetDate, startDate, endDate }, ); } return rawQuery( - `select - event_key as field, - data_type as type, - count(*) as total - from event_data - where website_id = $1${toUuid()} - and created_at >= $2 - and created_at between $3 and $4 - group by event_key, data_type - order by 3 desc, 2 asc, 1 asc - limit 100 + ` + select + event_key as field, + data_type as type, + count(*) as total + from event_data + where website_id = {{websiteId::uuid}} + and created_at >= {{resetDate}} + and created_at between {{startDate}} and {{endDate}} + group by event_key, data_type + order by 3 desc, 2 asc, 1 asc + limit 100 `, - [websiteId, resetDate, startDate, endDate] as any, + { websiteId, resetDate, startDate, endDate }, ); } async function clickhouseQuery(websiteId: string, startDate: Date, endDate: Date, field: string) { - const { rawQuery, getDateFormat } = clickhouse; + const { rawQuery } = clickhouse; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); if (field) { return rawQuery( - `select + ` + select event_key as field, string_value as value, count(*) as total - from event_data - where website_id = {websiteId:UUID} - and event_key = {field:String} - and created_at >= ${getDateFormat(resetDate)} - and created_at between ${getDateFormat(startDate)} and ${getDateFormat(endDate)} - group by event_key, string_value - order by 3 desc, 2 desc, 1 asc - limit 100 - `, - { websiteId, field }, + from event_data + where website_id = {websiteId:UUID} + and event_key = {field:String} + and created_at >= {resetDate:DateTime} + and created_at between {startDate:DateTime} and {endDate:DateTime} + group by event_key, string_value + order by 3 desc, 2 desc, 1 asc + limit 100 + `, + { websiteId, field, resetDate, startDate, endDate }, ); } return rawQuery( - `select - event_key as field, - data_type as type, - count(*) as total - from event_data - where website_id = {websiteId:UUID} - and created_at >= ${getDateFormat(resetDate)} - and created_at between ${getDateFormat(startDate)} and ${getDateFormat(endDate)} - group by event_key, data_type - order by 3 desc, 2 asc, 1 asc - limit 100 + ` + select + event_key as field, + data_type as type, + count(*) as total + from event_data + where website_id = {websiteId:UUID} + and created_at >= {resetDate:DateTime} + and created_at between {startDate:DateTime} and {endDate:DateTime} + group by event_key, data_type + order by 3 desc, 2 asc, 1 asc + limit 100 `, - { websiteId }, + { websiteId, resetDate, startDate, endDate }, ); } diff --git a/queries/analytics/eventData/getEventDataUsage.ts b/queries/analytics/eventData/getEventDataUsage.ts index 0abca05e..78bf7c91 100644 --- a/queries/analytics/eventData/getEventDataUsage.ts +++ b/queries/analytics/eventData/getEventDataUsage.ts @@ -1,28 +1,26 @@ import clickhouse from 'lib/clickhouse'; -import { CLICKHOUSE, PRISMA, runQuery } from 'lib/db'; +import { CLICKHOUSE, PRISMA, runQuery, notImplemented } from 'lib/db'; export function getEventDataUsage(...args: [websiteIds: string[], startDate: Date, endDate: Date]) { return runQuery({ - [PRISMA]: () => relationalQuery(...args), + [PRISMA]: notImplemented, [CLICKHOUSE]: () => clickhouseQuery(...args), }); } -function relationalQuery(websiteIds: string[], startDate: Date, endDate: Date) { - throw new Error('Not implemented.'); -} - function clickhouseQuery(websiteIds: string[], startDate: Date, endDate: Date) { const { rawQuery } = clickhouse; return rawQuery( - `select - website_id as websiteId, - count(*) as count + ` + select + website_id as websiteId, + count(*) as count from event_data where created_at between {startDate:DateTime64} and {endDate:DateTime64} - and website_id in {websiteIds:Array(UUID)} - group by website_id`, + and website_id in {websiteIds:Array(UUID)} + group by website_id + `, { websiteIds, startDate, diff --git a/queries/analytics/eventData/saveEventData.ts b/queries/analytics/eventData/saveEventData.ts index 30a6655e..50765229 100644 --- a/queries/analytics/eventData/saveEventData.ts +++ b/queries/analytics/eventData/saveEventData.ts @@ -31,7 +31,7 @@ async function relationalQuery(data: { const jsonKeys = flattenJSON(eventData); - //id, websiteEventId, eventStringValue + // id, websiteEventId, eventStringValue const flattendData = jsonKeys.map(a => ({ id: uuid(), websiteEventId: eventId, diff --git a/queries/analytics/events/getEventMetrics.ts b/queries/analytics/events/getEventMetrics.ts index ca104ded..e1312ee1 100644 --- a/queries/analytics/events/getEventMetrics.ts +++ b/queries/analytics/events/getEventMetrics.ts @@ -45,26 +45,27 @@ async function relationalQuery( }; }, ) { - const { toUuid, rawQuery, getDateQuery, getFilterQuery } = prisma; + const { rawQuery, getDateQuery, getFilterQuery } = prisma; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); - const params: any = [websiteId, resetDate, startDate, endDate]; - const filterQuery = getFilterQuery(filters, params); + const filterQuery = getFilterQuery(filters); return rawQuery( - `select + ` + select event_name x, ${getDateQuery('created_at', unit, timezone)} t, count(*) y from website_event - where website_id = $1${toUuid()} - and created_at >= $2 - and created_at between $3 and $4 + where website_id = {{websiteId::uuid}} + and created_at >= {{resetDate}} + and created_at between {{startDate}} and {{endDate}} and event_type = ${EVENT_TYPE.customEvent} ${filterQuery} group by 1, 2 - order by 2`, - params, + order by 2 + `, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } @@ -87,24 +88,26 @@ async function clickhouseQuery( }; }, ) { - const { rawQuery, getDateQuery, getDateFormat, getFilterQuery } = clickhouse; + const { rawQuery, getDateQuery, getFilterQuery } = clickhouse; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); - const params = { websiteId }; + const filterQuery = getFilterQuery(filters); return rawQuery( - `select + ` + select event_name x, ${getDateQuery('created_at', unit, timezone)} t, count(*) y from website_event where website_id = {websiteId:UUID} and event_type = ${EVENT_TYPE.customEvent} - and created_at >= ${getDateFormat(resetDate)} - and created_at between ${getDateFormat(startDate)} and ${getDateFormat(endDate)} - ${getFilterQuery(filters, params)} + and created_at >= {resetDate:DateTIme} + and created_at between {startDate:DateTime} and {endDate:DateTime} + ${filterQuery} group by x, t - order by t`, - params, + order by t + `, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } diff --git a/queries/analytics/events/getEventUsage.ts b/queries/analytics/events/getEventUsage.ts index 78616e04..e8ed975f 100644 --- a/queries/analytics/events/getEventUsage.ts +++ b/queries/analytics/events/getEventUsage.ts @@ -1,28 +1,26 @@ import clickhouse from 'lib/clickhouse'; -import { CLICKHOUSE, PRISMA, runQuery } from 'lib/db'; +import { CLICKHOUSE, PRISMA, runQuery, notImplemented } from 'lib/db'; export function getEventUsage(...args: [websiteIds: string[], startDate: Date, endDate: Date]) { return runQuery({ - [PRISMA]: () => relationalQuery(...args), + [PRISMA]: notImplemented, [CLICKHOUSE]: () => clickhouseQuery(...args), }); } -function relationalQuery(websiteIds: string[], startDate: Date, endDate: Date) { - throw new Error('Not implemented.'); -} - function clickhouseQuery(websiteIds: string[], startDate: Date, endDate: Date) { const { rawQuery } = clickhouse; return rawQuery( - `select - website_id as websiteId, - count(*) as count + ` + select + website_id as websiteId, + count(*) as count from website_event - where created_at between {startDate:DateTime64} and {endDate:DateTime64} - and website_id in {websiteIds:Array(UUID)} - group by website_id`, + where website_id in {websiteIds:Array(UUID)} + and created_at between {startDate:DateTime64} and {endDate:DateTime64} + group by website_id + `, { websiteIds, startDate, diff --git a/queries/analytics/events/getEvents.ts b/queries/analytics/events/getEvents.ts index 8197019d..5bf441e3 100644 --- a/queries/analytics/events/getEvents.ts +++ b/queries/analytics/events/getEvents.ts @@ -25,7 +25,8 @@ function clickhouseQuery(websiteId: string, startAt: Date, eventType: number) { const { rawQuery } = clickhouse; return rawQuery( - `select + ` + select event_id as id, website_id as websiteId, session_id as sessionId, @@ -37,7 +38,8 @@ function clickhouseQuery(websiteId: string, startAt: Date, eventType: number) { from website_event where event_type = {eventType:UInt32} and website_id = {websiteId:UUID} - and created_at >= {startAt:DateTime('UTC')}`, + and created_at >= {startAt:DateTime('UTC')} + `, { websiteId, startAt, diff --git a/queries/analytics/pageviews/getPageviewMetrics.ts b/queries/analytics/pageviews/getPageviewMetrics.ts index 37f39e52..e581c668 100644 --- a/queries/analytics/pageviews/getPageviewMetrics.ts +++ b/queries/analytics/pageviews/getPageviewMetrics.ts @@ -31,40 +31,43 @@ async function relationalQuery( }, ) { const { startDate, endDate, filters = {}, column } = criteria; - const { rawQuery, parseFilters, toUuid } = prisma; + const { rawQuery, parseFilters } = prisma; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); - const params: any = [ + const params: any = { websiteId, resetDate, startDate, endDate, - column === 'event_name' ? EVENT_TYPE.customEvent : EVENT_TYPE.pageView, - ]; + eventType: column === 'event_name' ? EVENT_TYPE.customEvent : EVENT_TYPE.pageView, + }; let excludeDomain = ''; if (column === 'referrer_domain') { excludeDomain = - 'and (website_event.referrer_domain != $6 or website_event.referrer_domain is null)'; - params.push(website.domain); + 'and (website_event.referrer_domain != {{domain}} or website_event.referrer_domain is null)'; + + params.domain = website.domain; } - const { filterQuery, joinSession } = parseFilters(filters, params); + const { filterQuery, joinSession } = parseFilters(filters); return rawQuery( - `select ${column} x, count(*) y + ` + select ${column} x, count(*) y from website_event ${joinSession} - where website_event.website_id = $1${toUuid()} - and website_event.created_at >= $2 - and website_event.created_at between $3 and $4 - and event_type = $5 + where website_event.website_id = {{websiteId::uuid}} + and website_event.created_at >= {{resetDate}} + and website_event.created_at between {{startDate}} and {{endDate}} + and event_type = {{eventType}} ${excludeDomain} ${filterQuery} group by 1 order by 2 desc - limit 100`, + limit 100 + `, params, ); } @@ -79,11 +82,14 @@ async function clickhouseQuery( }, ) { const { startDate, endDate, filters = {}, column } = criteria; - const { rawQuery, getDateFormat, parseFilters } = clickhouse; + const { rawQuery, parseFilters } = clickhouse; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); const params = { websiteId, + resetDate, + startDate, + endDate, eventType: column === 'event_name' ? EVENT_TYPE.customEvent : EVENT_TYPE.pageView, domain: undefined, }; @@ -98,17 +104,19 @@ async function clickhouseQuery( const { filterQuery } = parseFilters(filters, params); return rawQuery( - `select ${column} x, count(*) y + ` + select ${column} x, count(*) y from website_event where website_id = {websiteId:UUID} + and created_at >= {resetDate:DateTime} + and created_at between {startDate:DateTime} and {endDate:DateTime} and event_type = {eventType:UInt32} - and created_at >= ${getDateFormat(resetDate)} - and created_at between ${getDateFormat(startDate)} and ${getDateFormat(endDate)} ${excludeDomain} ${filterQuery} group by x order by y desc - limit 100`, + limit 100 + `, params, ); } diff --git a/queries/analytics/pageviews/getPageviewStats.ts b/queries/analytics/pageviews/getPageviewStats.ts index a83cfcd1..7421adf9 100644 --- a/queries/analytics/pageviews/getPageviewStats.ts +++ b/queries/analytics/pageviews/getPageviewStats.ts @@ -45,24 +45,26 @@ async function relationalQuery( filters = {}, sessionKey = 'session_id', } = criteria; - const { toUuid, getDateQuery, parseFilters, rawQuery } = prisma; + const { getDateQuery, parseFilters, rawQuery } = prisma; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); - const params: any = [websiteId, resetDate, startDate, endDate]; - const { filterQuery, joinSession } = parseFilters(filters, params); + const { filterQuery, joinSession } = parseFilters(filters); return rawQuery( - `select ${getDateQuery('website_event.created_at', unit, timezone)} x, - count(${count !== '*' ? `${count}${sessionKey}` : count}) y - from website_event - ${joinSession} - where website_event.website_id = $1${toUuid()} - and website_event.created_at >= $2 - and website_event.created_at between $3 and $4 - and event_type = ${EVENT_TYPE.pageView} - ${filterQuery} - group by 1`, - params, + ` + select + ${getDateQuery('website_event.created_at', unit, timezone)} x, + count(${count !== '*' ? `${count}${sessionKey}` : count}) y + from website_event + ${joinSession} + where website_event.website_id = {{websiteId::uuid}} + and website_event.created_at >= {{resetDate}} + and website_event.created_at between {{startDate}} and {{endDate}} + and event_type = ${EVENT_TYPE.pageView} + ${filterQuery} + group by 1 + `, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } @@ -86,28 +88,30 @@ async function clickhouseQuery( count = '*', filters = {}, } = criteria; - const { parseFilters, getDateFormat, rawQuery, getDateStringQuery, getDateQuery } = clickhouse; + const { parseFilters, rawQuery, getDateStringQuery, getDateQuery } = clickhouse; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); - const params = { websiteId }; - const { filterQuery } = parseFilters(filters, params); + const { filterQuery } = parseFilters(filters); return rawQuery( - `select + ` + select ${getDateStringQuery('g.t', unit)} as x, g.y as y - from - (select - ${getDateQuery('created_at', unit, timezone)} t, - count(${count !== '*' ? 'distinct session_id' : count}) y + from ( + select + ${getDateQuery('created_at', unit, timezone)} as t, + count(${count !== '*' ? 'distinct session_id' : count}) as y from website_event where website_id = {websiteId:UUID} + and created_at >= {resetDate:DateTime} + and created_at between {startDate:DateTime} and {endDate:DateTime} and event_type = ${EVENT_TYPE.pageView} - and created_at >= ${getDateFormat(resetDate)} - and created_at between ${getDateFormat(startDate)} and ${getDateFormat(endDate)} ${filterQuery} - group by t) g - order by t`, - params, + group by t + ) as g + order by t + `, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } diff --git a/queries/analytics/reports/getFunnel.ts b/queries/analytics/reports/getFunnel.ts index d7786477..1dde1a13 100644 --- a/queries/analytics/reports/getFunnel.ts +++ b/queries/analytics/reports/getFunnel.ts @@ -34,18 +34,16 @@ async function relationalQuery( }[] > { const { windowMinutes, startDate, endDate, urls } = criteria; - const { rawQuery, getFunnelQuery, toUuid } = prisma; + const { rawQuery, getFunnelQuery } = prisma; const { levelQuery, sumQuery, urlFilterQuery } = getFunnelQuery(urls, windowMinutes); - const params: any = [websiteId, startDate, endDate, ...urls]; - return rawQuery( `WITH level0 AS ( select distinct session_id, url_path, referrer_path, created_at from website_event where url_path in (${urlFilterQuery}) - and website_id = $1${toUuid()} - and created_at between $2 and $3 + and website_id = {{websiteId::uuid}} + and created_at between {{startDate}} and {{endDate}} ),level1 AS ( select distinct session_id, url_path as level_1_url, created_at as level_1_created_at from level0 @@ -55,7 +53,7 @@ async function relationalQuery( SELECT ${sumQuery} from level${urls.length}; `, - params, + { websiteId, startDate, endDate, ...urls }, ).then((a: { [key: string]: number }) => { return urls.map((b, i) => ({ x: b, y: a[0][`level${i + 1}`] || 0 })); }); diff --git a/queries/analytics/sessions/getSessionMetrics.ts b/queries/analytics/sessions/getSessionMetrics.ts index 60fde41b..0cdbd06a 100644 --- a/queries/analytics/sessions/getSessionMetrics.ts +++ b/queries/analytics/sessions/getSessionMetrics.ts @@ -23,9 +23,8 @@ async function relationalQuery( const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); const { startDate, endDate, column, filters = {} } = criteria; - const { toUuid, parseFilters, rawQuery } = prisma; - const params: any = [websiteId, resetDate, startDate, endDate]; - const { filterQuery, joinSession } = parseFilters(filters, params); + const { parseFilters, rawQuery } = prisma; + const { filterQuery, joinSession } = parseFilters(filters); return rawQuery( `select ${column} x, count(*) y @@ -36,15 +35,15 @@ async function relationalQuery( join website on website_event.website_id = website.website_id ${joinSession} - where website.website_id = $1${toUuid()} - and website_event.created_at >= $2 - and website_event.created_at between $3 and $4 + where website.website_id = {{websiteId::uuid}} + and website_event.created_at >= {{resetDate}} + and website_event.created_at between {{startDate}} and {{endDate}} ${filterQuery} ) group by 1 order by 2 desc limit 100`, - params, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } @@ -53,23 +52,25 @@ async function clickhouseQuery( data: { startDate: Date; endDate: Date; column: string; filters: object }, ) { const { startDate, endDate, column, filters = {} } = data; - const { getDateFormat, parseFilters, rawQuery } = clickhouse; + const { parseFilters, rawQuery } = clickhouse; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); - const params = { websiteId }; - const { filterQuery } = parseFilters(filters, params); + const { filterQuery } = parseFilters(filters); return rawQuery( - `select ${column} x, count(distinct session_id) y + ` + select + ${column} x, count(distinct session_id) y from website_event as x where website_id = {websiteId:UUID} - and event_type = ${EVENT_TYPE.pageView} - and created_at >= ${getDateFormat(resetDate)} - and created_at between ${getDateFormat(startDate)} and ${getDateFormat(endDate)} + and created_at >= {resetDate:DateTime} + and created_at between {startDate:DateTime} and {endDate:DateTime} + and event_type = ${EVENT_TYPE.pageView} ${filterQuery} group by x order by y desc - limit 100`, - params, + limit 100 + `, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } diff --git a/queries/analytics/sessions/getSessions.ts b/queries/analytics/sessions/getSessions.ts index a4fbb501..750b6249 100644 --- a/queries/analytics/sessions/getSessions.ts +++ b/queries/analytics/sessions/getSessions.ts @@ -24,7 +24,8 @@ async function clickhouseQuery(websiteId: string, startAt: Date) { const { rawQuery } = clickhouse; return rawQuery( - `select distinct + ` + select distinct session_id as id, website_id as websiteId, created_at as createdAt, @@ -41,7 +42,8 @@ async function clickhouseQuery(websiteId: string, startAt: Date) { city from website_event where website_id = {websiteId:UUID} - and created_at >= {startAt:DateTime('UTC')}`, + and created_at >= {startAt:DateTime} + `, { websiteId, startAt, diff --git a/queries/analytics/stats/getActiveVisitors.ts b/queries/analytics/stats/getActiveVisitors.ts index 89f092c1..8dcfd7c9 100644 --- a/queries/analytics/stats/getActiveVisitors.ts +++ b/queries/analytics/stats/getActiveVisitors.ts @@ -11,31 +11,32 @@ export async function getActiveVisitors(...args: [websiteId: string]) { } async function relationalQuery(websiteId: string) { - const { toUuid, rawQuery } = prisma; - - const date = subMinutes(new Date(), 5); - const params: any = [websiteId, date]; + const { rawQuery } = prisma; return rawQuery( - `select count(distinct session_id) x + ` + select count(distinct session_id) x from website_event - join website + join website on website_event.website_id = website.website_id - where website.website_id = $1${toUuid()} - and website_event.created_at >= $2`, - params, + where website.website_id = {{websiteId::uuid}} + and website_event.created_at >= {{startAt}} + `, + { websiteId, startAt: subMinutes(new Date(), 5) }, ); } async function clickhouseQuery(websiteId: string) { const { rawQuery } = clickhouse; - const params = { websiteId, startAt: subMinutes(new Date(), 5) }; return rawQuery( - `select count(distinct session_id) x + ` + select + count(distinct session_id) x from website_event where website_id = {websiteId:UUID} - and created_at >= {startAt:DateTime('UTC')}`, - params, + and created_at >= {startAt:DateTime} + `, + { websiteId, startAt: subMinutes(new Date(), 5) }, ); } diff --git a/queries/analytics/stats/getWebsiteStats.ts b/queries/analytics/stats/getWebsiteStats.ts index a3034879..aeae7b53 100644 --- a/queries/analytics/stats/getWebsiteStats.ts +++ b/queries/analytics/stats/getWebsiteStats.ts @@ -21,34 +21,37 @@ async function relationalQuery( criteria: { startDate: Date; endDate: Date; filters: object }, ) { const { startDate, endDate, filters = {} } = criteria; - const { toUuid, getDateQuery, getTimestampInterval, parseFilters, rawQuery } = prisma; + const { getDateQuery, getTimestampIntervalQuery, parseFilters, rawQuery } = prisma; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); - const params: any = [websiteId, resetDate, startDate, endDate]; - const { filterQuery, joinSession } = parseFilters(filters, params); + const { filterQuery, joinSession } = parseFilters(filters); return rawQuery( - `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 website_event.session_id, - ${getDateQuery('website_event.created_at', 'hour')}, - count(*) c, - ${getTimestampInterval('website_event.created_at')} as "time" - from website_event - join website - on website_event.website_id = website.website_id - ${joinSession} - where event_type = ${EVENT_TYPE.pageView} - and website.website_id = $1${toUuid()} - and website_event.created_at >= $2 - and website_event.created_at between $3 and $4 - ${filterQuery} - group by 1, 2 - ) t`, - params, + ` + 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 + website_event.session_id, + ${getDateQuery('website_event.created_at', 'hour')}, + count(*) as c, + ${getTimestampIntervalQuery('website_event.created_at')} as "time" + from website_event + join website + on website_event.website_id = website.website_id + ${joinSession} + where event_type = ${EVENT_TYPE.pageView} + and website.website_id = {{websiteId::uuid}} + and website_event.created_at >= {{resetDate}} + and website_event.created_at between {{startDate}} and {{endDate}} + ${filterQuery} + group by 1, 2 + ) as t + `, + { ...filters, websiteId, resetDate, startDate, endDate }, ); } @@ -57,32 +60,34 @@ async function clickhouseQuery( criteria: { startDate: Date; endDate: Date; filters: object }, ) { const { startDate, endDate, filters = {} } = criteria; - const { rawQuery, getDateFormat, getDateQuery, parseFilters } = clickhouse; + const { rawQuery, getDateQuery, parseFilters } = clickhouse; const website = await loadWebsite(websiteId); const resetDate = new Date(website?.resetAt || DEFAULT_RESET_DATE); - const params = { websiteId }; - const { filterQuery } = parseFilters(filters, params); + const { filterQuery } = parseFilters(filters); return rawQuery( - `select - sum(t.c) as "pageviews", - count(distinct t.session_id) as "uniques", - sum(if(t.c = 1, 1, 0)) as "bounces", - sum(if(max_time < min_time + interval 1 hour, max_time-min_time, 0)) as "totaltime" - from ( - select session_id, - ${getDateQuery('created_at', 'day')} time_series, - count(*) c, - min(created_at) min_time, - max(created_at) max_time - from website_event - where event_type = ${EVENT_TYPE.pageView} - and website_id = {websiteId:UUID} - and created_at >= ${getDateFormat(resetDate)} - and created_at between ${getDateFormat(startDate)} and ${getDateFormat(endDate)} - ${filterQuery} - group by session_id, time_series - ) t;`, - params, + ` + select + sum(t.c) as "pageviews", + count(distinct t.session_id) as "uniques", + sum(if(t.c = 1, 1, 0)) as "bounces", + sum(if(max_time < min_time + interval 1 hour, max_time-min_time, 0)) as "totaltime" + from ( + select + session_id, + ${getDateQuery('created_at', 'day')} time_series, + count(*) c, + min(created_at) min_time, + max(created_at) max_time + from website_event + where website_id = {websiteId:UUID} + and created_at >= {resetDate:DateTime} + and created_at between {startDate:DateTime} and {endDate:DateTime} + and event_type = ${EVENT_TYPE.pageView} + ${filterQuery} + group by session_id, time_series + ) as t; + `, + { ...filters, websiteId, resetDate, startDate, endDate }, ); }