From cbeefe733f92fcc416c5d4f38cce66851888d000 Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Thu, 21 Mar 2024 09:30:42 -0700 Subject: [PATCH 01/11] add psql migration --- db/clickhouse/schema.sql | 1 + .../migrations/05_add_visit_id/migration.sql | 14 ++++++++++++++ db/postgresql/schema.prisma | 3 +++ 3 files changed, 18 insertions(+) create mode 100644 db/postgresql/migrations/05_add_visit_id/migration.sql diff --git a/db/clickhouse/schema.sql b/db/clickhouse/schema.sql index 741f06ad..dad4f4af 100644 --- a/db/clickhouse/schema.sql +++ b/db/clickhouse/schema.sql @@ -3,6 +3,7 @@ CREATE TABLE umami.website_event ( website_id UUID, session_id UUID, + visit_id UUID, event_id UUID, --sessions hostname LowCardinality(String), diff --git a/db/postgresql/migrations/05_add_visit_id/migration.sql b/db/postgresql/migrations/05_add_visit_id/migration.sql new file mode 100644 index 00000000..b70b6a04 --- /dev/null +++ b/db/postgresql/migrations/05_add_visit_id/migration.sql @@ -0,0 +1,14 @@ +-- AlterTable +ALTER TABLE "website_event" ADD COLUMN "session_id" UUID NULL; + +UPDATE "website_event" +SET session_id = uuid_in(overlay(overlay(md5(CONCAT(session_id::text, to_char(date_trunc('hour', created_at), 'YYYY-MM-DD HH24:00:00'))) placing '4' from 13) placing '8' from 17)::cstring) +WHERE session_id IS NULL; + +ALTER TABLE "website_event" ALTER COLUMN "session_id" SET NOT NULL; + +-- CreateIndex +CREATE INDEX "website_event_visit_id_idx" ON "website_event"("visit_id"); + +-- CreateIndex +CREATE INDEX "website_event_website_id_visit_id_created_at_idx" ON "website_event"("website_id", "visit_id", "created_at"); diff --git a/db/postgresql/schema.prisma b/db/postgresql/schema.prisma index 31cc7616..0cb8ae8a 100644 --- a/db/postgresql/schema.prisma +++ b/db/postgresql/schema.prisma @@ -92,6 +92,7 @@ model WebsiteEvent { id String @id() @map("event_id") @db.Uuid websiteId String @map("website_id") @db.Uuid sessionId String @map("session_id") @db.Uuid + visitId String @map("visit_id") @db.Uuid createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) urlPath String @map("url_path") @db.VarChar(500) urlQuery String? @map("url_query") @db.VarChar(500) @@ -107,6 +108,7 @@ model WebsiteEvent { @@index([createdAt]) @@index([sessionId]) + @@index([visitId]) @@index([websiteId]) @@index([websiteId, createdAt]) @@index([websiteId, createdAt, urlPath]) @@ -115,6 +117,7 @@ model WebsiteEvent { @@index([websiteId, createdAt, pageTitle]) @@index([websiteId, createdAt, eventName]) @@index([websiteId, sessionId, createdAt]) + @@index([websiteId, visitId, createdAt]) @@map("website_event") } From b36d61609d2df7be2218832aac73365503291e9c Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Thu, 21 Mar 2024 09:36:27 -0700 Subject: [PATCH 02/11] fix migration bug --- db/postgresql/migrations/05_add_visit_id/migration.sql | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/db/postgresql/migrations/05_add_visit_id/migration.sql b/db/postgresql/migrations/05_add_visit_id/migration.sql index b70b6a04..8274d1fb 100644 --- a/db/postgresql/migrations/05_add_visit_id/migration.sql +++ b/db/postgresql/migrations/05_add_visit_id/migration.sql @@ -1,14 +1,14 @@ -- AlterTable -ALTER TABLE "website_event" ADD COLUMN "session_id" UUID NULL; +ALTER TABLE "website_event" ADD COLUMN "visit_id" UUID NULL; UPDATE "website_event" -SET session_id = uuid_in(overlay(overlay(md5(CONCAT(session_id::text, to_char(date_trunc('hour', created_at), 'YYYY-MM-DD HH24:00:00'))) placing '4' from 13) placing '8' from 17)::cstring) -WHERE session_id IS NULL; +SET visit_id = uuid_in(overlay(overlay(md5(CONCAT(session_id::text, to_char(date_trunc('hour', created_at), 'YYYY-MM-DD HH24:00:00'))) placing '4' from 13) placing '8' from 17)::cstring) +WHERE visit_id IS NULL; -ALTER TABLE "website_event" ALTER COLUMN "session_id" SET NOT NULL; +ALTER TABLE "website_event" ALTER COLUMN "visit_id" SET NOT NULL; -- CreateIndex CREATE INDEX "website_event_visit_id_idx" ON "website_event"("visit_id"); -- CreateIndex -CREATE INDEX "website_event_website_id_visit_id_created_at_idx" ON "website_event"("website_id", "visit_id", "created_at"); +CREATE INDEX "website_event_website_id_visit_id_created_at_idx" ON "website_event"("website_id", "visit_id", "created_at"); \ No newline at end of file From af1a118374edd3c0502230c56ae9f77e4288643a Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Thu, 21 Mar 2024 11:10:13 -0700 Subject: [PATCH 03/11] update mysql migrations --- .../migrations/05_add_visit_id/migration.sql | 21 +++++++++++++++++++ db/mysql/schema.prisma | 3 +++ 2 files changed, 24 insertions(+) create mode 100644 db/mysql/migrations/05_add_visit_id/migration.sql diff --git a/db/mysql/migrations/05_add_visit_id/migration.sql b/db/mysql/migrations/05_add_visit_id/migration.sql new file mode 100644 index 00000000..f4034006 --- /dev/null +++ b/db/mysql/migrations/05_add_visit_id/migration.sql @@ -0,0 +1,21 @@ +-- AlterTable +ALTER TABLE "website_event" ADD COLUMN "visit_id" VARCHAR(36) NULL; + +UPDATE "website_event" we +JOIN (SELECT s.session_id, + s.visit_time, + BIN_TO_UUID(RANDOM_BYTES(16) & 0xffffffffffff0fff3fffffffffffffff | 0x00000000000040008000000000000000) uuid + FROM (SELECT DISTINCT session_id, + DATE_FORMAT(created_at, '%Y-%m-%d %H:00:00') visit_time + FROM umami.website_event) s) a + ON we.session_id = a.session_id and DATE_FORMAT(we.created_at, '%Y-%m-%d %H:00:00') = a.visit_time +SET we.visit_id = a.uuid +WHERE we.visit_id IS NULL; + +ALTER TABLE "website_event" MODIFY "visit_id" VARCHAR(36) NOT NULL; + +-- CreateIndex +CREATE INDEX `website_event_visit_id_idx` ON `website_event`(`visit_id`); + +-- CreateIndex +CREATE INDEX `website_event_website_id_visit_id_created_at_idx` ON `website_event`(`website_id`, `visit_id`, `created_at`); diff --git a/db/mysql/schema.prisma b/db/mysql/schema.prisma index 8e5cbbc3..152ca265 100644 --- a/db/mysql/schema.prisma +++ b/db/mysql/schema.prisma @@ -92,6 +92,7 @@ model WebsiteEvent { id String @id() @map("event_id") @db.VarChar(36) websiteId String @map("website_id") @db.VarChar(36) sessionId String @map("session_id") @db.VarChar(36) + visitId String @map("visit_id") @db.VarChar(36) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) urlPath String @map("url_path") @db.VarChar(500) urlQuery String? @map("url_query") @db.VarChar(500) @@ -107,6 +108,7 @@ model WebsiteEvent { @@index([createdAt]) @@index([sessionId]) + @@index([visitId]) @@index([websiteId]) @@index([websiteId, createdAt]) @@index([websiteId, createdAt, urlPath]) @@ -115,6 +117,7 @@ model WebsiteEvent { @@index([websiteId, createdAt, pageTitle]) @@index([websiteId, createdAt, eventName]) @@index([websiteId, sessionId, createdAt]) + @@index([websiteId, visitId, createdAt]) @@map("website_event") } From 91a4cb4487660466250b9987919a4d12f0443664 Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Thu, 21 Mar 2024 11:33:35 -0700 Subject: [PATCH 04/11] add mysql column population --- db/mysql/migrations/05_add_visit_id/migration.sql | 11 ++++++----- 1 file changed, 6 insertions(+), 5 deletions(-) diff --git a/db/mysql/migrations/05_add_visit_id/migration.sql b/db/mysql/migrations/05_add_visit_id/migration.sql index f4034006..7a833a88 100644 --- a/db/mysql/migrations/05_add_visit_id/migration.sql +++ b/db/mysql/migrations/05_add_visit_id/migration.sql @@ -1,18 +1,19 @@ -- AlterTable -ALTER TABLE "website_event" ADD COLUMN "visit_id" VARCHAR(36) NULL; +ALTER TABLE `website_event` ADD COLUMN `visit_id` VARCHAR(36) NULL; -UPDATE "website_event" we -JOIN (SELECT s.session_id, +UPDATE `website_event` we +JOIN (SELECT DISTINCT + s.session_id, s.visit_time, BIN_TO_UUID(RANDOM_BYTES(16) & 0xffffffffffff0fff3fffffffffffffff | 0x00000000000040008000000000000000) uuid FROM (SELECT DISTINCT session_id, DATE_FORMAT(created_at, '%Y-%m-%d %H:00:00') visit_time - FROM umami.website_event) s) a + FROM `website_event`) s) a ON we.session_id = a.session_id and DATE_FORMAT(we.created_at, '%Y-%m-%d %H:00:00') = a.visit_time SET we.visit_id = a.uuid WHERE we.visit_id IS NULL; -ALTER TABLE "website_event" MODIFY "visit_id" VARCHAR(36) NOT NULL; +ALTER TABLE `website_event` MODIFY `visit_id` VARCHAR(36) NOT NULL; -- CreateIndex CREATE INDEX `website_event_visit_id_idx` ON `website_event`(`visit_id`); From d3ca8565214ecdced818d7118908ff49cc4956d1 Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Mon, 25 Mar 2024 16:29:29 -0700 Subject: [PATCH 05/11] check in clickhouse migration script --- db/clickhouse/migrations/02_add_visit_id.sql | 71 ++++++++++++++++++++ 1 file changed, 71 insertions(+) create mode 100644 db/clickhouse/migrations/02_add_visit_id.sql diff --git a/db/clickhouse/migrations/02_add_visit_id.sql b/db/clickhouse/migrations/02_add_visit_id.sql new file mode 100644 index 00000000..f0379330 --- /dev/null +++ b/db/clickhouse/migrations/02_add_visit_id.sql @@ -0,0 +1,71 @@ +-- create new table +CREATE TABLE test.website_event_new +( + website_id UUID, + session_id UUID, + visit_id UUID, + event_id UUID, + hostname LowCardinality(String), + browser LowCardinality(String), + os LowCardinality(String), + device LowCardinality(String), + screen LowCardinality(String), + language LowCardinality(String), + country LowCardinality(String), + subdivision1 LowCardinality(String), + subdivision2 LowCardinality(String), + city String, + url_path String, + url_query String, + referrer_path String, + referrer_query String, + referrer_domain String, + page_title String, + event_type UInt32, + event_name String, + created_at DateTime('UTC'), + job_id UUID +) + engine = MergeTree + ORDER BY (website_id, session_id, created_at) + SETTINGS index_granularity = 8192; + +INSERT INTO test.website_event_new +SELECT we.website_id, + we.session_id, + we2.visit_id, + we.event_id, + we.hostname, + we.browser, + we.os, + we.device, + we.screen, + we.language, + we.country, + we.subdivision1, + we.subdivision2, + we.city, + we.url_path, + we.url_query, + we.referrer_path, + we.referrer_query, + we.referrer_domain, + we.page_title, + we.event_type, + we.event_name, + we.created_at, + we.job_id +FROM test.website_event we +JOIN (SELECT DISTINCT + s.session_id, + generateUUIDv4() visit_id, + s.created_at +FROM (SELECT DISTINCT session_id, + date_trunc('hour', created_at) created_at + FROM test.website_event) s) we2 + ON we.session_id = we2.session_id + and date_trunc('hour', we.created_at) = we2.created_at +ORDER BY we.session_id, we.created_at + +RENAME TABLE test.website_event TO test.website_event_old; +RENAME TABLE test.website_event_new TO test.website_event; \ No newline at end of file From 0aaf2c0b3bb508a739e9bc91fa99da9345269bec Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Mon, 25 Mar 2024 17:47:53 -0700 Subject: [PATCH 06/11] update visitId hash and expiration logic --- .../migrations/05_add_visit_id/migration.sql | 14 +++++++++++--- src/lib/crypto.ts | 8 +++++++- src/lib/session.ts | 7 +++++-- src/pages/api/send.ts | 12 +++++++++++- src/queries/analytics/events/saveEvent.ts | 13 ++++++++++--- 5 files changed, 44 insertions(+), 10 deletions(-) diff --git a/db/postgresql/migrations/05_add_visit_id/migration.sql b/db/postgresql/migrations/05_add_visit_id/migration.sql index 8274d1fb..fd2f1b90 100644 --- a/db/postgresql/migrations/05_add_visit_id/migration.sql +++ b/db/postgresql/migrations/05_add_visit_id/migration.sql @@ -1,9 +1,17 @@ -- AlterTable ALTER TABLE "website_event" ADD COLUMN "visit_id" UUID NULL; -UPDATE "website_event" -SET visit_id = uuid_in(overlay(overlay(md5(CONCAT(session_id::text, to_char(date_trunc('hour', created_at), 'YYYY-MM-DD HH24:00:00'))) placing '4' from 13) placing '8' from 17)::cstring) -WHERE visit_id IS NULL; +UPDATE "website_event" we +SET visit_id = a.uuid +FROM (SELECT DISTINCT + s.session_id, + s.visit_time, + gen_random_uuid() uuid + FROM (SELECT DISTINCT session_id, + date_trunc('hour', created_at) visit_time + FROM "website_event") s) a +WHERE we.session_id = a.session_id + and date_trunc('hour', we.created_at) = a.visit_time; ALTER TABLE "website_event" ALTER COLUMN "visit_id" SET NOT NULL; diff --git a/src/lib/crypto.ts b/src/lib/crypto.ts index a2763352..d47c9fd8 100644 --- a/src/lib/crypto.ts +++ b/src/lib/crypto.ts @@ -1,4 +1,4 @@ -import { startOfMonth } from 'date-fns'; +import { startOfHour, startOfMonth } from 'date-fns'; import { hash } from 'next-basics'; import { v4, v5, validate } from 'uuid'; @@ -12,6 +12,12 @@ export function salt() { return hash(secret(), ROTATING_SALT); } +export function sessionSalt() { + const ROTATING_SALT = hash(startOfHour(new Date()).toUTCString()); + + return hash(secret(), ROTATING_SALT); +} + export function uuid(...args: any) { if (!args.length) return v4(); diff --git a/src/lib/session.ts b/src/lib/session.ts index 0f388db9..6e2cbcc3 100644 --- a/src/lib/session.ts +++ b/src/lib/session.ts @@ -1,4 +1,4 @@ -import { isUuid, secret, uuid } from 'lib/crypto'; +import { isUuid, secret, sessionSalt, uuid } from 'lib/crypto'; import { getClientInfo } from 'lib/detect'; import { parseToken } from 'next-basics'; import { NextApiRequestCollect } from 'pages/api/send'; @@ -10,6 +10,7 @@ import { loadSession, loadWebsite } from './load'; export async function findSession(req: NextApiRequestCollect): Promise<{ id: any; websiteId: string; + visitId: string; hostname: string; browser: string; os: any; @@ -67,12 +68,14 @@ export async function findSession(req: NextApiRequestCollect): Promise<{ await getClientInfo(req, payload); const sessionId = uuid(websiteId, hostname, ip, userAgent); + const visitId = uuid(sessionId, sessionSalt()); // Clickhouse does not require session lookup if (clickhouse.enabled) { return { id: sessionId, websiteId, + visitId, hostname, browser, os: os as any, @@ -114,7 +117,7 @@ export async function findSession(req: NextApiRequestCollect): Promise<{ } } - return { ...session, ownerId: website.userId }; + return { ...session, ownerId: website.userId, visitId: visitId }; } async function checkUserBlock(userId: string) { diff --git a/src/pages/api/send.ts b/src/pages/api/send.ts index 5aa367f0..726a6fcc 100644 --- a/src/pages/api/send.ts +++ b/src/pages/api/send.ts @@ -1,7 +1,7 @@ import ipaddr from 'ipaddr.js'; import { isbot } from 'isbot'; import { COLLECTION_TYPE, HOSTNAME_REGEX, IP_REGEX } from 'lib/constants'; -import { secret } from 'lib/crypto'; +import { secret, sessionSalt, uuid } from 'lib/crypto'; import { getIpAddress } from 'lib/detect'; import { useCors, useSession, useValidate } from 'lib/middleware'; import { CollectionType, YupRequest } from 'lib/types'; @@ -31,6 +31,7 @@ export interface NextApiRequestCollect extends NextApiRequest { session: { id: string; websiteId: string; + visitId: string; ownerId: string; hostname: string; browser: string; @@ -93,6 +94,14 @@ export default async (req: NextApiRequestCollect, res: NextApiResponse) => { const session = req.session; + // expire visitId after 30 minutes + session.visitId = + !!session.iat && Math.floor(new Date().getTime() / 1000) - session.iat > 1800 + ? uuid(session.id, sessionSalt()) + : session.visitId; + + session.iat = Math.floor(new Date().getTime() / 1000); + if (type === COLLECTION_TYPE.event) { // eslint-disable-next-line prefer-const let [urlPath, urlQuery] = url?.split('?') || []; @@ -125,6 +134,7 @@ export default async (req: NextApiRequestCollect, res: NextApiResponse) => { eventData, ...session, sessionId: session.id, + visitId: session.visitId, }); } diff --git a/src/queries/analytics/events/saveEvent.ts b/src/queries/analytics/events/saveEvent.ts index 0596023b..25bcf9e7 100644 --- a/src/queries/analytics/events/saveEvent.ts +++ b/src/queries/analytics/events/saveEvent.ts @@ -6,8 +6,9 @@ import { uuid } from 'lib/crypto'; import { saveEventData } from 'queries/analytics/eventData/saveEventData'; export async function saveEvent(args: { - sessionId: string; websiteId: string; + sessionId: string; + visitId: string; urlPath: string; urlQuery?: string; referrerPath?: string; @@ -34,8 +35,9 @@ export async function saveEvent(args: { } async function relationalQuery(data: { - sessionId: string; websiteId: string; + sessionId: string; + visitId: string; urlPath: string; urlQuery?: string; referrerPath?: string; @@ -48,6 +50,7 @@ async function relationalQuery(data: { const { websiteId, sessionId, + visitId, urlPath, urlQuery, referrerPath, @@ -64,6 +67,7 @@ async function relationalQuery(data: { id: websiteEventId, websiteId, sessionId, + visitId, urlPath: urlPath?.substring(0, URL_LENGTH), urlQuery: urlQuery?.substring(0, URL_LENGTH), referrerPath: referrerPath?.substring(0, URL_LENGTH), @@ -90,8 +94,9 @@ async function relationalQuery(data: { } async function clickhouseQuery(data: { - sessionId: string; websiteId: string; + sessionId: string; + visitId: string; urlPath: string; urlQuery?: string; referrerPath?: string; @@ -114,6 +119,7 @@ async function clickhouseQuery(data: { const { websiteId, sessionId, + visitId, urlPath, urlQuery, referrerPath, @@ -136,6 +142,7 @@ async function clickhouseQuery(data: { ...args, website_id: websiteId, session_id: sessionId, + visit_id: visitId, event_id: uuid(), country: country, subdivision1: From db75e1e5d20d2b87c91925433ffb7fe8474279fd Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Mon, 25 Mar 2024 17:49:13 -0700 Subject: [PATCH 07/11] Add iat to session object --- src/pages/api/send.ts | 1 + 1 file changed, 1 insertion(+) diff --git a/src/pages/api/send.ts b/src/pages/api/send.ts index 726a6fcc..df6115aa 100644 --- a/src/pages/api/send.ts +++ b/src/pages/api/send.ts @@ -43,6 +43,7 @@ export interface NextApiRequestCollect extends NextApiRequest { subdivision1: string; subdivision2: string; city: string; + iat: number; }; headers: { [key: string]: any }; yup: YupRequest; From 7c7fd577c3c24a6e77e842bccc593eaebcff1dad Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Mon, 25 Mar 2024 18:33:30 -0700 Subject: [PATCH 08/11] remove test schema from CH migration script --- db/clickhouse/migrations/02_add_visit_id.sql | 12 ++++++------ 1 file changed, 6 insertions(+), 6 deletions(-) diff --git a/db/clickhouse/migrations/02_add_visit_id.sql b/db/clickhouse/migrations/02_add_visit_id.sql index f0379330..8660e664 100644 --- a/db/clickhouse/migrations/02_add_visit_id.sql +++ b/db/clickhouse/migrations/02_add_visit_id.sql @@ -1,5 +1,5 @@ -- create new table -CREATE TABLE test.website_event_new +CREATE TABLE umami.website_event_new ( website_id UUID, session_id UUID, @@ -30,7 +30,7 @@ CREATE TABLE test.website_event_new ORDER BY (website_id, session_id, created_at) SETTINGS index_granularity = 8192; -INSERT INTO test.website_event_new +INSERT INTO umami.website_event_new SELECT we.website_id, we.session_id, we2.visit_id, @@ -55,17 +55,17 @@ SELECT we.website_id, we.event_name, we.created_at, we.job_id -FROM test.website_event we +FROM umami.website_event we JOIN (SELECT DISTINCT s.session_id, generateUUIDv4() visit_id, s.created_at FROM (SELECT DISTINCT session_id, date_trunc('hour', created_at) created_at - FROM test.website_event) s) we2 + FROM umami.website_event) s) we2 ON we.session_id = we2.session_id and date_trunc('hour', we.created_at) = we2.created_at ORDER BY we.session_id, we.created_at -RENAME TABLE test.website_event TO test.website_event_old; -RENAME TABLE test.website_event_new TO test.website_event; \ No newline at end of file +RENAME TABLE umami.website_event TO umami.website_event_old; +RENAME TABLE umami.website_event_new TO umami.website_event; \ No newline at end of file From d36bf4396add3f3424ccc76695a2a36802765e5c Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Mon, 25 Mar 2024 18:47:02 -0700 Subject: [PATCH 09/11] remove order by in insert select --- db/clickhouse/migrations/02_add_visit_id.sql | 3 +-- 1 file changed, 1 insertion(+), 2 deletions(-) diff --git a/db/clickhouse/migrations/02_add_visit_id.sql b/db/clickhouse/migrations/02_add_visit_id.sql index 8660e664..8aa5e6a1 100644 --- a/db/clickhouse/migrations/02_add_visit_id.sql +++ b/db/clickhouse/migrations/02_add_visit_id.sql @@ -64,8 +64,7 @@ FROM (SELECT DISTINCT session_id, date_trunc('hour', created_at) created_at FROM umami.website_event) s) we2 ON we.session_id = we2.session_id - and date_trunc('hour', we.created_at) = we2.created_at -ORDER BY we.session_id, we.created_at + and date_trunc('hour', we.created_at) = we2.created_at; RENAME TABLE umami.website_event TO umami.website_event_old; RENAME TABLE umami.website_event_new TO umami.website_event; \ No newline at end of file From c033b0582df5282545c77d76a37f754b670011cb Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Mon, 25 Mar 2024 19:13:54 -0700 Subject: [PATCH 10/11] create join table and remove subquery from insert --- db/clickhouse/migrations/02_add_visit_id.sql | 43 +++++++++++++++----- 1 file changed, 32 insertions(+), 11 deletions(-) diff --git a/db/clickhouse/migrations/02_add_visit_id.sql b/db/clickhouse/migrations/02_add_visit_id.sql index 8aa5e6a1..5dd7bcd1 100644 --- a/db/clickhouse/migrations/02_add_visit_id.sql +++ b/db/clickhouse/migrations/02_add_visit_id.sql @@ -1,3 +1,22 @@ +CREATE TABLE umami.website_event_join +( + session_id UUID, + visit_id UUID, + created_at DateTime('UTC') +) + engine = MergeTree + ORDER BY (session_id, created_at) + SETTINGS index_granularity = 8192; + +INSERT INTO umami.website_event_join +SELECT DISTINCT + s.session_id, + generateUUIDv4() visit_id, + s.created_at +FROM (SELECT DISTINCT session_id, + date_trunc('hour', created_at) created_at + FROM website_event) s; + -- create new table CREATE TABLE umami.website_event_new ( @@ -33,7 +52,7 @@ CREATE TABLE umami.website_event_new INSERT INTO umami.website_event_new SELECT we.website_id, we.session_id, - we2.visit_id, + j.visit_id, we.event_id, we.hostname, we.browser, @@ -56,15 +75,17 @@ SELECT we.website_id, we.created_at, we.job_id FROM umami.website_event we -JOIN (SELECT DISTINCT - s.session_id, - generateUUIDv4() visit_id, - s.created_at -FROM (SELECT DISTINCT session_id, - date_trunc('hour', created_at) created_at - FROM umami.website_event) s) we2 - ON we.session_id = we2.session_id - and date_trunc('hour', we.created_at) = we2.created_at; +JOIN umami.website_event_join j + ON we.session_id = j.session_id + and date_trunc('hour', we.created_at) = j.created_at +WHERE we.created_at > '2023-03-31'; RENAME TABLE umami.website_event TO umami.website_event_old; -RENAME TABLE umami.website_event_new TO umami.website_event; \ No newline at end of file +RENAME TABLE umami.website_event_new TO umami.website_event; + +/* + + DROP TABLE umami.website_event_old + DROP TABLE umami.website_event_join + + */ \ No newline at end of file From 7a6a598a19f617b4324d5424a220d86d90fbbae0 Mon Sep 17 00:00:00 2001 From: Brian Cao Date: Mon, 25 Mar 2024 21:41:31 -0700 Subject: [PATCH 11/11] Fix css date picker. --- src/components/metrics/DatePickerForm.module.css | 4 ---- 1 file changed, 4 deletions(-) diff --git a/src/components/metrics/DatePickerForm.module.css b/src/components/metrics/DatePickerForm.module.css index 92a41572..7168fa0d 100644 --- a/src/components/metrics/DatePickerForm.module.css +++ b/src/components/metrics/DatePickerForm.module.css @@ -9,10 +9,6 @@ justify-content: center; } -.calendars > div { - width: 380px; -} - .calendars > div + div { margin-inline-start: 20px; padding-inline-start: 20px;