1
1
Fork 0
mirror of https://code.mensbeam.com/MensBeam/Arsse.git synced 2024-12-22 21:22:40 +00:00

Changes to Database internals

- Driver->prepare() can now take a new Database\Query object as the first parameter
- The Query class allows for building a complex query out of a main body, common table expressions, WHERE coniditions, ordering conditions, a limit, and offset
- The subscriptionList method is the prototypical example of usage
- The experimental articleList method will in time be adapted to use this as well
- A generic means of specifying a selection context is forthcoming; this would remove subscriptionList's $folder and $id parameters, for instance
This commit is contained in:
J. King 2017-06-04 18:00:18 -04:00
parent 2332cd52a3
commit c37d476ba0
9 changed files with 190 additions and 69 deletions

View file

@ -2,6 +2,7 @@
declare(strict_types=1);
namespace JKingWeb\Arsse;
use PasswordGenerator\Generator as PassGen;
use JKingWeb\Arsse\Database\Query;
class Database {
@ -356,42 +357,36 @@ class Database {
public function subscriptionList(string $user, int $folder = null, int $id = null): Db\Result {
if(!Data::$user->authorize($user, __FUNCTION__)) throw new User\ExceptionAuthz("notAuthorized", ["action" => __FUNCTION__, "user" => $user]);
// lay out the base query parts
$queryCTE = ["topmost(f_id,top) as (select id,id from arsse_folders where owner is ? and parent is null union select id,top from arsse_folders join topmost on parent=f_id)"];
$queryWhere = ["owner is ?"];
$queryTypes = ["str", "str", "str", "str"];
$queryValues = [$user, $this->dateFormatDefault, $user, $user];
if(!is_null($folder)) {
// if a folder is specified, make sure it exists
$this->folderValidateId($user, $folder);
// if it does exist, add a common table expression to list it and its children so that we select from the entire subtree
array_unshift($queryCTE, "folders(folder) as (SELECT ? union select id from arsse_folders join folders on parent is folder)");
// add a suitable WHERE condition and bindings
$queryWhere[] = "folder in (select folder from folders)";
array_unshift($queryTypes, "int");
array_unshift($queryValues, $folder);
}
if(!is_null($id)) {
// this condition facilitates the implementation of subscriptionPropertiesGet, which would otherwise have to duplicate the complex query
// if an ID is specified, add a suitable WHERE condition and bindings
$queryWhere[] = "arsse_subscriptions.id is ?";
$queryTypes[] = "int";
$queryValues[] = $id;
}
// stitch the query together
$queryCTE = "WITH RECURSIVE ".implode(", ", $queryCTE)." ";
$queryWhere = implode(" AND ", $queryWhere);
$query =
$queryCTE."SELECT
// create a complex query
$q = new Query(
"SELECT
arsse_subscriptions.id,
url,favicon,source,folder,pinned,err_count,err_msg,order_type,
DATEFORMAT(?, added) as added,
topmost.top as top_folder,
CASE WHEN arsse_subscriptions.title is not null THEN arsse_subscriptions.title ELSE arsse_feeds.title END as title,
(SELECT count(*) from arsse_articles where feed is arsse_subscriptions.feed) - (SELECT count(*) from arsse_marks join arsse_articles on article = arsse_articles.id where owner is ? and feed is arsse_feeds.id and read is 1) as unread
from arsse_subscriptions join arsse_feeds on feed = arsse_feeds.id left join topmost on folder=f_id where $queryWhere order by pinned desc, title";
// execute the query
return $this->db->prepare($query, $queryTypes)->run($queryValues);
(SELECT count(*) from arsse_articles where feed is arsse_subscriptions.feed) - (SELECT count(*) from arsse_marks join user on user is owner join arsse_articles on article = arsse_articles.id where feed is arsse_feeds.id and read is 1) as unread
from arsse_subscriptions join user on user is owner join arsse_feeds on feed = arsse_feeds.id left join topmost on folder=f_id",
"", // where terms
"pinned desc, title" // order by terms
);
// define common table expressions
$q->setCTE("user(user) as (SELECT ?)", "str", $user); // the subject user; this way we only have to pass it to prepare() once
// topmost folders belonging to the user
$q->setCTE("topmost(f_id,top) as (select id,id from arsse_folders join user on owner is user where parent is null union select id,top from arsse_folders join topmost on parent=f_id)");
if(!is_null($id)) {
// this condition facilitates the implementation of subscriptionPropertiesGet, which would otherwise have to duplicate the complex query; it takes precedence over a specified folder
// if an ID is specified, add a suitable WHERE condition and bindings
$q->setWhere("arsse_subscriptions.id is ?", "int", $id);
} else if(!is_null($folder)) {
// if a folder is specified, make sure it exists
$this->folderValidateId($user, $folder);
// if it does exist, add a common table expression to list it and its children so that we select from the entire subtree
$q->setCTE("folders(folder) as (SELECT ? union select id from arsse_folders join folders on parent is folder)", "int", $folder);
// add a suitable WHERE condition
$q->setWhere("folder in (select folder from folders)");
}
return $this->db->prepare($q, "str")->run($this->dateFormatDefault);
}
public function subscriptionRemove(string $user, int $id): bool {
@ -608,4 +603,32 @@ class Database {
}
return (int) $this->db->prepare("SELECT max(id) from arsse_editions")->run()->getValue();
}
public function articleList(string $user): Db\Result {
if(!Data::$user->authorize($user, __FUNCTION__)) throw new User\ExceptionAuthz("notAuthorized", ["action" => __FUNCTION__, "user" => $user]);
return $this->db->prepare(
"WITH
user(user) as (SELECT ?),
subscribed_feeds(id) as (SELECT feed from arsse_subscriptions join user on user is owner)
".
"SELECT
arsse_articles.id,
arsse_articles.url,
title,author,content,feed,guid,
DATEFORMAT(?, edited) as edited,
DATEFORMAT(?, modified) as modified,
CASE (SELECT count(*) from arsse_marks join user on user is owner where article is arsse_articles.id and read is 1) when 1 then 0 else 1 end as unread,
(SELECT count(*) from arsse_marks join user on user is owner where article is arsse_articles.id and starred is 1) as starred,
(SELECT max(id) from arsse_editions where article is arsse_articles.id) as latestEdition,
url_title_hash||':'||url_content_hash||':'||title_content_hash as fingerprint,
arsse_enclosures.url as media_url,
arsse_enclosures.type as media_type
FROM arsse_articles
join subscribed_feeds on arsse_articles.feed is subscribed_feeds.id
left join arsse_enclosures on arsse_enclosures.article is arsse_articles.id
",
"str","str","str"
)-run($user, $this->dateFormatDefault, $this->dateFormatDefault);
}
}

110
lib/Database/Query.php Normal file
View file

@ -0,0 +1,110 @@
<?php
declare(strict_types=1);
namespace JKingWeb\Arsse\Database;
use JKingWeb\Arsse\Db\Driver;
use JKingWeb\Arsse\Db\Statement;
class Query {
protected $body = "";
protected $qCTE = []; // Common table expression query components
protected $tCTE = []; // Common table expression type bindings
protected $vCTE = []; // Common table expression binding values
protected $jCTE = []; // Common Table Expression joins
protected $qWhere = []; // WHERE clause components
protected $tWhere = []; // WHERE clause type bindings
protected $vWhere = []; // WHERE clause binding values
protected $order = []; // ORDER BY clause components
protected $limit = 0;
protected $offset = 0;
function __construct(string $body, string $where = "", string $order = "", int $limit = 0, int $offset = 0) {
if(strlen($body)) $this->body = $body;
if(strlen($where)) $this->where[] = $where;
if(strlen($order)) $this->order[] = $order;
$this->limit = $limit;
$this->offset = $offset;
}
function setCTE(string $body, $types = null, $values = null, string $join = ''): bool {
if(!strlen($body)) return false;
$this->qCTE[] = $body;
if(!is_null($types)) {
$this->tCTE[] = $types;
$this->vCTE[] = $values;
}
if(strlen($join)) $this->jCTE[] = $join; // the CTE may only participate in subqueries rather than a join on the main query
return true;
}
function setWhere(string $where, $types = null, $values = null): bool {
if(!strlen($where)) return false;
$this->qWhere[] = $where;
if(!is_null($types)) {
$this->tWhere[] = $types;
$this->vWhere[] = $values;
}
return true;
}
function setOrder(string $oder, bool $prepend = false): bool {
if(!strlen($order)) return false;
if($prepend) {
array_unshift($this->order, $order);
} else {
$this->order[] = $order;
}
return true;
}
function prepare(Driver $drv, ...$userTypes): Statement {
return new QueryStatement($drv->prepare($this->getQuery(), $this->getCTETypes(), $userTypes, $this->getWhereTypes()), $this->getCTEValues(), $this->getWhereValues());
}
function getQuery(bool $pretty = false): string {
$cte = sizeof($this->qCTE);
$out = "";
if($cte) {
// start with common table expressions
$out .= "WITH RECURSIVE ".implode(", ", $this->qCTE)." ";
}
// add the body
$out .= $this->body;
if($cte) {
// add any joins against CTEs
$out .= " ".implode(" ", $this->jCTE);
}
// add any WHERE terms
if(sizeof($this->qWhere)) {
$out .= " WHERE ".implode(" AND ", $this->qWhere);
}
// add any ORDER BY terms
if(sizeof($this->order)) {
$out .= " ORDER BY ".implode(", ", $this->order);
}
// add LIMIT and OFFSET if the former is specified
if($this->limit > 0) {
$out .= " LIMIT ".$this->limit;
if($this->offset > 0) {
$out .= " OFFSET ".$this->offset;
}
}
return $out;
}
function getWhereTypes(): array {
return $this->tWhere;
}
function getWhereValues(): array {
return $this->vWhere;
}
function getCTETypes(): array {
return $this->tCTE;
}
function getCTEValues(): array {
return $this->vCTE;
}
}

View file

@ -7,6 +7,8 @@ abstract class AbstractDriver implements Driver {
protected $transDepth = 0;
protected $transStatus = [];
public abstract function prepareArray($query, array $paramTypes): Statement;
public function schemaVersion(): int {
try {
return (int) $this->query("SELECT value from arsse_settings where key is schema_version")->getValue();
@ -128,7 +130,7 @@ abstract class AbstractDriver implements Driver {
return ($this->query("SELECT count(*) from arsse_settings where key is 'lock'")->getValue() > 0);
}
public function prepare(string $query, ...$paramType): Statement {
public function prepare($query, ...$paramType): Statement {
return $this->prepareArray($query, $paramType);
}
}

View file

@ -5,8 +5,9 @@ namespace JKingWeb\Arsse\Db;
abstract class AbstractStatement implements Statement {
protected $types = [];
protected $isNullable = [];
protected $values = ['pre' => [], 'post' => []];
abstract function runArray(array $values): Result;
abstract function runArray(array $values = []): Result;
abstract static function dateFormat(int $part = self::TS_BOTH): string;
public function run(...$values): Result {

View file

@ -33,5 +33,6 @@ interface Driver {
// perform a single unsanitized query and return a result set
function query(string $query): Result;
// ready a prepared statement for later execution
function prepare(string $query, ...$paramType): Statement;
function prepare($query, ...$paramType): Statement;
function prepareArray($query, array $paramTypes): Statement;
}

View file

@ -125,13 +125,22 @@ class Driver extends \JKingWeb\Arsse\Db\AbstractDriver {
return new Result($r, [$changes, $lastId]);
}
public function prepareArray(string $query, array $paramTypes): \JKingWeb\Arsse\Db\Statement {
public function prepareArray($query, array $paramTypes): \JKingWeb\Arsse\Db\Statement {
if($query instanceof \JKingWeb\Arsse\Database\Query) {
$preValues = $query->getCTEValues();
$postValues = $query->getWhereValues();
$paramTypes = [$query->getCTETypes(), $paramTypes, $query->getWhereTypes()];
$query = $query->getQuery();
} else {
$preValues = [];
$postValues = [];
}
try {
$s = $this->db->prepare($query);
} catch(\Exception $e) {
list($excClass, $excMsg, $excData) = $this->exceptionBuild();
throw new $excClass($excMsg, $excData);
}
return new Statement($this->db, $s, $paramTypes);
return new Statement($this->db, $s, $paramTypes, $preValues, $postValues);
}
}

View file

@ -26,10 +26,12 @@ class Statement extends \JKingWeb\Arsse\Db\AbstractStatement {
protected $db;
protected $st;
public function __construct(\SQLite3 $db, \SQLite3Stmt $st, array $bindings = []) {
public function __construct(\SQLite3 $db, \SQLite3Stmt $st, array $bindings = [], array $preValues, array $postValues) {
$this->db = $db;
$this->st = $st;
$this->rebindArray($bindings);
$this->values['pre'] = $preValues;
$this->values['post'] = $postValues;
}
public function __destruct() {
@ -45,9 +47,10 @@ class Statement extends \JKingWeb\Arsse\Db\AbstractStatement {
])[$part];
}
public function runArray(array $values = null): \JKingWeb\Arsse\Db\Result {
public function runArray(array $values = []): \JKingWeb\Arsse\Db\Result {
$this->st->clear();
if(!is_null($values)) $this->bindValues($values);
$values = [$this->values['pre'], $values, $this->values['post']];
$this->bindValues($values);
try {
$r = $this->st->execute();
} catch(\Exception $e) {

View file

@ -33,7 +33,7 @@ interface Statement {
static function dateFormat(int $part = self::TS_BOTH): string;
function run(...$values): Result;
function runArray(array $values): Result;
function runArray(array $values = []): Result;
function rebind(...$bindings): bool;
function rebindArray(array $bindings): bool;
}

View file

@ -1,28 +0,0 @@
<?php
namespace JKingWeb\Arsse;
const INSTALL = true;
require_once __DIR__."/../bootstrap.php";
$user = "john.doe@example.com";
$pass = "secret";
$_SERVER['PHP_AUTH_USER'] = $user;
$_SERVER['PHP_AUTH_PW'] = $pass;
$conf = new Conf();
$conf->dbSQLite3File = ":memory:";
Data::load($conf);
Data::$db->schemaUpdate();
Data::$user->add($user, $pass);
Data::$user->auth();
Data::$user->authorizationEnabled(false);
Data::$user->rightsSet($user, User\Driver::RIGHTS_GLOBAL_ADMIN);
Data::$user->authorizationEnabled(true);
Data::$db->folderAdd($user, ['name' => 'ook']);
/*Data::$db->subscriptionAdd($user, "http://linuxfr.org/news.atom");
Data::$db->subscriptionPropertiesSet($user, 1, [
'title' => "OOOOOOOOK!",
]);*/
(new REST())->dispatch(new REST\Request(
"POST", "/index.php/apps/news/api/v1-2/feeds/", json_encode(['url'=> "http://linuxfr.org/news.atom"])
));