Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Adding PostgreSQL support #62

Merged
merged 2 commits into from
Mar 15, 2013
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
141 changes: 141 additions & 0 deletions daos/pgsql/Database.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,141 @@
<?PHP

namespace daos\pgsql;

/**
* Base class for database access -- postgresql
*
* Note that before use you'll want to create the database itself. See
* http://www.postgresql.org/docs/8.4/static/manage-ag-createdb.html for full information.
* In a nutshell (from the command line), as the administrative user (postgres),
* execute "createdb -O USER DBNAME" where USER is the user you will be connecting as
* and DBNAME is the database to create. Administering users (roles) and authentication
* is out of scope for this comment, but the online postgresql documentation is comprehensive.
*
* @package daos
* @copyright Copyright (c) Michael Jackson <michael.o.jackson@gmail.com>
* @license GPLv3 (http://www.gnu.org/licenses/gpl-3.0.html)
* @author Michael Jackson <michael.o.jackson@gmail.com>
* @author Tobias Zeising <tobias.zeising@aditu.de>
*/
class Database {

/**
* indicates whether database connection was initialized
*
* @var bool
*/
static private $initialized = false;


/**
* establish connection and create undefined tables
*
* @return void
*/
public function __construct() {
if (self::$initialized === false && \F3::get('db_type')=="pgsql") {
// establish database connection
\F3::set('db', new \DB\SQL(
'pgsql:host=' . \F3::get('db_host') . ';port=' . \F3::get('db_port') . ';dbname='.\F3::get('db_database'),
\F3::get('db_username'),
\F3::get('db_password')
));

// create tables if necessary
$result = @\F3::get('db')->exec("SELECT table_name FROM information_schema.tables WHERE table_schema='public'");
$tables = array();
foreach($result as $table)
foreach($table as $key=>$value)
$tables[] = $value;

if(!in_array('items', $tables)) {
\F3::get('db')->exec('
CREATE TABLE items (
id SERIAL PRIMARY KEY,
datetime TIMESTAMP WITH TIME ZONE NOT NULL,
title TEXT NOT NULL,
content TEXT NOT NULL,
thumbnail TEXT,
icon TEXT,
unread BOOLEAN NOT NULL,
starred BOOLEAN NOT NULL,
source INTEGER NOT NULL,
uid TEXT NOT NULL,
link TEXT NOT NULL
);
');

\F3::get('db')->exec('
CREATE INDEX source ON items (
source
);
');
}

$isNewestSourcesTable = false;
if(!in_array('sources', $tables)) {
\F3::get('db')->exec('
CREATE TABLE sources (
id SERIAL PRIMARY KEY,
title TEXT NOT NULL,
tags TEXT,
spout TEXT NOT NULL,
params TEXT NOT NULL,
error TEXT
);
');
$isNewestSourcesTable = true;
}

// version 1
if(!in_array('version', $tables)) {
\F3::get('db')->exec('
CREATE TABLE version (
version INTEGER
);
');

\F3::get('db')->exec('
INSERT INTO version (version) VALUES (2);
');

\F3::get('db')->exec('
CREATE TABLE tags (
tag TEXT NOT NULL,
color TEXT NOT NULL
);
');

if($isNewestSourcesTable===false) {
\F3::get('db')->exec('
ALTER TABLE sources ADD COLUMN tags TEXT;
');
}
}

// just initialize once
$initialized = true;
}
}


/**
* optimize database by the database's own optimize statement
*
* Note that for pg, for full optimization you'd run "vacuum full analyze {table}". This does require
* an exclusive lock on the table though and so this is probably best run offline during scheduled
* downtime. See http://www.postgresql.org/docs/8.4/static/sql-vacuum.html for more information
* (particularly the notes in the footer of that page leading to further DBA-related info e.g. the
* autovacuum daemon).
*
* @return void
*/
public function optimize() {
$result = @\F3::get('db')->exec("SELECT table_name FROM information_schema.tables WHERE table_schema='public'");
$tables = array();
foreach($result as $table)
foreach($table as $key=>$value)
@\F3::get('db')->exec("VACUUM ANALYZE :table", array(':table' => $value));
}
}
173 changes: 173 additions & 0 deletions daos/pgsql/Items.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,173 @@
<?PHP

namespace daos\pgsql;

/**
* Class for accessing persistant saved items -- postgresql
*
* @package daos
* @copyright Copyright (c) Michael Jackson <michael.o.jackson@gmail.com>
* @license GPLv3 (http://www.gnu.org/licenses/gpl-3.0.html)
* @author Michael Jackson <michael.o.jackson@gmail.com>
* @author Tobias Zeising <tobias.zeising@aditu.de>
*/
class Items extends \daos\mysql\Items {
/**
* returns items
*
* @return mixed items as array
* @param mixed $options search, offset and filter params
*/
public function get($options = array()) {
$params = array();
$where = '';

// only starred
if(isset($options['type']) && $options['type']=='starred')
$where .= ' AND starred=true ';

// only unread
else if(isset($options['type']) && $options['type']=='unread')
$where .= ' AND unread=true ';

// search
if(isset($options['search']) && strlen($options['search'])>0) {
$search = str_replace(" ", "%", trim($options['search']));
$params[':search'] = $params[':search2'] = $params[':search3'] = array("%".$search."%", \PDO::PARAM_STR);
$where .= ' AND (items.title LIKE :search OR items.content LIKE :search2 OR sources.title LIKE :search3) ';
}

// tag filter
if(isset($options['tag']) && strlen($options['tag'])>0) {
$params[':tag'] = array("%".$options['tag']."%", \PDO::PARAM_STR);
$where .= ' AND (sources.tags LIKE :tag) ';
}

// set limit
if(!is_numeric($options['items']) || $options['items']>200)
$options['items'] = \F3::get('items_perpage');

// first check whether more items are available
$result = \F3::get('db')->exec('SELECT items.id
FROM items, sources
WHERE items.source=sources.id '.$where.'
LIMIT 1 OFFSET ' . ($options['offset']+$options['items']), $params);
$this->hasMore = count($result);

// get items from database
return \F3::get('db')->exec('SELECT
items.id, datetime, items.title AS title, content, unread, starred, source, thumbnail, icon, uid, link, sources.title as sourcetitle, sources.tags as tags
FROM items, sources
WHERE items.source=sources.id '.$where.'
ORDER BY items.datetime DESC
LIMIT ' . $options['items'] . ' OFFSET ' . $options['offset'], $params);
}

/**
* mark item as read
*
* @return void
* @param int $id
*/
public function mark($id) {
if($this->isValid('id', $id)===false)
return;

if(is_array($id))
$id = implode(",", $id);

// i used string concatenation after validating $id
\F3::get('db')->exec('UPDATE items SET unread=false WHERE id IN (' . $id . ')');
}

/**
* mark item as unread
*
* @return void
* @param int $id
*/
public function unmark($id) {
if(is_array($id)) {
$id = implode(",", $id);
} else if(!is_numeric($id)) {
return;
}
\F3::get('db')->exec('UPDATE items SET unread=true WHERE id IN (:id)',
array(':id' => $id));
}

/**
* returns the amount of entries in database which are unread
*
* @return int amount of entries in database which are unread
*/
public function numberOfUnread() {
$res = \F3::get('db')->exec('SELECT count(*) AS amount
FROM items
WHERE unread=true');
return $res[0]['amount'];
}

/**
* star item
*
* @return void
* @param int $id the item
*/
public function starr($id) {
\F3::get('db')->exec('UPDATE items SET starred=true WHERE id=:id',
array(':id' => $id));
}


/**
* un-star item
*
* @return void
* @param int $id the item
*/
public function unstarr($id) {
\F3::get('db')->exec('UPDATE items SET starred=false WHERE id=:id',
array(':id' => $id));
}
/**
* returns the amount of entries in database which are starred
*
* @return int amount of entries in database which are starred
*/
public function numberOfStarred() {
$res = \F3::get('db')->exec('SELECT count(*) AS amount
FROM items
WHERE starred=true');
return $res[0]['amount'];
}

/**
* returns the icon of the last fetched item.
*
* @return bool|string false if none was found
* @param number $sourceid id of the source
*/
public function getLastIcon($sourceid) {
if(is_numeric($sourceid)===false)
return false;

$res = \F3::get('db')->exec('SELECT icon FROM items WHERE source=:sourceid AND icon IS NOT NULL ORDER BY ID DESC LIMIT 1',
array(':sourceid' => $sourceid));
if(count($res)==1)
return $res[0]['icon'];

return false;
}

/**
* cleanup old items
*
* @return void
* @param DateTime $date date to delete all items older than this value
*/
public function cleanup(\DateTime $date) {
\F3::get('db')->exec('DELETE FROM items WHERE starred=false AND datetime<:date',
array(':date' => $date->format('Y-m-d').' 00:00:00'));
}
}
35 changes: 35 additions & 0 deletions daos/pgsql/Sources.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,35 @@
<?PHP

namespace daos\pgsql;

/**
* Class for accessing persistant saved sources -- postgresql
*
* @package daos
* @copyright Copyright (c) Michael Jackson <michael.o.jackson@gmail.com>
* @license GPLv3 (http://www.gnu.org/licenses/gpl-3.0.html)
* @author Michael Jackson <michael.o.jackson@gmail.com>
* @author Tobias Zeising <tobias.zeising@aditu.de>
*/
class Sources extends \daos\mysql\Sources {
/**
* add new source
*
* @return int new id
* @param string $title
* @param string $tags
* @param string $spout the source type
* @param mixed $params depends from spout
*/
public function add($title, $tags, $spout, $params) {
$res = \F3::get('db')->exec('INSERT INTO sources (title, tags, spout, params) VALUES (:title, :tags, :spout, :params) RETURNING id',
array(
':title' => $title,
':tags' => $tags,
':spout' => $spout,
':params' => htmlentities(json_encode($params))
));

return $res[0]['id'];
}
}
14 changes: 14 additions & 0 deletions daos/pgsql/Tags.php
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
<?PHP

namespace daos\pgsql;

/**
* Class for accessing persistant saved tags -- postgresql
*
* @package daos
* @copyright Copyright (c) Michael Jackson <michael.o.jackson@gmail.com>
* @license GPLv3 (http://www.gnu.org/licenses/gpl-3.0.html)
* @author Michael Jackson <michael.o.jackson@gmail.com>
* @author Tobias Zeising <tobias.zeising@aditu.de>
*/
class Tags extends \daos\mysql\Tags { }