From 6de82cfd5e6773610ed2073af11f925f62180d90 Mon Sep 17 00:00:00 2001 From: emma Date: Thu, 4 May 2023 15:10:49 -0400 Subject: [PATCH 1/6] attempt adding event data rows to output not trying to join yet, just poking around --- lib/types.ts | 2 ++ queries/analytics/event/getEventMetrics.ts | 6 ++++-- 2 files changed, 6 insertions(+), 2 deletions(-) diff --git a/lib/types.ts b/lib/types.ts index 37c1ffdc..4a154ed5 100644 --- a/lib/types.ts +++ b/lib/types.ts @@ -69,6 +69,7 @@ export interface WebsiteActive { export interface WebsiteMetric { x: string; y: number; + d?: unknown; } export interface WebsiteMetricFilter { @@ -90,6 +91,7 @@ export interface WebsiteEventMetric { x: string; t: string; y: number; + d?: unknown; } export interface WebsiteEventDataMetric { diff --git a/queries/analytics/event/getEventMetrics.ts b/queries/analytics/event/getEventMetrics.ts index 32c4c3d0..a630e7ed 100644 --- a/queries/analytics/event/getEventMetrics.ts +++ b/queries/analytics/event/getEventMetrics.ts @@ -54,6 +54,7 @@ async function relationalQuery( return rawQuery( `select event_name x, + event_data d, ${getDateQuery('created_at', unit, timezone)} t, count(*) y from website_event @@ -62,8 +63,8 @@ async function relationalQuery( and created_at between $3 and $4 and event_type = ${EVENT_TYPE.customEvent} ${filterQuery} - group by 1, 2 - order by 2`, + group by 1, 3 + order by 3`, params, ); } @@ -95,6 +96,7 @@ async function clickhouseQuery( return rawQuery( `select event_name x, + event_data d, ${getDateQuery('created_at', unit, timezone)} t, count(*) y from website_event From 53523ed3db849bff1f2319bc6468a700b078ebc1 Mon Sep 17 00:00:00 2001 From: emma Date: Sun, 7 May 2023 13:47:39 -0400 Subject: [PATCH 2/6] allow saving bool values into a separate bool field --- db/clickhouse/schema.sql | 1 + db/mysql/schema.prisma | 9 +++++---- db/postgresql/schema.prisma | 9 +++++---- queries/analytics/eventData/saveEventData.ts | 10 ++++------ 4 files changed, 15 insertions(+), 14 deletions(-) diff --git a/db/clickhouse/schema.sql b/db/clickhouse/schema.sql index 77176413..c6445318 100644 --- a/db/clickhouse/schema.sql +++ b/db/clickhouse/schema.sql @@ -104,6 +104,7 @@ CREATE TABLE umami.event_data event_string_value Nullable(String), event_numeric_value Nullable(Decimal64(4)), --922337203685477.5625 event_date_value Nullable(DateTime('UTC')), + event_bool_value Nullable(Boolean), event_data_type UInt32, created_at DateTime('UTC') ) diff --git a/db/mysql/schema.prisma b/db/mysql/schema.prisma index 6455c8c0..ca5d3de9 100644 --- a/db/mysql/schema.prisma +++ b/db/mysql/schema.prisma @@ -14,7 +14,7 @@ model User { password String @db.VarChar(60) role String @map("role") @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) - updatedAt DateTime? @map("updated_at") @updatedAt @db.Timestamp(0) + updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamp(0) deletedAt DateTime? @map("deleted_at") @db.Timestamp(0) website Website[] @@ -53,7 +53,7 @@ model Website { resetAt DateTime? @map("reset_at") @db.Timestamp(0) userId String? @map("user_id") @db.VarChar(36) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) - updatedAt DateTime? @map("updated_at") @updatedAt @db.Timestamp(0) + updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamp(0) deletedAt DateTime? @map("deleted_at") @db.Timestamp(0) user User? @relation(fields: [userId], references: [id]) @@ -99,6 +99,7 @@ model EventData { 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) + eventBoolValue Boolean? @map("event_bool_value") eventDataType Int @map("event_data_type") @db.UnsignedInt createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) @@ -117,7 +118,7 @@ model Team { name String @db.VarChar(50) accessCode String? @unique @map("access_code") @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) - updatedAt DateTime? @map("updated_at") @updatedAt @db.Timestamp(0) + updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamp(0) teamUser TeamUser[] teamWebsite TeamWebsite[] @@ -132,7 +133,7 @@ model TeamUser { userId String @map("user_id") @db.VarChar(36) role String @map("role") @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamp(0) - updatedAt DateTime? @map("updated_at") @updatedAt @db.Timestamp(0) + updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamp(0) team Team @relation(fields: [teamId], references: [id]) user User @relation(fields: [userId], references: [id]) diff --git a/db/postgresql/schema.prisma b/db/postgresql/schema.prisma index b336bce4..a50a4919 100644 --- a/db/postgresql/schema.prisma +++ b/db/postgresql/schema.prisma @@ -14,7 +14,7 @@ model User { password String @db.VarChar(60) role String @map("role") @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) - updatedAt DateTime? @map("updated_at") @updatedAt @db.Timestamptz(6) + updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamptz(6) deletedAt DateTime? @map("deleted_at") @db.Timestamptz(6) website Website[] @@ -53,7 +53,7 @@ model Website { resetAt DateTime? @map("reset_at") @db.Timestamptz(6) userId String? @map("user_id") @db.Uuid createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) - updatedAt DateTime? @map("updated_at") @updatedAt @db.Timestamptz(6) + updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamptz(6) deletedAt DateTime? @map("deleted_at") @db.Timestamptz(6) user User? @relation(fields: [userId], references: [id]) @@ -99,6 +99,7 @@ model EventData { 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) + eventBoolValue Boolean? @map("event_bool_value") @db.Boolean eventDataType Int @map("event_data_type") @db.Integer createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) @@ -116,7 +117,7 @@ model Team { name String @db.VarChar(50) accessCode String? @unique @map("access_code") @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) - updatedAt DateTime? @map("updated_at") @updatedAt @db.Timestamptz(6) + updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamptz(6) teamUser TeamUser[] teamWebsite TeamWebsite[] @@ -131,7 +132,7 @@ model TeamUser { userId String @map("user_id") @db.Uuid role String @map("role") @db.VarChar(50) createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6) - updatedAt DateTime? @map("updated_at") @updatedAt @db.Timestamptz(6) + updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamptz(6) team Team @relation(fields: [teamId], references: [id]) user User @relation(fields: [userId], references: [id]) diff --git a/queries/analytics/eventData/saveEventData.ts b/queries/analytics/eventData/saveEventData.ts index 90e63565..43168be7 100644 --- a/queries/analytics/eventData/saveEventData.ts +++ b/queries/analytics/eventData/saveEventData.ts @@ -38,13 +38,12 @@ async function relationalQuery(data: { websiteId, eventKey: a.key, eventStringValue: - a.eventDataType === EVENT_DATA_TYPE.string || - a.eventDataType === EVENT_DATA_TYPE.boolean || - a.eventDataType === EVENT_DATA_TYPE.array + a.eventDataType === EVENT_DATA_TYPE.string || a.eventDataType === EVENT_DATA_TYPE.array ? a.value : null, eventNumericValue: a.eventDataType === EVENT_DATA_TYPE.number ? a.value : null, eventDateValue: a.eventDataType === EVENT_DATA_TYPE.date ? new Date(a.value) : null, + eventBoolValue: a.eventDataType === EVENT_DATA_TYPE.boolean ? a.value : null, eventDataType: a.eventDataType, })); @@ -76,13 +75,12 @@ async function clickhouseQuery(data: { event_name: eventName, event_key: a.key, event_string_value: - a.eventDataType === EVENT_DATA_TYPE.string || - a.eventDataType === EVENT_DATA_TYPE.boolean || - a.eventDataType === EVENT_DATA_TYPE.array + a.eventDataType === EVENT_DATA_TYPE.string || a.eventDataType === EVENT_DATA_TYPE.array ? a.value : null, event_numeric_value: a.eventDataType === EVENT_DATA_TYPE.number ? a.value : null, event_date_value: a.eventDataType === EVENT_DATA_TYPE.date ? getDateFormat(a.value) : null, + event_bool_value: a.eventDataType === EVENT_DATA_TYPE.boolean ? a.value : null, event_data_type: a.eventDataType, created_at: createdAt, })); From c1eaa5507093e43155e9c65e412f0bd4099672f0 Mon Sep 17 00:00:00 2001 From: emma Date: Sun, 7 May 2023 13:56:19 -0400 Subject: [PATCH 3/6] update event metrics to return event data grouped by event data --- queries/analytics/event/getEventMetrics.ts | 68 +++++++++++++++++----- 1 file changed, 53 insertions(+), 15 deletions(-) diff --git a/queries/analytics/event/getEventMetrics.ts b/queries/analytics/event/getEventMetrics.ts index a630e7ed..bd97d85e 100644 --- a/queries/analytics/event/getEventMetrics.ts +++ b/queries/analytics/event/getEventMetrics.ts @@ -52,18 +52,37 @@ async function relationalQuery( const filterQuery = getFilterQuery(filters, params); return rawQuery( - `select - event_name x, - event_data d, - ${getDateQuery('created_at', unit, timezone)} t, + `with event_data as ( + select d.website_event_id, + jsonb_object_agg( + d.event_key, + case + d.event_data_type + when 1 then to_jsonb(d.event_string_value) -- string + when 2 then to_jsonb(d.event_numeric_value) -- number + when 3 then to_jsonb(d.event_bool_value) -- boolean + when 4 then to_jsonb(d.event_date_value) -- date + when 5 then d.event_string_value::jsonb -- array + end + ) filter ( + where d.event_key is not null + ) as event_data + from event_data d + group by d.website_event_id + ) + select + w.event_name x, + e.event_data d, + ${getDateQuery('w.created_at', unit, timezone)} t, count(*) y - from website_event + from website_event w + left join event_data d on w.event_id = d.website_event_id where website_id = $1${toUuid()} and created_at >= $2 and created_at between $3 and $4 and event_type = ${EVENT_TYPE.customEvent} ${filterQuery} - group by 1, 3 + group by 1, 2, 3 order by 3`, params, ); @@ -94,18 +113,37 @@ async function clickhouseQuery( const params = { websiteId }; return rawQuery( - `select - event_name x, - event_data d, - ${getDateQuery('created_at', unit, timezone)} t, + `with event_data as ( + select d.website_event_id, + jsonb_object_agg( + d.event_key, + case + d.event_data_type + when 1 then to_jsonb(d.event_string_value) -- string + when 2 then to_jsonb(d.event_numeric_value) -- number + when 3 then to_jsonb(d.event_bool_value) -- boolean + when 4 then to_jsonb(d.event_date_value) -- date + when 5 then d.event_string_value::jsonb -- array + end + ) filter ( + where d.event_key is not null + ) as event_data + from event_data d + group by d.website_event_id + ) + select + w.event_name x, + d.event_data d, + ${getDateQuery('w.created_at', unit, timezone)} t, count(*) y - from website_event + from website_event w + left join event_data d on w.event_id = d.website_event_id where website_id = {websiteId:UUID} - and event_type = ${EVENT_TYPE.customEvent} - and created_at >= ${getDateFormat(resetDate)} - and ${getBetweenDates('created_at', startDate, endDate)} + and w.event_type = ${EVENT_TYPE.customEvent} + and w.created_at >= ${getDateFormat(resetDate)} + and ${getBetweenDates('w.created_at', startDate, endDate)} ${getFilterQuery(filters, params)} - group by x, t + group by x, d, t order by t`, params, ); From 288b9db8ad5cf30133848d7a7345ee950a69e8e1 Mon Sep 17 00:00:00 2001 From: emma Date: Sun, 7 May 2023 14:15:20 -0400 Subject: [PATCH 4/6] add migrations for adding bool column --- .../20230507181402_add_event_bool_field/migration.sql | 2 ++ .../20230507180839_add_event_bool_field/migration.sql | 2 ++ 2 files changed, 4 insertions(+) create mode 100644 db/mysql/migrations/20230507181402_add_event_bool_field/migration.sql create mode 100644 db/postgresql/migrations/20230507180839_add_event_bool_field/migration.sql diff --git a/db/mysql/migrations/20230507181402_add_event_bool_field/migration.sql b/db/mysql/migrations/20230507181402_add_event_bool_field/migration.sql new file mode 100644 index 00000000..4828bc41 --- /dev/null +++ b/db/mysql/migrations/20230507181402_add_event_bool_field/migration.sql @@ -0,0 +1,2 @@ +-- AlterTable +ALTER TABLE `event_data` ADD COLUMN `event_bool_value` BOOLEAN NULL; diff --git a/db/postgresql/migrations/20230507180839_add_event_bool_field/migration.sql b/db/postgresql/migrations/20230507180839_add_event_bool_field/migration.sql new file mode 100644 index 00000000..f85441d5 --- /dev/null +++ b/db/postgresql/migrations/20230507180839_add_event_bool_field/migration.sql @@ -0,0 +1,2 @@ +-- AlterTable +ALTER TABLE "event_data" ADD COLUMN "event_bool_value" BOOLEAN; From f12f4f5697a5154fd23755deb048447b7f70cebe Mon Sep 17 00:00:00 2001 From: emma Date: Sun, 7 May 2023 14:18:24 -0400 Subject: [PATCH 5/6] fix typo in query --- queries/analytics/event/getEventMetrics.ts | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/queries/analytics/event/getEventMetrics.ts b/queries/analytics/event/getEventMetrics.ts index bd97d85e..b4544905 100644 --- a/queries/analytics/event/getEventMetrics.ts +++ b/queries/analytics/event/getEventMetrics.ts @@ -72,7 +72,7 @@ async function relationalQuery( ) select w.event_name x, - e.event_data d, + d.event_data d, ${getDateQuery('w.created_at', unit, timezone)} t, count(*) y from website_event w From 334297f194178778f1d833e475758a32cc7f8370 Mon Sep 17 00:00:00 2001 From: emma Date: Sun, 7 May 2023 14:56:39 -0400 Subject: [PATCH 6/6] attempt fetching custom event data for data table --- components/metrics/MetricsTable.js | 9 ++++-- pages/api/websites/[id]/metrics.ts | 29 ++++++++++++++++-- .../analytics/pageview/getPageviewMetrics.ts | 2 +- umami-pr-1.session copy.sql | 2 ++ umami-pr-1.session.sql | 30 +++++++++++++++++++ 5 files changed, 67 insertions(+), 5 deletions(-) create mode 100644 umami-pr-1.session copy.sql create mode 100644 umami-pr-1.session.sql diff --git a/components/metrics/MetricsTable.js b/components/metrics/MetricsTable.js index 97deb39d..3b9c6ca8 100644 --- a/components/metrics/MetricsTable.js +++ b/components/metrics/MetricsTable.js @@ -6,6 +6,7 @@ import classNames from 'classnames'; import useApi from 'hooks/useApi'; import { percentFilter } from 'lib/filters'; import useDateRange from 'hooks/useDateRange'; +import useTimezone from 'hooks/useTimezone'; import usePageQuery from 'hooks/usePageQuery'; import ErrorMessage from 'components/common/ErrorMessage'; import DataTable from './DataTable'; @@ -26,7 +27,8 @@ export function MetricsTable({ delay = null, ...props }) { - const [{ startDate, endDate, modified }] = useDateRange(websiteId); + const [{ startDate, endDate, modified, unit }] = useDateRange(websiteId); + const [timezone] = useTimezone(); const { resolveUrl, router, @@ -53,6 +55,9 @@ export function MetricsTable({ country, region, city, + unit, + timezone, + includeEventData: type === 'event', }), { onSuccess: onDataLoad, retryDelay: delay || DEFAULT_ANIMATION_DURATION }, ); @@ -69,7 +74,7 @@ export function MetricsTable({ return items.sort(firstBy('y', -1).thenBy('x')); } return []; - }, [data, error, dataFilter, filterOptions]); + }, [data, dataFilter, filterOptions, limit]); const { dir } = useLocale(); return ( diff --git a/pages/api/websites/[id]/metrics.ts b/pages/api/websites/[id]/metrics.ts index 5cf818a0..98d03314 100644 --- a/pages/api/websites/[id]/metrics.ts +++ b/pages/api/websites/[id]/metrics.ts @@ -1,10 +1,12 @@ import { NextApiResponse } from 'next'; -import { methodNotAllowed, ok, unauthorized } from 'next-basics'; +import { methodNotAllowed, ok, unauthorized, badRequest } from 'next-basics'; import { WebsiteMetric, NextApiRequestQueryBody } from 'lib/types'; import { canViewWebsite } from 'lib/auth'; import { useAuth, useCors } from 'lib/middleware'; import { SESSION_COLUMNS, EVENT_COLUMNS, FILTER_COLUMNS } from 'lib/constants'; -import { getPageviewMetrics, getSessionMetrics } from 'queries'; +import { getEventMetrics, getPageviewMetrics, getSessionMetrics } from 'queries'; +import moment from 'moment-timezone'; +const unitTypes = ['year', 'month', 'hour', 'day']; export interface WebsiteMetricsRequestQuery { id: string; @@ -47,6 +49,9 @@ export default async ( country, region, city, + includeEventData, + timezone, + unit, } = req.query; if (req.method === 'GET') { @@ -54,6 +59,15 @@ export default async ( return unauthorized(res); } + if ( + typeof timezone !== 'string' || + typeof unit !== 'string' || + !moment.tz.zone(String(timezone)) || + !unitTypes.includes(String(unit)) + ) { + return badRequest(res); + } + const startDate = new Date(+startAt); const endDate = new Date(+endAt); @@ -114,6 +128,17 @@ export default async ( filters[type] = undefined; + if (type === 'event' && includeEventData) { + const data = await getEventMetrics(websiteId, { + startDate, + endDate, + timezone, + unit, + filters: { url: filters.url, eventName: undefined }, + }); + + return ok(res, data); + } const data = await getPageviewMetrics(websiteId, { startDate, endDate, diff --git a/queries/analytics/pageview/getPageviewMetrics.ts b/queries/analytics/pageview/getPageviewMetrics.ts index db82720d..c95c5ecd 100644 --- a/queries/analytics/pageview/getPageviewMetrics.ts +++ b/queries/analytics/pageview/getPageviewMetrics.ts @@ -102,7 +102,7 @@ async function clickhouseQuery( where website_id = {websiteId:UUID} and event_type = {eventType:UInt32} and created_at >= ${getDateFormat(resetDate)} - and ${getBetweenDates('created_at', startDate, endDate)} + and ${getBetweenDates('created_at', startDate, endDate)} ${excludeDomain} ${filterQuery} group by x diff --git a/umami-pr-1.session copy.sql b/umami-pr-1.session copy.sql new file mode 100644 index 00000000..bd51082e --- /dev/null +++ b/umami-pr-1.session copy.sql @@ -0,0 +1,2 @@ +select * +from event_data -- WHERE event_data.website_event_id = '91bac2f4-4039-4b2a-a2ab-8c86f71ef95d' diff --git a/umami-pr-1.session.sql b/umami-pr-1.session.sql new file mode 100644 index 00000000..b76a456d --- /dev/null +++ b/umami-pr-1.session.sql @@ -0,0 +1,30 @@ +WITH event_data_query AS ( + SELECT d.website_event_id, + jsonb_object_agg( + d.event_key, + CASE + d.event_data_type + when 1 then to_jsonb(d.event_string_value) -- string + when 2 then to_jsonb(d.event_numeric_value) -- number + when 3 then to_jsonb(d.event_bool_value) -- boolean + when 4 then to_jsonb(d.event_date_value) -- date + when 5 then d.event_string_value::jsonb -- array + end + ) filter ( + where d.event_key is not null + ) as event_data + FROM event_data d + GROUP BY d.website_event_id +) +select e.event_name x, + to_char( + date_trunc('hour', e.created_at), + 'YYYY-MM-DD HH24:00:00' + ) c, + edq.event_data::jsonb->'data.target' t, + edq.event_data::jsonb->'data.release' r +from website_event e + LEFT JOIN event_data_query edq ON e.event_id = edq.website_event_id +where e.event_name = 'Outbound click' + or e.event_name = 'NewSong PRO click' +order by c desc