diff --git a/components/metrics/MetricsTable.js b/components/metrics/MetricsTable.js index 258ea1e8..945f7796 100644 --- a/components/metrics/MetricsTable.js +++ b/components/metrics/MetricsTable.js @@ -40,7 +40,7 @@ export default function MetricsTable({ const { data, isLoading, isFetched, error } = useQuery( [ - 'websites:mnetrics', + 'websites:metrics', { websiteId, type, modified, url, referrer, os, browser, device, country }, ], () => diff --git a/db/clickhouse/schema.sql b/db/clickhouse/schema.sql index d4d7310c..c0a2f62d 100644 --- a/db/clickhouse/schema.sql +++ b/db/clickhouse/schema.sql @@ -19,8 +19,11 @@ CREATE TABLE event subdivision2 LowCardinality(String), city String, --pageview - url String, - referrer String, + url_path String, + url_query String, + referrer_path String, + referrer_query String, + referrer_domain String, page_title String, --event event_type UInt32, @@ -48,8 +51,11 @@ CREATE TABLE event_queue ( subdivision2 LowCardinality(String), city String, --pageview - url String, - referrer String, + url_path String, + url_query String, + referrer_path String, + referrer_query String, + referrer_domain String, page_title String, --event event_type UInt32, @@ -79,8 +85,11 @@ SELECT website_id, subdivision1, subdivision2, city, - url, - referrer, + url_path, + url_query, + referrer_path, + referrer_query, + referrer_domain, page_title, event_type, event_name, diff --git a/db/mysql/migrations/01_init/migration.sql b/db/mysql/migrations/01_init/migration.sql index a083d03a..eacbc38d 100644 --- a/db/mysql/migrations/01_init/migration.sql +++ b/db/mysql/migrations/01_init/migration.sql @@ -61,8 +61,11 @@ CREATE TABLE `website_event` ( `website_id` VARCHAR(36) NOT NULL, `session_id` VARCHAR(36) NOT NULL, `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), - `url` VARCHAR(500) NOT NULL, - `referrer` VARCHAR(500) NULL, + `url_path` VARCHAR(500) NOT NULL, + `url_query` VARCHAR(500) NULL, + `referrer_path` VARCHAR(500) NULL, + `referrer_query` VARCHAR(500) NULL, + `referrer_domain` VARCHAR(500) NULL, `page_title` VARCHAR(500) NULL, `event_type` INTEGER UNSIGNED NOT NULL DEFAULT 1, `event_name` VARCHAR(50) NULL, @@ -79,14 +82,12 @@ CREATE TABLE `website_event` ( CREATE TABLE `team` ( `team_id` VARCHAR(36) NOT NULL, `name` VARCHAR(50) NOT NULL, - `user_id` VARCHAR(36) NOT NULL, `access_code` VARCHAR(50) NULL, `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), `updated_at` TIMESTAMP(0) NULL, UNIQUE INDEX `team_team_id_key`(`team_id`), UNIQUE INDEX `team_access_code_key`(`access_code`), - INDEX `team_user_id_idx`(`user_id`), INDEX `team_access_code_idx`(`access_code`), PRIMARY KEY (`team_id`) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; @@ -110,13 +111,11 @@ CREATE TABLE `team_user` ( CREATE TABLE `team_website` ( `team_website_id` VARCHAR(36) NOT NULL, `team_id` VARCHAR(36) NOT NULL, - `user_id` VARCHAR(36) NOT NULL, `website_id` VARCHAR(36) NOT NULL, `created_at` TIMESTAMP(0) NULL DEFAULT CURRENT_TIMESTAMP(0), UNIQUE INDEX `team_website_team_website_id_key`(`team_website_id`), INDEX `team_website_team_id_idx`(`team_id`), - INDEX `team_website_user_id_idx`(`user_id`), INDEX `team_website_website_id_idx`(`website_id`), PRIMARY KEY (`team_website_id`) ) DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; diff --git a/db/mysql/schema.prisma b/db/mysql/schema.prisma index a47ff428..1f182716 100644 --- a/db/mysql/schema.prisma +++ b/db/mysql/schema.prisma @@ -19,7 +19,6 @@ model User { teamUser TeamUser[] Website Website[] - teamWebsite TeamWebsite[] @@map("user") } @@ -65,15 +64,18 @@ model Website { } 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) - createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) - url String @db.VarChar(500) - referrer String? @db.VarChar(500) - pageTitle String? @map("page_title") @db.VarChar(500) - eventType Int @default(1) @map("event_type") @db.UnsignedInt - eventName String? @map("event_name") @db.VarChar(50) + 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) + 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) + 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) + eventType Int @default(1) @map("event_type") @db.UnsignedInt + eventName String? @map("event_name") @db.VarChar(50) @@index([createdAt]) @@index([sessionId]) @@ -86,7 +88,6 @@ model WebsiteEvent { model Team { id String @id() @unique() @map("team_id") @db.VarChar(36) name String @db.VarChar(50) - userId String @map("user_id") @db.VarChar(36) accessCode String? @unique @map("access_code") @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) updatedAt DateTime? @map("updated_at") @db.Timestamp(0) @@ -94,7 +95,6 @@ model Team { teamUsers TeamUser[] teamWebsite TeamWebsite[] - @@index([userId]) @@index([accessCode]) @@map("team") } @@ -118,16 +118,13 @@ model TeamUser { model TeamWebsite { id String @id() @unique() @map("team_website_id") @db.VarChar(36) teamId String @map("team_id") @db.VarChar(36) - userId String @map("user_id") @db.VarChar(36) websiteId String @map("website_id") @db.VarChar(36) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) team Team @relation(fields: [teamId], references: [id]) - user User @relation(fields: [userId], references: [id]) website Website @relation(fields: [websiteId], references: [id]) @@index([teamId]) - @@index([userId]) @@index([websiteId]) @@map("team_website") } diff --git a/db/postgresql/migrations/07_remove_user_id/migration.sql b/db/postgresql/migrations/07_remove_user_id/migration.sql index 63122f49..ff92f545 100644 --- a/db/postgresql/migrations/07_remove_user_id/migration.sql +++ b/db/postgresql/migrations/07_remove_user_id/migration.sql @@ -15,5 +15,4 @@ DROP INDEX "team_website_user_id_idx"; ALTER TABLE "team" DROP COLUMN "user_id"; -- AlterTable -ALTER TABLE "team_website" DROP COLUMN "user_id", -ADD COLUMN "userId" UUID; +ALTER TABLE "team_website" DROP COLUMN "user_id"; \ No newline at end of file diff --git a/db/postgresql/migrations/08_split_url_referrer/migration.sql b/db/postgresql/migrations/08_split_url_referrer/migration.sql new file mode 100644 index 00000000..7129d87a --- /dev/null +++ b/db/postgresql/migrations/08_split_url_referrer/migration.sql @@ -0,0 +1,16 @@ +/* + Warnings: + + - You are about to drop the column `referrer` on the `website_event` table. All the data in the column will be lost. + - You are about to drop the column `url` on the `website_event` table. All the data in the column will be lost. + - Added the required column `url_path` to the `website_event` table without a default value. This is not possible if the table is not empty. + +*/ +-- AlterTable +ALTER TABLE "website_event" DROP COLUMN "referrer", +DROP COLUMN "url", +ADD COLUMN "referrer_domain" VARCHAR(500), +ADD COLUMN "referrer_path" VARCHAR(500), +ADD COLUMN "referrer_query" VARCHAR(500), +ADD COLUMN "url_path" VARCHAR(500) NOT NULL, +ADD COLUMN "url_query" VARCHAR(500); diff --git a/db/postgresql/schema.prisma b/db/postgresql/schema.prisma index be3be8f1..82b22c64 100644 --- a/db/postgresql/schema.prisma +++ b/db/postgresql/schema.prisma @@ -64,15 +64,18 @@ model Website { } model WebsiteEvent { - id String @id() @map("event_id") @db.Uuid - websiteId String @map("website_id") @db.Uuid - sessionId String @map("session_id") @db.Uuid - createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) - url String @db.VarChar(500) - referrer String? @db.VarChar(500) - pageTitle String? @map("page_title") @db.VarChar(500) - eventType Int @default(1) @map("event_type") @db.Integer - eventName String? @map("event_name") @db.VarChar(50) + id String @id() @map("event_id") @db.Uuid + websiteId String @map("website_id") @db.Uuid + sessionId String @map("session_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) + 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) + eventType Int @default(1) @map("event_type") @db.Integer + eventName String? @map("event_name") @db.VarChar(50) @@index([createdAt]) @@index([sessionId]) diff --git a/lib/clickhouse.ts b/lib/clickhouse.ts index a3030eeb..073a92e7 100644 --- a/lib/clickhouse.ts +++ b/lib/clickhouse.ts @@ -74,6 +74,9 @@ function getFilterQuery(filters = {}, params = {}) { switch (key) { case 'url': + arr.push(`and url_path = {${key}:String}`); + params[key] = filter; + break; case 'pageTitle': case 'os': case 'browser': @@ -92,18 +95,20 @@ function getFilterQuery(filters = {}, params = {}) { break; case 'referrer': - arr.push(`and referrer ILIKE {${key}:String}`); - params[key] = `%${filter}`; + arr.push(`and referrer_domain= {${key}:String}`); + params[key] = filter; break; case 'domain': - arr.push(`and referrer NOT ILIKE {${key}:String}`); - arr.push(`and referrer NOT ILIKE '/%'`); + arr.push(`and referrer_domain NOT ILIKE {${key}:String}`); + arr.push(`and referrer_domain NOT ILIKE '/%'`); params[key] = `%://${filter}/%`; break; case 'query': - arr.push(`and url like '%?%'`); + arr.push(`and url_query= {${key}:String}`); + params[key] = filter; + break; } return arr; diff --git a/lib/detect.js b/lib/detect.js index d8294f05..e5bdd733 100644 --- a/lib/detect.js +++ b/lib/detect.js @@ -79,10 +79,10 @@ export async function getClientInfo(req, { screen }) { const userAgent = req.headers['user-agent']; const ip = getIpAddress(req); const location = await getLocation(ip); - const country = location.country; - const subdivision1 = location.subdivision1; - const subdivision2 = location.subdivision2; - const city = location.city; + const country = location?.country; + const subdivision1 = location?.subdivision1; + const subdivision2 = location?.subdivision2; + const city = location?.city; const browser = browserName(userAgent); const os = detectOS(userAgent); const device = getDevice(screen, browser, os); diff --git a/lib/prisma.ts b/lib/prisma.ts index 4461f044..20a5e4a6 100644 --- a/lib/prisma.ts +++ b/lib/prisma.ts @@ -74,6 +74,9 @@ function getFilterQuery(filters = {}, params = []): string { switch (key) { case 'url': + arr.push(`and url_path=$${params.length + 1}`); + params.push(decodeURIComponent(filter)); + break; case 'os': case 'pageTitle': case 'browser': @@ -92,18 +95,20 @@ function getFilterQuery(filters = {}, params = []): string { break; case 'referrer': - arr.push(`and referrer like $${params.length + 1}`); - params.push(`%${decodeURIComponent(filter)}%`); + arr.push(`and referrer_domain=$${params.length + 1}`); + params.push(decodeURIComponent(filter)); break; case 'domain': - arr.push(`and referrer not like $${params.length + 1}`); - arr.push(`and referrer not like '/%'`); + arr.push(`and referrer_domain not like $${params.length + 1}`); + arr.push(`and referrer_domain not like '/%'`); params.push(`%://${filter}/%`); break; case 'query': - arr.push(`and url like '%?%'`); + arr.push(`and url_query=$${params.length + 1}`); + params.push(decodeURIComponent(filter)); + break; } return arr; diff --git a/pages/api/send.ts b/pages/api/send.ts index 04e62f07..86632bf3 100644 --- a/pages/api/send.ts +++ b/pages/api/send.ts @@ -34,9 +34,7 @@ export default async (req: NextApiRequestCollect, res: NextApiResponse) => { const { type, payload } = getJsonBody(req); - const { referrer, eventName, pageTitle } = payload; - let { url } = payload; - + const { url, referrer, eventName, pageTitle } = payload; const ignoreIps = process.env.IGNORE_IP; const ignoreHostnames = process.env.IGNORE_HOSTNAME; @@ -83,17 +81,41 @@ export default async (req: NextApiRequestCollect, res: NextApiResponse) => { const session = req.session; + let urlPath = url.split('?')[0]; + const urlQuery = url.split('?')[1]; + let referrerPath; + let referrerQuery; + let referrerDomain; + + try { + const newRef = new URL(referrer); + referrerPath = newRef.pathname; + referrerDomain = newRef.hostname; + referrerQuery = newRef.search.substring(1); + } catch { + referrerPath = referrer.split('?')[0]; + referrerQuery = referrer.split('?')[1]; + } + if (process.env.REMOVE_TRAILING_SLASH) { - url = url.replace(/\/$/, ''); + urlPath = urlPath.replace(/\/$/, ''); } if (type === 'pageview') { - await savePageView({ ...session, url, referrer, pageTitle }); + await savePageView({ + ...session, + urlPath, + urlQuery, + referrerPath, + referrerQuery, + referrerDomain, + pageTitle, + }); } else if (type === 'event') { await saveEvent({ ...session, - url, - referrer, + urlPath, + urlQuery, pageTitle, eventName, }); diff --git a/pages/api/websites/[id]/metrics.ts b/pages/api/websites/[id]/metrics.ts index c547daee..ad57790e 100644 --- a/pages/api/websites/[id]/metrics.ts +++ b/pages/api/websites/[id]/metrics.ts @@ -6,7 +6,17 @@ import { NextApiResponse } from 'next'; import { badRequest, methodNotAllowed, ok, unauthorized } from 'next-basics'; import { getPageviewMetrics, getSessionMetrics, getWebsite } from 'queries'; -const sessionColumns = ['browser', 'os', 'device', 'screen', 'country', 'language']; +const sessionColumns = [ + 'browser', + 'os', + 'device', + 'screen', + 'country', + 'language', + 'subdivision1', + 'subdivision2', + 'city', +]; const pageviewColumns = ['url', 'referrer', 'query', 'pageTitle']; function getTable(type) { @@ -26,12 +36,17 @@ function getTable(type) { } function getColumn(type) { - if (type === 'event') { - return 'event_name'; - } - if (type === 'query') { - return 'url'; + switch (type) { + case 'url': + return 'url_path'; + case 'referrer': + return 'referrer_domain'; + case 'event': + return 'event_name'; + case 'query': + return 'url_query'; } + return type; } diff --git a/queries/analytics/event/saveEvent.ts b/queries/analytics/event/saveEvent.ts index 60f5348f..73ecee27 100644 --- a/queries/analytics/event/saveEvent.ts +++ b/queries/analytics/event/saveEvent.ts @@ -8,8 +8,8 @@ import cache from 'lib/cache'; export async function saveEvent(args: { id: string; websiteId: string; - url: string; - referrer?: string; + urlPath: string; + urlQuery?: string; pageTitle?: string; eventName?: string; hostname?: string; @@ -32,20 +32,20 @@ export async function saveEvent(args: { async function relationalQuery(data: { id: string; websiteId: string; - url: string; - referrer?: string; + urlPath: string; + urlQuery?: string; pageTitle?: string; eventName?: string; }) { - const { websiteId, id: sessionId, url, eventName, referrer, pageTitle } = data; + const { websiteId, id: sessionId, urlPath, urlQuery, eventName, pageTitle } = data; return prisma.client.websiteEvent.create({ data: { id: uuid(), websiteId, sessionId, - url: url?.substring(0, URL_LENGTH), - referrer: referrer?.substring(0, URL_LENGTH), + urlPath: urlPath?.substring(0, URL_LENGTH), + urlQuery: urlQuery?.substring(0, URL_LENGTH), pageTitle: pageTitle, eventType: EVENT_TYPE.customEvent, eventName: eventName?.substring(0, EVENT_NAME_LENGTH), @@ -56,8 +56,8 @@ async function relationalQuery(data: { async function clickhouseQuery(data: { id: string; websiteId: string; - url: string; - referrer?: string; + urlPath: string; + urlQuery?: string; pageTitle?: string; eventName?: string; hostname?: string; @@ -74,7 +74,8 @@ async function clickhouseQuery(data: { const { websiteId, id: sessionId, - url, + urlPath, + urlQuery, pageTitle, eventName, country, @@ -94,7 +95,8 @@ async function clickhouseQuery(data: { subdivision1: subdivision1 ? subdivision1 : null, subdivision2: subdivision2 ? subdivision2 : null, city: city ? city : null, - url: url?.substring(0, URL_LENGTH), + urlPath: urlPath?.substring(0, URL_LENGTH), + urlQuery: urlQuery?.substring(0, URL_LENGTH), page_title: pageTitle, event_type: EVENT_TYPE.customEvent, event_name: eventName?.substring(0, EVENT_NAME_LENGTH), diff --git a/queries/analytics/pageview/savePageView.ts b/queries/analytics/pageview/savePageView.ts index 24f45b5e..9a2a9c9e 100644 --- a/queries/analytics/pageview/savePageView.ts +++ b/queries/analytics/pageview/savePageView.ts @@ -8,8 +8,11 @@ import { uuid } from 'lib/crypto'; export async function savePageView(args: { id: string; websiteId: string; - url: string; - referrer?: string; + urlPath: string; + urlQuery?: string; + referrerPath?: string; + referrerQuery?: string; + referrerDomain?: string; pageTitle?: string; hostname?: string; browser?: string; @@ -31,19 +34,34 @@ export async function savePageView(args: { async function relationalQuery(data: { id: string; websiteId: string; - url: string; - referrer?: string; + urlPath: string; + urlQuery?: string; + referrerPath?: string; + referrerQuery?: string; + referrerDomain?: string; pageTitle?: string; }) { - const { websiteId, id: sessionId, url, referrer, pageTitle } = data; + const { + websiteId, + id: sessionId, + urlPath, + urlQuery, + referrerPath, + referrerQuery, + referrerDomain, + pageTitle, + } = data; return prisma.client.websiteEvent.create({ data: { id: uuid(), websiteId, sessionId, - url: url?.substring(0, URL_LENGTH), - referrer: referrer?.substring(0, URL_LENGTH), + urlPath: urlPath?.substring(0, URL_LENGTH), + urlQuery: urlQuery?.substring(0, URL_LENGTH), + referrerPath: referrerPath?.substring(0, URL_LENGTH), + referrerQuery: referrerQuery?.substring(0, URL_LENGTH), + referrerDomain: referrerDomain?.substring(0, URL_LENGTH), pageTitle: pageTitle, eventType: EVENT_TYPE.pageView, }, @@ -53,8 +71,11 @@ async function relationalQuery(data: { async function clickhouseQuery(data: { id: string; websiteId: string; - url: string; - referrer?: string; + urlPath: string; + urlQuery?: string; + referrerPath?: string; + referrerQuery?: string; + referrerDomain?: string; pageTitle?: string; hostname?: string; browser?: string; @@ -70,8 +91,11 @@ async function clickhouseQuery(data: { const { websiteId, id: sessionId, - url, - referrer, + urlPath, + urlQuery, + referrerPath, + referrerQuery, + referrerDomain, pageTitle, country, subdivision1, @@ -90,8 +114,11 @@ async function clickhouseQuery(data: { subdivision1: subdivision1 ? subdivision1 : null, subdivision2: subdivision2 ? subdivision2 : null, city: city ? city : null, - url: url?.substring(0, URL_LENGTH), - referrer: referrer?.substring(0, URL_LENGTH), + urlPath: urlPath?.substring(0, URL_LENGTH), + urlQuery: urlQuery?.substring(0, URL_LENGTH), + referrerPath: referrerPath?.substring(0, URL_LENGTH), + referrerQuery: referrerQuery?.substring(0, URL_LENGTH), + referrerDomain: referrerDomain?.substring(0, URL_LENGTH), page_title: pageTitle, event_type: EVENT_TYPE.pageView, created_at: getDateFormat(new Date()),