diff --git a/src/server/config.ts b/src/server/config.ts index 5080d9cb68..4553a9bdcb 100644 --- a/src/server/config.ts +++ b/src/server/config.ts @@ -388,6 +388,7 @@ export const BffEndpoints = { CMS_MAINTENANCE_NOTIFICATIONS: '/services/cms/maintenance-notifications', CACHE_OVERVIEW: '/status/cache', LOGIN_STATS: '/status/logins/:authMethod?', + LOGIN_RAW: '/status/logins/table', STATUS_HEALTH: '/status/health', STATUS_HEALTH2: '/bff/status/health', USER_DATA_OVERVIEW: '/status/user-data-overview', diff --git a/src/server/router-public.ts b/src/server/router-public.ts index 6eb20624f8..9721b409f8 100644 --- a/src/server/router-public.ts +++ b/src/server/router-public.ts @@ -20,7 +20,7 @@ import { } from './services'; import { getDatasetEndpointConfig } from './services/buurt/helpers'; import { fetchMaintenanceNotificationsActual } from './services/cms-maintenance-notifications'; -import { loginStats } from './services/visitors'; +import { loginStats, rawDataTable } from './services/visitors'; import { generateOverview } from './generate-user-data-overview'; export const router = express.Router(); @@ -150,6 +150,7 @@ if (process.env.BFF_LOGIN_COUNT_ADMIN_PW) { }, challenge: true, }); + router.get(BffEndpoints.LOGIN_RAW, auth, rawDataTable); router.get(BffEndpoints.LOGIN_STATS, auth, loginStats); // Currently this endpoint can only be used when running the application locally. diff --git a/src/server/services/db/config.ts b/src/server/services/db/config.ts new file mode 100644 index 0000000000..a5677c0d0c --- /dev/null +++ b/src/server/services/db/config.ts @@ -0,0 +1,8 @@ +import { IS_AP, IS_OT, IS_PRODUCTION } from '../../../universal/config'; + +export const IS_PG = IS_AP; +export const IS_VERBOSE = IS_OT; + +export const tableNameLoginCount = + process.env.BFF_LOGIN_COUNT_TABLE ?? + (IS_PRODUCTION ? 'prod_login_count' : 'acc_login_count'); diff --git a/src/server/services/db/db.ts b/src/server/services/db/db.ts index 0da8bcc18c..fc80f23a04 100644 --- a/src/server/services/db/db.ts +++ b/src/server/services/db/db.ts @@ -1,10 +1,10 @@ -import { IS_AP } from '../../../universal/config'; +import { IS_PG } from './config'; type DBAdapter = { - tableNameLoginCount: string; query: (query: string, values?: any[] | undefined) => Promise; queryGET: (query: string, values?: any[] | undefined) => Promise; + queryALL: (query: string, values?: any[] | undefined) => Promise; }; export const db: () => Promise = () => - IS_AP ? import('./postgres') : import('./sqlite3'); + IS_PG ? import('./postgres') : import('./sqlite3'); diff --git a/src/server/services/db/postgres.ts b/src/server/services/db/postgres.ts index 1c3853ff9b..ad3df11778 100644 --- a/src/server/services/db/postgres.ts +++ b/src/server/services/db/postgres.ts @@ -17,39 +17,6 @@ let isConnected = false; /** * To develop against a working database you should enable the Datapunt VPN and use the credentials for the connection in your env.local file. */ -export const tableNameLoginCount = - process.env.BFF_LOGIN_COUNT_TABLE ?? - (IS_PRODUCTION ? 'prod_login_count' : 'acc_login_count'); - -const createTableQuery = ` --- Sequence and defined type -CREATE SEQUENCE IF NOT EXISTS ${tableNameLoginCount}_id_seq; - --- Table Definition -CREATE TABLE IF NOT EXISTS "public"."${tableNameLoginCount}" ( - "id" int4 NOT NULL DEFAULT nextval('${tableNameLoginCount}_id_seq'::regclass), - "uid" varchar(100) NOT NULL, - "authMethod" varchar(100) NOT NULL, - "date_created" timestamp NOT NULL DEFAULT now(), - PRIMARY KEY ("id") -); -`; - -const alterTableQuery1 = ` - ALTER TABLE IF EXISTS "public"."${tableNameLoginCount}" - ADD IF NOT EXISTS "authMethod" VARCHAR(100); -`; - -if (IS_PRODUCTION) { - (function setupTable() { - pool.query(createTableQuery, (err, res) => { - console.log(err, res); - }); - pool.query(alterTableQuery1, (err, res) => { - console.log(err, res); - }); - })(); -} export async function query(queryString: string, values?: any[]) { let result = null; @@ -70,6 +37,11 @@ export async function queryGET(queryString: string, values?: any[]) { return result?.rows[0] ?? null; } +export async function queryALL(queryString: string, values?: any[]) { + const result = await query(queryString, values); + return result?.rows ?? []; +} + process.on('beforeExit', () => { pool.end(); }); diff --git a/src/server/services/db/sqlite3.ts b/src/server/services/db/sqlite3.ts index 92ef1d00de..529b9295be 100644 --- a/src/server/services/db/sqlite3.ts +++ b/src/server/services/db/sqlite3.ts @@ -1,5 +1,5 @@ import Database from 'better-sqlite3'; -import { IS_OT } from '../../../universal/config'; +import { IS_VERBOSE } from './config'; export const tableNameLoginCount = process.env.BFF_LOGIN_COUNT_TABLE ?? 'login_count'; @@ -7,7 +7,7 @@ export const tableNameLoginCount = const SQLITE3_DB_PATH_FILE = `${process.env.BFF_DB_FILE}`; const dbOptions: Database.Options = { - verbose: IS_OT ? console.log : undefined, + verbose: IS_VERBOSE ? console.log : undefined, }; const db = new Database(SQLITE3_DB_PATH_FILE, dbOptions); @@ -15,16 +15,6 @@ const db = new Database(SQLITE3_DB_PATH_FILE, dbOptions); // https://github.com/WiseLibs/better-sqlite3/blob/master/docs/performance.md db.pragma('journal_mode = WAL'); -// Create the table -db.exec(` -CREATE TABLE IF NOT EXISTS ${tableNameLoginCount} ( - "id" INTEGER PRIMARY KEY, - "uid" VARCHAR(100) NOT NULL, - "date_created" DATETIME NOT NULL DEFAULT (datetime(CURRENT_TIMESTAMP, 'localtime')), - "auth_method" VARCHAR(100) DEFAULT NULL -); -`); - export async function query( query: string, values?: any[] @@ -44,8 +34,22 @@ export async function queryGET( if (Array.isArray(values)) { return statement.get(...values); } - const rs = await statement.get(); - return rs; + return statement.get(); +} + +export async function queryALL( + query: string, + values?: any[] +): Promise { + const statement = db.prepare(query); + if (Array.isArray(values)) { + return statement.all(...values); + } + return statement.all(); +} + +export function execDB(query: string) { + return db.exec(query); } process.on('beforeExit', () => { diff --git a/src/server/services/visitors.ts b/src/server/services/visitors.ts index 9c0feba0fe..a777fea2ba 100644 --- a/src/server/services/visitors.ts +++ b/src/server/services/visitors.ts @@ -1,3 +1,4 @@ +import * as Sentry from '@sentry/node'; import crypto from 'crypto'; import { add, @@ -11,9 +12,11 @@ import { subQuarters, } from 'date-fns'; import { Request, Response } from 'express'; -import { IS_AP, IS_TAP } from '../../universal/config'; +import { IS_PRODUCTION, IS_TAP } from '../../universal/config'; import { defaultDateFormat } from '../../universal/helpers'; +import { IS_PG, tableNameLoginCount } from './db/config'; import { db } from './db/db'; +import { execDB } from './db/sqlite3'; /** * This service gives us the ability to count the exact amount of visitors that logged in into Mijn Amsterdam over start - end period. @@ -26,25 +29,68 @@ const queriesSQLITE = (tableNameLoginCount: string) => ({ countLogin: `INSERT INTO ${tableNameLoginCount} (uid, auth_method) VALUES (?, ?)`, totalLogins: `SELECT count(id) as count FROM ${tableNameLoginCount} WHERE DATE(date_created) BETWEEN ? AND ? AND auth_method = ?`, totalLoginsAll: `SELECT count(id) as count FROM ${tableNameLoginCount} WHERE DATE(date_created) BETWEEN ? AND ?`, - uniqueLogins: `SELECT uid, count(uid) FROM ${tableNameLoginCount} WHERE DATE((date_created) BETWEEN ? AND ? AND auth_method = ? GROUP BY uid`, - uniqueLoginsAll: `SELECT uid, count(uid) as count FROM ${tableNameLoginCount} WHERE DATE(date_created) BETWEEN ? AND ? GROUP BY uid`, + uniqueLogins: `SELECT count(distinct uid) as count FROM ${tableNameLoginCount} WHERE DATE(date_created) BETWEEN ? AND ? AND auth_method = ?`, + uniqueLoginsAll: `SELECT count(distinct uid) as count FROM ${tableNameLoginCount} WHERE DATE(date_created) BETWEEN ? AND ?`, dateMinAll: `SELECT min(date_created) as date_min FROM ${tableNameLoginCount}`, dateMaxAll: `SELECT max(date_created) as date_max FROM ${tableNameLoginCount}`, + rawOverview: `SELECT uid, count(uid) as count, auth_method FROM ${tableNameLoginCount} WHERE auth_method IS NOT null GROUP BY auth_method, uid ORDER BY auth_method ASC, count DESC, uid ASC`, }); const queriesPG = (tableNameLoginCount: string) => ({ countLogin: `INSERT INTO ${tableNameLoginCount} (uid, "authMethod") VALUES ($1, $2) RETURNING id`, - totalLogins: `SELECT count(id) FROM ${tableNameLoginCount} WHERE "authMethod"=$2 AND $1::daterange @> date_created::date`, // NOTE: can be another, faster query if we'd have millions of records - totalLoginsAll: `SELECT count(id) FROM ${tableNameLoginCount} WHERE $1::daterange @> date_created::date`, // NOTE: can be another, faster query if we'd have millions of records - uniqueLogins: `SELECT uid, count(uid) FROM ${tableNameLoginCount} WHERE "authMethod"=$2 AND $1::daterange @> date_created::date GROUP BY uid`, - uniqueLoginsAll: `SELECT uid, count(uid) FROM ${tableNameLoginCount} WHERE $1::daterange @> date_created::date GROUP BY uid`, + totalLogins: `SELECT count(id) FROM ${tableNameLoginCount} WHERE "authMethod"=$3 AND date_created >= $1::date AND date_created <= $2::date`, // NOTE: can be another, faster query if we'd have millions of records + totalLoginsAll: `SELECT count(id) FROM ${tableNameLoginCount} WHERE date_created >= $1::date AND date_created <= $2::date`, // NOTE: can be another, faster query if we'd have millions of records + uniqueLogins: `SELECT count(distinct uid) as count FROM ${tableNameLoginCount} WHERE "authMethod"=$3 AND date_created >= $1::date AND date_created <= $2::date`, + uniqueLoginsAll: `SELECT count(distinct uid) as count FROM ${tableNameLoginCount} WHERE date_created >= $1::date AND date_created <= $2::date`, dateMinAll: `SELECT min(date_created) as date_min FROM ${tableNameLoginCount}`, dateMaxAll: `SELECT max(date_created) as date_max FROM ${tableNameLoginCount}`, + rawOverview: `SELECT uid, count(uid) as count, "authMethod" FROM ${tableNameLoginCount} WHERE "authMethod" IS NOT null GROUP BY "authMethod", uid ORDER BY "authMethod" ASC, count DESC, uid ASC`, }); +async function setupTables() { + const { query } = await db(); + + if (IS_PRODUCTION) { + if (IS_PG) { + const createTableQuery = ` + -- Sequence and defined type + CREATE SEQUENCE IF NOT EXISTS ${tableNameLoginCount}_id_seq; + + -- Table Definition + CREATE TABLE IF NOT EXISTS "public"."${tableNameLoginCount}" ( + "id" int4 NOT NULL DEFAULT nextval('${tableNameLoginCount}_id_seq'::regclass), + "uid" varchar(100) NOT NULL, + "authMethod" varchar(100) NOT NULL, + "date_created" timestamp NOT NULL DEFAULT now(), + PRIMARY KEY ("id") + ); + `; + + const alterTableQuery1 = ` + ALTER TABLE IF EXISTS "public"."${tableNameLoginCount}" + ADD IF NOT EXISTS "authMethod" VARCHAR(100); + `; + + await query(createTableQuery); + await query(alterTableQuery1); + } else { + // Create the table + execDB(` + CREATE TABLE IF NOT EXISTS ${tableNameLoginCount} ( + "id" INTEGER PRIMARY KEY, + "uid" VARCHAR(100) NOT NULL, + "date_created" DATETIME NOT NULL DEFAULT (datetime(CURRENT_TIMESTAMP, 'localtime')), + "auth_method" VARCHAR(100) DEFAULT NULL + ); + `); + } + } +} + +setupTables(); + async function getQueries() { - const { tableNameLoginCount } = await db(); - return (IS_AP ? queriesPG : queriesSQLITE)(tableNameLoginCount); + return (IS_PG ? queriesPG : queriesSQLITE)(tableNameLoginCount); } function hashUserId(userID: string, salt = SALT) { @@ -75,7 +121,7 @@ export async function loginStats(req: Request, res: Response) { } const queries = await getQueries(); - const { queryGET, tableNameLoginCount } = await db(); + const { queryGET, queryALL } = await db(); let authMethodSelected = ''; @@ -145,22 +191,38 @@ export async function loginStats(req: Request, res: Response) { }); const dateMinResult = (await queryGET(queries.dateMinAll)) as { - date_min: string; + date_min: string | Date; }; const dateMaxResult = (await queryGET(queries.dateMaxAll)) as { - date_max: string; + date_max: string | Date; }; - let dateMin: Date | null = null; - let dateMax: Date | null = null; + let dateMin: Date = sub(new Date(), { years: 1 }); + let dateMax: Date = new Date(); - if (dateMinResult) { - dateMin = parseISO(dateMinResult.date_min); - } + try { + if (dateMinResult.date_min) { + dateMin = + dateMinResult.date_min instanceof Date + ? dateMinResult.date_min + : parseISO(dateMinResult.date_min); + } - if (dateMaxResult) { - dateMax = parseISO(dateMaxResult.date_max); + if (dateMaxResult.date_max) { + dateMax = + dateMaxResult.date_max instanceof Date + ? dateMaxResult.date_max + : parseISO(dateMaxResult.date_max); + } + } catch (error) { + Sentry.captureException(error), + { + extra: { + dateMaxResult, + dateMinResult, + }, + }; } let dateStart: string = dateMin @@ -226,3 +288,51 @@ export async function loginStats(req: Request, res: Response) { authMethodSelected, }); } + +export async function rawDataTable(req: Request, res: Response) { + const { queryGET, queryALL } = await db(); + const queries = await getQueries(); + + function generateHtmlTable(rows: any[]) { + if (rows.length === 0) { + return '

No data found.

'; + } + + const tableHeader = Object.keys(rows[0]) + .map((columnName) => `${columnName}`) + .join(''); + + const tableRows = rows + .map( + (row) => + `${Object.values(row) + .map((value) => `${value}`) + .join('')}` + ) + .join(''); + + const htmlTable = ` + + + ${tableHeader} + + + ${tableRows} + +
+ `; + + return htmlTable; + } + + // SQLite3 query to select all data from the specified table + const query = queries.rawOverview; + + // Execute the query and retrieve the results + const rows = (await queryALL(query)) as any[]; + + // Generate and display the HTML table + const htmlTable = generateHtmlTable(rows); + + return res.send(htmlTable); +}