Skip to content

Commit

Permalink
Implements filter and sorting functionality for PostgreSQL
Browse files Browse the repository at this point in the history
Signed-off-by: Philipp Hempel <Philipp.Hempel1@web.de>
  • Loading branch information
Hephi2 committed Aug 8, 2023
1 parent ba1de3a commit 7b4afaa
Show file tree
Hide file tree
Showing 6 changed files with 131 additions and 110 deletions.
99 changes: 51 additions & 48 deletions lib/Db/ColumnTypes/SuperColumnQB.php
Original file line number Diff line number Diff line change
Expand Up @@ -55,43 +55,32 @@ public function passSearchValue(IQueryBuilder $qb, string $unformattedSearchValu
* @return string
* @throws InternalError
*/
private function buildSqlFilterString(string $operator, string $formattedCellValue, string $searchValuePlaceHolder, string $columnPlaceHolder = null) : string {
if ($this->platform === self::DB_PLATFORM_PGSQL) {
return "id IN (".
"SELECT id ".
"FROM oc_tables_rows, json_array_elements(data) as t1 ".
"WHERE CAST(t1->>'columnId' AS int) = :".$columnPlaceHolder." AND ".$formattedCellValue." LIKE :".$searchValuePlaceHolder.
")";
} elseif ($this->platform === self::DB_PLATFORM_SQLITE) {
// TODO DB BE SQLITE
return '';
} else { // mariadb / mysql
switch ($operator) {
case 'begins-with':
case 'ends-with':
case 'contains':
return $formattedCellValue.' LIKE :'.$searchValuePlaceHolder;
case 'is-equal':
return $formattedCellValue.' = :'.$searchValuePlaceHolder;
case 'is-greater-than':
return $formattedCellValue.' > :'.$searchValuePlaceHolder;
case 'is-greater-than-or-equal':
return $formattedCellValue.' >= :'.$searchValuePlaceHolder;
case 'is-lower-than':
return $formattedCellValue.' < :'.$searchValuePlaceHolder;
case 'is-lower-than-or-equal':
return $formattedCellValue.' <= :'.$searchValuePlaceHolder;
case 'is-empty':
return $formattedCellValue.' = \'\' OR '.$formattedCellValue.' IS NULL';
default:
throw new InternalError('Operator '.$operator.' is not supported.');
}
private function sqlFilterOperation(string $operator, string $formattedCellValue, string $searchValuePlaceHolder) : string {
switch ($operator) {
case 'begins-with':
case 'ends-with':
case 'contains':
return $formattedCellValue.' LIKE :'.$searchValuePlaceHolder;
case 'is-equal':
return $formattedCellValue.' = :'.$searchValuePlaceHolder;
case 'is-greater-than':
return $formattedCellValue.' > :'.$searchValuePlaceHolder;
case 'is-greater-than-or-equal':
return $formattedCellValue.' >= :'.$searchValuePlaceHolder;
case 'is-lower-than':
return $formattedCellValue.' < :'.$searchValuePlaceHolder;
case 'is-lower-than-or-equal':
return $formattedCellValue.' <= :'.$searchValuePlaceHolder;
case 'is-empty':
return $formattedCellValue.' = \'\' OR '.$formattedCellValue.' IS NULL';
default:
throw new InternalError('Operator '.$operator.' is not supported.');
}
}

private function getFormattedDataCellValue(string $columnPlaceHolder): string {
private function getFormattedDataCellValue(string $columnPlaceHolder, int $columnId): string {
if ($this->platform === self::DB_PLATFORM_PGSQL) {
$cellValue = 't1 ->> \'value\'';
$cellValue = 'c'.intval($columnId).' ->> \'value\'';
} elseif ($this->platform === self::DB_PLATFORM_SQLITE) {
// TODO DB BE SQLITE
} else {
Expand All @@ -106,14 +95,20 @@ private function getFormattedDataCellValue(string $columnPlaceHolder): string {
* @return string
* @throws InternalError
*/
private function getFormattedMetaDataCellValue(int $metaId): string {
switch($metaId) {
case -1: return 'id';
case -2: return 'created_by';
case -3: return 'last_edit_by';
case -4: return 'created_at';
case -5: return 'last_edit_at';
default: throw new InternalError('No meta data column exists with id '.$metaId);
private function getMetaColumnName(int $metaId): string {
switch ($metaId) {
case -1:
return 'id';
case -2:
return 'created_by';
case -3:
return 'last_edit_by';
case -4:
return 'created_at';
case -5:
return 'last_edit_at';
default:
throw new InternalError('No meta data column exists with id ' . $metaId);
}
}

Expand All @@ -126,17 +121,25 @@ private function getFormattedMetaDataCellValue(int $metaId): string {
*/
public function addWhereFilterExpression(IQueryBuilder $qb, array $filter, string $filterId): IQueryFunction {
$searchValuePlaceHolder = 'searchValue'.$filterId; // qb parameter binding name
$this->passSearchValue($qb, $filter['value'], $filter['operator'], $searchValuePlaceHolder);
$columnPlaceHolder = 'column'.$filterId; // qb parameter binding name
if($filter['columnId'] >= 0) { // negative ids for meta data columns
$qb->setParameter($columnPlaceHolder, $filter['columnId'], IQueryBuilder::PARAM_INT);
$formattedCellValue = $this->getFormattedDataCellValue($columnPlaceHolder); // as sql string
} else {
$formattedCellValue = $this->getFormattedMetaDataCellValue($filter['columnId']); // as sql string
if($filter['columnId'] < 0) { // negative ids for meta data columns
return $qb->createFunction($this->sqlFilterOperation($filter['operator'], $this->getMetaColumnName($filter['columnId']), $searchValuePlaceHolder));
}

$this->passSearchValue($qb, $filter['value'], $filter['operator'], $searchValuePlaceHolder);
return $qb->createFunction($this->buildSqlFilterString($filter['operator'], $formattedCellValue, $searchValuePlaceHolder, $columnPlaceHolder));
$qb->setParameter($columnPlaceHolder, $filter['columnId'], IQueryBuilder::PARAM_INT);
$formattedCellValue = $this->getFormattedDataCellValue($columnPlaceHolder, $filter['columnId']); // as sql string
$filterOperation = $this->sqlFilterOperation($filter['operator'], $formattedCellValue, $searchValuePlaceHolder);

if ($this->platform === self::DB_PLATFORM_PGSQL) {
$sqlFilterString = $filterOperation;
} elseif ($this->platform === self::DB_PLATFORM_SQLITE) {
// TODO DB BE SQLITE
$sqlFilterString = '';
} else { // mariadb / mysql
$sqlFilterString = $filterOperation;
}
return $qb->createFunction($sqlFilterString);
}

public function addWhereForFindAllWithColumn(IQueryBuilder $qb, int $columnId): void {
Expand Down
94 changes: 55 additions & 39 deletions lib/Db/RowMapper.php
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,8 @@ class RowMapper extends QBMapper {
protected LoggerInterface $logger;
protected UserHelper $userHelper;

protected int $platform;

public function __construct(IDBConnection $db, LoggerInterface $logger, TextColumnQB $textColumnQB, SelectionColumnQB $selectionColumnQB, NumberColumnQB $numberColumnQB, DatetimeColumnQB $datetimeColumnQB, SuperColumnQB $columnQB, ColumnMapper $columnMapper, UserHelper $userHelper) {
parent::__construct($db, $this->table, Row::class);
$this->logger = $logger;
Expand All @@ -48,24 +50,17 @@ public function __construct(IDBConnection $db, LoggerInterface $logger, TextColu

private function setPlatform() {
if (str_contains(strtolower(get_class($this->db->getDatabasePlatform())), 'postgres')) {
$this->genericColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_PGSQL);
$this->textColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_PGSQL);
$this->numberColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_PGSQL);
$this->selectionColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_PGSQL);
$this->datetimeColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_PGSQL);
$this->platform = IColumnTypeQB::DB_PLATFORM_PGSQL;
} elseif (str_contains(strtolower(get_class($this->db->getDatabasePlatform())), 'sqlite')) {
$this->genericColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_SQLITE);
$this->textColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_SQLITE);
$this->numberColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_SQLITE);
$this->selectionColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_SQLITE);
$this->datetimeColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_SQLITE);
$this->platform = IColumnTypeQB::DB_PLATFORM_SQLITE;
} else {
$this->genericColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_MYSQL);
$this->textColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_MYSQL);
$this->numberColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_MYSQL);
$this->selectionColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_MYSQL);
$this->datetimeColumnQB->setPlatform(IColumnTypeQB::DB_PLATFORM_MYSQL);
$this->platform = IColumnTypeQB::DB_PLATFORM_MYSQL;
}
$this->genericColumnQB->setPlatform($this->platform);
$this->textColumnQB->setPlatform($this->platform);
$this->numberColumnQB->setPlatform($this->platform);
$this->selectionColumnQB->setPlatform($this->platform);
$this->datetimeColumnQB->setPlatform($this->platform);
}

/**
Expand All @@ -78,8 +73,8 @@ private function setPlatform() {
*/
public function find(int $id): Row {
$qb = $this->db->getQueryBuilder();
$qb->select('*')
->from($this->table)
$qb->select('t1.*')
->from($this->table, 't1')
->where($qb->expr()->eq('id', $qb->createNamedParameter($id, IQueryBuilder::PARAM_INT)));
return $this->findEntity($qb);
}
Expand Down Expand Up @@ -147,10 +142,22 @@ private function addOrderByRules(IQueryBuilder $qb, $sortArray) {
continue;
}
$sortColumnPlaceholder = 'sortColumn'.$index;
$orderString = 'JSON_EXTRACT(data, CONCAT( JSON_UNQUOTE(JSON_SEARCH(JSON_EXTRACT(data, \'$[*].columnId\'), \'one\', :'.$sortColumnPlaceholder.')), \'.value\'))';
if (str_starts_with($sortRule['columnType'], 'number')) {
$orderString = 'CAST('.$orderString.' as int)';
if ($sortRule['columnId'] < 0) {
$orderString = ':'.$sortColumnPlaceholder;
} else {
if ($this->platform === IColumnTypeQB::DB_PLATFORM_PGSQL) {
$orderString = 'c'.$sortRule['columnId'].'->>\'value\'';
} elseif ($this->platform === IColumnTypeQB::DB_PLATFORM_SQLITE) {
// TODO DB BE SQLITE
$orderString = '';
} else { // mariadb / mysql
$orderString = 'JSON_EXTRACT(data, CONCAT( JSON_UNQUOTE(JSON_SEARCH(JSON_EXTRACT(data, \'$[*].columnId\'), \'one\', :'.$sortColumnPlaceholder.')), \'.value\'))';
}
if (str_starts_with($sortRule['columnType'], 'number')) {
$orderString = 'CAST('.$orderString.' as decimal)';
}
}

$qb->addOrderBy($qb->createFunction($orderString), $sortMode);
$qb->setParameter($sortColumnPlaceholder, $sortRule['columnId'], IQueryBuilder::PARAM_INT);
}
Expand All @@ -164,11 +171,11 @@ private function addOrderByRules(IQueryBuilder $qb, $sortArray) {
*/
public function countRowsForView(View $view, $userId): int {
$qb = $this->db->getQueryBuilder();
$qb->select($qb->func()->count('*', 'counter'))
->from($this->table)
$qb->select($qb->func()->count('t1.*', 'counter'))
->from($this->table, 't1')
->where($qb->expr()->eq('table_id', $qb->createNamedParameter($view->getTableId(), IQueryBuilder::PARAM_INT)));

$neededColumnIds = $this->getAllColumnIdsFromView($view);
$neededColumnIds = $this->getAllColumnIdsFromView($view, $qb);
try {
$neededColumns = $this->columnMapper->getColumnTypes($neededColumnIds);
} catch (Exception $e) {
Expand All @@ -191,11 +198,11 @@ public function countRowsForView(View $view, $userId): int {

public function getRowIdsOfView(View $view, $userId): array {
$qb = $this->db->getQueryBuilder();
$qb->select('id')
->from($this->table)
$qb->select('t1.id')
->from($this->table,'t1')
->where($qb->expr()->eq('table_id', $qb->createNamedParameter($view->getTableId(), IQueryBuilder::PARAM_INT)));

$neededColumnIds = $this->getAllColumnIdsFromView($view);
$neededColumnIds = $this->getAllColumnIdsFromView($view, $qb);
$neededColumns = $this->columnMapper->getColumnTypes($neededColumnIds);

// Filter
Expand Down Expand Up @@ -243,8 +250,8 @@ private function addFilterToQuery(IQueryBuilder $qb, View $view, array $neededCo
*/
public function findAllByTable(int $tableId, ?int $limit = null, ?int $offset = null): array {
$qb = $this->db->getQueryBuilder();
$qb->select('*')
->from($this->table)
$qb->select('t1.*')
->from($this->table, 't1')
->where($qb->expr()->eq('table_id', $qb->createNamedParameter($tableId)));

if ($limit !== null) {
Expand All @@ -267,12 +274,12 @@ public function findAllByTable(int $tableId, ?int $limit = null, ?int $offset =
*/
public function findAllByView(View $view, string $userId, ?int $limit = null, ?int $offset = null): array {
$qb = $this->db->getQueryBuilder();
$qb->select('*')
->from($this->table)
$qb->select('t1.*')
->from($this->table, 't1')
->where($qb->expr()->eq('table_id', $qb->createNamedParameter($view->getTableId(), IQueryBuilder::PARAM_INT)));


$neededColumnIds = $this->getAllColumnIdsFromView($view);
$neededColumnIds = $this->getAllColumnIdsFromView($view, $qb);
$neededColumnsTypes = $this->columnMapper->getColumnTypes($neededColumnIds);

// Filter
Expand Down Expand Up @@ -302,7 +309,7 @@ public function findAllByView(View $view, string $userId, ?int $limit = null, ?i
return $rows;
}

private function getAllColumnIdsFromView(View $view): array {
private function getAllColumnIdsFromView(View $view, IQueryBuilder $qb): array {
$neededColumnIds = [];
$filters = $view->getFilterArray();
$sorts = $view->getSortArray();
Expand All @@ -314,7 +321,16 @@ private function getAllColumnIdsFromView(View $view): array {
foreach ($sorts as $sortRule) {
$neededColumnIds[] = $sortRule['columnId'];
}
return array_unique($neededColumnIds);
$neededColumnIds = array_unique($neededColumnIds);
if ($this->platform === IColumnTypeQB::DB_PLATFORM_PGSQL) {
foreach ($neededColumnIds as $columnId) {
if ($columnId >= 0) {
$qb->leftJoin("t1", $qb->createFunction('json_array_elements(t1.data)'), 'c' . intval($columnId),$qb->createFunction("CAST(c".intval($columnId).".value->>'columnId' AS int) = ".$columnId));
// TODO Security
}
}
}
return $neededColumnIds;
}

/**
Expand All @@ -324,8 +340,8 @@ private function getAllColumnIdsFromView(View $view): array {
*/
public function findNext(int $offsetId = -1): Row {
$qb = $this->db->getQueryBuilder();
$qb->select('*')
->from($this->table)
$qb->select('t1.*')
->from($this->table, 't1')
->where($qb->expr()->gt('id', $qb->createNamedParameter($offsetId)))
->setMaxResults(1)
->orderBy('id', 'ASC');
Expand All @@ -351,8 +367,8 @@ public function deleteAllByTable(int $tableId): int {
*/
public function findAllWithColumn(int $columnId): array {
$qb = $this->db->getQueryBuilder();
$qb->select('*')
->from($this->table);
$qb->select('t1.*')
->from($this->table, 't1');

$this->genericColumnQB->addWhereForFindAllWithColumn($qb, $columnId);

Expand All @@ -365,8 +381,8 @@ public function findAllWithColumn(int $columnId): array {
*/
public function countRows(int $tableId): int {
$qb = $this->db->getQueryBuilder();
$qb->select($qb->func()->count('*', 'counter'));
$qb->from($this->table);
$qb->select($qb->func()->count('t1.*', 'counter'));
$qb->from($this->table, 't1');
$qb->where(
$qb->expr()->eq('table_id', $qb->createNamedParameter($tableId))
);
Expand Down
2 changes: 1 addition & 1 deletion lib/Db/Table.php
Original file line number Diff line number Diff line change
Expand Up @@ -25,7 +25,7 @@
* @method getRowsCount(): int
* @method setRowsCount(int $rowsCount)
* @method getColumnsCount(): int
* @method setColumnsCount(int $rowsCount)
* @method setColumnsCount(int $columnsCount)
* @method getViews(): array
* @method setViews(array $views)
* @method getColumns(): array
Expand Down
2 changes: 1 addition & 1 deletion lib/Service/ColumnService.php
Original file line number Diff line number Diff line change
Expand Up @@ -443,7 +443,7 @@ public function findOrCreateColumnsByTitleForTableAsArray(?int $tableId, ?int $v
* @throws PermissionError
*/
public function getColumnsCount(int $tableId): int {
if ($this->permissionsService->canManageTableById($tableId)) {
if ($this->permissionsService->canReadColumnsByTableId($tableId)) {
return $this->mapper->countColumns($tableId);
} else {
throw new PermissionError('no read access for counting to table id = '.$tableId);
Expand Down
2 changes: 1 addition & 1 deletion lib/Service/TableService.php
Original file line number Diff line number Diff line change
Expand Up @@ -161,7 +161,7 @@ private function enhanceTable(Table $table, string $userId): void {
try {
$table->setColumnsCount($this->columnService->getColumnsCount($table->getId()));
} catch (InternalError|PermissionError $e) {
$table->setRowsCount(0);
$table->setColumnsCount(0);
}

// set if this is a shared table with you (somebody else shared it with you)
Expand Down
Loading

0 comments on commit 7b4afaa

Please sign in to comment.