mirror of
https://github.com/Part-DB/Part-DB-server.git
synced 2025-06-20 17:15:51 +02:00
Use postgres native array_position function instead of our FIELD function and pass it as array literal instead of variadic function
Otherwise we will run into errors, that we can not give more than 100 arguments to a function
This commit is contained in:
parent
8bb8118d9f
commit
0a482da93e
4 changed files with 90 additions and 17 deletions
|
@ -47,6 +47,7 @@ doctrine:
|
|||
field: DoctrineExtensions\Query\Mysql\Field
|
||||
field2: App\Doctrine\Functions\Field2
|
||||
natsort: App\Doctrine\Functions\Natsort
|
||||
array_position: App\Doctrine\Functions\ArrayPosition
|
||||
|
||||
when@test:
|
||||
doctrine:
|
||||
|
|
|
@ -202,15 +202,6 @@ final class Version20240606203053 extends AbstractMultiPlatformMigration impleme
|
|||
$this->addSql('ALTER TABLE "users" ADD CONSTRAINT FK_1483A5E938248176 FOREIGN KEY (currency_id) REFERENCES currencies (id) NOT DEFERRABLE INITIALLY IMMEDIATE');
|
||||
$this->addSql('ALTER TABLE webauthn_keys ADD CONSTRAINT FK_799FD143A76ED395 FOREIGN KEY (user_id) REFERENCES "users" (id) NOT DEFERRABLE INITIALLY IMMEDIATE');
|
||||
|
||||
//Create the FIELD() function for PostgreSQL
|
||||
$this->addSql(<<<SQL
|
||||
CREATE OR REPLACE FUNCTION FIELD(anyelement, VARIADIC anyarray) RETURNS bigint AS $$
|
||||
SELECT n FROM (
|
||||
SELECT row_number() OVER () AS n, x FROM unnest($2) x)
|
||||
numbered WHERE numbered.x = $1;
|
||||
$$ LANGUAGE SQL IMMUTABLE STRICT;
|
||||
SQL);
|
||||
|
||||
//Create the initial groups and users
|
||||
//Retrieve the json representations of the presets
|
||||
$admin = $this->getJSONPermDataFromPreset(PermissionPresetsHelper::PRESET_ADMIN);
|
||||
|
|
59
src/Doctrine/Functions/ArrayPosition.php
Normal file
59
src/Doctrine/Functions/ArrayPosition.php
Normal file
|
@ -0,0 +1,59 @@
|
|||
<?php
|
||||
/*
|
||||
* This file is part of Part-DB (https://github.com/Part-DB/Part-DB-symfony).
|
||||
*
|
||||
* Copyright (C) 2019 - 2024 Jan Böhmer (https://github.com/jbtronics)
|
||||
*
|
||||
* This program is free software: you can redistribute it and/or modify
|
||||
* it under the terms of the GNU Affero General Public License as published
|
||||
* by the Free Software Foundation, either version 3 of the License, or
|
||||
* (at your option) any later version.
|
||||
*
|
||||
* This program is distributed in the hope that it will be useful,
|
||||
* but WITHOUT ANY WARRANTY; without even the implied warranty of
|
||||
* MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
|
||||
* GNU Affero General Public License for more details.
|
||||
*
|
||||
* You should have received a copy of the GNU Affero General Public License
|
||||
* along with this program. If not, see <https://www.gnu.org/licenses/>.
|
||||
*/
|
||||
|
||||
declare(strict_types=1);
|
||||
|
||||
|
||||
namespace App\Doctrine\Functions;
|
||||
|
||||
use Doctrine\ORM\Query\AST\Functions\FunctionNode;
|
||||
use Doctrine\ORM\Query\AST\Node;
|
||||
use Doctrine\ORM\Query\Parser;
|
||||
use Doctrine\ORM\Query\SqlWalker;
|
||||
use Doctrine\ORM\Query\TokenType;
|
||||
|
||||
class ArrayPosition extends FunctionNode
|
||||
{
|
||||
private ?Node $array = null;
|
||||
|
||||
private ?Node $field = null;
|
||||
|
||||
public function parse(Parser $parser): void
|
||||
{
|
||||
$parser->match(TokenType::T_IDENTIFIER);
|
||||
$parser->match(TokenType::T_OPEN_PARENTHESIS);
|
||||
|
||||
$this->array = $parser->InParameter();
|
||||
|
||||
$parser->match(TokenType::T_COMMA);
|
||||
|
||||
$this->field = $parser->ArithmeticPrimary();
|
||||
|
||||
$parser->match(TokenType::T_CLOSE_PARENTHESIS);
|
||||
}
|
||||
|
||||
public function getSql(SqlWalker $sqlWalker): string
|
||||
{
|
||||
return 'ARRAY_POSITION(' .
|
||||
$this->array->dispatch($sqlWalker) . ', ' .
|
||||
$this->field->dispatch($sqlWalker) .
|
||||
')';
|
||||
}
|
||||
}
|
|
@ -45,11 +45,11 @@ final class FieldHelper
|
|||
{
|
||||
$db_platform = $qb->getEntityManager()->getConnection()->getDatabasePlatform();
|
||||
|
||||
//If we are on MySQL, we can just use the FIELD function, for PostgreSQL we can use our custom defined one
|
||||
if ($db_platform instanceof AbstractMySQLPlatform || $db_platform instanceof PostgreSQLPlatform) {
|
||||
$param = (is_numeric($bound_param) ? '?' : ":") . (string) $bound_param;
|
||||
//If we are on MySQL, we can just use the FIELD function
|
||||
if ($db_platform instanceof AbstractMySQLPlatform ) {
|
||||
$param = (is_numeric($bound_param) ? '?' : ":").(string)$bound_param;
|
||||
$qb->orderBy("FIELD($field_expr, $param)", $order);
|
||||
} else { //Use the sqlite/portable version
|
||||
} else { //Use the sqlite/portable version or postgresql
|
||||
//Retrieve the values from the bound parameter
|
||||
$param = $qb->getParameter($bound_param);
|
||||
if ($param === null) {
|
||||
|
@ -58,12 +58,31 @@ final class FieldHelper
|
|||
|
||||
//Generate a unique key from the field_expr
|
||||
$key = 'field2_' . (string) $bound_param;
|
||||
self::addSqliteOrderBy($qb, $field_expr, $key, $param->getValue(), $order);
|
||||
|
||||
if ($db_platform instanceof PostgreSQLPlatform) {
|
||||
self::addPostgresOrderBy($qb, $field_expr, $key, $param->getValue(), $order);
|
||||
} else {
|
||||
self::addSqliteOrderBy($qb, $field_expr, $key, $param->getValue(), $order);
|
||||
}
|
||||
}
|
||||
|
||||
return $qb;
|
||||
}
|
||||
|
||||
|
||||
private static function addPostgresOrderBy(QueryBuilder $qb, string $field_expr, string $key, array $values, ?string $order = null): void
|
||||
{
|
||||
//Use postgres native array_position function, to get the index of the value in the array
|
||||
//In the end it gives a similar result as the FIELD function
|
||||
$qb->orderBy("array_position(:$key, $field_expr)", $order);
|
||||
|
||||
//Convert the values to a literal array, to overcome the problem of passing more than 100 parameters
|
||||
$values = array_map(fn($value) => is_string($value) ? "'$value'" : $value, $values);
|
||||
$literalArray = '{' . implode(',', $values) . '}';
|
||||
|
||||
$qb->setParameter($key, $literalArray);
|
||||
}
|
||||
|
||||
private static function addSqliteOrderBy(QueryBuilder $qb, string $field_expr, string $key, array $values, ?string $order = null): void
|
||||
{
|
||||
//Otherwise we emulate it using
|
||||
|
@ -87,9 +106,12 @@ final class FieldHelper
|
|||
|
||||
$key = 'field2_' . md5($field_expr);
|
||||
|
||||
//If we are on MySQL, we can just use the FIELD function, for postgres we can use our custom defined one
|
||||
if ($db_platform instanceof AbstractMySQLPlatform || $db_platform instanceof PostgreSQLPlatform) {
|
||||
$qb->orderBy("FIELD($field_expr, :field_arr)", $order);
|
||||
//If we are on MySQL, we can just use the FIELD function
|
||||
if ($db_platform instanceof AbstractMySQLPlatform) {
|
||||
$qb->orderBy("FIELD2($field_expr, :field_arr)", $order);
|
||||
} else if ($db_platform instanceof PostgreSQLPlatform) {
|
||||
//Use the postgres native array_position function
|
||||
self::addPostgresOrderBy($qb, $field_expr, $key, $values, $order);
|
||||
} else {
|
||||
//Otherwise use the portable version using string concatenation
|
||||
self::addSqliteOrderBy($qb, $field_expr, $key, $values, $order);
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue