Changed database schema for groups & permissions. Implemented versioning.

This commit is contained in:
Richard Underwood 2017-01-04 11:45:01 +00:00
parent 119e1376ee
commit f2377913f0
5 changed files with 138 additions and 25 deletions

61
includes/database.inc.php Normal file
View file

@ -0,0 +1,61 @@
<?php
// matches version in scheme.sql
$db_version=2;
// Initialise a new DB with latest version
function init_db() {
global $authdb, $db;
is_dir(dirname($authdb)) || mkdir(dirname($authdb));
$db = new SQLite3($authdb, SQLITE3_OPEN_CREATE|SQLITE3_OPEN_READWRITE);
$createsql = file_get_contents('includes/scheme.sql');
$db->exec($createsql);
$salt = bin2hex(openssl_random_pseudo_bytes(16));
$db->exec("INSERT INTO users (emailaddress, password, isadmin) VALUES ('admin', '".crypt("admin", '$6$'.$salt)."', 1)");
return $db;
}
function open_db() {
global $authdb, $db;
if (!isset($db)) {
$db = new SQLite3($authdb, SQLITE3_OPEN_READWRITE);
$db->exec('PRAGMA foreign_keys = 1');
}
$version = intval($db->querySingle('SELECT value FROM metadata WHERE name = "version"'));
switch($version) {
case 0:
$sql = file_get_contents('includes/upgrade-0-1.sql');
$db->exec($sql);
writelog("Upgraded schema to version 1","system");
// continue
case 1: // never existed
$sql = file_get_contents('includes/upgrade-1-2.sql');
$db->exec($sql);
writelog("Upgraded schema to version 2","system");
// continue
case $db_version:
break;
}
return $db;
}
function get_db() {
global $authdb, $db;
if (!isset($db)) {
$db = new SQLite3($authdb, SQLITE3_OPEN_READWRITE);
$db->exec('PRAGMA foreign_keys = 1');
}
return $db;
}
?>

View file

@ -1,6 +1,7 @@
<?php <?php
include_once('config.inc.php'); include_once('config.inc.php');
include_once('database.inc.php');
$blocklogin = FALSE; $blocklogin = FALSE;
@ -59,13 +60,12 @@ if (function_exists('openssl_random_pseudo_bytes') === FALSE) {
$defaults['defaulttype'] = ucfirst(strtolower($defaults['defaulttype'])); $defaults['defaulttype'] = ucfirst(strtolower($defaults['defaulttype']));
if (isset($authdb) && !file_exists($authdb) && class_exists('SQLite3')) { if(class_exists('SQLite3')) {
is_dir(dirname($authdb)) || mkdir(dirname($authdb)); if (isset($authdb) && !file_exists($authdb)) {
$db = new SQLite3($authdb, SQLITE3_OPEN_CREATE|SQLITE3_OPEN_READWRITE); init_db();
$createsql = file_get_contents('includes/scheme.sql'); } else {
$db->exec($createsql); open_db();
$salt = bin2hex(openssl_random_pseudo_bytes(16)); }
$db->exec("INSERT INTO users (emailaddress, password, isadmin) VALUES ('admin', '".crypt("admin", '$6$'.$salt)."', 1)");
} }
function string_starts_with($string, $prefix) function string_starts_with($string, $prefix)
@ -84,17 +84,6 @@ function string_ends_with($string, $suffix)
return (substr($string, -$length) === $suffix); return (substr($string, -$length) === $suffix);
} }
function get_db() {
global $authdb, $db;
if (!isset($db)) {
$db = new SQLite3($authdb, SQLITE3_OPEN_READWRITE);
$db->exec('PRAGMA foreign_keys = 1');
}
return $db;
}
function get_all_users() { function get_all_users() {
$db = get_db(); $db = get_db();
$r = $db->query('SELECT id, emailaddress, isadmin FROM users ORDER BY emailaddress'); $r = $db->query('SELECT id, emailaddress, isadmin FROM users ORDER BY emailaddress');
@ -379,13 +368,6 @@ function writelog($line, $user=False) {
try { try {
$db = get_db(); $db = get_db();
$q = $db->prepare('CREATE TABLE IF NOT EXISTS logs (
id INTEGER PRIMARY KEY,
user TEXT NOT NULL,
log TEXT NOT NULL,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP);');
$ret = $q->execute();
$q = $db->prepare('INSERT INTO logs (user, log) VALUES (:user, :log)'); $q = $db->prepare('INSERT INTO logs (user, log) VALUES (:user, :log)');
$q->bindValue(':user', $user, SQLITE3_TEXT); $q->bindValue(':user', $user, SQLITE3_TEXT);
$q->bindValue(':log', $line, SQLITE3_TEXT); $q->bindValue(':log', $line, SQLITE3_TEXT);

View file

@ -12,3 +12,39 @@ CREATE TABLE zones (
owner INTEGER NOT NULL, owner INTEGER NOT NULL,
UNIQUE(zone), UNIQUE(zone),
FOREIGN KEY(owner) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE ); FOREIGN KEY(owner) REFERENCES users(id) ON DELETE CASCADE ON UPDATE CASCADE );
CREATE TABLE logs (
id INTEGER PRIMARY KEY,
user TEXT NOT NULL,
log TEXT NOT NULL,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP);
CREATE TABLE groups (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name VARCHAR UNIQUE NOT NULL,
desc VARCHAR);
CREATE TABLE groupmembers (
id INTEGER PRIMARY KEY AUTOINCREMENT,
"group" INTEGER NOT NULL,
user INTEGER NOT NULL,
UNIQUE("group",user),
FOREIGN KEY("group") REFERENCES groups(id) ON DELETE CASCADE,
FOREIGN KEY(user) REFERENCES users(id) ON DELETE CASCADE);
CREATE TABLE permissions (
id INTEGER PRIMARY KEY AUTOINCREMENT,
zone INTEGER NOT NULL,
user INTEGER,
"group" INTEGER,
permissions INTEGER,
UNIQUE(zone,user,"group"),
FOREIGN KEY(zone) REFERENCES zones(id) ON DELETE CASCADE,
FOREIGN KEY(user) REFERENCES users(id) ON DELETE CASCADE,
FOREIGN KEY("group") REFERENCES groups(id) ON DELETE CASCADE);
CREATE TABLE metadata (
name VARCHAR PRIMARY KEY,
value VARCHAR NOT NULL);
INSERT INTO metadata (name, value) VALUES ("version","2");

5
includes/upgrade-0-1.sql Normal file
View file

@ -0,0 +1,5 @@
CREATE TABLE IF NOT EXISTS logs (
id INTEGER PRIMARY KEY,
user TEXT NOT NULL,
log TEXT NOT NULL,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP);

29
includes/upgrade-1-2.sql Normal file
View file

@ -0,0 +1,29 @@
CREATE TABLE groups (
id INTEGER PRIMARY KEY AUTOINCREMENT,
name VARCHAR UNIQUE NOT NULL,
desc VARCHAR);
CREATE TABLE groupmembers (
id INTEGER PRIMARY KEY AUTOINCREMENT,
"group" INTEGER NOT NULL,
user INTEGER NOT NULL,
UNIQUE("group",user),
FOREIGN KEY("group") REFERENCES groups(id) ON DELETE CASCADE,
FOREIGN KEY(user) REFERENCES users(id) ON DELETE CASCADE);
CREATE TABLE permissions (
id INTEGER PRIMARY KEY AUTOINCREMENT,
zone INTEGER NOT NULL,
user INTEGER,
"group" INTEGER,
permissions INTEGER,
UNIQUE(zone,user,"group"),
FOREIGN KEY(zone) REFERENCES zones(id) ON DELETE CASCADE,
FOREIGN KEY(user) REFERENCES users(id) ON DELETE CASCADE,
FOREIGN KEY("group") REFERENCES groups(id) ON DELETE CASCADE);
CREATE TABLE metadata (
name VARCHAR PRIMARY KEY,
value VARCHAR NOT NULL);
INSERT INTO metadata (name, value) VALUES ("version","2");