Skip to content
This repository was archived by the owner on Sep 19, 2022. It is now read-only.

Commit 63f4b49

Browse files
authored
Merge pull request #51 from CESNET/postgresql
feat: adapt for PostgreSQL
2 parents a95158d + d778a96 commit 63f4b49

File tree

6 files changed

+144
-66
lines changed

6 files changed

+144
-66
lines changed

composer.json

Lines changed: 0 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -16,8 +16,6 @@
1616
],
1717
"require": {
1818
"php": ">=7.1",
19-
"simplesamlphp/simplesamlphp": "~1.17",
20-
"ext-pdo": "*",
2119
"ext-json": "*"
2220
},
2321
"suggest": {

config-templates/tables.sql

Lines changed: 14 additions & 14 deletions
Original file line numberDiff line numberDiff line change
@@ -6,14 +6,14 @@ CREATE TABLE `statistics_sums` (
66
`year` YEAR NOT NULL,
77
`month` TINYINT UNSIGNED DEFAULT NULL,
88
`day` TINYINT UNSIGNED DEFAULT NULL,
9-
`idpId` INT UNSIGNED NOT NULL DEFAULT 0,
10-
`spId` INT UNSIGNED NOT NULL DEFAULT 0,
9+
`idp_id` INT UNSIGNED NOT NULL DEFAULT 0,
10+
`sp_id` INT UNSIGNED NOT NULL DEFAULT 0,
1111
`logins` INT UNSIGNED DEFAULT NULL,
1212
`users` INT UNSIGNED DEFAULT NULL,
1313
PRIMARY KEY (`id`),
14-
UNIQUE KEY `year` (`year`,`month`,`day`,`idpId`,`spId`),
15-
KEY `idpId` (`idpId`),
16-
KEY `spId` (`spId`)
14+
UNIQUE KEY `year` (`year`,`month`,`day`,`idp_id`,`sp_id`),
15+
KEY `idp_id` (`idp_id`),
16+
KEY `sp_id` (`sp_id`)
1717
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
1818
-- ROWS
1919
-- each row contains daily users = COUNT(1) and daily logins = SUM(logins) from statistics_per_user
@@ -27,29 +27,29 @@ CREATE TABLE `statistics_sums` (
2727
-- data is being kept for ~1 month
2828
CREATE TABLE `statistics_per_user` (
2929
`day` date NOT NULL,
30-
`idpId` INT UNSIGNED NOT NULL,
31-
`spId` INT UNSIGNED NOT NULL,
30+
`idp_id` INT UNSIGNED NOT NULL,
31+
`sp_id` INT UNSIGNED NOT NULL,
3232
`user` VARCHAR(255) NOT NULL,
3333
`logins` INT UNSIGNED DEFAULT '1',
34-
PRIMARY KEY (`day`,`idpId`,`spId`,`user`),
35-
KEY `idpId` (`idpId`),
36-
KEY `spId` (`spId`)
34+
PRIMARY KEY (`day`,`idp_id`,`sp_id`,`user`),
35+
KEY `idp_id` (`idp_id`),
36+
KEY `sp_id` (`sp_id`)
3737
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
3838

3939
-- identity providers
4040
CREATE TABLE `statistics_idp` (
41-
`idpId` INT UNSIGNED NOT NULL AUTO_INCREMENT,
41+
`idp_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
4242
`identifier` VARCHAR(255) NOT NULL,
4343
`name` VARCHAR(255) NOT NULL,
44-
PRIMARY KEY (`idpId`),
44+
PRIMARY KEY (`idp_id`),
4545
UNIQUE KEY `identifier` (`identifier`)
4646
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
4747

4848
-- services
4949
CREATE TABLE `statistics_sp` (
50-
`spId` INT UNSIGNED NOT NULL AUTO_INCREMENT,
50+
`sp_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
5151
`identifier` VARCHAR(255) NOT NULL,
5252
`name` VARCHAR(255) NOT NULL,
53-
PRIMARY KEY (`spId`),
53+
PRIMARY KEY (`sp_id`),
5454
UNIQUE KEY `identifier` (`identifier`)
5555
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

lib/DatabaseCommand.php

Lines changed: 108 additions & 48 deletions
Original file line numberDiff line numberDiff line change
@@ -24,8 +24,8 @@ class DatabaseCommand
2424
];
2525

2626
private const TABLE_IDS = [
27-
self::TABLE_IDP => 'idpId',
28-
self::TABLE_SP => 'spId',
27+
self::TABLE_IDP => 'idp_id',
28+
self::TABLE_SP => 'sp_id',
2929
];
3030

3131
private $tables = [
@@ -41,11 +41,15 @@ class DatabaseCommand
4141

4242
private $mode;
4343

44+
private $escape_char = '`';
45+
4446
public function __construct()
4547
{
4648
$this->config = Config::getInstance();
4749
$this->conn = Database::getInstance($this->config->getStore());
48-
assert($this->conn !== null);
50+
if ($this->conn->getDriver() === 'pgsql') {
51+
$this->escape_char = '"';
52+
}
4953
$this->tables = array_merge($this->tables, $this->config->getTables());
5054
$this->mode = $this->config->getMode();
5155
}
@@ -84,7 +88,7 @@ public function getNameById($side, $id)
8488
{
8589
$table = self::TABLE_SIDES[$side];
8690
return $this->read(
87-
'SELECT IFNULL(name, identifier) ' .
91+
'SELECT COALESCE(name, identifier) ' .
8892
'FROM ' . $this->tables[$table] . ' ' .
8993
'WHERE ' . self::TABLE_IDS[$table] . '=:id',
9094
[
@@ -96,16 +100,20 @@ public function getNameById($side, $id)
96100
public function getLoginCountPerDay($days, $where = [])
97101
{
98102
$params = [];
99-
$query = 'SELECT UNIX_TIMESTAMP(STR_TO_DATE(CONCAT(year,"-",month,"-",day), "%Y-%m-%d")) AS day, ' .
100-
'logins AS count, users ' .
103+
if ($this->conn->getDriver() === 'pgsql') {
104+
$query = "SELECT EXTRACT(epoch FROM TO_DATE(CONCAT(year,'-',month,'-',day), 'YYYY-MM-DD')) AS day, ";
105+
} else {
106+
$query = "SELECT UNIX_TIMESTAMP(STR_TO_DATE(CONCAT(year,'-',month,'-',day), '%Y-%m-%d')) AS day, ";
107+
}
108+
$query .= 'logins AS count, users ' .
101109
'FROM ' . $this->tables[self::TABLE_SUM] . ' ' .
102110
'WHERE ';
103111
$where = array_merge([
104112
Config::MODE_SP => null,
105113
Config::MODE_IDP => null,
106114
], $where);
107-
self::addWhereId($where, $query, $params);
108-
self::addDaysRange($days, $query, $params);
115+
$this->addWhereId($where, $query, $params);
116+
$this->addDaysRange($days, $query, $params);
109117
$query .= //'GROUP BY day ' .
110118
'ORDER BY day ASC';
111119

@@ -117,13 +125,13 @@ public function getAccessCount($side, $days, $where = [])
117125
{
118126
$table = self::TABLE_SIDES[$side];
119127
$params = [];
120-
$query = 'SELECT IFNULL(name,identifier) AS name, ' . self::TABLE_IDS[$table] . ', SUM(logins) AS count ' .
128+
$query = 'SELECT COALESCE(name,identifier) AS name, ' . self::TABLE_IDS[$table] . ', SUM(logins) AS count ' .
121129
'FROM ' . $this->tables[$table] . ' ' .
122130
'LEFT OUTER JOIN ' . $this->tables[self::TABLE_SUM] . ' ' .
123131
'USING (' . self::TABLE_IDS[$table] . ') ' .
124132
'WHERE ';
125-
self::addWhereId($where, $query, $params);
126-
self::addDaysRange($days, $query, $params);
133+
$this->addWhereId($where, $query, $params);
134+
$this->addDaysRange($days, $query, $params);
127135
$query .= 'GROUP BY ' . self::TABLE_IDS[$table] . ' ';
128136
$query .= 'ORDER BY SUM(logins) DESC';
129137

@@ -133,22 +141,32 @@ public function getAccessCount($side, $days, $where = [])
133141

134142
public function aggregate()
135143
{
136-
foreach ([self::TABLE_IDS[self::TABLE_IDP], null] as $idpId) {
137-
foreach ([self::TABLE_IDS[self::TABLE_SP], null] as $spId) {
138-
$ids = [$idpId, $spId];
144+
foreach ([self::TABLE_IDS[self::TABLE_IDP], null] as $idp_id) {
145+
foreach ([self::TABLE_IDS[self::TABLE_SP], null] as $sp_id) {
146+
$ids = [$idp_id, $sp_id];
139147
$msg = 'Aggregating daily statistics per ' . implode(' and ', array_filter($ids));
140148
Logger::info($msg);
141149
$query = 'INSERT INTO ' . $this->tables[self::TABLE_SUM] . ' '
142-
. '(`year`,`month`,`day`,idpId,spId,logins,users) '
143-
. 'SELECT YEAR(`day`), MONTH(`day`), DAY(`day`), ';
150+
. '(' . $this->escape_cols(['year', 'month', 'day', 'idp_id', 'sp_id', 'logins', 'users']) . ') '
151+
. 'SELECT EXTRACT(YEAR FROM ' . $this->escape_col(
152+
'day'
153+
) . '), EXTRACT(MONTH FROM ' . $this->escape_col(
154+
'day'
155+
) . '), EXTRACT(DAY FROM ' . $this->escape_col('day') . '), ';
144156
foreach ($ids as $id) {
145157
$query .= ($id === null ? '0' : $id) . ',';
146158
}
147-
$query .= 'SUM(logins), COUNT(DISTINCT user) '
159+
$query .= 'SUM(logins), COUNT(DISTINCT ' . $this->escape_col('user') . ') '
148160
. 'FROM ' . $this->tables[self::TABLE_PER_USER] . ' '
149161
. 'WHERE day<DATE(NOW()) '
150-
. 'GROUP BY ' . self::getAggregateGroupBy($ids) . ' '
151-
. 'ON DUPLICATE KEY UPDATE id=id;';
162+
. 'GROUP BY ' . $this->getAggregateGroupBy($ids) . ' ';
163+
if ($this->conn->getDriver() === 'pgsql') {
164+
$query .= 'ON CONFLICT (' . $this->escape_cols(
165+
['year', 'month', 'day', 'idp_id', 'sp_id']
166+
) . ') DO NOTHING;';
167+
} else {
168+
$query .= 'ON DUPLICATE KEY UPDATE id=id;';
169+
}
152170
// do nothing if row already exists
153171
if (! $this->conn->write($query)) {
154172
Logger::warning($msg . ' failed');
@@ -160,30 +178,52 @@ public function aggregate()
160178

161179
$msg = 'Deleting detailed statistics';
162180
Logger::info($msg);
163-
// INNER JOIN ensures that only aggregated stats are deleted
181+
if ($this->conn->getDriver() === 'pgsql') {
182+
$make_date = 'MAKE_DATE(' . $this->escape_cols(['year', 'month', 'day']) . ')';
183+
$date_clause = sprintf('CURRENT_DATE - INTERVAL \'%s DAY\' ', $keepPerUserDays);
184+
$params = [];
185+
} else {
186+
$make_date = 'STR_TO_DATE(CONCAT(' . $this->escape_col('year') . ",'-'," . $this->escape_col(
187+
'month'
188+
) . ",'-'," . $this->escape_col('day') . "), '%Y-%m-%d')";
189+
$date_clause = 'CURDATE() - INTERVAL :days DAY';
190+
$params = [
191+
'days' => $keepPerUserDays,
192+
];
193+
}
194+
$query = 'DELETE FROM ' . $this->tables[self::TABLE_PER_USER] . ' WHERE ' . $this->escape_col(
195+
'day'
196+
) . ' < ' . $date_clause
197+
. ' AND ' . $this->escape_col(
198+
'day'
199+
) . ' IN (SELECT ' . $make_date . ' FROM ' . $this->tables[self::TABLE_SUM] . ')';
164200
if (
165-
! $this->conn->write(
166-
'DELETE u FROM ' . $this->tables[self::TABLE_PER_USER] . ' AS u '
167-
. 'INNER JOIN ' . $this->tables[self::TABLE_SUM] . ' AS s '
168-
. 'ON YEAR(u.`day`)=s.`year` AND MONTH(u.`day`)=s.`month` AND DAY(u.`day`)=s.`day`'
169-
. 'WHERE u.`day` < CURDATE() - INTERVAL :days DAY',
170-
[
171-
'days' => $keepPerUserDays,
172-
]
173-
)
201+
! $this->conn->write($query, $params)
174202
) {
175203
Logger::warning($msg . ' failed');
176204
}
177205
}
178206

207+
private function escape_col($col_name)
208+
{
209+
return $this->escape_char . $col_name . $this->escape_char;
210+
}
211+
212+
private function escape_cols($col_names)
213+
{
214+
return $this->escape_char . implode(
215+
$this->escape_char . ',' . $this->escape_char,
216+
$col_names
217+
) . $this->escape_char;
218+
}
219+
179220
private function read($query, $params)
180221
{
181222
return $this->conn->read($query, $params);
182223
}
183224

184-
private static function addWhereId($where, &$query, &$params)
225+
private function addWhereId($where, &$query, &$params)
185226
{
186-
assert(count(array_filter($where)) <= 1); //placeholder would be overwritten
187227
$parts = [];
188228
foreach ($where as $side => $value) {
189229
$table = self::TABLE_SIDES[$side];
@@ -216,8 +256,15 @@ private function writeLogin($date, $ids, $user)
216256
]);
217257
$fields = array_keys($params);
218258
$placeholders = array_map(['self', 'prependColon'], $fields);
219-
$query = 'INSERT INTO ' . $this->tables[self::TABLE_PER_USER] . ' (' . implode(', ', $fields) . ')' .
220-
' VALUES (' . implode(', ', $placeholders) . ') ON DUPLICATE KEY UPDATE logins = logins + 1';
259+
$query = 'INSERT INTO ' . $this->tables[self::TABLE_PER_USER] . ' (' . $this->escape_cols($fields) . ')' .
260+
' VALUES (' . implode(', ', $placeholders) . ') ';
261+
if ($this->conn->getDriver() === 'pgsql') {
262+
$query .= 'ON CONFLICT (' . $this->escape_cols(
263+
['day', 'idp_id', 'sp_id', 'user']
264+
) . ') DO UPDATE SET "logins" = ' . $this->tables[self::TABLE_PER_USER] . '.logins + 1;';
265+
} else {
266+
$query .= 'ON DUPLICATE KEY UPDATE logins = logins + 1;';
267+
}
221268

222269
return $this->conn->write($query, $params);
223270
}
@@ -262,47 +309,60 @@ private function getIdFromIdentifier($table, $entity, $idColumn)
262309
{
263310
$identifier = $entity['id'];
264311
$name = $entity['name'];
265-
$this->conn->write(
266-
'INSERT INTO ' . $this->tables[$table]
267-
. '(identifier, name) VALUES (:identifier, :name1) ON DUPLICATE KEY UPDATE name = :name2',
268-
[
269-
'identifier' => $identifier,
270-
'name1' => $name,
271-
'name2' => $name,
272-
]
273-
);
312+
$query = 'INSERT INTO ' . $this->tables[$table] . '(identifier, name) VALUES (:identifier, :name1) ';
313+
if ($this->conn->getDriver() === 'pgsql') {
314+
$query .= 'ON CONFLICT (identifier) DO UPDATE SET name = :name2;';
315+
} else {
316+
$query .= 'ON DUPLICATE KEY UPDATE name = :name2';
317+
}
318+
$this->conn->write($query, [
319+
'identifier' => $identifier,
320+
'name1' => $name,
321+
'name2' => $name,
322+
]);
274323
return $this->read('SELECT ' . $idColumn . ' FROM ' . $this->tables[$table]
275324
. ' WHERE identifier=:identifier', [
276325
'identifier' => $identifier,
277326
])
278327
->fetchColumn();
279328
}
280329

281-
private static function addDaysRange($days, &$query, &$params, $not = false)
330+
private function addDaysRange($days, &$query, &$params, $not = false)
282331
{
283332
if ($days !== 0) { // 0 = all time
284333
if (stripos($query, 'WHERE') === false) {
285334
$query .= 'WHERE';
286335
} else {
287336
$query .= 'AND';
288337
}
289-
$query .= ' CONCAT(year,"-",LPAD(month,2,"00"),"-",LPAD(day,2,"00")) ';
338+
if ($this->conn->getDriver() === 'pgsql') {
339+
$query .= ' MAKE_DATE(year,month,day) ';
340+
} else {
341+
$query .= " CONCAT(year,'-',LPAD(month,2,'00'),'-',LPAD(day,2,'00')) ";
342+
}
290343
if ($not) {
291344
$query .= 'NOT ';
292345
}
293-
$query .= 'BETWEEN CURDATE() - INTERVAL :days DAY AND CURDATE() ';
294-
$params['days'] = $days;
346+
if ($this->conn->getDriver() === 'pgsql') {
347+
if (! is_int($days) && ! ctype_digit($days)) {
348+
throw new \Exception('days have to be an integer');
349+
}
350+
$query .= sprintf('BETWEEN CURRENT_DATE - INTERVAL \'%s DAY\' AND CURRENT_DATE ', $days);
351+
} else {
352+
$query .= 'BETWEEN CURDATE() - INTERVAL :days DAY AND CURDATE() ';
353+
$params['days'] = $days;
354+
}
295355
}
296356
}
297357

298-
private static function getAggregateGroupBy($ids)
358+
private function getAggregateGroupBy($ids)
299359
{
300360
$columns = ['day'];
301361
foreach ($ids as $id) {
302362
if ($id !== null) {
303363
$columns[] = $id;
304364
}
305365
}
306-
return '`' . implode('`,`', $columns) . '`';
366+
return $this->escape_cols($columns);
307367
}
308368
}

scripts/migrate_v6_mysql.sql

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,9 @@
1+
ALTER TABLE statistics_sums CHANGE idpId idp_id INT UNSIGNED NOT NULL DEFAULT 0;
2+
ALTER TABLE statistics_sums CHANGE spId sp_id INT UNSIGNED NOT NULL DEFAULT 0;
3+
4+
ALTER TABLE statistics_per_user CHANGE idpId idp_id INT UNSIGNED NOT NULL DEFAULT 0;
5+
ALTER TABLE statistics_per_user CHANGE spId sp_id INT UNSIGNED NOT NULL DEFAULT 0;
6+
7+
ALTER TABLE statistics_idp CHANGE idpId idp_id INT UNSIGNED NOT NULL DEFAULT 0;
8+
9+
ALTER TABLE statistics_sp CHANGE spId sp_id INT UNSIGNED NOT NULL DEFAULT 0;

scripts/migrate_v6_pgsql.sql

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,9 @@
1+
ALTER TABLE statistics_sums RENAME "idpId" TO idp_id;
2+
ALTER TABLE statistics_sums RENAME "spId" TO sp_id;
3+
4+
ALTER TABLE statistics_per_user RENAME "idpId" TO idp_id;
5+
ALTER TABLE statistics_per_user RENAME "spId" TO sp_id;
6+
7+
ALTER TABLE statistics_idp RENAME "idpId" TO idp_id;
8+
9+
ALTER TABLE statistics_sp RENAME "spId" TO sp_id;

www/assets/js/index.js

Lines changed: 4 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -8,8 +8,10 @@ function getStatisticsData(name) {
88

99
function getStatisticsDataYMDC(name, field) {
1010
return getStatisticsData(name).map(function mapItemToDate(item) {
11+
var d = new Date(item.day * 1000);
12+
d.setHours(0);
1113
return {
12-
x: new Date(item.day * 1000),
14+
x: d,
1315
y: item[field]
1416
};
1517
});
@@ -22,7 +24,7 @@ function getTranslation(str) {
2224
function extendData(data, minX, maxX) {
2325
var i = 0;
2426
var extendedData = [];
25-
for (var d = new Date(minX); d <= maxX; d.setDate(d.getDate() + 1)) {
27+
for (var d = new Date(minX); d <= maxX; d.setDate(d.getDate() + 1),d.setHours(0)) {
2628
if (data[i].x.getTime() === d.getTime()) {
2729
extendedData.push(data[i]);
2830
i += 1;

0 commit comments

Comments
 (0)