Skip to content

Commit

Permalink
refactor(stats): sql functions in link statistics repo
Browse files Browse the repository at this point in the history
  • Loading branch information
kylerwsm committed Jul 8, 2020
1 parent 97bfdd1 commit da57108
Show file tree
Hide file tree
Showing 3 changed files with 52 additions and 58 deletions.
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
import { QueryTypes } from 'sequelize'

import { sequelize } from '../../util/sequelize'
import { updateLinkStatistics } from './updateLinkStatistics'
import { sequelize } from '../util/sequelize'
import { updateLinkStatistics } from '../repositories/LinkStatisticsRepository'

/**
* Syncs database functions.
Expand Down
56 changes: 0 additions & 56 deletions src/server/models/functions/updateLinkStatistics.ts

This file was deleted.

50 changes: 50 additions & 0 deletions src/server/repositories/LinkStatisticsRepository.ts
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,56 @@ import { getLocalDayGroup } from '../util/time'
import { sequelize } from '../util/sequelize'
import { DeviceType } from '../services/interfaces/DeviceCheckServiceInterface'

// Get the relevant table names from their models.
const urlTable = Url.getTableName()
const devicesTable = Devices.getTableName()
const clicksTable = Clicks.getTableName()
const weekdayTable = WeekdayClicks.getTableName()

/**
* This function is used to update the relevant link statistics tables, when called.
*/
export const updateLinkStatistics = `CREATE OR REPLACE FUNCTION update_link_statistics (inputShortUrl text, device text)
RETURNS void AS $$
BEGIN
-- Update total clicks.
UPDATE "${urlTable}" SET "clicks" = "${urlTable}"."clicks" + 1
WHERE "shortUrl" = inputShortUrl;
-- Update devices clicks.
IF device='mobile' THEN
INSERT INTO "${devicesTable}" ("shortUrl", "mobile", "tablet", "desktop", "others", "createdAt", "updatedAt")
VALUES (inputShortUrl, 1, 0, 0, 0, current_timestamp, current_timestamp)
ON CONFLICT ("shortUrl")
DO UPDATE SET "mobile" = "${devicesTable}"."mobile" + 1;
ELSIF device='tablet' THEN
INSERT INTO "${devicesTable}" ("shortUrl", "mobile", "tablet", "desktop", "others", "createdAt", "updatedAt")
VALUES (inputShortUrl, 0, 1, 0, 0, current_timestamp, current_timestamp)
ON CONFLICT ("shortUrl")
DO UPDATE SET "tablet" = "${devicesTable}"."tablet" + 1;
ELSIF device='desktop' THEN
INSERT INTO "${devicesTable}" ("shortUrl", "mobile", "tablet", "desktop", "others", "createdAt", "updatedAt")
VALUES (inputShortUrl, 0, 0, 1, 0, current_timestamp, current_timestamp)
ON CONFLICT ("shortUrl")
DO UPDATE SET "desktop" = "${devicesTable}"."desktop" + 1;
ELSIF device='others' THEN
INSERT INTO "${devicesTable}" ("shortUrl", "mobile", "tablet", "desktop", "others", "createdAt", "updatedAt")
VALUES (inputShortUrl, 0, 0, 0, 1, current_timestamp, current_timestamp)
ON CONFLICT ("shortUrl")
DO UPDATE SET "others" = "${devicesTable}"."others" + 1;
END IF;
-- Update daily clicks.
INSERT INTO "${clicksTable}" ("shortUrl", "date", "clicks", "createdAt", "updatedAt")
VALUES (inputShortUrl, current_timestamp::date, 1, current_timestamp, current_timestamp)
ON CONFLICT ("shortUrl", "date")
DO UPDATE SET "clicks" = "${clicksTable}"."clicks" + 1;
-- Update weekday clicks.
INSERT INTO "${weekdayTable}" ("shortUrl", "weekday", "hours", "clicks", "createdAt", "updatedAt")
VALUES (inputShortUrl, extract(dow from current_timestamp), extract(hour from current_timestamp), 1, current_timestamp, current_timestamp)
ON CONFLICT ("shortUrl", "weekday", "hours")
DO UPDATE SET "clicks" = "${weekdayTable}"."clicks" + 1;
END; $$ LANGUAGE plpgsql;
`

export type UrlStats = UrlType & {
DeviceClicks?: DevicesType
DailyClicks: ClicksType[]
Expand Down

0 comments on commit da57108

Please sign in to comment.