Add Postgresql support
This commit is contained in:
parent
23341b2326
commit
035294798d
|
|
@ -98,7 +98,8 @@ Documentation
|
|||
#### Database
|
||||
|
||||
- [Sqlite database management](docs/sqlite-database.markdown)
|
||||
- [How to use Mysql instead of Sqlite](docs/mysql-configuration.markdown)
|
||||
- [How to use Mysql](docs/mysql-configuration.markdown)
|
||||
- [How to use Postgresql](docs/postgresql-configuration.markdown)
|
||||
|
||||
#### Authentication
|
||||
|
||||
|
|
|
|||
|
|
@ -99,6 +99,11 @@ class Board extends Base
|
|||
|
||||
foreach (array('title', 'task_limit') as $field) {
|
||||
foreach ($values[$field] as $column_id => $field_value) {
|
||||
|
||||
if ($field === 'task_limit' && empty($field_value)) {
|
||||
$field_value = 0;
|
||||
}
|
||||
|
||||
$this->updateColumn($column_id, array($field => $field_value));
|
||||
}
|
||||
}
|
||||
|
|
|
|||
|
|
@ -174,7 +174,10 @@ class Config extends Base
|
|||
*/
|
||||
public function regenerateTokens()
|
||||
{
|
||||
$this->db->table(self::TABLE)->update(array('webhooks_token' => Security::generateToken()));
|
||||
$this->db->table(self::TABLE)->update(array(
|
||||
'webhooks_token' => Security::generateToken(),
|
||||
'api_token' => Security::generateToken(),
|
||||
));
|
||||
|
||||
$projects = $this->db->table(Project::TABLE)->findAllByColumn('id');
|
||||
|
||||
|
|
|
|||
|
|
@ -327,6 +327,13 @@ class Task extends Base
|
|||
if (! empty($values['date_due']) && ! is_numeric($values['date_due'])) {
|
||||
$values['date_due'] = $this->parseDate($values['date_due']);
|
||||
}
|
||||
else {
|
||||
$values['date_due'] = 0;
|
||||
}
|
||||
|
||||
if (empty($values['score'])) {
|
||||
$values['score'] = 0;
|
||||
}
|
||||
|
||||
$values['date_creation'] = time();
|
||||
$values['position'] = $this->countByColumnId($values['project_id'], $values['column_id']);
|
||||
|
|
@ -361,6 +368,13 @@ class Task extends Base
|
|||
if (! empty($values['date_due']) && ! is_numeric($values['date_due'])) {
|
||||
$values['date_due'] = $this->parseDate($values['date_due']);
|
||||
}
|
||||
else {
|
||||
$values['date_due'] = 0;
|
||||
}
|
||||
|
||||
if (empty($values['score'])) {
|
||||
$values['score'] = 0;
|
||||
}
|
||||
|
||||
$original_task = $this->getById($values['id']);
|
||||
|
||||
|
|
|
|||
|
|
@ -118,6 +118,14 @@ class User extends Base
|
|||
$values['password'] = \password_hash($values['password'], PASSWORD_BCRYPT);
|
||||
}
|
||||
|
||||
if (empty($values['is_admin'])) {
|
||||
$values['is_admin'] = 0;
|
||||
}
|
||||
|
||||
if (empty($values['is_ldap_user'])) {
|
||||
$values['is_ldap_user'] = 0;
|
||||
}
|
||||
|
||||
return $this->db->table(self::TABLE)->save($values);
|
||||
}
|
||||
|
||||
|
|
@ -145,6 +153,14 @@ class User extends Base
|
|||
unset($values['current_password']);
|
||||
}
|
||||
|
||||
if (empty($values['is_admin'])) {
|
||||
$values['is_admin'] = 0;
|
||||
}
|
||||
|
||||
if (empty($values['is_ldap_user'])) {
|
||||
$values['is_ldap_user'] = 0;
|
||||
}
|
||||
|
||||
$result = $this->db->table(self::TABLE)->eq('id', $values['id'])->update($values);
|
||||
|
||||
if (session_id() !== '' && $_SESSION['user']['id'] == $values['id']) {
|
||||
|
|
|
|||
|
|
@ -3,6 +3,7 @@
|
|||
namespace Schema;
|
||||
|
||||
use Core\Security;
|
||||
|
||||
const VERSION = 20;
|
||||
|
||||
function version_20($pdo)
|
||||
|
|
|
|||
|
|
@ -0,0 +1,166 @@
|
|||
<?php
|
||||
|
||||
namespace Schema;
|
||||
|
||||
use Core\Security;
|
||||
|
||||
const VERSION = 1;
|
||||
|
||||
function version_1($pdo)
|
||||
{
|
||||
$pdo->exec("
|
||||
CREATE TABLE config (
|
||||
language CHAR(5) DEFAULT 'en_US',
|
||||
webhooks_token VARCHAR(255),
|
||||
timezone VARCHAR(50) DEFAULT 'UTC',
|
||||
api_token VARCHAR(255)
|
||||
);
|
||||
|
||||
CREATE TABLE users (
|
||||
id SERIAL PRIMARY KEY,
|
||||
username VARCHAR(50),
|
||||
password VARCHAR(255),
|
||||
is_admin BOOLEAN DEFAULT '0',
|
||||
default_project_id INTEGER DEFAULT 0,
|
||||
is_ldap_user BOOLEAN DEFAULT '0',
|
||||
name VARCHAR(255),
|
||||
email VARCHAR(255),
|
||||
google_id VARCHAR(255),
|
||||
github_id VARCHAR(30)
|
||||
);
|
||||
|
||||
CREATE TABLE remember_me (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_id INTEGER,
|
||||
ip VARCHAR(40),
|
||||
user_agent VARCHAR(255),
|
||||
token VARCHAR(255),
|
||||
sequence VARCHAR(255),
|
||||
expiration INTEGER,
|
||||
date_creation INTEGER,
|
||||
FOREIGN KEY(user_id) REFERENCES users(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE last_logins (
|
||||
id SERIAL PRIMARY KEY,
|
||||
auth_type VARCHAR(25),
|
||||
user_id INTEGER,
|
||||
ip VARCHAR(40),
|
||||
user_agent VARCHAR(255),
|
||||
date_creation INTEGER,
|
||||
FOREIGN KEY(user_id) REFERENCES users(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE projects (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(255) UNIQUE,
|
||||
is_active BOOLEAN DEFAULT '1',
|
||||
token VARCHAR(255),
|
||||
last_modified INTEGER DEFAULT 0
|
||||
);
|
||||
|
||||
CREATE TABLE project_has_users (
|
||||
id SERIAL PRIMARY KEY,
|
||||
project_id INTEGER,
|
||||
user_id INTEGER,
|
||||
FOREIGN KEY(project_id) REFERENCES projects(id) ON DELETE CASCADE,
|
||||
FOREIGN KEY(user_id) REFERENCES users(id) ON DELETE CASCADE,
|
||||
UNIQUE(project_id, user_id)
|
||||
);
|
||||
|
||||
CREATE TABLE project_has_categories (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(255),
|
||||
project_id INTEGER,
|
||||
UNIQUE (project_id, name),
|
||||
FOREIGN KEY(project_id) REFERENCES projects(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE columns (
|
||||
id SERIAL PRIMARY KEY,
|
||||
title VARCHAR(255),
|
||||
position INTEGER,
|
||||
project_id INTEGER,
|
||||
task_limit INTEGER DEFAULT 0,
|
||||
FOREIGN KEY(project_id) REFERENCES projects(id) ON DELETE CASCADE,
|
||||
UNIQUE (title, project_id)
|
||||
);
|
||||
|
||||
CREATE TABLE tasks (
|
||||
id SERIAL PRIMARY KEY,
|
||||
title VARCHAR(255),
|
||||
description TEXT,
|
||||
date_creation INTEGER,
|
||||
color_id VARCHAR(255),
|
||||
project_id INTEGER,
|
||||
column_id INTEGER,
|
||||
owner_id INTEGER DEFAULT 0,
|
||||
position INTEGER,
|
||||
is_active BOOLEAN DEFAULT '1',
|
||||
date_completed INTEGER,
|
||||
score INTEGER,
|
||||
date_due INTEGER,
|
||||
category_id INTEGER DEFAULT 0,
|
||||
FOREIGN KEY(project_id) REFERENCES projects(id) ON DELETE CASCADE,
|
||||
FOREIGN KEY(column_id) REFERENCES columns(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE task_has_subtasks (
|
||||
id SERIAL PRIMARY KEY,
|
||||
title VARCHAR(255),
|
||||
status SMALLINT DEFAULT 0,
|
||||
time_estimated INTEGER DEFAULT 0,
|
||||
time_spent INTEGER DEFAULT 0,
|
||||
task_id INTEGER,
|
||||
user_id INTEGER,
|
||||
FOREIGN KEY(task_id) REFERENCES tasks(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE task_has_files (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(255),
|
||||
path VARCHAR(255),
|
||||
is_image BOOLEAN DEFAULT '0',
|
||||
task_id INTEGER,
|
||||
FOREIGN KEY(task_id) REFERENCES tasks(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE comments (
|
||||
id SERIAL PRIMARY KEY,
|
||||
task_id INTEGER,
|
||||
user_id INTEGER,
|
||||
date INTEGER,
|
||||
comment TEXT,
|
||||
FOREIGN KEY(task_id) REFERENCES tasks(id) ON DELETE CASCADE,
|
||||
FOREIGN KEY(user_id) REFERENCES users(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE actions (
|
||||
id SERIAL PRIMARY KEY,
|
||||
project_id INTEGER,
|
||||
event_name VARCHAR(50),
|
||||
action_name VARCHAR(50),
|
||||
FOREIGN KEY(project_id) REFERENCES projects(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE TABLE action_has_params (
|
||||
id SERIAL PRIMARY KEY,
|
||||
action_id INTEGER,
|
||||
name VARCHAR(50),
|
||||
value VARCHAR(50),
|
||||
FOREIGN KEY(action_id) REFERENCES actions(id) ON DELETE CASCADE
|
||||
);
|
||||
");
|
||||
|
||||
$pdo->exec("
|
||||
INSERT INTO users
|
||||
(username, password, is_admin)
|
||||
VALUES ('admin', '".\password_hash('admin', PASSWORD_BCRYPT)."', '1')
|
||||
");
|
||||
|
||||
$pdo->exec("
|
||||
INSERT INTO config
|
||||
(webhooks_token, api_token)
|
||||
VALUES ('".Security::generateToken()."', '".Security::generateToken()."')
|
||||
");
|
||||
}
|
||||
|
|
@ -1,6 +1,7 @@
|
|||
<?php
|
||||
|
||||
namespace Schema;
|
||||
|
||||
use Core\Security;
|
||||
|
||||
const VERSION = 20;
|
||||
|
|
|
|||
|
|
@ -66,31 +66,49 @@ $registry = new Registry;
|
|||
$registry->db = function() use ($registry) {
|
||||
require __DIR__.'/../vendor/PicoDb/Database.php';
|
||||
|
||||
if (DB_DRIVER === 'sqlite') {
|
||||
switch (DB_DRIVER) {
|
||||
case 'sqlite':
|
||||
require __DIR__.'/Schema/Sqlite.php';
|
||||
|
||||
require __DIR__.'/Schema/Sqlite.php';
|
||||
$params = array(
|
||||
'driver' => 'sqlite',
|
||||
'filename' => DB_FILENAME
|
||||
);
|
||||
|
||||
$db = new \PicoDb\Database(array(
|
||||
'driver' => 'sqlite',
|
||||
'filename' => DB_FILENAME
|
||||
));
|
||||
break;
|
||||
|
||||
case 'mysql':
|
||||
require __DIR__.'/Schema/Mysql.php';
|
||||
|
||||
$params = array(
|
||||
'driver' => 'mysql',
|
||||
'hostname' => DB_HOSTNAME,
|
||||
'username' => DB_USERNAME,
|
||||
'password' => DB_PASSWORD,
|
||||
'database' => DB_NAME,
|
||||
'charset' => 'utf8',
|
||||
);
|
||||
|
||||
break;
|
||||
|
||||
case 'postgres':
|
||||
require __DIR__.'/Schema/Postgres.php';
|
||||
|
||||
$params = array(
|
||||
'driver' => 'postgres',
|
||||
'hostname' => DB_HOSTNAME,
|
||||
'username' => DB_USERNAME,
|
||||
'password' => DB_PASSWORD,
|
||||
'database' => DB_NAME,
|
||||
);
|
||||
|
||||
break;
|
||||
|
||||
default:
|
||||
die('Database driver not supported');
|
||||
}
|
||||
elseif (DB_DRIVER === 'mysql') {
|
||||
|
||||
require __DIR__.'/Schema/Mysql.php';
|
||||
|
||||
$db = new \PicoDb\Database(array(
|
||||
'driver' => 'mysql',
|
||||
'hostname' => DB_HOSTNAME,
|
||||
'username' => DB_USERNAME,
|
||||
'password' => DB_PASSWORD,
|
||||
'database' => DB_NAME,
|
||||
'charset' => 'utf8',
|
||||
));
|
||||
}
|
||||
else {
|
||||
die('Database driver not supported');
|
||||
}
|
||||
$db = new \PicoDb\Database($params);
|
||||
|
||||
if ($db->schema()->check(Schema\VERSION)) {
|
||||
return $db;
|
||||
|
|
|
|||
|
|
@ -0,0 +1,38 @@
|
|||
Postgresql configuration
|
||||
========================
|
||||
|
||||
By default, Kanboard use Sqlite to store its data but it's also possible to use Postgresql.
|
||||
|
||||
Requirements
|
||||
------------
|
||||
|
||||
- A Postgresql server already installed and configured
|
||||
- The PHP extension `pdo_pgsql` installed (Debian/Ubuntu: `apt-get install php5-pgsql`)
|
||||
|
||||
Configuration
|
||||
-------------
|
||||
|
||||
### Create an empty database with the command `pgsql`:
|
||||
|
||||
```sql
|
||||
CREATE DATABASE kanboard;
|
||||
```
|
||||
|
||||
### Create a config file
|
||||
|
||||
Inside our config file write those lines:
|
||||
|
||||
```php
|
||||
<?php
|
||||
|
||||
// We choose to use Postgresql instead of Sqlite
|
||||
define('DB_DRIVER', 'postgres');
|
||||
|
||||
// Mysql parameters
|
||||
define('DB_USERNAME', 'REPLACE_ME');
|
||||
define('DB_PASSWORD', 'REPLACE_ME');
|
||||
define('DB_HOSTNAME', 'REPLACE_ME');
|
||||
define('DB_NAME', 'kanboard');
|
||||
```
|
||||
|
||||
Now, you are ready to use Postgresql.
|
||||
|
|
@ -27,6 +27,11 @@ class Database
|
|||
$this->pdo = new Mysql($settings);
|
||||
break;
|
||||
|
||||
case 'postgres':
|
||||
require_once __DIR__.'/Drivers/Postgres.php';
|
||||
$this->pdo = new Postgres($settings);
|
||||
break;
|
||||
|
||||
default:
|
||||
throw new \LogicException('This database driver is not supported.');
|
||||
}
|
||||
|
|
|
|||
|
|
@ -0,0 +1,73 @@
|
|||
<?php
|
||||
|
||||
namespace PicoDb;
|
||||
|
||||
class Postgres extends \PDO {
|
||||
|
||||
private $schema_table = 'schema_version';
|
||||
|
||||
|
||||
public function __construct(array $settings)
|
||||
{
|
||||
$required_atttributes = array(
|
||||
'hostname',
|
||||
'username',
|
||||
'password',
|
||||
'database',
|
||||
);
|
||||
|
||||
foreach ($required_atttributes as $attribute) {
|
||||
if (! isset($settings[$attribute])) {
|
||||
throw new \LogicException('This configuration parameter is missing: "'.$attribute.'"');
|
||||
}
|
||||
}
|
||||
|
||||
$dsn = 'pgsql:host='.$settings['hostname'].';dbname='.$settings['database'];
|
||||
|
||||
parent::__construct($dsn, $settings['username'], $settings['password']);
|
||||
|
||||
if (isset($settings['schema_table'])) {
|
||||
$this->schema_table = $settings['schema_table'];
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
public function getSchemaVersion()
|
||||
{
|
||||
$this->exec("CREATE TABLE IF NOT EXISTS ".$this->schema_table." (version SMALLINT DEFAULT 0)");
|
||||
|
||||
$rq = $this->prepare('SELECT version FROM '.$this->schema_table.'');
|
||||
$rq->execute();
|
||||
$result = $rq->fetch(\PDO::FETCH_ASSOC);
|
||||
|
||||
if (isset($result['version'])) {
|
||||
return (int) $result['version'];
|
||||
}
|
||||
else {
|
||||
$this->exec('INSERT INTO '.$this->schema_table.' VALUES(0)');
|
||||
}
|
||||
|
||||
return 0;
|
||||
}
|
||||
|
||||
|
||||
public function setSchemaVersion($version)
|
||||
{
|
||||
$rq = $this->prepare('UPDATE '.$this->schema_table.' SET version=?');
|
||||
$rq->execute(array($version));
|
||||
}
|
||||
|
||||
|
||||
public function getLastId()
|
||||
{
|
||||
$rq = $this->prepare('SELECT LASTVAL()');
|
||||
$rq->execute();
|
||||
return $rq->fetchColumn();
|
||||
}
|
||||
|
||||
|
||||
public function escapeIdentifier($value)
|
||||
{
|
||||
return $value;
|
||||
}
|
||||
}
|
||||
Loading…
Reference in New Issue