mirror of
https://github.com/umami-software/umami.git
synced 2026-02-04 04:37:11 +01:00
app and db schema - region rename, hostname move
This commit is contained in:
parent
5dccca0c3f
commit
12b8ac4272
19 changed files with 11252 additions and 89 deletions
122
db/clickhouse/migrations/06_update_subdivision.sql
Normal file
122
db/clickhouse/migrations/06_update_subdivision.sql
Normal file
|
|
@ -0,0 +1,122 @@
|
|||
-- drop projections
|
||||
ALTER TABLE umami.website_event DROP PROJECTION website_event_url_path_projection;
|
||||
ALTER TABLE umami.website_event DROP PROJECTION website_event_referrer_domain_projection;
|
||||
|
||||
--drop view
|
||||
DROP TABLE umami.website_event_stats_hourly_mv;
|
||||
|
||||
-- rename columns
|
||||
ALTER TABLE umami.website_event RENAME COLUMN "subdivision1" TO "region";
|
||||
ALTER TABLE umami.website_event_stats_hourly RENAME COLUMN "subdivision1" TO "region";
|
||||
|
||||
-- drop columns
|
||||
ALTER TABLE umami.website_event DROP COLUMN "subdivision2";
|
||||
|
||||
-- recreate projections
|
||||
ALTER TABLE umami.website_event
|
||||
ADD PROJECTION website_event_url_path_projection (
|
||||
SELECT * ORDER BY toStartOfDay(created_at), website_id, url_path, created_at
|
||||
);
|
||||
|
||||
ALTER TABLE umami.website_event MATERIALIZE PROJECTION website_event_url_path_projection;
|
||||
|
||||
ALTER TABLE umami.website_event
|
||||
ADD PROJECTION website_event_referrer_domain_projection (
|
||||
SELECT * ORDER BY toStartOfDay(created_at), website_id, referrer_domain, created_at
|
||||
);
|
||||
|
||||
ALTER TABLE umami.website_event MATERIALIZE PROJECTION website_event_referrer_domain_projection;
|
||||
|
||||
-- recreate view
|
||||
CREATE MATERIALIZED VIEW umami.website_event_stats_hourly_mv
|
||||
TO umami.website_event_stats_hourly
|
||||
AS
|
||||
SELECT
|
||||
website_id,
|
||||
session_id,
|
||||
visit_id,
|
||||
hostname,
|
||||
browser,
|
||||
os,
|
||||
device,
|
||||
screen,
|
||||
language,
|
||||
country,
|
||||
region,
|
||||
city,
|
||||
entry_url,
|
||||
exit_url,
|
||||
url_paths as url_path,
|
||||
url_query,
|
||||
utm_source,
|
||||
utm_medium,
|
||||
utm_campaign,
|
||||
utm_content,
|
||||
utm_term,
|
||||
referrer_domain,
|
||||
page_title,
|
||||
gclid,
|
||||
fbclid,
|
||||
msclkid,
|
||||
ttclid,
|
||||
li_fat_id,
|
||||
twclid,
|
||||
event_type,
|
||||
event_name,
|
||||
views,
|
||||
min_time,
|
||||
max_time,
|
||||
tag,
|
||||
timestamp as created_at
|
||||
FROM (SELECT
|
||||
website_id,
|
||||
session_id,
|
||||
visit_id,
|
||||
hostname,
|
||||
browser,
|
||||
os,
|
||||
device,
|
||||
screen,
|
||||
language,
|
||||
country,
|
||||
region,
|
||||
city,
|
||||
argMinState(url_path, created_at) entry_url,
|
||||
argMaxState(url_path, created_at) exit_url,
|
||||
arrayFilter(x -> x != '', groupArray(url_path)) as url_paths,
|
||||
arrayFilter(x -> x != '', groupArray(url_query)) url_query,
|
||||
arrayFilter(x -> x != '', groupArray(utm_source)) utm_source,
|
||||
arrayFilter(x -> x != '', groupArray(utm_medium)) utm_medium,
|
||||
arrayFilter(x -> x != '', groupArray(utm_campaign)) utm_campaign,
|
||||
arrayFilter(x -> x != '', groupArray(utm_content)) utm_content,
|
||||
arrayFilter(x -> x != '', groupArray(utm_term)) utm_term,
|
||||
arrayFilter(x -> x != '', groupArray(referrer_domain)) referrer_domain,
|
||||
arrayFilter(x -> x != '', groupArray(page_title)) page_title,
|
||||
arrayFilter(x -> x != '', groupArray(gclid)) gclid,
|
||||
arrayFilter(x -> x != '', groupArray(fbclid)) fbclid,
|
||||
arrayFilter(x -> x != '', groupArray(msclkid)) msclkid,
|
||||
arrayFilter(x -> x != '', groupArray(ttclid)) ttclid,
|
||||
arrayFilter(x -> x != '', groupArray(li_fat_id)) li_fat_id,
|
||||
arrayFilter(x -> x != '', groupArray(twclid)) twclid,
|
||||
event_type,
|
||||
if(event_type = 2, groupArray(event_name), []) event_name,
|
||||
sumIf(1, event_type = 1) views,
|
||||
min(created_at) min_time,
|
||||
max(created_at) max_time,
|
||||
arrayFilter(x -> x != '', groupArray(tag)) tag,
|
||||
toStartOfHour(created_at) timestamp
|
||||
FROM umami.website_event
|
||||
GROUP BY website_id,
|
||||
session_id,
|
||||
visit_id,
|
||||
hostname,
|
||||
browser,
|
||||
os,
|
||||
device,
|
||||
screen,
|
||||
language,
|
||||
country,
|
||||
region,
|
||||
city,
|
||||
event_type,
|
||||
timestamp);
|
||||
|
|
@ -13,8 +13,7 @@ CREATE TABLE umami.website_event
|
|||
screen LowCardinality(String),
|
||||
language LowCardinality(String),
|
||||
country LowCardinality(String),
|
||||
subdivision1 LowCardinality(String),
|
||||
subdivision2 LowCardinality(String),
|
||||
region LowCardinality(String),
|
||||
city String,
|
||||
--pageviews
|
||||
url_path String,
|
||||
|
|
@ -96,7 +95,7 @@ CREATE TABLE umami.website_event_stats_hourly
|
|||
screen LowCardinality(String),
|
||||
language LowCardinality(String),
|
||||
country LowCardinality(String),
|
||||
subdivision1 LowCardinality(String),
|
||||
region LowCardinality(String),
|
||||
city String,
|
||||
entry_url AggregateFunction(argMin, String, DateTime('UTC')),
|
||||
exit_url AggregateFunction(argMax, String, DateTime('UTC')),
|
||||
|
|
@ -148,7 +147,7 @@ SELECT
|
|||
screen,
|
||||
language,
|
||||
country,
|
||||
subdivision1,
|
||||
region,
|
||||
city,
|
||||
entry_url,
|
||||
exit_url,
|
||||
|
|
@ -185,7 +184,7 @@ FROM (SELECT
|
|||
screen,
|
||||
language,
|
||||
country,
|
||||
subdivision1,
|
||||
region,
|
||||
city,
|
||||
argMinState(url_path, created_at) entry_url,
|
||||
argMaxState(url_path, created_at) exit_url,
|
||||
|
|
@ -222,7 +221,7 @@ GROUP BY website_id,
|
|||
screen,
|
||||
language,
|
||||
country,
|
||||
subdivision1,
|
||||
region,
|
||||
city,
|
||||
event_type,
|
||||
timestamp);
|
||||
|
|
|
|||
22
db/mysql/migrations/09_update_hostname_region/migration.sql
Normal file
22
db/mysql/migrations/09_update_hostname_region/migration.sql
Normal file
|
|
@ -0,0 +1,22 @@
|
|||
-- AlterTable
|
||||
ALTER TABLE `website_event` ADD COLUMN `hostname` VARCHAR(100) NULL;
|
||||
|
||||
-- DataMigration
|
||||
UPDATE `website_event` w
|
||||
JOIN `session` s
|
||||
ON s.website_id = w.website_id
|
||||
and s.session_id = w.session_id
|
||||
SET w.hostname = s.hostname;
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX `session_website_id_created_at_hostname_idx` ON `session`;
|
||||
DROP INDEX `session_website_id_created_at_subdivision1_idx` ON `session`;
|
||||
|
||||
-- AlterTable
|
||||
ALTER TABLE `session` RENAME COLUMN `subdivision1` TO `region`;
|
||||
ALTER TABLE `session` DROP COLUMN `subdivision2`;
|
||||
ALTER TABLE `session` DROP COLUMN `hostname`;
|
||||
|
||||
-- CreateIndex
|
||||
CREATE INDEX `website_event_website_id_created_at_hostname_idx` ON `website_event`(`website_id`, `created_at`, `hostname`);
|
||||
CREATE INDEX `session_website_id_created_at_region_idx` ON `session`(`website_id`, `created_at`, `region`);
|
||||
|
|
@ -31,15 +31,13 @@ model User {
|
|||
model Session {
|
||||
id String @id @unique @map("session_id") @db.VarChar(36)
|
||||
websiteId String @map("website_id") @db.VarChar(36)
|
||||
hostname String? @db.VarChar(100)
|
||||
browser String? @db.VarChar(20)
|
||||
os String? @db.VarChar(20)
|
||||
device String? @db.VarChar(20)
|
||||
screen String? @db.VarChar(11)
|
||||
language String? @db.VarChar(35)
|
||||
country String? @db.Char(2)
|
||||
subdivision1 String? @db.Char(20)
|
||||
subdivision2 String? @db.VarChar(50)
|
||||
region String? @db.Char(20)
|
||||
city String? @db.VarChar(50)
|
||||
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0)
|
||||
|
||||
|
|
@ -49,14 +47,13 @@ model Session {
|
|||
@@index([createdAt])
|
||||
@@index([websiteId])
|
||||
@@index([websiteId, createdAt])
|
||||
@@index([websiteId, createdAt, hostname])
|
||||
@@index([websiteId, createdAt, browser])
|
||||
@@index([websiteId, createdAt, os])
|
||||
@@index([websiteId, createdAt, device])
|
||||
@@index([websiteId, createdAt, screen])
|
||||
@@index([websiteId, createdAt, language])
|
||||
@@index([websiteId, createdAt, country])
|
||||
@@index([websiteId, createdAt, subdivision1])
|
||||
@@index([websiteId, createdAt, region])
|
||||
@@index([websiteId, createdAt, city])
|
||||
@@map("session")
|
||||
}
|
||||
|
|
@ -115,6 +112,7 @@ model WebsiteEvent {
|
|||
eventType Int @default(1) @map("event_type") @db.UnsignedInt
|
||||
eventName String? @map("event_name") @db.VarChar(50)
|
||||
tag String? @db.VarChar(50)
|
||||
hostname String? @db.VarChar(100)
|
||||
|
||||
eventData EventData[]
|
||||
session Session @relation(fields: [sessionId], references: [id])
|
||||
|
|
@ -132,6 +130,7 @@ model WebsiteEvent {
|
|||
@@index([websiteId, createdAt, tag])
|
||||
@@index([websiteId, sessionId, createdAt])
|
||||
@@index([websiteId, visitId, createdAt])
|
||||
@@index([websiteId, createdAt, hostname])
|
||||
@@map("website_event")
|
||||
}
|
||||
|
||||
|
|
|
|||
|
|
@ -0,0 +1,25 @@
|
|||
-- AlterTable
|
||||
ALTER TABLE "website_event" ADD COLUMN "hostname" VARCHAR(100);
|
||||
|
||||
-- DataMigration
|
||||
UPDATE "website_event" w
|
||||
SET hostname = s.hostname
|
||||
FROM "session" s
|
||||
WHERE s.website_id = w.website_id
|
||||
and s.session_id = w.session_id;
|
||||
|
||||
-- DropIndex
|
||||
DROP INDEX IF EXISTS "session_website_id_created_at_hostname_idx";
|
||||
DROP INDEX IF EXISTS "session_website_id_created_at_subdivision1_idx";
|
||||
|
||||
-- AlterTable
|
||||
ALTER TABLE "session" RENAME COLUMN "subdivision1" TO "region";
|
||||
ALTER TABLE "session" DROP COLUMN "subdivision2";
|
||||
ALTER TABLE "session" DROP COLUMN "hostname";
|
||||
|
||||
-- CreateIndex
|
||||
CREATE INDEX "website_event_website_id_created_at_hostname_idx" ON "website_event"("website_id", "created_at", "hostname");
|
||||
CREATE INDEX "session_website_id_created_at_region_idx" ON "session"("website_id", "created_at", "region");
|
||||
|
||||
|
||||
|
||||
|
|
@ -31,15 +31,13 @@ model User {
|
|||
model Session {
|
||||
id String @id @unique @map("session_id") @db.Uuid
|
||||
websiteId String @map("website_id") @db.Uuid
|
||||
hostname String? @db.VarChar(100)
|
||||
browser String? @db.VarChar(20)
|
||||
os String? @db.VarChar(20)
|
||||
device String? @db.VarChar(20)
|
||||
screen String? @db.VarChar(11)
|
||||
language String? @db.VarChar(35)
|
||||
country String? @db.Char(2)
|
||||
subdivision1 String? @db.VarChar(20)
|
||||
subdivision2 String? @db.VarChar(50)
|
||||
region String? @db.VarChar(20)
|
||||
city String? @db.VarChar(50)
|
||||
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6)
|
||||
|
||||
|
|
@ -49,14 +47,13 @@ model Session {
|
|||
@@index([createdAt])
|
||||
@@index([websiteId])
|
||||
@@index([websiteId, createdAt])
|
||||
@@index([websiteId, createdAt, hostname])
|
||||
@@index([websiteId, createdAt, browser])
|
||||
@@index([websiteId, createdAt, os])
|
||||
@@index([websiteId, createdAt, device])
|
||||
@@index([websiteId, createdAt, screen])
|
||||
@@index([websiteId, createdAt, language])
|
||||
@@index([websiteId, createdAt, country])
|
||||
@@index([websiteId, createdAt, subdivision1])
|
||||
@@index([websiteId, createdAt, region])
|
||||
@@index([websiteId, createdAt, city])
|
||||
@@map("session")
|
||||
}
|
||||
|
|
@ -115,6 +112,7 @@ model WebsiteEvent {
|
|||
eventType Int @default(1) @map("event_type") @db.Integer
|
||||
eventName String? @map("event_name") @db.VarChar(50)
|
||||
tag String? @db.VarChar(50)
|
||||
hostname String? @db.VarChar(100)
|
||||
|
||||
eventData EventData[]
|
||||
session Session @relation(fields: [sessionId], references: [id])
|
||||
|
|
@ -132,6 +130,7 @@ model WebsiteEvent {
|
|||
@@index([websiteId, createdAt, tag])
|
||||
@@index([websiteId, sessionId, createdAt])
|
||||
@@index([websiteId, visitId, createdAt])
|
||||
@@index([websiteId, createdAt, hostname])
|
||||
@@map("website_event")
|
||||
}
|
||||
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue