forked from Public/pics
Add SQLite support as alternative database backend
Support config-driven choice between MySQL and SQLite via DB_DRIVER constant, defaulting to MySQL for backward compatibility. All SQL adaptation lives in Database.php (UDFs + query rewriting), so model files need no changes. Co-Authored-By: Claude Opus 4.6 <noreply@anthropic.com> SQLite: remove FK constraints, revert 0→null sentinel changes The SQLite schema had FOREIGN KEY constraints that don't exist in the MySQL schema. These forced a cascade of 0→null changes to satisfy FK enforcement. Removing them keeps the two backends behaviorally consistent and minimises the diff. Real SQLite compat fixes (UDFs, query rewriting, rowCount→count, Router fixes, EditAlbum guard) are preserved. Co-Authored-By: Claude Opus 4.6 <noreply@anthropic.com>
This commit is contained in:
8
app.php
8
app.php
@@ -14,7 +14,13 @@ require_once 'vendor/autoload.php';
|
||||
|
||||
// Initialise the database.
|
||||
Registry::set('start', microtime(true));
|
||||
Registry::set('db', new Database(DB_SERVER, DB_USER, DB_PASS, DB_NAME));
|
||||
if (defined('DB_DRIVER') && DB_DRIVER === 'sqlite')
|
||||
Registry::set('db', new Database('sqlite', ['file' => DB_FILE]));
|
||||
else
|
||||
Registry::set('db', new Database('mysql', [
|
||||
'host' => DB_SERVER, 'user' => DB_USER,
|
||||
'password' => DB_PASS, 'name' => DB_NAME,
|
||||
]));
|
||||
|
||||
// Handle errors our own way.
|
||||
ErrorHandler::enable();
|
||||
|
||||
@@ -206,7 +206,7 @@ class EditAlbum extends HTMLController
|
||||
$data = $this->form->getData();
|
||||
|
||||
// Sanity check: don't let an album be its own parent
|
||||
if ($data['id_parent'] == $id_tag)
|
||||
if ($id_tag && $data['id_parent'] == $id_tag)
|
||||
{
|
||||
return $this->formview->adopt(new Alert('Invalid parent', 'An album cannot be its own parent.', 'danger'));
|
||||
}
|
||||
|
||||
@@ -10,7 +10,6 @@ class AssetIterator implements Iterator
|
||||
{
|
||||
private $direction;
|
||||
private $return_format;
|
||||
private $rowCount;
|
||||
|
||||
private $assets_iterator;
|
||||
private $meta_iterator;
|
||||
@@ -21,7 +20,6 @@ class AssetIterator implements Iterator
|
||||
{
|
||||
$this->direction = $direction;
|
||||
$this->return_format = $return_format;
|
||||
$this->rowCount = $stmt_assets->rowCount();
|
||||
|
||||
$this->assets_iterator = new CachedPDOIterator($stmt_assets);
|
||||
$this->assets_iterator->rewind();
|
||||
@@ -209,7 +207,7 @@ class AssetIterator implements Iterator
|
||||
|
||||
public function num(): int
|
||||
{
|
||||
return $this->rowCount;
|
||||
return count($this->assets_iterator);
|
||||
}
|
||||
|
||||
public function rewind(): void
|
||||
|
||||
@@ -9,18 +9,35 @@
|
||||
class Database
|
||||
{
|
||||
private $connection;
|
||||
private $driver;
|
||||
private $query_count = 0;
|
||||
private $logged_queries = [];
|
||||
|
||||
public function __construct($host, $user, $password, $name)
|
||||
public function __construct($driver, array $options)
|
||||
{
|
||||
$this->driver = $driver;
|
||||
|
||||
try
|
||||
{
|
||||
$this->connection = new PDO("mysql:host=$host;dbname=$name;charset=utf8mb4", $user, $password, [
|
||||
PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION,
|
||||
PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC,
|
||||
PDO::ATTR_EMULATE_PREPARES => false,
|
||||
]);
|
||||
if ($driver === 'sqlite')
|
||||
{
|
||||
$this->connection = new PDO("sqlite:" . $options['file'], null, null, [
|
||||
PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION,
|
||||
PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC,
|
||||
]);
|
||||
$this->connection->exec('PRAGMA journal_mode=WAL');
|
||||
$this->registerSQLiteFunctions();
|
||||
}
|
||||
else
|
||||
{
|
||||
$this->connection = new PDO(
|
||||
"mysql:host={$options['host']};dbname={$options['name']};charset=utf8mb4",
|
||||
$options['user'], $options['password'], [
|
||||
PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION,
|
||||
PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC,
|
||||
PDO::ATTR_EMULATE_PREPARES => false,
|
||||
]);
|
||||
}
|
||||
}
|
||||
// Give up if we have a connection error.
|
||||
catch (PDOException $e)
|
||||
@@ -31,6 +48,72 @@ class Database
|
||||
}
|
||||
}
|
||||
|
||||
private function registerSQLiteFunctions()
|
||||
{
|
||||
$pdo = $this->connection;
|
||||
|
||||
$pdo->sqliteCreateFunction('CONCAT', function () {
|
||||
return implode('', func_get_args());
|
||||
}, -1);
|
||||
|
||||
$pdo->sqliteCreateFunction('IF', function ($cond, $t, $f) {
|
||||
return $cond ? $t : $f;
|
||||
}, 3);
|
||||
|
||||
$pdo->sqliteCreateFunction('FROM_UNIXTIME', function ($ts) {
|
||||
return date('Y-m-d H:i:s', $ts);
|
||||
}, 1);
|
||||
|
||||
$pdo->sqliteCreateFunction('UNIX_TIMESTAMP', function () {
|
||||
return time();
|
||||
}, 0);
|
||||
|
||||
$pdo->sqliteCreateFunction('CURRENT_TIMESTAMP', function () {
|
||||
return date('Y-m-d H:i:s');
|
||||
}, 0);
|
||||
}
|
||||
|
||||
private function rewriteForSQLite($sql)
|
||||
{
|
||||
// REPLACE INTO → INSERT OR REPLACE INTO
|
||||
$sql = preg_replace('/\bREPLACE\s+INTO\b/i', 'INSERT OR REPLACE INTO', $sql);
|
||||
|
||||
// ON DUPLICATE KEY UPDATE → ON CONFLICT(slug) DO UPDATE SET
|
||||
// When present, strip INSERT IGNORE down to INSERT (OR IGNORE conflicts with ON CONFLICT).
|
||||
if (preg_match('/\bON\s+DUPLICATE\s+KEY\s+UPDATE\b/i', $sql))
|
||||
{
|
||||
$sql = preg_replace('/\bINSERT\s+IGNORE\s+INTO\b/i', 'INSERT INTO', $sql);
|
||||
$sql = preg_replace(
|
||||
'/\bON\s+DUPLICATE\s+KEY\s+UPDATE\s+(.+)/i',
|
||||
'ON CONFLICT(slug) DO UPDATE SET $1',
|
||||
$sql
|
||||
);
|
||||
}
|
||||
else
|
||||
{
|
||||
// INSERT IGNORE INTO → INSERT OR IGNORE INTO
|
||||
$sql = preg_replace('/\bINSERT\s+IGNORE\s+INTO\b/i', 'INSERT OR IGNORE INTO', $sql);
|
||||
}
|
||||
|
||||
// UPDATE table AS alias SET ... → UPDATE table SET ... (with alias replaced by table name)
|
||||
if (preg_match('/\bUPDATE\s+(\w+)\s+AS\s+(\w+)\s+SET\b/i', $sql, $m))
|
||||
{
|
||||
$table = $m[1];
|
||||
$alias = $m[2];
|
||||
$sql = preg_replace('/\bUPDATE\s+\w+\s+AS\s+\w+\s+SET\b/i', "UPDATE $table SET", $sql);
|
||||
$sql = preg_replace('/\b' . preg_quote($alias, '/') . '\.(\w+)\b/', "$table.$1", $sql);
|
||||
}
|
||||
|
||||
// LIMIT :offset, :limit → LIMIT :limit OFFSET :offset
|
||||
$sql = preg_replace(
|
||||
'/\bLIMIT\s+:offset\s*,\s*:limit\b/i',
|
||||
'LIMIT :limit OFFSET :offset',
|
||||
$sql
|
||||
);
|
||||
|
||||
return $sql;
|
||||
}
|
||||
|
||||
public function getQueryCount()
|
||||
{
|
||||
return $this->query_count;
|
||||
@@ -180,6 +263,10 @@ class Database
|
||||
// Preprocessing/checks: prepare any arrays for binding
|
||||
$db_string = $this->expandPlaceholders($db_string, $db_values);
|
||||
|
||||
// SQLite query rewriting
|
||||
if ($this->driver === 'sqlite')
|
||||
$db_string = $this->rewriteForSQLite($db_string);
|
||||
|
||||
// Prepare query for execution
|
||||
$statement = $this->connection->prepare($db_string);
|
||||
|
||||
@@ -223,13 +310,10 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if (!$res || $this->rowCount($res) === 0)
|
||||
return null;
|
||||
|
||||
$object = $this->fetchObject($res, $class);
|
||||
$this->free($res);
|
||||
|
||||
return $object;
|
||||
return $object ?: null;
|
||||
}
|
||||
|
||||
/**
|
||||
@@ -239,9 +323,6 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if (!$res || $this->rowCount($res) === 0)
|
||||
return [];
|
||||
|
||||
$rows = [];
|
||||
while ($object = $this->fetchObject($res, $class))
|
||||
$rows[] = $object;
|
||||
@@ -258,13 +339,10 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if ($this->rowCount($res) === 0)
|
||||
return [];
|
||||
|
||||
$row = $this->fetchNum($res);
|
||||
$this->free($res);
|
||||
|
||||
return $row;
|
||||
return $row ?: [];
|
||||
}
|
||||
|
||||
/**
|
||||
@@ -274,9 +352,6 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if ($this->rowCount($res) === 0)
|
||||
return [];
|
||||
|
||||
$rows = [];
|
||||
while ($row = $this->fetchNum($res))
|
||||
$rows[] = $row;
|
||||
@@ -293,9 +368,6 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if ($this->rowCount($res) === 0)
|
||||
return [];
|
||||
|
||||
$rows = [];
|
||||
while ($row = $this->fetchNum($res))
|
||||
$rows[$row[0]] = $row[1];
|
||||
@@ -312,9 +384,6 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if (!$res || $this->rowCount($res) === 0)
|
||||
return [];
|
||||
|
||||
$rows = [];
|
||||
while ($row = $this->fetchAssoc($res))
|
||||
{
|
||||
@@ -334,13 +403,10 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if ($this->rowCount($res) === 0)
|
||||
return [];
|
||||
|
||||
$row = $this->fetchAssoc($res);
|
||||
$this->free($res);
|
||||
|
||||
return $row;
|
||||
return $row ?: [];
|
||||
}
|
||||
|
||||
/**
|
||||
@@ -350,9 +416,6 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if ($this->rowCount($res) === 0)
|
||||
return [];
|
||||
|
||||
$rows = [];
|
||||
while ($row = $this->fetchAssoc($res))
|
||||
$rows[] = $row;
|
||||
@@ -369,14 +432,13 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
// If this happens, you're doing it wrong.
|
||||
if ($this->rowCount($res) === 0)
|
||||
return null;
|
||||
|
||||
list($value) = $this->fetchNum($res);
|
||||
$row = $this->fetchNum($res);
|
||||
$this->free($res);
|
||||
|
||||
return $value;
|
||||
if (!$row)
|
||||
return null;
|
||||
|
||||
return $row[0];
|
||||
}
|
||||
|
||||
/**
|
||||
@@ -386,9 +448,6 @@ class Database
|
||||
{
|
||||
$res = $this->query($db_string, $db_values);
|
||||
|
||||
if ($this->rowCount($res) === 0)
|
||||
return [];
|
||||
|
||||
$rows = [];
|
||||
while ($row = $this->fetchNum($res))
|
||||
$rows[] = $row[0];
|
||||
@@ -412,7 +471,10 @@ class Database
|
||||
$data = [$data];
|
||||
|
||||
// Determine the method of insertion.
|
||||
$method = $method == 'replace' ? 'REPLACE' : ($method == 'ignore' ? 'INSERT IGNORE' : 'INSERT');
|
||||
if ($this->driver === 'sqlite')
|
||||
$method = $method == 'replace' ? 'INSERT OR REPLACE' : ($method == 'ignore' ? 'INSERT OR IGNORE' : 'INSERT');
|
||||
else
|
||||
$method = $method == 'replace' ? 'REPLACE' : ($method == 'ignore' ? 'INSERT IGNORE' : 'INSERT');
|
||||
|
||||
// What columns are we inserting?
|
||||
$columns = array_keys($data[0]);
|
||||
|
||||
@@ -123,7 +123,7 @@ class ErrorHandler
|
||||
'debug_info' => $debug_info,
|
||||
'file' => str_replace(BASEDIR, '', $file),
|
||||
'line' => $line,
|
||||
'id_user' => Registry::has('user') ? Registry::get('user')->getUserId() : 0,
|
||||
'id_user' => Registry::has('user') && Registry::get('user')->getUserId() ? Registry::get('user')->getUserId() : 0,
|
||||
'ip_address' => isset($_SERVER['REMOTE_ADDR']) ? $_SERVER['REMOTE_ADDR'] : '',
|
||||
'request_uri' => isset($_SERVER['REQUEST_URI']) ? $_SERVER['REQUEST_URI'] : '',
|
||||
]))
|
||||
|
||||
@@ -13,7 +13,7 @@ class Router
|
||||
$possibleActions = [
|
||||
'accountsettings' => 'AccountSettings',
|
||||
'addalbum' => 'EditAlbum',
|
||||
'albums' => 'ViewPhotoAlbums',
|
||||
'albums' => 'ViewPhotoAlbum',
|
||||
'editalbum' => 'EditAlbum',
|
||||
'editasset' => 'EditAsset',
|
||||
'edittag' => 'EditTag',
|
||||
@@ -54,7 +54,7 @@ class Router
|
||||
return new GenerateThumbnail();
|
||||
}
|
||||
// Look for particular actions...
|
||||
elseif (preg_match('~^/(?<action>[a-z]+)(?:/page/(?<page>\d+))?/?~', $_SERVER['PATH_INFO'], $path) && isset($possibleActions[$path['action']]))
|
||||
elseif (preg_match('~^/(?<action>[a-z]+)(?:/page/(?<page>\d+))?/?$~', $_SERVER['PATH_INFO'], $path) && isset($possibleActions[$path['action']]))
|
||||
{
|
||||
$_GET = array_merge($_GET, $path);
|
||||
return new $possibleActions[$path['action']]();
|
||||
|
||||
@@ -294,6 +294,8 @@ class Tag
|
||||
|
||||
public function save()
|
||||
{
|
||||
$vars = get_object_vars($this);
|
||||
|
||||
return Registry::get('db')->query('
|
||||
UPDATE tags
|
||||
SET
|
||||
@@ -306,7 +308,7 @@ class Tag
|
||||
description = :description,
|
||||
count = :count
|
||||
WHERE id_tag = :id_tag',
|
||||
get_object_vars($this));
|
||||
$vars);
|
||||
}
|
||||
|
||||
public function delete()
|
||||
@@ -461,10 +463,12 @@ class Tag
|
||||
$albums_by_parent = [];
|
||||
while ($row = $db->fetchAssoc($res))
|
||||
{
|
||||
if (!isset($albums_by_parent[$row['id_parent']]))
|
||||
$albums_by_parent[$row['id_parent']] = [];
|
||||
$parent = $row['id_parent'];
|
||||
|
||||
$albums_by_parent[$row['id_parent']][] = $row + ['children' => []];
|
||||
if (!isset($albums_by_parent[$parent]))
|
||||
$albums_by_parent[$parent] = [];
|
||||
|
||||
$albums_by_parent[$parent][] = $row + ['children' => []];
|
||||
}
|
||||
|
||||
$albums = self::getChildrenRecursively(0, 0, $albums_by_parent);
|
||||
|
||||
103
schema.sqlite.sql
Normal file
103
schema.sqlite.sql
Normal file
@@ -0,0 +1,103 @@
|
||||
-- SQLite schema for Kabuki CMS / pics
|
||||
--
|
||||
-- Usage:
|
||||
-- sqlite3 data/pics.sqlite < schema.sqlite.sql
|
||||
--
|
||||
-- Config (add to config.php):
|
||||
-- define('DB_DRIVER', 'sqlite');
|
||||
-- define('DB_FILE', __DIR__ . '/data/pics.sqlite');
|
||||
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
id_user INTEGER PRIMARY KEY,
|
||||
first_name TEXT NOT NULL,
|
||||
surname TEXT NOT NULL,
|
||||
slug TEXT NOT NULL UNIQUE,
|
||||
emailaddress TEXT NOT NULL UNIQUE,
|
||||
password_hash TEXT NOT NULL,
|
||||
creation_time INTEGER NOT NULL,
|
||||
last_action_time INTEGER,
|
||||
ip_address TEXT,
|
||||
is_admin INTEGER NOT NULL DEFAULT 0,
|
||||
reset_key TEXT,
|
||||
reset_blocked_until INTEGER
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS assets (
|
||||
id_asset INTEGER PRIMARY KEY,
|
||||
id_user_uploaded INTEGER NOT NULL,
|
||||
subdir TEXT NOT NULL,
|
||||
filename TEXT NOT NULL,
|
||||
title TEXT,
|
||||
slug TEXT UNIQUE,
|
||||
mimetype TEXT,
|
||||
image_width INTEGER,
|
||||
image_height INTEGER,
|
||||
date_captured TEXT,
|
||||
priority INTEGER DEFAULT 0
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS assets_meta (
|
||||
id_asset INTEGER NOT NULL,
|
||||
variable TEXT NOT NULL,
|
||||
value TEXT,
|
||||
PRIMARY KEY (id_asset, variable)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS assets_thumbs (
|
||||
id_asset INTEGER NOT NULL,
|
||||
width INTEGER NOT NULL,
|
||||
height INTEGER NOT NULL,
|
||||
mode TEXT,
|
||||
filename TEXT,
|
||||
PRIMARY KEY (id_asset, width, height, mode)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS tags (
|
||||
id_tag INTEGER PRIMARY KEY,
|
||||
id_parent INTEGER,
|
||||
id_asset_thumb INTEGER,
|
||||
id_user_owner INTEGER,
|
||||
tag TEXT NOT NULL,
|
||||
slug TEXT NOT NULL UNIQUE,
|
||||
description TEXT,
|
||||
kind TEXT NOT NULL DEFAULT 'Tag',
|
||||
count INTEGER DEFAULT 0
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS assets_tags (
|
||||
id_asset INTEGER NOT NULL,
|
||||
id_tag INTEGER NOT NULL,
|
||||
PRIMARY KEY (id_asset, id_tag)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS posts_assets (
|
||||
id_post INTEGER NOT NULL,
|
||||
id_asset INTEGER NOT NULL,
|
||||
PRIMARY KEY (id_post, id_asset)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS posts_tags (
|
||||
id_post INTEGER NOT NULL,
|
||||
id_tag INTEGER NOT NULL,
|
||||
PRIMARY KEY (id_post, id_tag)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS settings (
|
||||
id_user INTEGER NOT NULL,
|
||||
variable TEXT NOT NULL,
|
||||
value TEXT,
|
||||
time_set TEXT DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (id_user, variable)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS log_errors (
|
||||
id_entry INTEGER PRIMARY KEY,
|
||||
id_user INTEGER,
|
||||
message TEXT,
|
||||
debug_info TEXT,
|
||||
file TEXT,
|
||||
line INTEGER,
|
||||
request_uri TEXT,
|
||||
time TEXT DEFAULT CURRENT_TIMESTAMP,
|
||||
ip_address TEXT
|
||||
);
|
||||
58
seed.php
Normal file
58
seed.php
Normal file
@@ -0,0 +1,58 @@
|
||||
<?php
|
||||
/*****************************************************************************
|
||||
* seed.php
|
||||
* Seeds a fresh database with an admin user and root album.
|
||||
*
|
||||
* Usage: php seed.php
|
||||
*****************************************************************************/
|
||||
|
||||
require_once __DIR__ . '/config.php';
|
||||
require_once __DIR__ . '/vendor/autoload.php';
|
||||
|
||||
if (!defined('DB_DRIVER') || DB_DRIVER !== 'sqlite')
|
||||
{
|
||||
echo "Error: seed.php currently only supports SQLite.\n";
|
||||
echo "Set DB_DRIVER to 'sqlite' in config.php.\n";
|
||||
exit(1);
|
||||
}
|
||||
|
||||
if (!file_exists(DB_FILE))
|
||||
{
|
||||
echo "Error: database file not found at " . DB_FILE . "\n";
|
||||
echo "Create it first: sqlite3 " . DB_FILE . " < schema.sqlite.sql\n";
|
||||
exit(1);
|
||||
}
|
||||
|
||||
$db = new Database('sqlite', ['file' => DB_FILE]);
|
||||
Registry::set('db', $db);
|
||||
|
||||
// Create admin user.
|
||||
$password = 'admin';
|
||||
$hash = password_hash($password, PASSWORD_DEFAULT);
|
||||
|
||||
$db->insert('insert', 'users', [], [
|
||||
'first_name' => 'Admin',
|
||||
'surname' => 'User',
|
||||
'slug' => 'admin',
|
||||
'emailaddress' => 'admin@localhost',
|
||||
'password_hash' => $hash,
|
||||
'creation_time' => time(),
|
||||
'ip_address' => '',
|
||||
'is_admin' => 1,
|
||||
'reset_key' => '',
|
||||
]);
|
||||
|
||||
echo "Created admin user (admin@localhost / admin)\n";
|
||||
|
||||
// Create root album (id_tag = 1).
|
||||
$db->insert('insert', 'tags', [], [
|
||||
'id_parent' => 0,
|
||||
'tag' => 'Albums',
|
||||
'slug' => 'albums',
|
||||
'kind' => 'Album',
|
||||
'description' => '',
|
||||
'count' => 0,
|
||||
]);
|
||||
|
||||
echo "Created root album (id_tag = 1)\n";
|
||||
echo "\nDone. You can now log in at the web UI.\n";
|
||||
Reference in New Issue
Block a user