From 14e4a090bb79ef61c33ea57ea8d4be21ac34bc51 Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Mon, 27 Mar 2023 11:25:16 -0700 Subject: [PATCH] update schema and queries to implement reset_at --- db/clickhouse/schema.sql | 6 ------ db/mysql/schema.prisma | 2 +- db/postgresql/schema.prisma | 2 +- lib/types.ts | 2 +- queries/admin/website.ts | 9 +++++--- queries/analytics/event/getEventMetrics.ts | 14 ++++++++----- queries/analytics/event/saveEvent.ts | 6 ------ queries/analytics/eventData/getEventData.ts | 17 +++++++++------ queries/analytics/eventData/saveEventData.ts | 5 +---- .../analytics/pageview/getPageviewMetrics.ts | 14 ++++++++----- .../analytics/pageview/getPageviewStats.ts | 21 ++++++++++++++----- queries/analytics/pageview/savePageView.ts | 3 --- queries/analytics/session/createSession.ts | 2 -- .../analytics/session/getSessionMetrics.ts | 14 ++++++++----- queries/analytics/stats/getWebsiteStats.ts | 16 ++++++++------ 15 files changed, 74 insertions(+), 59 deletions(-) diff --git a/db/clickhouse/schema.sql b/db/clickhouse/schema.sql index 3fd99aa3..904cd377 100644 --- a/db/clickhouse/schema.sql +++ b/db/clickhouse/schema.sql @@ -6,7 +6,6 @@ CREATE TABLE umami.event website_id UUID, session_id UUID, event_id UUID, - rev_id UInt32, --session hostname LowCardinality(String), browser LowCardinality(String), @@ -38,7 +37,6 @@ CREATE TABLE umami.event_queue ( website_id UUID, session_id UUID, event_id UUID, - rev_id UInt32, --session hostname LowCardinality(String), browser LowCardinality(String), @@ -74,7 +72,6 @@ CREATE MATERIALIZED VIEW umami.event_queue_mv TO umami.event AS SELECT website_id, session_id, event_id, - rev_id, hostname, browser, os, @@ -101,7 +98,6 @@ CREATE TABLE umami.event_data website_id UUID, session_id UUID, event_id UUID, - rev_id UInt32, url_path String, event_name String, event_key String, @@ -119,7 +115,6 @@ CREATE TABLE umami.event_data_queue ( website_id UUID, session_id UUID, event_id UUID, - rev_id UInt32, url_path String, event_name String, event_key String, @@ -141,7 +136,6 @@ CREATE MATERIALIZED VIEW umami.event_data_queue_mv TO umami.event_data AS SELECT website_id, session_id, event_id, - rev_id, url_path, event_name, event_key, diff --git a/db/mysql/schema.prisma b/db/mysql/schema.prisma index 13dcdcbc..af939c0c 100644 --- a/db/mysql/schema.prisma +++ b/db/mysql/schema.prisma @@ -50,7 +50,7 @@ model Website { name String @db.VarChar(100) domain String? @db.VarChar(500) shareId String? @unique @map("share_id") @db.VarChar(50) - revId Int @default(0) @map("rev_id") @db.UnsignedInt + resetAt DateTime? @map("reset_at") @db.Timestamp(0) userId String? @map("user_id") @db.VarChar(36) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) updatedAt DateTime? @map("updated_at") @db.Timestamp(0) diff --git a/db/postgresql/schema.prisma b/db/postgresql/schema.prisma index bb26a807..57f7a78f 100644 --- a/db/postgresql/schema.prisma +++ b/db/postgresql/schema.prisma @@ -50,7 +50,7 @@ model Website { name String @db.VarChar(100) domain String? @db.VarChar(500) shareId String? @unique @map("share_id") @db.VarChar(50) - revId Int @default(0) @map("rev_id") @db.Integer + resetAt DateTime? @map("reset_at") @db.Timestamptz(6) userId String? @map("user_id") @db.Uuid createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) updatedAt DateTime? @map("updated_at") @db.Timestamptz(6) diff --git a/lib/types.ts b/lib/types.ts index c818d6ff..88a3907c 100644 --- a/lib/types.ts +++ b/lib/types.ts @@ -48,7 +48,7 @@ export interface User { export interface Website { id: string; userId: string; - revId: number; + resetAt: Date; name: string; domain: string; shareId: string; diff --git a/queries/admin/website.ts b/queries/admin/website.ts index 7bcb66b2..49c97691 100644 --- a/queries/admin/website.ts +++ b/queries/admin/website.ts @@ -49,8 +49,6 @@ export async function resetWebsite( ): Promise<[Prisma.BatchPayload, Prisma.BatchPayload, Website]> { const { client, transaction } = prisma; - const { revId } = await getWebsite({ id: websiteId }); - return transaction([ client.websiteEvent.deleteMany({ where: { websiteId }, @@ -58,7 +56,12 @@ export async function resetWebsite( client.session.deleteMany({ where: { websiteId }, }), - client.website.update({ where: { id: websiteId }, data: { revId: revId + 1 } }), + client.website.update({ + where: { id: websiteId }, + data: { + resetAt: new Date(), + }, + }), ]).then(async data => { if (cache.enabled) { await cache.storeWebsite(data[2]); diff --git a/queries/analytics/event/getEventMetrics.ts b/queries/analytics/event/getEventMetrics.ts index 31cfe327..35eda8f6 100644 --- a/queries/analytics/event/getEventMetrics.ts +++ b/queries/analytics/event/getEventMetrics.ts @@ -46,7 +46,9 @@ async function relationalQuery( }, ) { const { toUuid, rawQuery, getDateQuery, getFilterQuery } = prisma; - const params: any = [websiteId, startDate, endDate]; + const website = await cache.fetchWebsite(websiteId); + const resetDate = website?.resetAt || website?.createdAt; + const params: any = [websiteId, resetDate, startDate, endDate]; return rawQuery( `select @@ -55,7 +57,8 @@ async function relationalQuery( count(*) y from website_event where website_id = $1${toUuid()} - and created_at between $2 and $3 + and created_at >= $2 + and created_at between $3 and $4 and event_type = ${EVENT_TYPE.customEvent} ${getFilterQuery(filters, params)} group by 1, 2 @@ -83,9 +86,10 @@ async function clickhouseQuery( }; }, ) { - const { rawQuery, getDateQuery, getBetweenDates, getFilterQuery } = clickhouse; + const { rawQuery, getDateQuery, getDateFormat, getBetweenDates, getFilterQuery } = clickhouse; const website = await cache.fetchWebsite(websiteId); - const params = { websiteId, revId: website?.revId || 0 }; + const resetDate = website?.resetAt || website?.createdAt; + const params = { websiteId }; return rawQuery( `select @@ -94,8 +98,8 @@ async function clickhouseQuery( count(*) y from event where website_id = {websiteId:UUID} - and rev_id = {revId:UInt32} and event_type = ${EVENT_TYPE.customEvent} + and created_at >= ${getDateFormat(resetDate)} and ${getBetweenDates('created_at', startDate, endDate)} ${getFilterQuery(filters, params)} group by x, t diff --git a/queries/analytics/event/saveEvent.ts b/queries/analytics/event/saveEvent.ts index d1f124ea..cbb48826 100644 --- a/queries/analytics/event/saveEvent.ts +++ b/queries/analytics/event/saveEvent.ts @@ -3,7 +3,6 @@ import { CLICKHOUSE, PRISMA, runQuery } from 'lib/db'; import kafka from 'lib/kafka'; import prisma from 'lib/prisma'; import { uuid } from 'lib/crypto'; -import cache from 'lib/cache'; import { saveEventData } from '../eventData/saveEventData'; export async function saveEvent(args: { @@ -41,7 +40,6 @@ async function relationalQuery(data: { eventData?: any; }) { const { websiteId, id: sessionId, urlPath, urlQuery, eventName, eventData, pageTitle } = data; - const website = await cache.fetchWebsite(websiteId); const websiteEventId = uuid(); const websiteEvent = prisma.client.websiteEvent.create({ @@ -62,7 +60,6 @@ async function relationalQuery(data: { websiteId, sessionId, eventId: websiteEventId, - revId: website?.revId, urlPath: urlPath?.substring(0, URL_LENGTH), eventName: eventName?.substring(0, EVENT_NAME_LENGTH), eventData, @@ -106,7 +103,6 @@ async function clickhouseQuery(data: { ...args } = data; const { getDateFormat, sendMessage } = kafka; - const website = await cache.fetchWebsite(websiteId); const eventId = uuid(); const createdAt = getDateFormat(new Date()); @@ -123,7 +119,6 @@ async function clickhouseQuery(data: { page_title: pageTitle, event_type: EVENT_TYPE.customEvent, event_name: eventName?.substring(0, EVENT_NAME_LENGTH), - rev_id: website?.revId || 0, created_at: createdAt, ...args, }; @@ -135,7 +130,6 @@ async function clickhouseQuery(data: { websiteId, sessionId, eventId, - revId: website?.revId, urlPath: urlPath?.substring(0, URL_LENGTH), eventName: eventName?.substring(0, EVENT_NAME_LENGTH), eventData, diff --git a/queries/analytics/eventData/getEventData.ts b/queries/analytics/eventData/getEventData.ts index 1c34a733..f8e2febb 100644 --- a/queries/analytics/eventData/getEventData.ts +++ b/queries/analytics/eventData/getEventData.ts @@ -48,7 +48,9 @@ async function relationalQuery( ) { const { startDate, endDate, timeSeries, eventName, urlPath, filters } = data; const { toUuid, rawQuery, getEventDataFilterQuery, getDateQuery } = prisma; - const params: any = [websiteId, startDate, endDate, eventName || '']; + const website = await cache.fetchWebsite(websiteId); + const resetDate = website?.resetAt || website?.createdAt; + const params: any = [websiteId, resetDate, startDate, endDate, eventName || '']; return rawQuery( `select @@ -65,8 +67,9 @@ async function relationalQuery( : '' } where website_id = $1${toUuid()} - and created_at between $2 and $3 - ${eventName ? `and eventName = $4` : ''} + and created_at >= $2 + and created_at between $3 and $4 + ${eventName ? `and eventName = $5` : ''} ${getEventDataFilterQuery(filters, params)} ${timeSeries ? 'group by t' : ''}`, params, @@ -93,9 +96,11 @@ async function clickhouseQuery( }, ) { const { startDate, endDate, timeSeries, eventName, urlPath, filters } = data; - const { rawQuery, getBetweenDates, getDateQuery, getEventDataFilterQuery } = clickhouse; + const { rawQuery, getDateFormat, getBetweenDates, getDateQuery, getEventDataFilterQuery } = + clickhouse; const website = await cache.fetchWebsite(websiteId); - const params = { websiteId, revId: website?.revId || 0 }; + const resetDate = website?.resetAt || website?.createdAt; + const params = { websiteId }; return rawQuery( `select @@ -107,8 +112,8 @@ async function clickhouseQuery( } from event_data where website_id = {websiteId:UUID} - and rev_id = {revId:UInt32} ${eventName ? `and eventName = ${eventName}` : ''} + and created_at >= ${getDateFormat(resetDate)} and ${getBetweenDates('created_at', startDate, endDate)} ${getEventDataFilterQuery(filters, params)} ${timeSeries ? 'group by t' : ''}`, diff --git a/queries/analytics/eventData/saveEventData.ts b/queries/analytics/eventData/saveEventData.ts index c7ccb1b1..90e63565 100644 --- a/queries/analytics/eventData/saveEventData.ts +++ b/queries/analytics/eventData/saveEventData.ts @@ -11,7 +11,6 @@ export async function saveEventData(args: { websiteId: string; eventId: string; sessionId?: string; - revId?: number; urlPath?: string; eventName?: string; eventData: EventData; @@ -58,13 +57,12 @@ async function clickhouseQuery(data: { websiteId: string; eventId: string; sessionId?: string; - revId?: number; urlPath?: string; eventName?: string; eventData: EventData; createdAt?: string; }) { - const { websiteId, sessionId, eventId, revId, urlPath, eventName, eventData, createdAt } = data; + const { websiteId, sessionId, eventId, urlPath, eventName, eventData, createdAt } = data; const { getDateFormat, sendMessages } = kafka; @@ -74,7 +72,6 @@ async function clickhouseQuery(data: { website_id: websiteId, session_id: sessionId, event_id: eventId, - rev_id: revId, url_path: urlPath, event_name: eventName, event_key: a.key, diff --git a/queries/analytics/pageview/getPageviewMetrics.ts b/queries/analytics/pageview/getPageviewMetrics.ts index 0475207c..09524047 100644 --- a/queries/analytics/pageview/getPageviewMetrics.ts +++ b/queries/analytics/pageview/getPageviewMetrics.ts @@ -35,8 +35,11 @@ async function relationalQuery( ) { const { startDate, endDate, column, filters = {}, type } = data; const { rawQuery, parseFilters, toUuid } = prisma; + const website = await cache.fetchWebsite(websiteId); + const resetDate = website?.resetAt || website?.createdAt; const params: any = [ websiteId, + resetDate, startDate, endDate, type === 'event' ? EVENT_TYPE.customEvent : EVENT_TYPE.pageView, @@ -48,8 +51,9 @@ async function relationalQuery( from website_event ${joinSession} where website_event.website_id = $1${toUuid()} - and website_event.created_at between $2 and $3 - and event_type = $4 + and website_event.created_at >= $2 + and website_event.created_at between $3 and $4 + and event_type = $5 ${filterQuery} group by 1 order by 2 desc @@ -69,11 +73,11 @@ async function clickhouseQuery( }, ) { const { startDate, endDate, column, filters = {}, type } = data; - const { rawQuery, parseFilters, getBetweenDates } = clickhouse; + const { rawQuery, getDateFormat, parseFilters, getBetweenDates } = clickhouse; const website = await cache.fetchWebsite(websiteId); + const resetDate = website?.resetAt || website?.createdAt; const params = { websiteId, - revId: website?.revId || 0, eventType: type === 'event' ? EVENT_TYPE.customEvent : EVENT_TYPE.pageView, }; const { filterQuery } = parseFilters(filters, params); @@ -82,8 +86,8 @@ async function clickhouseQuery( `select ${column} x, count(*) y from event where website_id = {websiteId:UUID} - and rev_id = {revId:UInt32} and event_type = {eventType:UInt32} + and created_at >= ${getDateFormat(resetDate)} and ${getBetweenDates('created_at', startDate, endDate)} ${filterQuery} group by x diff --git a/queries/analytics/pageview/getPageviewStats.ts b/queries/analytics/pageview/getPageviewStats.ts index 273151aa..c6197312 100644 --- a/queries/analytics/pageview/getPageviewStats.ts +++ b/queries/analytics/pageview/getPageviewStats.ts @@ -46,7 +46,9 @@ async function relationalQuery( sessionKey = 'session_id', } = data; const { toUuid, getDateQuery, parseFilters, rawQuery } = prisma; - const params: any = [websiteId, startDate, endDate]; + const website = await cache.fetchWebsite(websiteId); + const resetDate = website?.resetAt || website?.createdAt; + const params: any = [websiteId, resetDate, startDate, endDate]; const { filterQuery, joinSession } = parseFilters(filters, params); return rawQuery( @@ -55,7 +57,8 @@ async function relationalQuery( from website_event ${joinSession} where website_event.website_id = $1${toUuid()} - and website_event.created_at between $2 and $3 + 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`, @@ -76,9 +79,17 @@ async function clickhouseQuery( }, ) { const { startDate, endDate, timezone = 'UTC', unit = 'day', count = '*', filters = {} } = data; - const { parseFilters, rawQuery, getDateStringQuery, getDateQuery, getBetweenDates } = clickhouse; + const { + parseFilters, + getDateFormat, + rawQuery, + getDateStringQuery, + getDateQuery, + getBetweenDates, + } = clickhouse; const website = await cache.fetchWebsite(websiteId); - const params = { websiteId, revId: website?.revId || 0 }; + const resetDate = website?.resetAt || website?.createdAt; + const params = { websiteId }; const { filterQuery } = parseFilters(filters, params); return rawQuery( @@ -91,8 +102,8 @@ async function clickhouseQuery( count(${count !== '*' ? 'distinct session_id' : count}) y from event where website_id = {websiteId:UUID} - and rev_id = {revId:UInt32} and event_type = ${EVENT_TYPE.pageView} + and created_at >= ${getDateFormat(resetDate)} and ${getBetweenDates('created_at', startDate, endDate)} ${filterQuery} group by t) g diff --git a/queries/analytics/pageview/savePageView.ts b/queries/analytics/pageview/savePageView.ts index 1b0239ca..41742774 100644 --- a/queries/analytics/pageview/savePageView.ts +++ b/queries/analytics/pageview/savePageView.ts @@ -2,7 +2,6 @@ import { URL_LENGTH, EVENT_TYPE } from 'lib/constants'; import { CLICKHOUSE, PRISMA, runQuery } from 'lib/db'; import kafka from 'lib/kafka'; import prisma from 'lib/prisma'; -import cache from 'lib/cache'; import { uuid } from 'lib/crypto'; export async function savePageView(args: { @@ -104,13 +103,11 @@ async function clickhouseQuery(data: { ...args } = data; const { getDateFormat, sendMessage } = kafka; - const website = await cache.fetchWebsite(websiteId); const message = { website_id: websiteId, session_id: sessionId, event_id: uuid(), - rev_id: website?.revId || 0, country: country ? country : null, subdivision1: subdivision1 ? subdivision1 : null, subdivision2: subdivision2 ? subdivision2 : null, diff --git a/queries/analytics/session/createSession.ts b/queries/analytics/session/createSession.ts index 3afa9c9a..d2657d60 100644 --- a/queries/analytics/session/createSession.ts +++ b/queries/analytics/session/createSession.ts @@ -50,7 +50,6 @@ async function clickhouseQuery(data: { city, } = data; const { getDateFormat, sendMessage } = kafka; - const website = await cache.fetchWebsite(websiteId); const msg = { session_id: id, @@ -65,7 +64,6 @@ async function clickhouseQuery(data: { subdivision1, subdivision2, city, - rev_id: website?.revId || 0, created_at: getDateFormat(new Date()), }; diff --git a/queries/analytics/session/getSessionMetrics.ts b/queries/analytics/session/getSessionMetrics.ts index 9f427e53..073f93f6 100644 --- a/queries/analytics/session/getSessionMetrics.ts +++ b/queries/analytics/session/getSessionMetrics.ts @@ -20,9 +20,11 @@ async function relationalQuery( websiteId: string, data: { startDate: Date; endDate: Date; field: string; filters: object }, ) { + const website = await cache.fetchWebsite(websiteId); + const resetDate = website?.resetAt || website?.createdAt; const { startDate, endDate, field, filters = {} } = data; const { toUuid, parseFilters, rawQuery } = prisma; - const params: any = [websiteId, startDate, endDate]; + const params: any = [websiteId, resetDate, startDate, endDate]; const { filterQuery, joinSession } = parseFilters(filters, params); return rawQuery( @@ -35,7 +37,8 @@ async function relationalQuery( on website_event.website_id = website.website_id ${joinSession} where website.website_id = $1${toUuid()} - and website_event.created_at between $2 and $3 + and website_event.created_at >= $2 + and website_event.created_at between $3 and $4 ${filterQuery} ) group by 1 @@ -50,17 +53,18 @@ async function clickhouseQuery( data: { startDate: Date; endDate: Date; field: string; filters: object }, ) { const { startDate, endDate, field, filters = {} } = data; - const { parseFilters, getBetweenDates, rawQuery } = clickhouse; + const { getDateFormat, parseFilters, getBetweenDates, rawQuery } = clickhouse; const website = await cache.fetchWebsite(websiteId); - const params = { websiteId, revId: website?.revId || 0 }; + const resetDate = website?.resetAt || website?.createdAt; + const params = { websiteId }; const { filterQuery } = parseFilters(filters, params); return rawQuery( `select ${field} x, count(distinct session_id) y from event as x where website_id = {websiteId:UUID} - and rev_id = {revId:UInt32} and event_type = ${EVENT_TYPE.pageView} + and created_at >= ${getDateFormat(resetDate)} and ${getBetweenDates('created_at', startDate, endDate)} ${filterQuery} group by x diff --git a/queries/analytics/stats/getWebsiteStats.ts b/queries/analytics/stats/getWebsiteStats.ts index 73d28fb6..d11de565 100644 --- a/queries/analytics/stats/getWebsiteStats.ts +++ b/queries/analytics/stats/getWebsiteStats.ts @@ -19,7 +19,9 @@ async function relationalQuery( ) { const { startDate, endDate, filters = {} } = data; const { toUuid, getDateQuery, getTimestampInterval, parseFilters, rawQuery } = prisma; - const params: any = [websiteId, startDate, endDate]; + const website = await cache.fetchWebsite(websiteId); + const resetDate = website?.resetAt || website?.createdAt; + const params: any = [websiteId, resetDate, startDate, endDate]; const { filterQuery, joinSession } = parseFilters(filters, params); return rawQuery( @@ -37,7 +39,8 @@ async function relationalQuery( on website_event.website_id = website.website_id ${joinSession} where website.website_id = $1${toUuid()} - and website_event.created_at between $2 and $3 + and website_event.created_at >= $2 + and website_event.created_at between $3 and $4 ${filterQuery} group by 1, 2 ) t`, @@ -50,9 +53,10 @@ async function clickhouseQuery( data: { startDate: Date; endDate: Date; filters: object }, ) { const { startDate, endDate, filters = {} } = data; - const { rawQuery, getDateQuery, getBetweenDates, parseFilters } = clickhouse; + const { rawQuery, getDateFormat, getDateQuery, getBetweenDates, parseFilters } = clickhouse; const website = await cache.fetchWebsite(websiteId); - const params = { websiteId, revId: website?.revId || 0 }; + const resetDate = website?.resetAt || website?.createdAt; + const params = { websiteId }; const { filterQuery } = parseFilters(filters, params); return rawQuery( @@ -70,8 +74,8 @@ async function clickhouseQuery( from event where event_type = ${EVENT_TYPE.pageView} and website_id = {websiteId:UUID} - and rev_id = {revId:UInt32} - and ${getBetweenDates('created_at', startDate, endDate)} + and created_at >= ${getDateFormat(resetDate)} + and ${getBetweenDates('created_at', startDate, endDate)} ${filterQuery} group by session_id, time_series ) t;`,