From 07cc61f5c3021461c4466df616e2285ead78c473 Mon Sep 17 00:00:00 2001 From: Mike Cao Date: Sat, 29 Aug 2020 23:17:32 -0700 Subject: [PATCH] Fixed date parsing in database queries. --- lib/date.js | 9 +++++++-- lib/queries.js | 43 ++++++++++++++++++++++++++++++------------- package.json | 2 +- 3 files changed, 38 insertions(+), 16 deletions(-) diff --git a/lib/date.js b/lib/date.js index 6e10f610..07a32654 100644 --- a/lib/date.js +++ b/lib/date.js @@ -95,17 +95,22 @@ export function getDateArray(data, startDate, endDate, unit) { const arr = []; const [diff, add, normalize] = dateFuncs[unit]; const n = diff(endDate, startDate) + 1; + console.log({ startDate, endDate, n }); function findData(t) { const x = data.find(e => { - return getLocalTime(new Date(e.t)).getTime() === normalize(new Date(t)).getTime(); + if (unit === 'day') { + const [year, month, day] = e.t.split('-'); + return normalize(new Date(year, month - 1, day)).getTime() === t.getTime(); + } + return normalize(new Date(e.t)).getTime() === t.getTime(); }); return x?.y || 0; } for (let i = 0; i < n; i++) { - const t = add(startDate, i); + const t = normalize(add(startDate, i)); const y = findData(t); arr.push({ ...data[i], t, y }); diff --git a/lib/queries.js b/lib/queries.js index 0b8dde89..4faad484 100644 --- a/lib/queries.js +++ b/lib/queries.js @@ -5,7 +5,7 @@ import { subMinutes } from 'date-fns'; const POSTGRESQL = 'postgresql'; const MYSQL = 'mysql'; -const DATE_FORMATS = { +const MYSQL_DATE_FORMATS = { minute: '%Y-%m-%d %H:%i:00', hour: '%Y-%m-%d %H:00:00', day: '%Y-%m-%d', @@ -13,18 +13,35 @@ const DATE_FORMATS = { year: '%Y-01-01', }; +const POSTGRESQL_DATE_FORMATS = { + minute: 'YYYY-MM-DD HH24:MI:00', + hour: 'YYYY-MM-DD HH24:00:00', + day: 'YYYY-MM-DD', + month: 'YYYY-MM-01', + year: 'YYYY-01-01', +}; + export function getDatabase() { return process.env.DATABASE_TYPE || process.env.DATABASE_URL.split(':')[0]; } -export function getDateQuery(field, unit, timezone) { - if (timezone) { - const tz = moment.tz(timezone).format('Z'); - - return `DATE_FORMAT(convert_tz(${field},'+00:00','${tz}'), '${DATE_FORMATS[unit]}')`; +export function getDateQuery(db, field, unit, timezone) { + if (db === POSTGRESQL) { + if (timezone) { + return `to_char(date_trunc('${unit}', ${field} at time zone '${timezone}'), '${POSTGRESQL_DATE_FORMATS[unit]}')`; + } + return `to_char(date_trunc('${unit}', ${field}), '${POSTGRESQL_DATE_FORMATS[unit]}')`; } - return `DATE_FORMAT(${field}, '${DATE_FORMATS[unit]}')`; + if (db === MYSQL) { + if (timezone) { + const tz = moment.tz(timezone).format('Z'); + + return `DATE_FORMAT(convert_tz(${field},'+00:00','${tz}'), '${MYSQL_DATE_FORMATS[unit]}')`; + } + + return `DATE_FORMAT(${field}, '${MYSQL_DATE_FORMATS[unit]}')`; + } } export async function getWebsiteById(website_id) { @@ -258,7 +275,7 @@ export function getMetrics(website_id, start_at, end_at) { sum(t.time) as "totaltime" from ( select session_id, - date_trunc('hour', created_at), + ${getDateQuery(db, 'created_at', 'hour')}, count(*) c, floor(extract(epoch from max(created_at) - min(created_at))) as "time" from pageview @@ -282,7 +299,7 @@ export function getMetrics(website_id, start_at, end_at) { sum(t.time) as "totaltime" from ( select session_id, - ${getDateQuery('created_at', 'hour')}, + ${getDateQuery(db, 'created_at', 'hour')}, count(*) c, floor(unix_timestamp(max(created_at)) - unix_timestamp(min(created_at))) as "time" from pageview @@ -313,7 +330,7 @@ export function getPageviews( if (db === POSTGRESQL) { return prisma.$queryRaw( ` - select date_trunc('${unit}', created_at at time zone '${timezone}') t, + select ${getDateQuery(db, 'created_at', unit, timezone)} t, count(${count}) y from pageview where website_id=$1 @@ -330,7 +347,7 @@ export function getPageviews( if (db === MYSQL) { return prisma.$queryRaw( ` - select ${getDateQuery('created_at', unit, timezone)} t, + select ${getDateQuery(db, 'created_at', unit, timezone)} t, count(${count}) y from pageview where website_id=? @@ -430,7 +447,7 @@ export function getEvents(website_id, start_at, end_at, timezone = 'utc', unit = ` select event_value x, - date_trunc('${unit}', created_at at time zone '${timezone}') t, + ${getDateQuery(db, 'created_at', unit, timezone)} t, count(*) y from event where website_id=$1 @@ -449,7 +466,7 @@ export function getEvents(website_id, start_at, end_at, timezone = 'utc', unit = ` select event_value x, - ${getDateQuery('created_at', unit, timezone)} t, + ${getDateQuery(db, 'created_at', unit, timezone)} t, count(*) y from event where website_id=? diff --git a/package.json b/package.json index 1e3add00..17b79794 100644 --- a/package.json +++ b/package.json @@ -1,6 +1,6 @@ { "name": "umami", - "version": "0.18.0", + "version": "0.19.0", "description": "A simple, fast, website analytics alternative to Google Analytics. ", "author": "Mike Cao ", "license": "MIT",