Replaced SQL scripts with Knex migrations

This commit is contained in:
Maciej Krzyżanowski 2023-03-18 09:00:37 +01:00
parent 001d37a0f5
commit 4819d4f2d1
6 changed files with 482 additions and 168 deletions

17
knexfile.js Normal file
View File

@ -0,0 +1,17 @@
require('dotenv').config();
module.exports = {
client: 'postgresql',
connection: {
database: `${process.env.DB_NAME}` ,
user: `${process.env.DB_USER}`,
password: `${process.env.DB_PASS}`
},
pool: {
min: 2,
max: 10
},
migrations: {
tableName: 'knex_migrations'
}
};

View File

@ -0,0 +1,259 @@
/**
* @param { import("knex").Knex } knex
* @returns { Promise<void> }
*/
exports.up = function(knex) {
return knex.schema.createTable('osp_unit', function (table) {
table.increments();
table.string('name')
.notNullable();
table.string('locality')
.notNullable()
.checkRegex('[A-ZĄĆĘŁŃÓŚŹŻ][A-zĄĆĘŁŃÓŚŹŻząćęłńóśźż. ]+');
}).createTable('fire_truck', function (table) {
table.increments();
table.string('name')
.notNullable();
table.string('image_path')
.notNullable()
.checkRegex('^([0-9a-z_]+/?)*[0-9a-z_]+\.((png)|(jpg)|(jpeg)|(webp))$');
table.integer('osp_unit_id')
.unsigned()
.notNullable()
.references('id').inTable('osp_unit')
.onUpdate('CASCADE')
.onDelete('CASCADE');
}).createTable('truck_side', function (table) {
table.increments();
table.string('image_path')
.notNullable()
.checkRegex('^([0-9a-z_]+/?)*[0-9a-z_]+\.((png)|(jpg)|(jpeg)|(webp))$');
table.integer('ordinal_number')
.notNullable();
table.integer('fire_truck_id')
.unsigned()
.notNullable()
.references('id').inTable('fire_truck')
.onUpdate('CASCADE')
.onDelete('CASCADE');
}).createTable('cache', function (table) {
table.increments();
table.string('name')
.notNullable();
// I think it may be reasonable to eliminate using Box type as it is not well supported by JS tools
table.specificType('rectangle', 'box')
.notNullable();
table.integer('truck_side_id')
.unsigned()
.notNullable()
.references('id').inTable('truck_side')
.onUpdate('CASCADE')
.onDelete('CASCADE');
table.check('(rectangle[0])[0] <= 1 AND (rectangle[0])[0] >= 0 AND (rectangle[0])[1] <= 1 AND (rectangle[0])[1] >= 0 AND (rectangle[1])[0] <= 1 AND (rectangle[1])[0] >= 0 AND (rectangle[1])[1] <= 1 AND (rectangle[1])[1] >= 0');
}).createTable('equipment', function (table) {
table.increments();
table.string('name')
.notNullable();
table.integer('cache_id')
.notNullable()
.references('id')
.inTable('cache');
}).createTable('account', function (table) {
table.string('nickname')
.primary()
.checkRegex('^[0-9A-z_żółćęśąźńŻÓŁĆĘŚĄŹŃ]{3,}$');
table.string('name')
.checkRegex('^[A-ZŻÓŁĆĘŚĄŹŃ][a-zżółćęśąźń]+$');
table.string('surname')
.checkRegex('^[A-ZŻÓŁĆĘŚĄŹŃ][a-zżółćęśąźń]+$');
// TODO: Does it need any constraint?
table.string('pass_hash')
.notNullable();
table.integer('default_osp')
.unsigned()
.references('id').inTable('osp_unit')
.onUpdate('CASCADE')
.onDelete('SET NULL');
}).createTable('permission', function (table) {
table.string('code')
.primary()
.checkRegex('^[0-9A-Z_]{3,}$');
table.string('name')
.checkLength('>=', 3);
table.string('description');
}).createTable('score', function (table) {
table.increments();
table.string('account_nickname')
.notNullable()
.references('nickname')
.inTable('account')
.onUpdate('CASCADE')
.onDelete('CASCADE');
table.timestamp('got_at')
.notNullable()
.defaultTo(knex.fn.now());
table.integer('fire_truck_id')
.unsigned()
.notNullable()
.references('id').inTable('fire_truck')
.onUpdate('CASCADE')
.onDelete('CASCADE');
table.integer('points')
.notNullable()
.checkBetween([0, 10]);
table.integer('seconds')
.notNullable()
.checkPositive();
}).createTable('account_permission', function (table) {
table.string('account_nickname')
.notNullable()
.references('nickname')
.inTable('account')
.onUpdate('CASCADE')
.onDelete('CASCADE');
table.string('permission_code')
.notNullable()
.references('code')
.inTable('permission')
.onUpdate('CASCADE')
.onDelete('CASCADE');
table.integer('osp_unit_id')
.notNullable()
.references('id')
.inTable('osp_unit')
.onUpdate('CASCADE')
.onDelete('CASCADE');
table.primary(
['account_nickname',
'permission_code',
'osp_unit_id']
);
}).createTable('event', function (table) {
table.increments();
table.string('name')
.notNullable()
.checkLength('>=', 3);
table.string('details');
table.timestamp('report_time')
.notNullable();
table.string('account_nickname')
.notNullable()
.references('nickname')
.inTable('account')
.onUpdate('CASCADE')
.onDelete('SET NULL');
table.integer('osp_unit_id')
.notNullable()
.references('id')
.inTable('osp_unit')
.onUpdate('CASCADE')
.onDelete('CASCADE');
table.check('report_time <= now() AND date_part(\'hour\', CURRENT_TIMESTAMP - report_time) < 1');
}).raw(
`
CREATE FUNCTION get_units_list(prefix VARCHAR)
RETURNS TABLE (id INTEGER, name VARCHAR, locality VARCHAR) AS
$func$
SELECT id, name, locality FROM osp_unit
WHERE LOWER(locality) LIKE LOWER('%' || prefix || '%')
OR LOWER(name) LIKE LOWER('%' || prefix || '%')
ORDER BY locality, name LIMIT 3;
$func$
LANGUAGE SQL;
`
).raw(
`
CREATE FUNCTION get_trucks_list_with_scores(osp_unit INTEGER, nickname VARCHAR, last_scores_num INTEGER = 3)
RETURNS TABLE (id INTEGER, name VARCHAR, image_path VARCHAR, avg_percent FLOAT) AS
$func$
SELECT ft.id, name, image_path, ROUND(AVG(s.points) * 10, 2) AS avg_percent
FROM fire_truck ft
JOIN score s ON ft.id = s.fire_truck_id AND s.account_nickname = nickname
WHERE ft.osp_unit_id = osp_unit AND s.id IN (
SELECT sc.id FROM score sc
WHERE sc.account_nickname = nickname AND sc.fire_truck_id = ft.id
ORDER BY sc.got_at DESC
LIMIT last_scores_num
) GROUP BY ft.id, name, image_path
UNION
(SELECT ft.id, name, image_path, 0
FROM fire_truck ft
WHERE ft.osp_unit_id = osp_unit AND
ft.id NOT IN (SELECT fire_truck_id FROM score WHERE account_nickname = nickname))
ORDER BY 1;
$func$
LANGUAGE SQL;
`
).raw(
`
CREATE FUNCTION get_quiz_data_for_truck(truck_id INTEGER)
RETURNS TABLE (side_id INTEGER, side_image_path VARCHAR, cache_id INTEGER,
cache_rectangle BOX, cache_name VARCHAR) AS
$func$
SELECT ts.id, ts.image_path, c.id, c.rectangle, c.name
FROM fire_truck
JOIN truck_side ts on fire_truck.id = ts.fire_truck_id
JOIN cache c on ts.id = c.truck_side_id
WHERE fire_truck.id = truck_id
ORDER BY ts.ordinal_number;
$func$
LANGUAGE SQL;
`
).raw(
`
CREATE FUNCTION get_random_question(truck_id INTEGER)
RETURNS TABLE (cache_id INTEGER, equipment_name VARCHAR) AS
$func$
SELECT c.id, e.name
FROM truck_side ts
JOIN cache c on ts.id = c.truck_side_id
JOIN equipment e on c.id = e.cache_id
WHERE ts.fire_truck_id = truck_id
ORDER BY RANDOM()
LIMIT 1;
$func$
LANGUAGE SQL;
`
).raw(
`
CREATE TABLE user_session (
"sid" varchar NOT NULL COLLATE "default",
"sess" json NOT NULL,
"expire" timestamp(6) NOT NULL
)
WITH (OIDS=FALSE);
ALTER TABLE user_session ADD CONSTRAINT "session_pkey" PRIMARY KEY ("sid") NOT DEFERRABLE INITIALLY IMMEDIATE;
CREATE INDEX "IDX_session_expire" ON user_session ("expire");
`
);
};
/**
* @param { import("knex").Knex } knex
* @returns { Promise<void> }
*/
exports.down = function(knex) {
return new Promise(async (resolve, reject) => {
await knex.schema
.dropTableIfExists('event')
.dropTableIfExists('account_permission')
.dropTableIfExists('permission')
.dropTableIfExists('score')
.dropTableIfExists('account')
.dropTableIfExists('equipment')
.dropTableIfExists('cache')
.dropTableIfExists('truck_side')
.dropTableIfExists('fire_truck')
.dropTableIfExists('osp_unit')
.dropTableIfExists('user_session');
await knex.raw('DROP FUNCTION IF EXISTS get_units_list');
await knex.raw('DROP FUNCTION IF EXISTS get_trucks_list_with_scores');
await knex.raw('DROP FUNCTION IF EXISTS get_quiz_data_for_truck');
await knex.raw('DROP FUNCTION IF EXISTS get_random_question');
resolve();
});
}

205
package-lock.json generated
View File

@ -13,6 +13,7 @@
"dotenv": "^16.0.3", "dotenv": "^16.0.3",
"express": "^4.18.2", "express": "^4.18.2",
"express-session": "^1.17.3", "express-session": "^1.17.3",
"knex": "^2.4.2",
"pg": "^8.9.0", "pg": "^8.9.0",
"pg-promise": "^11.2.0", "pg-promise": "^11.2.0",
"response-time": "^2.3.2", "response-time": "^2.3.2",
@ -110,6 +111,19 @@
"url": "https://github.com/sponsors/ljharb" "url": "https://github.com/sponsors/ljharb"
} }
}, },
"node_modules/colorette": {
"version": "2.0.19",
"resolved": "https://registry.npmjs.org/colorette/-/colorette-2.0.19.tgz",
"integrity": "sha512-3tlv/dIP7FWvj3BsbHrGLJ6l/oKh1O3TcgBqMn+yyCagOxc23fyzDS6HypQbgxWbkpDnf52p1LuR4eWDQ/K9WQ=="
},
"node_modules/commander": {
"version": "9.5.0",
"resolved": "https://registry.npmjs.org/commander/-/commander-9.5.0.tgz",
"integrity": "sha512-KRs7WVDKg86PWiuAqhDrAQnTXZKraVcCc6vFdL14qrZ/DcWwuRo7VoiYXalXO7S5GKpqYiVEwCbgFDfxNHKJBQ==",
"engines": {
"node": "^12.20.0 || >=14"
}
},
"node_modules/connect-pg-simple": { "node_modules/connect-pg-simple": {
"version": "8.0.0", "version": "8.0.0",
"resolved": "https://registry.npmjs.org/connect-pg-simple/-/connect-pg-simple-8.0.0.tgz", "resolved": "https://registry.npmjs.org/connect-pg-simple/-/connect-pg-simple-8.0.0.tgz",
@ -200,11 +214,27 @@
"node": ">= 0.8" "node": ">= 0.8"
} }
}, },
"node_modules/escalade": {
"version": "3.1.1",
"resolved": "https://registry.npmjs.org/escalade/-/escalade-3.1.1.tgz",
"integrity": "sha512-k0er2gUkLf8O0zKJiAhmkTnJlTvINGv7ygDNPbeIsX/TJjGJZHuh9B2UxbsaEkmlEo9MfhrSzmhIlhRlI2GXnw==",
"engines": {
"node": ">=6"
}
},
"node_modules/escape-html": { "node_modules/escape-html": {
"version": "1.0.3", "version": "1.0.3",
"resolved": "https://registry.npmjs.org/escape-html/-/escape-html-1.0.3.tgz", "resolved": "https://registry.npmjs.org/escape-html/-/escape-html-1.0.3.tgz",
"integrity": "sha512-NiSupZ4OeuGwr68lGIeym/ksIZMJodUGOSCZ/FSnTxcrekbvqrgdUxlJOMpijaKZVjAJrWrGs/6Jy8OMuyj9ow==" "integrity": "sha512-NiSupZ4OeuGwr68lGIeym/ksIZMJodUGOSCZ/FSnTxcrekbvqrgdUxlJOMpijaKZVjAJrWrGs/6Jy8OMuyj9ow=="
}, },
"node_modules/esm": {
"version": "3.2.25",
"resolved": "https://registry.npmjs.org/esm/-/esm-3.2.25.tgz",
"integrity": "sha512-U1suiZ2oDVWv4zPO56S0NcR5QriEahGtdN2OR6FiOG4WJvcjBVFB0qI4+eKoWFH483PKGuLuu6V8Z4T5g63UVA==",
"engines": {
"node": ">=6"
}
},
"node_modules/etag": { "node_modules/etag": {
"version": "1.8.1", "version": "1.8.1",
"resolved": "https://registry.npmjs.org/etag/-/etag-1.8.1.tgz", "resolved": "https://registry.npmjs.org/etag/-/etag-1.8.1.tgz",
@ -331,6 +361,19 @@
"url": "https://github.com/sponsors/ljharb" "url": "https://github.com/sponsors/ljharb"
} }
}, },
"node_modules/get-package-type": {
"version": "0.1.0",
"resolved": "https://registry.npmjs.org/get-package-type/-/get-package-type-0.1.0.tgz",
"integrity": "sha512-pjzuKtY64GYfWizNAJ0fr9VqttZkNiK2iS430LtIHzjBEr6bX8Am2zm4sW4Ro5wjWW5cAlRL1qAMTcXbjNAO2Q==",
"engines": {
"node": ">=8.0.0"
}
},
"node_modules/getopts": {
"version": "2.3.0",
"resolved": "https://registry.npmjs.org/getopts/-/getopts-2.3.0.tgz",
"integrity": "sha512-5eDf9fuSXwxBL6q5HX+dhDj+dslFGWzU5thZ9kNKUkcPtaPdatmUFKwHFrLb/uf/WpA4BHET+AX3Scl56cAjpA=="
},
"node_modules/has": { "node_modules/has": {
"version": "1.0.3", "version": "1.0.3",
"resolved": "https://registry.npmjs.org/has/-/has-1.0.3.tgz", "resolved": "https://registry.npmjs.org/has/-/has-1.0.3.tgz",
@ -384,6 +427,14 @@
"resolved": "https://registry.npmjs.org/inherits/-/inherits-2.0.4.tgz", "resolved": "https://registry.npmjs.org/inherits/-/inherits-2.0.4.tgz",
"integrity": "sha512-k/vGaX4/Yla3WzyMCvTQOXYeIHvqOKtnqBduzTHpzpQZzAskKMhZ2K+EnBiSM9zGSoIFeMpXKxa4dYeZIQqewQ==" "integrity": "sha512-k/vGaX4/Yla3WzyMCvTQOXYeIHvqOKtnqBduzTHpzpQZzAskKMhZ2K+EnBiSM9zGSoIFeMpXKxa4dYeZIQqewQ=="
}, },
"node_modules/interpret": {
"version": "2.2.0",
"resolved": "https://registry.npmjs.org/interpret/-/interpret-2.2.0.tgz",
"integrity": "sha512-Ju0Bz/cEia55xDwUWEa8+olFpCiQoypjnQySseKtmjNrnps3P+xfpUmGr90T7yjlVJmOtybRvPXhKMbHr+fWnw==",
"engines": {
"node": ">= 0.10"
}
},
"node_modules/ipaddr.js": { "node_modules/ipaddr.js": {
"version": "1.9.1", "version": "1.9.1",
"resolved": "https://registry.npmjs.org/ipaddr.js/-/ipaddr.js-1.9.1.tgz", "resolved": "https://registry.npmjs.org/ipaddr.js/-/ipaddr.js-1.9.1.tgz",
@ -392,6 +443,93 @@
"node": ">= 0.10" "node": ">= 0.10"
} }
}, },
"node_modules/is-core-module": {
"version": "2.11.0",
"resolved": "https://registry.npmjs.org/is-core-module/-/is-core-module-2.11.0.tgz",
"integrity": "sha512-RRjxlvLDkD1YJwDbroBHMb+cukurkDWNyHx7D3oNB5x9rb5ogcksMC5wHCadcXoo67gVr/+3GFySh3134zi6rw==",
"dependencies": {
"has": "^1.0.3"
},
"funding": {
"url": "https://github.com/sponsors/ljharb"
}
},
"node_modules/knex": {
"version": "2.4.2",
"resolved": "https://registry.npmjs.org/knex/-/knex-2.4.2.tgz",
"integrity": "sha512-tMI1M7a+xwHhPxjbl/H9K1kHX+VncEYcvCx5K00M16bWvpYPKAZd6QrCu68PtHAdIZNQPWZn0GVhqVBEthGWCg==",
"dependencies": {
"colorette": "2.0.19",
"commander": "^9.1.0",
"debug": "4.3.4",
"escalade": "^3.1.1",
"esm": "^3.2.25",
"get-package-type": "^0.1.0",
"getopts": "2.3.0",
"interpret": "^2.2.0",
"lodash": "^4.17.21",
"pg-connection-string": "2.5.0",
"rechoir": "^0.8.0",
"resolve-from": "^5.0.0",
"tarn": "^3.0.2",
"tildify": "2.0.0"
},
"bin": {
"knex": "bin/cli.js"
},
"engines": {
"node": ">=12"
},
"peerDependenciesMeta": {
"better-sqlite3": {
"optional": true
},
"mysql": {
"optional": true
},
"mysql2": {
"optional": true
},
"pg": {
"optional": true
},
"pg-native": {
"optional": true
},
"sqlite3": {
"optional": true
},
"tedious": {
"optional": true
}
}
},
"node_modules/knex/node_modules/debug": {
"version": "4.3.4",
"resolved": "https://registry.npmjs.org/debug/-/debug-4.3.4.tgz",
"integrity": "sha512-PRWFHuSU3eDtQJPvnNY7Jcket1j0t5OuOsFzPPzsekD52Zl8qUfFIPEiswXqIvHWGVHOgX+7G/vCNNhehwxfkQ==",
"dependencies": {
"ms": "2.1.2"
},
"engines": {
"node": ">=6.0"
},
"peerDependenciesMeta": {
"supports-color": {
"optional": true
}
}
},
"node_modules/knex/node_modules/ms": {
"version": "2.1.2",
"resolved": "https://registry.npmjs.org/ms/-/ms-2.1.2.tgz",
"integrity": "sha512-sGkPx+VjMtmA6MX27oA4FBFELFCZZ4S4XqeGOXCv68tT+jb3vk/RyaKWP0PTKyWtmLSM0b+adUTEvbs1PEaH2w=="
},
"node_modules/lodash": {
"version": "4.17.21",
"resolved": "https://registry.npmjs.org/lodash/-/lodash-4.17.21.tgz",
"integrity": "sha512-v2kDEe57lecTulaDIuNTPy3Ry4gLGJ6Z1O3vE1krgXZNrsQ+LFTGHVxVjcXPs17LhbZVGedAJv8XZ1tvj5FvSg=="
},
"node_modules/media-typer": { "node_modules/media-typer": {
"version": "0.3.0", "version": "0.3.0",
"resolved": "https://registry.npmjs.org/media-typer/-/media-typer-0.3.0.tgz", "resolved": "https://registry.npmjs.org/media-typer/-/media-typer-0.3.0.tgz",
@ -496,6 +634,11 @@
"node": ">= 0.8" "node": ">= 0.8"
} }
}, },
"node_modules/path-parse": {
"version": "1.0.7",
"resolved": "https://registry.npmjs.org/path-parse/-/path-parse-1.0.7.tgz",
"integrity": "sha512-LDJzPVEEEPR+y48z93A0Ed0yXb8pAByGWo/k5YYdYgpY2/2EsOsksJrq7lOHxryrVOn1ejG6oAp8ahvOIQD8sw=="
},
"node_modules/path-to-regexp": { "node_modules/path-to-regexp": {
"version": "0.1.7", "version": "0.1.7",
"resolved": "https://registry.npmjs.org/path-to-regexp/-/path-to-regexp-0.1.7.tgz", "resolved": "https://registry.npmjs.org/path-to-regexp/-/path-to-regexp-0.1.7.tgz",
@ -688,6 +831,41 @@
"node": ">= 0.8" "node": ">= 0.8"
} }
}, },
"node_modules/rechoir": {
"version": "0.8.0",
"resolved": "https://registry.npmjs.org/rechoir/-/rechoir-0.8.0.tgz",
"integrity": "sha512-/vxpCXddiX8NGfGO/mTafwjq4aFa/71pvamip0++IQk3zG8cbCj0fifNPrjjF1XMXUne91jL9OoxmdykoEtifQ==",
"dependencies": {
"resolve": "^1.20.0"
},
"engines": {
"node": ">= 10.13.0"
}
},
"node_modules/resolve": {
"version": "1.22.1",
"resolved": "https://registry.npmjs.org/resolve/-/resolve-1.22.1.tgz",
"integrity": "sha512-nBpuuYuY5jFsli/JIs1oldw6fOQCBioohqWZg/2hiaOybXOft4lonv85uDOKXdf8rhyK159cxU5cDcK/NKk8zw==",
"dependencies": {
"is-core-module": "^2.9.0",
"path-parse": "^1.0.7",
"supports-preserve-symlinks-flag": "^1.0.0"
},
"bin": {
"resolve": "bin/resolve"
},
"funding": {
"url": "https://github.com/sponsors/ljharb"
}
},
"node_modules/resolve-from": {
"version": "5.0.0",
"resolved": "https://registry.npmjs.org/resolve-from/-/resolve-from-5.0.0.tgz",
"integrity": "sha512-qYg9KP24dD5qka9J47d0aVky0N+b4fTU89LN9iDnjB5waksiC49rvMB0PrUJQGoTmH50XPiqOvAjDfaijGxYZw==",
"engines": {
"node": ">=8"
}
},
"node_modules/response-time": { "node_modules/response-time": {
"version": "2.3.2", "version": "2.3.2",
"resolved": "https://registry.npmjs.org/response-time/-/response-time-2.3.2.tgz", "resolved": "https://registry.npmjs.org/response-time/-/response-time-2.3.2.tgz",
@ -816,6 +994,33 @@
"node": ">= 0.8" "node": ">= 0.8"
} }
}, },
"node_modules/supports-preserve-symlinks-flag": {
"version": "1.0.0",
"resolved": "https://registry.npmjs.org/supports-preserve-symlinks-flag/-/supports-preserve-symlinks-flag-1.0.0.tgz",
"integrity": "sha512-ot0WnXS9fgdkgIcePe6RHNk1WA8+muPa6cSjeR3V8K27q9BB1rTE3R1p7Hv0z1ZyAc8s6Vvv8DIyWf681MAt0w==",
"engines": {
"node": ">= 0.4"
},
"funding": {
"url": "https://github.com/sponsors/ljharb"
}
},
"node_modules/tarn": {
"version": "3.0.2",
"resolved": "https://registry.npmjs.org/tarn/-/tarn-3.0.2.tgz",
"integrity": "sha512-51LAVKUSZSVfI05vjPESNc5vwqqZpbXCsU+/+wxlOrUjk2SnFTt97v9ZgQrD4YmxYW1Px6w2KjaDitCfkvgxMQ==",
"engines": {
"node": ">=8.0.0"
}
},
"node_modules/tildify": {
"version": "2.0.0",
"resolved": "https://registry.npmjs.org/tildify/-/tildify-2.0.0.tgz",
"integrity": "sha512-Cc+OraorugtXNfs50hU9KS369rFXCfgGLpfCfvlc+Ud5u6VWmUQsOAa9HbTvheQdYnrdJqqv1e5oIqXppMYnSw==",
"engines": {
"node": ">=8"
}
},
"node_modules/toidentifier": { "node_modules/toidentifier": {
"version": "1.0.1", "version": "1.0.1",
"resolved": "https://registry.npmjs.org/toidentifier/-/toidentifier-1.0.1.tgz", "resolved": "https://registry.npmjs.org/toidentifier/-/toidentifier-1.0.1.tgz",

View File

@ -13,6 +13,7 @@
"dotenv": "^16.0.3", "dotenv": "^16.0.3",
"express": "^4.18.2", "express": "^4.18.2",
"express-session": "^1.17.3", "express-session": "^1.17.3",
"knex": "^2.4.2",
"pg": "^8.9.0", "pg": "^8.9.0",
"pg-promise": "^11.2.0", "pg-promise": "^11.2.0",
"response-time": "^2.3.2", "response-time": "^2.3.2",

View File

@ -1,104 +0,0 @@
SET client_encoding TO 'UTF8';
DROP TABLE IF EXISTS osp_unit CASCADE;
DROP TABLE IF EXISTS fire_truck CASCADE;
DROP TABLE IF EXISTS truck_side CASCADE;
DROP TABLE IF EXISTS cache CASCADE;
DROP TABLE IF EXISTS account CASCADE;
DROP TABLE IF EXISTS equipment CASCADE;
DROP TABLE IF EXISTS score CASCADE;
DROP TABLE IF EXISTS permission CASCADE;
DROP TABLE IF EXISTS accounts_permissions CASCADE;
DROP TABLE IF EXISTS event CASCADE;
DROP TABLE IF EXISTS user_session;
CREATE TABLE osp_unit (
id SERIAL PRIMARY KEY,
name VARCHAR(128) NOT NULL,
locality VARCHAR(64) NOT NULL CHECK(locality SIMILAR TO '[A-ZĄĆĘŁŃÓŚŹŻ][A-zĄĆĘŁŃÓŚŹŻząćęłńóśźż. ]+')
);
CREATE TABLE fire_truck (
id SERIAL PRIMARY KEY,
name VARCHAR(64) NOT NULL,
image_path VARCHAR(128) CHECK(image_path ~ '^([0-9A-Za-z_]+/?)*[0-9A-Za-z_]+\.((png)|(jpg)|(jpeg)|(webp))$'),
osp_unit_id INTEGER NOT NULL REFERENCES osp_unit ON DELETE CASCADE ON UPDATE CASCADE
);
CREATE TABLE truck_side (
id SERIAL PRIMARY KEY,
image_path VARCHAR(128) NOT NULL CHECK(image_path ~ '^([0-9A-Za-z_]+/?)*[0-9A-Za-z_]+\.((png)|(jpg)|(jpeg)|(webp))$'),
ordinal_number INTEGER NOT NULL,
fire_truck_id INTEGER REFERENCES fire_truck ON DELETE CASCADE ON UPDATE CASCADE
);
CREATE TABLE cache (
id SERIAL PRIMARY KEY,
name VARCHAR(64),
rectangle BOX NOT NULL CHECK(
(rectangle[0])[0] <= 1 AND (rectangle[0])[0] >= 0 AND
(rectangle[0])[1] <= 1 AND (rectangle[0])[1] >= 0 AND
(rectangle[1])[0] <= 1 AND (rectangle[1])[0] >= 0 AND
(rectangle[1])[1] <= 1 AND (rectangle[1])[1] >= 0
),
truck_side INTEGER NOT NULL REFERENCES truck_side ON DELETE CASCADE ON UPDATE CASCADE
);
CREATE TABLE account (
nickname VARCHAR(32) CHECK(nickname SIMILAR TO '[0-9A-z_żółćęśąźńŻÓŁĆĘŚĄŹŃ]{3,}') PRIMARY KEY,
name VARCHAR(32) CHECK(name SIMILAR TO '[A-ZŻÓŁĆĘŚĄŹŃ][a-zżółćęśąźń]+'),
surname VARCHAR(64) CHECK(surname SIMILAR TO '[A-ZŻÓŁĆĘŚĄŹŃ][a-zżółćęśąźń]+'),
pass_hash CHAR(72) NOT NULL, -- Tu należy dostosować odpowiednio dla wybranego sposobu hashowania
default_osp INTEGER REFERENCES osp_unit ON DELETE SET NULL ON UPDATE CASCADE
);
CREATE TABLE equipment (
id SERIAL PRIMARY KEY,
name VARCHAR(64) NOT NULL CHECK(LENGTH(name) > 0),
cache_id INTEGER NOT NULL REFERENCES cache ON DELETE CASCADE ON UPDATE CASCADE
);
CREATE TABLE score (
id SERIAL PRIMARY KEY,
account_nickname VARCHAR(32) REFERENCES account ON DELETE CASCADE ON UPDATE CASCADE,
acquisition_timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
fire_truck_id INTEGER NOT NULL REFERENCES fire_truck ON DELETE CASCADE ON UPDATE CASCADE,
points INTEGER NOT NULL CHECK(points BETWEEN 0 AND 10),
seconds INTEGER NOT NULL CHECK(seconds > 0)
);
CREATE TABLE permission (
code VARCHAR(64) CHECK(code ~ '^[0-9A-Z_]{3,}$') PRIMARY KEY,
name VARCHAR(64) CHECK(LENGTH(name) >= 3),
description VARCHAR(128)
);
-- PYTANIE: Czy aktualizować permission code przy zmianie czy na NULL?
CREATE TABLE accounts_permissions (
account_nickname VARCHAR(32) REFERENCES account ON DELETE CASCADE ON UPDATE CASCADE,
permission_code VARCHAR(64) REFERENCES permission ON DELETE CASCADE ON UPDATE CASCADE,
osp_unit_id INTEGER REFERENCES osp_unit ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT pk_users_permissions PRIMARY KEY (account_nickname, permission_code, osp_unit_id)
);
CREATE TABLE event (
id SERIAL PRIMARY KEY,
name VARCHAR(64) NOT NULL CHECK(LENGTH(name) >= 3),
details VARCHAR(128),
report_time TIMESTAMP WITH TIME ZONE
CHECK(report_time <= NOW() AND DATE_PART('hour', CURRENT_TIMESTAMP - report_time) < 1),
-- Chcemy zachować spójność dziennika zdarzeń, nawet jak użytkownik usunie konto:
account_nickname VARCHAR(32) REFERENCES account ON DELETE SET NULL ON UPDATE CASCADE,
osp_unit_id INTEGER REFERENCES osp_unit ON DELETE CASCADE ON UPDATE CASCADE
);
CREATE TABLE user_session (
"sid" varchar NOT NULL COLLATE "default",
"sess" json NOT NULL,
"expire" timestamp(6) NOT NULL
)
WITH (OIDS=FALSE);
ALTER TABLE user_session ADD CONSTRAINT "session_pkey" PRIMARY KEY ("sid") NOT DEFERRABLE INITIALLY IMMEDIATE;
CREATE INDEX "IDX_session_expire" ON user_session ("expire");

View File

@ -1,64 +0,0 @@
DROP VIEW IF EXISTS units_list;
CREATE VIEW units_list AS
SELECT id, name, locality FROM osp_unit;
DROP FUNCTION IF EXISTS get_units_list;
CREATE FUNCTION get_units_list(prefix VARCHAR) RETURNS TABLE (id INTEGER, name VARCHAR, locality VARCHAR)
AS
$func$
SELECT * FROM units_list
WHERE LOWER(locality) LIKE LOWER('%' || prefix || '%')
OR LOWER(name) LIKE LOWER('%' || prefix || '%')
ORDER BY locality, name LIMIT 3;
$func$
LANGUAGE SQL;
DROP FUNCTION IF EXISTS get_trucks_list_with_scores;
CREATE FUNCTION get_trucks_list_with_scores(osp_unit INTEGER, nickname VARCHAR, last_scores_num INTEGER = 3)
RETURNS TABLE (id INTEGER, name VARCHAR, image_path VARCHAR, avg_percent FLOAT) AS
$func$
SELECT ft.id, name, image_path, ROUND(AVG(s.points) * 10, 2) AS avg_percent
FROM fire_truck ft
JOIN score s ON ft.id = s.fire_truck_id AND s.account_nickname = nickname
WHERE ft.osp_unit_id = osp_unit AND s.id IN (
SELECT sc.id FROM score sc
WHERE sc.account_nickname = nickname AND sc.fire_truck_id = ft.id
ORDER BY sc.acquisition_timestamp DESC
LIMIT last_scores_num
) GROUP BY ft.id, name, image_path
UNION
(SELECT ft.id, name, image_path, 0
FROM fire_truck ft
WHERE ft.osp_unit_id = osp_unit AND
ft.id NOT IN (SELECT fire_truck_id FROM score WHERE account_nickname = nickname))
ORDER BY 1;
$func$
LANGUAGE SQL;
DROP FUNCTION IF EXISTS get_quiz_data_for_truck;
CREATE FUNCTION get_quiz_data_for_truck(truck_id INTEGER)
RETURNS TABLE (side_id INTEGER, side_image_path VARCHAR, cache_id INTEGER,
cache_rectangle BOX, cache_name VARCHAR) AS
$func$
SELECT ts.id, ts.image_path, c.id, c.rectangle, c.name
FROM fire_truck
JOIN truck_side ts on fire_truck.id = ts.fire_truck_id
JOIN cache c on ts.id = c.truck_side
WHERE fire_truck.id = truck_id
ORDER BY ts.ordinal_number;
$func$
LANGUAGE SQL;
DROP FUNCTION IF EXISTS get_random_question;
CREATE FUNCTION get_random_question(truck_id INTEGER)
RETURNS TABLE (cache_id INTEGER, equipment_name VARCHAR) AS
$func$
SELECT c.id, e.name
FROM truck_side ts
JOIN cache c on ts.id = c.truck_side
JOIN equipment e on c.id = e.cache_id
WHERE ts.fire_truck_id = truck_id
ORDER BY RANDOM()
LIMIT 1;
$func$
LANGUAGE SQL;