From 62b1e3361600078b83635ce15e60053ceacca8a7 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jan=20B=C3=B6hmer?= Date: Sat, 29 Jul 2023 16:42:27 +0200 Subject: [PATCH] Fixed field ordering on SQLite --- config/packages/doctrine.yaml | 3 +- src/DataTables/PartsDataTable.php | 9 +- src/Doctrine/Functions/CustomField.php | 130 ------------------ src/Doctrine/Functions/Field2.php | 81 +++++++++++ src/Doctrine/Helpers/FieldHelper.php | 96 +++++++++++++ ...ttachmentContainingDBElementRepository.php | 19 ++- src/Repository/DBElementRepository.php | 19 ++- 7 files changed, 214 insertions(+), 143 deletions(-) delete mode 100644 src/Doctrine/Functions/CustomField.php create mode 100644 src/Doctrine/Functions/Field2.php create mode 100644 src/Doctrine/Helpers/FieldHelper.php diff --git a/config/packages/doctrine.yaml b/config/packages/doctrine.yaml index 37d74b14..2db28db2 100644 --- a/config/packages/doctrine.yaml +++ b/config/packages/doctrine.yaml @@ -38,7 +38,8 @@ doctrine: string_functions: regexp: DoctrineExtensions\Query\Mysql\Regexp ifnull: DoctrineExtensions\Query\Mysql\IfNull - field: App\Doctrine\Functions\CustomField + field: DoctrineExtensions\Query\Mysql\Field + field2: App\Doctrine\Functions\Field2 when@test: doctrine: diff --git a/src/DataTables/PartsDataTable.php b/src/DataTables/PartsDataTable.php index 18eee1b5..eac739f8 100644 --- a/src/DataTables/PartsDataTable.php +++ b/src/DataTables/PartsDataTable.php @@ -25,6 +25,7 @@ namespace App\DataTables; use App\DataTables\Adapters\FetchResultsAtOnceORMAdapter; use App\DataTables\Adapters\TwoStepORMAdapater; use App\DataTables\Column\EnumColumn; +use App\Doctrine\Helpers\FieldHelper; use App\Entity\Parts\ManufacturingStatus; use Doctrine\ORM\Mapping\ClassMetadata; use Doctrine\ORM\Mapping\ClassMetadataInfo; @@ -324,8 +325,10 @@ final class PartsDataTable implements DataTableTypeInterface ; } - private function getDetailQuery(QueryBuilder $builder, array $ids): void + private function getDetailQuery(QueryBuilder $builder, array $filter_results): void { + $ids = array_map(fn($row) => $row['id'], $filter_results); + /* * In this query we take the IDs which were filtered, paginated and sorted in the filter query, and fetch the * full entities. @@ -370,7 +373,6 @@ final class PartsDataTable implements DataTableTypeInterface ->leftJoin('part.parameters', 'parameters') ->where('part.id IN (:ids)') - ->orderBy('FIELD(part.id, :ids)') ->setParameter('ids', $ids) //We have to group by all elements, or only the first sub elements of an association is fetched! (caused issue #190) @@ -388,6 +390,9 @@ final class PartsDataTable implements DataTableTypeInterface ->addGroupBy('partUnit') ->addGroupBy('parameters') ; + + //Get the results in the same order as the IDs were passed + FieldHelper::addOrderByFieldParam($builder, 'part.id', 'ids'); } private function buildCriteria(QueryBuilder $builder, array $options): void diff --git a/src/Doctrine/Functions/CustomField.php b/src/Doctrine/Functions/CustomField.php deleted file mode 100644 index 31a2b3de..00000000 --- a/src/Doctrine/Functions/CustomField.php +++ /dev/null @@ -1,130 +0,0 @@ -. - */ - -declare(strict_types=1); - - -namespace App\Doctrine\Functions; - -use Doctrine\DBAL\Platforms\AbstractMySQLPlatform; -use Doctrine\DBAL\Platforms\SqlitePlatform; -use Doctrine\ORM\Query\AST\Functions\FunctionNode; -use Doctrine\ORM\Query\AST\InputParameter; -use Doctrine\ORM\Query\AST\Literal; -use Doctrine\ORM\Query\AST\Node; -use Doctrine\ORM\Query\Lexer; -use Doctrine\ORM\Query\Parser; -use Doctrine\ORM\Query\SqlWalker; -use DoctrineExtensions\Query\Mysql\Field; - -class CustomField extends Field -{ - - protected Node|null|string $field = null; - - /** @var Node[] */ - protected array $values = []; - - - public function parse(\Doctrine\ORM\Query\Parser $parser): void - { - //If we are on MySQL, we can just call the parent method, as these values are not needed in that class then - if ($parser->getEntityManager()->getConnection()->getDatabasePlatform() instanceof AbstractMySQLPlatform) { - parent::parse($parser); - return; - } - - //Otherwise we have to do the same as the parent class, so we can use the same getSql method - $parser->match(Lexer::T_IDENTIFIER); - $parser->match(Lexer::T_OPEN_PARENTHESIS); - - // Do the field. - $this->field = $parser->ArithmeticPrimary(); - - // Add the strings to the values array. FIELD must - // be used with at least 1 string not including the field. - - $lexer = $parser->getLexer(); - - while (count($this->values) < 1 || - $lexer->lookahead['type'] != Lexer::T_CLOSE_PARENTHESIS) { - $parser->match(Lexer::T_COMMA); - $this->values[] = $parser->ArithmeticPrimary(); - } - - $parser->match(Lexer::T_CLOSE_PARENTHESIS); - } - - public function getSql(SqlWalker $sqlWalker): string - { - //If we are on MySQL, we can use the builtin FIELD function and just call the parent method - if ($sqlWalker->getConnection()->getDatabasePlatform() instanceof AbstractMySQLPlatform) { - return parent::getSql($sqlWalker); - } - - //When we are on SQLite, we have to emulate it with the FIELD2 function - if ($sqlWalker->getConnection()->getDatabasePlatform() instanceof SqlitePlatform) { - return $this->getSqlForSQLite($sqlWalker); - } - - throw new \LogicException('Unsupported database platform'); - } - - /** - * Very similar to the parent method, but uses custom implmented FIELD2 function, which takes the values as a comma separated list - * instead of an array to migigate the argument count limit of SQLite. - * @param SqlWalker $sqlWalker - * @return string - * @throws \Doctrine\ORM\Query\AST\ASTException - */ - private function getSqlForSQLite(SqlWalker $sqlWalker): string - { - //We must collect the real values (including the bind ones, of all values) and merge them into one string - $resolved = []; - - foreach ($this->values as $node) { - if ($node instanceof InputParameter) { - $value = $sqlWalker->getQuery()->getParameter($node->name)?->getValue(); - if ($value) { - $resolved[] = $value; - } - } - } - - $output = []; - array_walk_recursive($resolved, function($value) use (&$output) { - $output[] = $value; - }); - - //Merge all values into one string and create a new node - $stringified = implode(',', $output); - //We use it as a string literal here, as bound parameters, seems to be difficult to use here - $literal = new Literal(Literal::STRING, $stringified); - - $query = 'FIELD2('; - $query .= $this->field->dispatch($sqlWalker); - $query .= ','; - //We bind the stringified values as a new parameter - $query .= $literal->dispatch($sqlWalker); - $query .= ')'; - - return $query; - } -} \ No newline at end of file diff --git a/src/Doctrine/Functions/Field2.php b/src/Doctrine/Functions/Field2.php new file mode 100644 index 00000000..dc12b294 --- /dev/null +++ b/src/Doctrine/Functions/Field2.php @@ -0,0 +1,81 @@ +. + */ + +declare(strict_types=1); + + +namespace App\Doctrine\Functions; + +use Doctrine\ORM\Query\AST\Functions\FunctionNode; +use Doctrine\ORM\Query\Lexer; + +/** + * Basically the same as the original Field function, but uses FIELD2 for the SQL query. + */ +class Field2 extends FunctionNode +{ + + private $field = null; + + private $values = []; + + public function parse(\Doctrine\ORM\Query\Parser $parser) + { + $parser->match(Lexer::T_IDENTIFIER); + $parser->match(Lexer::T_OPEN_PARENTHESIS); + + // Do the field. + $this->field = $parser->ArithmeticPrimary(); + + // Add the strings to the values array. FIELD must + // be used with at least 1 string not including the field. + + $lexer = $parser->getLexer(); + + while (count($this->values) < 1 || + $lexer->lookahead['type'] != Lexer::T_CLOSE_PARENTHESIS) { + $parser->match(Lexer::T_COMMA); + $this->values[] = $parser->ArithmeticPrimary(); + } + + $parser->match(Lexer::T_CLOSE_PARENTHESIS); + } + + public function getSql(\Doctrine\ORM\Query\SqlWalker $sqlWalker) + { + $query = 'FIELD2('; + + $query .= $this->field->dispatch($sqlWalker); + + $query .= ', '; + + for ($i = 0; $i < count($this->values); $i++) { + if ($i > 0) { + $query .= ', '; + } + + $query .= $this->values[$i]->dispatch($sqlWalker); + } + + $query .= ')'; + + return $query; + } +} \ No newline at end of file diff --git a/src/Doctrine/Helpers/FieldHelper.php b/src/Doctrine/Helpers/FieldHelper.php new file mode 100644 index 00000000..17fbe733 --- /dev/null +++ b/src/Doctrine/Helpers/FieldHelper.php @@ -0,0 +1,96 @@ +. + */ + +declare(strict_types=1); + + +namespace App\Doctrine\Helpers; + +use Doctrine\DBAL\Platforms\AbstractMySQLPlatform; +use Doctrine\ORM\QueryBuilder; + +/** + * The purpose of this class is to provide help with using the FIELD functions in Doctrine, which depends on the database platform. + */ +final class FieldHelper +{ + /** + * Add an ORDER BY FIELD expression to the query builder. The correct FIELD function is used depending on the database platform. + * In this function an already bound paramater is used. If you want to a not already bound value, use the addOrderByFieldValues function. + * @param QueryBuilder $qb The query builder to apply the order by to + * @param string $field_expr The expression to compare with the values + * @param string|int $bound_param The already bound parameter to use for the values + * @param string|null $order The order direction (ASC or DESC) + * @return QueryBuilder + */ + public static function addOrderByFieldParam(QueryBuilder $qb, string $field_expr, string|int $bound_param, ?string $order = null): QueryBuilder + { + $db_platform = $qb->getEntityManager()->getConnection()->getDatabasePlatform(); + + //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 { + //Retrieve the values from the bound parameter + $param = $qb->getParameter($bound_param); + if ($param === null) { + throw new \InvalidArgumentException("The bound parameter $bound_param does not exist."); + } + + //Generate a unique key from the field_expr + $key = 'field2_' . (string) $bound_param; + //Otherwise we have to it using the FIELD2 function + $qb->orderBy("FIELD2($field_expr, :$key)", $order); + $qb->setParameter($key, implode(',', $param->getValue())); + } + + return $qb; + } + + /** + * Add an ORDER BY FIELD expression to the query builder. The correct FIELD function is used depending on the database platform. + * In this function the values are passed as an array. If you want to reuse an existing bound parameter, use the addOrderByFieldParam function. + * @param QueryBuilder $qb The query builder to apply the order by to + * @param string $field_expr The expression to compare with the values + * @param array $values The values to compare with the expression as array + * @param string|null $order The order direction (ASC or DESC) + * @return QueryBuilder + */ + public static function addOrderByFieldValues(QueryBuilder $qb, string $field_expr, array $values, ?string $order = null): QueryBuilder + { + $db_platform = $qb->getEntityManager()->getConnection()->getDatabasePlatform(); + + $key = 'field2_' . md5($field_expr); + + //If we are on MySQL, we can just use the FIELD function + if ($db_platform instanceof AbstractMySQLPlatform) { + $qb->orderBy("FIELD($field_expr, :field_arr)", $order); + } else { + //Generate a unique key from the field_expr + + //Otherwise we have to it using the FIELD2 function + $qb->orderBy("FIELD2($field_expr, :$key)", $order); + $qb->setParameter($key, implode(',', $values)); + } + + return $qb; + } +} \ No newline at end of file diff --git a/src/Repository/AttachmentContainingDBElementRepository.php b/src/Repository/AttachmentContainingDBElementRepository.php index 267982a1..7f00f87f 100644 --- a/src/Repository/AttachmentContainingDBElementRepository.php +++ b/src/Repository/AttachmentContainingDBElementRepository.php @@ -23,6 +23,7 @@ declare(strict_types=1); namespace App\Repository; +use App\Doctrine\Helpers\FieldHelper; use App\Entity\Attachments\AttachmentContainingDBElement; use Doctrine\ORM\Mapping\ClassMetadataInfo; @@ -45,6 +46,11 @@ class AttachmentContainingDBElementRepository extends NamedDBElementRepository */ public function getElementsAndPreviewAttachmentByIDs(array $ids): array { + //If no IDs are given, return an empty array + if (count($ids) === 0) { + return []; + } + //Convert the ids to a string $cache_key = implode(',', $ids); @@ -53,13 +59,16 @@ class AttachmentContainingDBElementRepository extends NamedDBElementRepository return $this->elementsAndPreviewAttachmentCache[$cache_key]; } - $qb = $this->createQueryBuilder('element'); - $q = $qb->select('element') + $qb = $this->createQueryBuilder('element') + ->select('element') ->where('element.id IN (?1)') //Order the results in the same order as the IDs in the input array (mysql supports this native, for SQLite we emulate it) - ->orderBy('FIELD(element.id, ?1)') - ->setParameter(1, $ids) - ->getQuery(); + ->setParameter(1, $ids); + + //Order the results in the same order as the IDs in the input array + FieldHelper::addOrderByFieldParam($qb, 'element.id', 1); + + $q = $qb->getQuery(); $q->setFetchMode($this->getEntityName(), 'master_picture_attachment', ClassMetadataInfo::FETCH_EAGER); diff --git a/src/Repository/DBElementRepository.php b/src/Repository/DBElementRepository.php index 26bcb7a8..296f2a9a 100644 --- a/src/Repository/DBElementRepository.php +++ b/src/Repository/DBElementRepository.php @@ -41,7 +41,9 @@ declare(strict_types=1); namespace App\Repository; +use App\Doctrine\Helpers\FieldHelper; use App\Entity\Base\AbstractDBElement; +use Doctrine\DBAL\Platforms\AbstractMySQLPlatform; use Doctrine\ORM\EntityRepository; use ReflectionClass; @@ -101,6 +103,11 @@ class DBElementRepository extends EntityRepository */ public function findByIDInMatchingOrder(array $ids): array { + //If no IDs are given, return an empty array + if (count($ids) === 0) { + return []; + } + $cache_key = implode(',', $ids); //Check if the result is already cached @@ -110,12 +117,14 @@ class DBElementRepository extends EntityRepository //Otherwise do the query $qb = $this->createQueryBuilder('element'); - $q = $qb->select('element') + $qb->select('element') ->where('element.id IN (?1)') - ->setParameter(1, $ids) - //Order the results in the same order as the IDs in the input array (mysql supports this native, for SQLite we emulate it) - ->orderBy('FIELD(element.id, ?1)') - ->getQuery(); + ->setParameter(1, $ids); + + //Order the results in the same order as the IDs in the input array + FieldHelper::addOrderByFieldParam($qb, 'element.id', 1); + + $q = $qb->getQuery(); $result = $q->getResult();