From ea39f5b43120ae9701ac6039cd07e780a3a9a299 Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Wed, 22 Mar 2023 23:02:37 -0700 Subject: [PATCH 1/2] add new event data schema --- db/clickhouse/schema.sql | 68 +++++++++++++++++-- db/mysql/migrations/01_init/migration.sql | 28 +++++++- db/mysql/schema.prisma | 37 +++++++++- .../09_add_new_event_data/migration.sql | 38 +++++++++++ db/postgresql/schema.prisma | 39 ++++++++++- 5 files changed, 198 insertions(+), 12 deletions(-) create mode 100644 db/postgresql/migrations/09_add_new_event_data/migration.sql diff --git a/db/clickhouse/schema.sql b/db/clickhouse/schema.sql index c0a2f62d..acae2ac9 100644 --- a/db/clickhouse/schema.sql +++ b/db/clickhouse/schema.sql @@ -1,11 +1,11 @@ SET allow_experimental_object_type = 1; -- Create Event -CREATE TABLE event +CREATE TABLE umami.event ( website_id UUID, session_id UUID, - event_id Nullable(UUID), + event_id UUID, rev_id UInt32, --session hostname LowCardinality(String), @@ -34,10 +34,10 @@ CREATE TABLE event ORDER BY (website_id, session_id, created_at) SETTINGS index_granularity = 8192; -CREATE TABLE event_queue ( +CREATE TABLE umami.event_queue ( website_id UUID, session_id UUID, - event_id Nullable(UUID), + event_id UUID, rev_id UInt32, --session hostname LowCardinality(String), @@ -70,7 +70,7 @@ SETTINGS kafka_broker_list = 'domain:9092,domain:9093,domain:9094', -- input bro kafka_max_block_size = 1048576, kafka_skip_broken_messages = 1; -CREATE MATERIALIZED VIEW event_queue_mv TO event AS +CREATE MATERIALIZED VIEW umami.event_queue_mv TO umami.event AS SELECT website_id, session_id, event_id, @@ -94,4 +94,60 @@ SELECT website_id, event_type, event_name, created_at -FROM event_queue; \ No newline at end of file +FROM umami.event_queue; + +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, + event_string_value Nullable(String), + event_numeric_value Nullable(Decimal64(4)), + event_date_value Nullable(DateTime('UTC')), + event_data_type UInt32, + created_at DateTime('UTC') +) + engine = MergeTree + ORDER BY (website_id, session_id, event_id, event_key, created_at) + SETTINGS index_granularity = 8192; + +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, + event_string_value Nullable(String), + event_numeric_value Nullable(Decimal64(4)), + event_date_value Nullable(DateTime('UTC')), + event_data_type UInt32, + created_at DateTime('UTC') +) +ENGINE = Kafka +SETTINGS kafka_broker_list = 'domain:9092,domain:9093,domain:9094', -- input broker list + kafka_topic_list = 'event_data', + kafka_group_name = 'event_data_consumer_group', + kafka_format = 'JSONEachRow', + kafka_max_block_size = 1048576, + kafka_skip_broken_messages = 1; + +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, + event_string_value, + event_numeric_value, + event_date_value, + event_data_type, + created_at +FROM umami.event_data_queue; \ No newline at end of file diff --git a/db/mysql/migrations/01_init/migration.sql b/db/mysql/migrations/01_init/migration.sql index eacbc38d..84dfea01 100644 --- a/db/mysql/migrations/01_init/migration.sql +++ b/db/mysql/migrations/01_init/migration.sql @@ -78,6 +78,31 @@ CREATE TABLE `website_event` ( PRIMARY KEY (`event_id`) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; +-- CreateTable +CREATE TABLE `event_data` ( + `event_id` VARCHAR(36) NOT NULL, + `website_event_id` VARCHAR(36) NOT NULL, + `website_id` VARCHAR(36) NOT NULL, + `session_id` VARCHAR(36) NOT NULL, + `url_path` VARCHAR(500) NOT NULL, + `event_name` VARCHAR(500) NOT NULL, + `event_key` VARCHAR(500) NOT NULL, + `event_string_value` VARCHAR(500) NOT NULL, + `event_numeric_value` DECIMAL(19, 4) NOT NULL, + `event_date_value` TIMESTAMP(0) NULL, + `event_data_type` INTEGER UNSIGNED NOT NULL, + `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), + + INDEX `event_data_created_at_idx`(`created_at`), + INDEX `event_data_session_id_idx`(`session_id`), + INDEX `event_data_website_id_idx`(`website_id`), + INDEX `event_data_website_event_id_idx`(`website_event_id`), + INDEX `event_data_website_id_website_event_id_created_at_idx`(`website_id`, `website_event_id`, `created_at`), + INDEX `event_data_website_id_session_id_created_at_idx`(`website_id`, `session_id`, `created_at`), + INDEX `event_data_website_id_session_id_website_event_id_created_at_idx`(`website_id`, `session_id`, `website_event_id`, `created_at`), + PRIMARY KEY (`event_id`) +) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; + -- CreateTable CREATE TABLE `team` ( `team_id` VARCHAR(36) NOT NULL, @@ -119,6 +144,3 @@ CREATE TABLE `team_website` ( INDEX `team_website_website_id_idx`(`website_id`), PRIMARY KEY (`team_website_id`) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; - --- AddSystemUser -INSERT INTO "user" (user_id, username, role, password) VALUES ('41e2b680-648e-4b09-bcd7-3e2b10c06264' , 'admin', 'admin', '$2b$10$BUli0c.muyCW1ErNJc3jL.vFRFtFJWrT8/GcR4A.sUdCznaXiqFXa'); \ No newline at end of file diff --git a/db/mysql/schema.prisma b/db/mysql/schema.prisma index 1f182716..7a7a1b15 100644 --- a/db/mysql/schema.prisma +++ b/db/mysql/schema.prisma @@ -17,8 +17,8 @@ model User { updatedAt DateTime? @map("updated_at") @db.Timestamp(0) deletedAt DateTime? @map("deleted_at") @db.Timestamp(0) + website Website[] teamUser TeamUser[] - Website Website[] @@map("user") } @@ -38,6 +38,9 @@ model Session { city String? @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) + websiteEvent WebsiteEvent[] + eventData EventData[] + @@index([createdAt]) @@index([websiteId]) @@map("session") @@ -56,6 +59,7 @@ model Website { user User? @relation(fields: [userId], references: [id]) teamWebsite TeamWebsite[] + eventData EventData[] @@index([userId]) @@index([createdAt]) @@ -77,6 +81,9 @@ model WebsiteEvent { eventType Int @default(1) @map("event_type") @db.UnsignedInt eventName String? @map("event_name") @db.VarChar(50) + eventData EventData[] + session Session @relation(fields: [sessionId], references: [id]) + @@index([createdAt]) @@index([sessionId]) @@index([websiteId]) @@ -85,6 +92,34 @@ model WebsiteEvent { @@map("website_event") } +model EventData { + id String @id() @map("event_id") @db.VarChar(36) + websiteEventId String @map("website_event_id") @db.VarChar(36) + websiteId String @map("website_id") @db.VarChar(36) + sessionId String @map("session_id") @db.VarChar(36) + urlPath String @map("url_path") @db.VarChar(500) + eventName String @map("event_name") @db.VarChar(500) + eventKey String @map("event_key") @db.VarChar(500) + eventStringValue String @map("event_string_value") @db.VarChar(500) + eventNumericValue Decimal @map("event_numeric_value") @db.Decimal(19,4) + eventDateValue DateTime? @map("event_date_value") @db.Timestamp(0) + eventDataType Int @map("event_data_type") @db.UnsignedInt + createdAt DateTime? @default(now()) @map("created_at")@db.Timestamp(0) + + website Website @relation(fields: [websiteId], references: [id]) + websiteEvent WebsiteEvent @relation(fields: [websiteEventId], references: [id]) + session Session @relation(fields: [sessionId], references: [id]) + + @@index([createdAt]) + @@index([sessionId]) + @@index([websiteId]) + @@index([websiteEventId]) + @@index([websiteId, websiteEventId, createdAt]) + @@index([websiteId, sessionId, createdAt]) + @@index([websiteId, sessionId, websiteEventId, createdAt]) + @@map("event_data") +} + model Team { id String @id() @unique() @map("team_id") @db.VarChar(36) name String @db.VarChar(50) diff --git a/db/postgresql/migrations/09_add_new_event_data/migration.sql b/db/postgresql/migrations/09_add_new_event_data/migration.sql new file mode 100644 index 00000000..932d4f19 --- /dev/null +++ b/db/postgresql/migrations/09_add_new_event_data/migration.sql @@ -0,0 +1,38 @@ +-- CreateTable +CREATE TABLE "event_data" ( + "event_id" UUID NOT NULL, + "website_event_id" UUID NOT NULL, + "website_id" UUID NOT NULL, + "session_id" UUID NOT NULL, + "url_path" VARCHAR(500) NOT NULL, + "event_name" VARCHAR(500) NOT NULL, + "event_key" VARCHAR(500) NOT NULL, + "event_string_value" VARCHAR(500) NOT NULL, + "event_numeric_value" DECIMAL(19,4) NOT NULL, + "event_date_value" TIMESTAMPTZ(6), + "event_data_type" INTEGER NOT NULL, + "created_at" TIMESTAMPTZ(6) DEFAULT CURRENT_TIMESTAMP, + + CONSTRAINT "event_data_pkey" PRIMARY KEY ("event_id") +); + +-- CreateIndex +CREATE INDEX "event_data_created_at_idx" ON "event_data"("created_at"); + +-- CreateIndex +CREATE INDEX "event_data_session_id_idx" ON "event_data"("session_id"); + +-- CreateIndex +CREATE INDEX "event_data_website_id_idx" ON "event_data"("website_id"); + +-- CreateIndex +CREATE INDEX "event_data_website_event_id_idx" ON "event_data"("website_event_id"); + +-- CreateIndex +CREATE INDEX "event_data_website_id_website_event_id_created_at_idx" ON "event_data"("website_id", "website_event_id", "created_at"); + +-- CreateIndex +CREATE INDEX "event_data_website_id_session_id_created_at_idx" ON "event_data"("website_id", "session_id", "created_at"); + +-- CreateIndex +CREATE INDEX "event_data_website_id_session_id_website_event_id_created_a_idx" ON "event_data"("website_id", "session_id", "website_event_id", "created_at"); diff --git a/db/postgresql/schema.prisma b/db/postgresql/schema.prisma index 82b22c64..a29b96b2 100644 --- a/db/postgresql/schema.prisma +++ b/db/postgresql/schema.prisma @@ -17,7 +17,7 @@ model User { updatedAt DateTime? @map("updated_at") @db.Timestamptz(6) deletedAt DateTime? @map("deleted_at") @db.Timestamptz(6) - Website Website[] + website Website[] teamUser TeamUser[] @@map("user") @@ -38,6 +38,9 @@ model Session { city String? @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) + websiteEvent WebsiteEvent[] + eventData EventData[] + @@index([createdAt]) @@index([websiteId]) @@map("session") @@ -56,6 +59,7 @@ model Website { user User? @relation(fields: [userId], references: [id]) teamWebsite TeamWebsite[] + eventData EventData[] @@index([userId]) @@index([createdAt]) @@ -77,6 +81,9 @@ model WebsiteEvent { eventType Int @default(1) @map("event_type") @db.Integer eventName String? @map("event_name") @db.VarChar(50) + eventData EventData[] + session Session @relation(fields: [sessionId], references: [id]) + @@index([createdAt]) @@index([sessionId]) @@index([websiteId]) @@ -85,6 +92,34 @@ model WebsiteEvent { @@map("website_event") } +model EventData { + id String @id() @map("event_id") @db.Uuid + websiteEventId String @map("website_event_id") @db.Uuid + websiteId String @map("website_id") @db.Uuid + sessionId String @map("session_id") @db.Uuid + urlPath String @map("url_path") @db.VarChar(500) + eventName String @map("event_name") @db.VarChar(500) + eventKey String @map("event_key") @db.VarChar(500) + eventStringValue String @map("event_string_value") @db.VarChar(500) + eventNumericValue Decimal @map("event_numeric_value") @db.Decimal(19,4) + eventDateValue DateTime? @map("event_date_value") @db.Timestamptz(6) + eventDataType Int @map("event_data_type") @db.Integer + createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) + + website Website @relation(fields: [websiteId], references: [id]) + websiteEvent WebsiteEvent @relation(fields: [websiteEventId], references: [id]) + session Session @relation(fields: [sessionId], references: [id]) + + @@index([createdAt]) + @@index([sessionId]) + @@index([websiteId]) + @@index([websiteEventId]) + @@index([websiteId, websiteEventId, createdAt]) + @@index([websiteId, sessionId, createdAt]) + @@index([websiteId, sessionId, websiteEventId, createdAt]) + @@map("event_data") +} + model Team { id String @id() @unique() @map("team_id") @db.Uuid name String @db.VarChar(50) @@ -127,4 +162,4 @@ model TeamWebsite { @@index([teamId]) @@index([websiteId]) @@map("team_website") -} +} \ No newline at end of file From 87545a5648ce920245dd5360f1ab39496bb513bf Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Wed, 22 Mar 2023 23:07:01 -0700 Subject: [PATCH 2/2] add system user insert back for MySQL --- db/mysql/migrations/01_init/migration.sql | 3 +++ 1 file changed, 3 insertions(+) diff --git a/db/mysql/migrations/01_init/migration.sql b/db/mysql/migrations/01_init/migration.sql index 84dfea01..586c604f 100644 --- a/db/mysql/migrations/01_init/migration.sql +++ b/db/mysql/migrations/01_init/migration.sql @@ -144,3 +144,6 @@ CREATE TABLE `team_website` ( INDEX `team_website_website_id_idx`(`website_id`), PRIMARY KEY (`team_website_id`) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; + +-- AddSystemUser +INSERT INTO "user" (user_id, username, role, password) VALUES ('41e2b680-648e-4b09-bcd7-3e2b10c06264' , 'admin', 'admin', '$2b$10$BUli0c.muyCW1ErNJc3jL.vFRFtFJWrT8/GcR4A.sUdCznaXiqFXa'); \ No newline at end of file