Merge branch 'umami-software:master' into master

This commit is contained in:
Adam Stamper 2025-05-08 07:34:24 +01:00 committed by GitHub
commit d1ae32017a
No known key found for this signature in database
GPG key ID: B5690EEEBB952194
214 changed files with 58648 additions and 12243 deletions

View file

@ -0,0 +1,332 @@
-- Create Event
CREATE TABLE umami.website_event_new
(
website_id UUID,
session_id UUID,
visit_id UUID,
event_id UUID,
--sessions
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,
--pageviews
url_path String,
url_query String,
utm_source String,
utm_medium String,
utm_campaign String,
utm_content String,
utm_term String,
referrer_path String,
referrer_query String,
referrer_domain String,
page_title String,
--clickIDs
gclid String,
fbclid String,
msclkid String,
ttclid String,
li_fat_id String,
twclid String,
--events
event_type UInt32,
event_name String,
tag String,
created_at DateTime('UTC'),
job_id Nullable(UUID)
)
ENGINE = MergeTree
PARTITION BY toYYYYMM(created_at)
ORDER BY (toStartOfHour(created_at), website_id, session_id, visit_id, created_at)
PRIMARY KEY (toStartOfHour(created_at), website_id, session_id, visit_id)
SETTINGS index_granularity = 8192;
-- stats hourly
CREATE TABLE umami.website_event_stats_hourly_new
(
website_id UUID,
session_id UUID,
visit_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),
city String,
entry_url AggregateFunction(argMin, String, DateTime('UTC')),
exit_url AggregateFunction(argMax, String, DateTime('UTC')),
url_path SimpleAggregateFunction(groupArrayArray, Array(String)),
url_query SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_source SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_medium SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_campaign SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_content SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_term SimpleAggregateFunction(groupArrayArray, Array(String)),
referrer_domain SimpleAggregateFunction(groupArrayArray, Array(String)),
page_title SimpleAggregateFunction(groupArrayArray, Array(String)),
gclid SimpleAggregateFunction(groupArrayArray, Array(String)),
fbclid SimpleAggregateFunction(groupArrayArray, Array(String)),
msclkid SimpleAggregateFunction(groupArrayArray, Array(String)),
ttclid SimpleAggregateFunction(groupArrayArray, Array(String)),
li_fat_id SimpleAggregateFunction(groupArrayArray, Array(String)),
twclid SimpleAggregateFunction(groupArrayArray, Array(String)),
event_type UInt32,
event_name SimpleAggregateFunction(groupArrayArray, Array(String)),
views SimpleAggregateFunction(sum, UInt64),
min_time SimpleAggregateFunction(min, DateTime('UTC')),
max_time SimpleAggregateFunction(max, DateTime('UTC')),
tag SimpleAggregateFunction(groupArrayArray, Array(String)),
created_at Datetime('UTC')
)
ENGINE = AggregatingMergeTree
PARTITION BY toYYYYMM(created_at)
ORDER BY (
website_id,
event_type,
toStartOfHour(created_at),
cityHash64(visit_id),
visit_id
)
SAMPLE BY cityHash64(visit_id);
CREATE MATERIALIZED VIEW umami.website_event_stats_hourly_mv_new
TO umami.website_event_stats_hourly_new
AS
SELECT
website_id,
session_id,
visit_id,
hostname,
browser,
os,
device,
screen,
language,
country,
subdivision1,
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,
subdivision1,
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_new
GROUP BY website_id,
session_id,
visit_id,
hostname,
browser,
os,
device,
screen,
language,
country,
subdivision1,
city,
event_type,
timestamp);
-- projections
ALTER TABLE umami.website_event_new
ADD PROJECTION website_event_url_path_projection (
SELECT * ORDER BY toStartOfDay(created_at), website_id, url_path, created_at
);
ALTER TABLE umami.website_event_new MATERIALIZE PROJECTION website_event_url_path_projection;
ALTER TABLE umami.website_event_new
ADD PROJECTION website_event_referrer_domain_projection (
SELECT * ORDER BY toStartOfDay(created_at), website_id, referrer_domain, created_at
);
ALTER TABLE umami.website_event_new MATERIALIZE PROJECTION website_event_referrer_domain_projection;
-- migration
INSERT INTO umami.website_event_new
SELECT website_id, session_id, visit_id, event_id, hostname, browser, os, device, screen, language, country, subdivision1, subdivision2, city, url_path, url_query,
extract(url_query, 'utm_source=([^&]*)') AS utm_source,
extract(url_query, 'utm_medium=([^&]*)') AS utm_medium,
extract(url_query, 'utm_campaign=([^&]*)') AS utm_campaign,
extract(url_query, 'utm_content=([^&]*)') AS utm_content,
extract(url_query, 'utm_term=([^&]*)') AS utm_term,referrer_path, referrer_query, referrer_domain,
page_title,
extract(url_query, 'gclid=([^&]*)') gclid,
extract(url_query, 'fbclid=([^&]*)') fbclid,
extract(url_query, 'msclkid=([^&]*)') msclkid,
extract(url_query, 'ttclid=([^&]*)') ttclid,
extract(url_query, 'li_fat_id=([^&]*)') li_fat_id,
extract(url_query, 'twclid=([^&]*)') twclid,
event_type, event_name, tag, created_at, job_id
FROM umami.website_event
-- rename tables
RENAME TABLE umami.website_event TO umami.website_event_old;
RENAME TABLE umami.website_event_new TO umami.website_event;
RENAME TABLE umami.website_event_stats_hourly TO umami.website_event_stats_hourly_old;
RENAME TABLE umami.website_event_stats_hourly_new TO umami.website_event_stats_hourly;
RENAME TABLE umami.website_event_stats_hourly_mv TO umami.website_event_stats_hourly_mv_old;
RENAME TABLE umami.website_event_stats_hourly_mv_new TO umami.website_event_stats_hourly_mv;
-- recreate view
DROP TABLE umami.website_event_stats_hourly_mv;
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,
subdivision1,
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,
subdivision1,
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,
subdivision1,
city,
event_type,
timestamp);

View 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);

View file

@ -0,0 +1,103 @@
-- add tag column
ALTER TABLE umami.website_event ADD COLUMN "distinct_id" String AFTER "tag";
ALTER TABLE umami.website_event_stats_hourly ADD COLUMN "distinct_id" String AFTER "tag";
ALTER TABLE umami.session_data ADD COLUMN "distinct_id" String AFTER "data_type";
-- update materialized view
DROP TABLE umami.website_event_stats_hourly_mv;
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,
distinct_id,
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,
distinct_id,
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,
distinct_id,
timestamp);

View file

@ -13,20 +13,32 @@ 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,
url_query String,
utm_source String,
utm_medium String,
utm_campaign String,
utm_content String,
utm_term String,
referrer_path String,
referrer_query String,
referrer_domain String,
page_title String,
--clickIDs
gclid String,
fbclid String,
msclkid String,
ttclid String,
li_fat_id String,
twclid String,
--events
event_type UInt32,
event_name String,
tag String,
distinct_id String,
created_at DateTime('UTC'),
job_id Nullable(UUID)
)
@ -64,6 +76,7 @@ CREATE TABLE umami.session_data
number_value Nullable(Decimal64(4)),
date_value Nullable(DateTime('UTC')),
data_type UInt32,
distinct_id String,
created_at DateTime('UTC'),
job_id Nullable(UUID)
)
@ -84,20 +97,32 @@ 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')),
url_path SimpleAggregateFunction(groupArrayArray, Array(String)),
url_query SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_source SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_medium SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_campaign SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_content SimpleAggregateFunction(groupArrayArray, Array(String)),
utm_term SimpleAggregateFunction(groupArrayArray, Array(String)),
referrer_domain SimpleAggregateFunction(groupArrayArray, Array(String)),
page_title SimpleAggregateFunction(groupArrayArray, Array(String)),
gclid SimpleAggregateFunction(groupArrayArray, Array(String)),
fbclid SimpleAggregateFunction(groupArrayArray, Array(String)),
msclkid SimpleAggregateFunction(groupArrayArray, Array(String)),
ttclid SimpleAggregateFunction(groupArrayArray, Array(String)),
li_fat_id SimpleAggregateFunction(groupArrayArray, Array(String)),
twclid SimpleAggregateFunction(groupArrayArray, Array(String)),
event_type UInt32,
event_name SimpleAggregateFunction(groupArrayArray, Array(String)),
views SimpleAggregateFunction(sum, UInt64),
min_time SimpleAggregateFunction(min, DateTime('UTC')),
max_time SimpleAggregateFunction(max, DateTime('UTC')),
tag SimpleAggregateFunction(groupArrayArray, Array(String)),
distinct_id,
created_at Datetime('UTC')
)
ENGINE = AggregatingMergeTree
@ -125,20 +150,32 @@ SELECT
screen,
language,
country,
subdivision1,
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,
distinct_id,
timestamp as created_at
FROM (SELECT
website_id,
@ -151,20 +188,32 @@ FROM (SELECT
screen,
language,
country,
subdivision1,
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,
distinct_id String,
toStartOfHour(created_at) timestamp
FROM umami.website_event
GROUP BY website_id,
@ -177,9 +226,10 @@ GROUP BY website_id,
screen,
language,
country,
subdivision1,
region,
city,
event_type,
distinct_id,
timestamp);
-- projections

View file

@ -0,0 +1,13 @@
-- AlterTable
ALTER TABLE `website_event`
ADD COLUMN `fbclid` VARCHAR(255) NULL,
ADD COLUMN `gclid` VARCHAR(255) NULL,
ADD COLUMN `li_fat_id` VARCHAR(255) NULL,
ADD COLUMN `msclkid` VARCHAR(255) NULL,
ADD COLUMN `ttclid` VARCHAR(255) NULL,
ADD COLUMN `twclid` VARCHAR(255) NULL,
ADD COLUMN `utm_campaign` VARCHAR(255) NULL,
ADD COLUMN `utm_content` VARCHAR(255) NULL,
ADD COLUMN `utm_medium` VARCHAR(255) NULL,
ADD COLUMN `utm_source` VARCHAR(255) NULL,
ADD COLUMN `utm_term` VARCHAR(255) NULL;

View 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`);

View file

@ -0,0 +1,5 @@
-- AlterTable
ALTER TABLE `session` ADD COLUMN `distinct_id` VARCHAR(50) NULL;
-- AlterTable
ALTER TABLE `session_data` ADD COLUMN `distinct_id` VARCHAR(50) NULL;

View file

@ -1,3 +1,3 @@
# Please do not edit this file manually
# It should be added in your version-control system (i.e. Git)
provider = "mysql"
# It should be added in your version-control system (e.g., Git)
provider = "mysql"

View file

@ -1,6 +1,5 @@
generator client {
provider = "prisma-client-js"
binaryTargets = ["native"]
provider = "prisma-client-js"
}
datasource db {
@ -29,19 +28,18 @@ 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)
city String? @db.VarChar(50)
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0)
id String @id @unique @map("session_id") @db.VarChar(36)
websiteId String @map("website_id") @db.VarChar(36)
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)
region String? @db.Char(20)
city String? @db.VarChar(50)
distinctId String? @map("distinct_id") @db.VarChar(50)
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0)
websiteEvent WebsiteEvent[]
sessionData SessionData[]
@ -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")
}
@ -97,13 +94,25 @@ model WebsiteEvent {
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)
utmSource String? @map("utm_source") @db.VarChar(255)
utmMedium String? @map("utm_medium") @db.VarChar(255)
utmCampaign String? @map("utm_campaign") @db.VarChar(255)
utmContent String? @map("utm_content") @db.VarChar(255)
utmTerm String? @map("utm_term") @db.VarChar(255)
referrerPath String? @map("referrer_path") @db.VarChar(500)
referrerQuery String? @map("referrer_query") @db.VarChar(500)
referrerDomain String? @map("referrer_domain") @db.VarChar(500)
pageTitle String? @map("page_title") @db.VarChar(500)
gclid String? @map("gclid") @db.VarChar(255)
fbclid String? @map("fbclid") @db.VarChar(255)
msclkid String? @map("msclkid") @db.VarChar(255)
ttclid String? @map("ttclid") @db.VarChar(255)
lifatid String? @map("li_fat_id") @db.VarChar(255)
twclid String? @map("twclid") @db.VarChar(255)
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])
@ -121,6 +130,7 @@ model WebsiteEvent {
@@index([websiteId, createdAt, tag])
@@index([websiteId, sessionId, createdAt])
@@index([websiteId, visitId, createdAt])
@@index([websiteId, createdAt, hostname])
@@map("website_event")
}
@ -155,6 +165,7 @@ model SessionData {
numberValue Decimal? @map("number_value") @db.Decimal(19, 4)
dateValue DateTime? @map("date_value") @db.Timestamp(0)
dataType Int @map("data_type") @db.UnsignedInt
distinctId String? @map("distinct_id") @db.VarChar(50)
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0)
website Website @relation(fields: [websiteId], references: [id])

View file

@ -0,0 +1,13 @@
-- AlterTable
ALTER TABLE "website_event"
ADD COLUMN "fbclid" VARCHAR(255),
ADD COLUMN "gclid" VARCHAR(255),
ADD COLUMN "li_fat_id" VARCHAR(255),
ADD COLUMN "msclkid" VARCHAR(255),
ADD COLUMN "ttclid" VARCHAR(255),
ADD COLUMN "twclid" VARCHAR(255),
ADD COLUMN "utm_campaign" VARCHAR(255),
ADD COLUMN "utm_content" VARCHAR(255),
ADD COLUMN "utm_medium" VARCHAR(255),
ADD COLUMN "utm_source" VARCHAR(255),
ADD COLUMN "utm_term" VARCHAR(255);

View file

@ -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");

View file

@ -0,0 +1,5 @@
-- AlterTable
ALTER TABLE "session" ADD COLUMN "distinct_id" VARCHAR(50);
-- AlterTable
ALTER TABLE "session_data" ADD COLUMN "distinct_id" VARCHAR(50);

View file

@ -1,3 +1,3 @@
# Please do not edit this file manually
# It should be added in your version-control system (i.e. Git)
provider = "postgresql"
# It should be added in your version-control system (e.g., Git)
provider = "postgresql"

View file

@ -1,6 +1,5 @@
generator client {
provider = "prisma-client-js"
binaryTargets = ["native"]
provider = "prisma-client-js"
}
datasource db {
@ -30,19 +29,18 @@ 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)
city String? @db.VarChar(50)
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6)
id String @id @unique @map("session_id") @db.Uuid
websiteId String @map("website_id") @db.Uuid
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)
region String? @db.VarChar(20)
city String? @db.VarChar(50)
distinctId String? @map("distinct_id") @db.VarChar(50)
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6)
websiteEvent WebsiteEvent[]
sessionData SessionData[]
@ -50,14 +48,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")
}
@ -98,13 +95,25 @@ model WebsiteEvent {
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)
utmSource String? @map("utm_source") @db.VarChar(255)
utmMedium String? @map("utm_medium") @db.VarChar(255)
utmCampaign String? @map("utm_campaign") @db.VarChar(255)
utmContent String? @map("utm_content") @db.VarChar(255)
utmTerm String? @map("utm_term") @db.VarChar(255)
referrerPath String? @map("referrer_path") @db.VarChar(500)
referrerQuery String? @map("referrer_query") @db.VarChar(500)
referrerDomain String? @map("referrer_domain") @db.VarChar(500)
pageTitle String? @map("page_title") @db.VarChar(500)
gclid String? @map("gclid") @db.VarChar(255)
fbclid String? @map("fbclid") @db.VarChar(255)
msclkid String? @map("msclkid") @db.VarChar(255)
ttclid String? @map("ttclid") @db.VarChar(255)
lifatid String? @map("li_fat_id") @db.VarChar(255)
twclid String? @map("twclid") @db.VarChar(255)
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])
@ -122,6 +131,7 @@ model WebsiteEvent {
@@index([websiteId, createdAt, tag])
@@index([websiteId, sessionId, createdAt])
@@index([websiteId, visitId, createdAt])
@@index([websiteId, createdAt, hostname])
@@map("website_event")
}
@ -156,6 +166,7 @@ model SessionData {
numberValue Decimal? @map("number_value") @db.Decimal(19, 4)
dateValue DateTime? @map("date_value") @db.Timestamptz(6)
dataType Int @map("data_type") @db.Integer
distinctId String? @map("distinct_id") @db.VarChar(50)
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6)
website Website @relation(fields: [websiteId], references: [id])