Skip to content

Commit 563eaf8

Browse files
committed
[BUGFIX] Avoid PostgreSQL type issue in LiveSearch providers
With #106040 general search field lists has been streamlined to retrieve it from TcaSchema single source of truth, streamlining related code for the LiveSearch related provider implementation. PostgreSQL is really picky related to value or field types when used in query constraints, for example using SQL functions which expects string (TEXT) values but recieves an integer or another type and awarding this with errors like following: Undefined function: 7 ERROR: function lower(integer) does not exist Using integer field values for LIKE queries does not work for PostgreSQL, beside not making much sense to search for '%admin%' on a integerfield like 'pages.uid'. Integer values may still valid to be searched partly on integer fields, requiring to cast values to a compatible TEXT type first. Searching for non-integer values does not make much sense, but at least should not break with an error. This change completes #106040 work for all databases ... * Removing like search constraints for hardcoded 'uid' and 'pid' fields in case the search tearm is not an integer. * Enhancing `ExpressionBuilder` methods `like()` and `notLike()` to cast provided field to text field representation only for PostgreSQL, literally providing matching behaviour from MySQL, MariaDB and SQLite for integer columns. * Modifing `LikeWildcardTest` functional test to reflect the added type-cast to `ExpressionBuilder` methods and simplifing the setup to easier read the expected results instead of obscure build up. * Casting field value to text representation on PostgresSQL for the direct created lower-case like query constraints in the providers. * Slightly modifing the constraint build code for searchfields to use `AND` composition only when a second part is added to make it less confusing. TCA field search option `case` is not really enforcable in all cases, requiring specific collation on column and values which is not ensured. Corresponding todo's are added, out-of-scope of this change and a bigger general issue. Resolves: #106085 Related: #106097 Related: #106040 Releases: main, 13.4 Change-Id: I5be380f17c1c3a62d5cafbd5933bd1678c37a2be Reviewed-on: https://review.typo3.org/c/Packages/TYPO3.CMS/+/88030 Tested-by: core-ci <typo3@b13.com> Reviewed-by: Benni Mack <benni@typo3.org> Tested-by: Christian Kuhn <lolli@schwarzbu.ch> Reviewed-by: Christian Kuhn <lolli@schwarzbu.ch> Tested-by: Stefan Bürk <stefan@buerk.tech> Reviewed-by: Stefan Bürk <stefan@buerk.tech> Tested-by: Anja Leichsenring <aleichsenring@ab-softlab.de> Reviewed-by: Anja Leichsenring <aleichsenring@ab-softlab.de>
1 parent 01080ce commit 563eaf8

File tree

6 files changed

+132
-123
lines changed

6 files changed

+132
-123
lines changed

typo3/sysext/backend/Classes/RecordList/DatabaseRecordList.php

Lines changed: 0 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -32,7 +32,6 @@
3232
use TYPO3\CMS\Backend\Routing\UriBuilder;
3333
use TYPO3\CMS\Backend\Template\Components\Buttons\ButtonInterface;
3434
use TYPO3\CMS\Backend\Template\Components\Buttons\GenericButton;
35-
use TYPO3\CMS\Backend\Template\Components\MultiRecordSelection\Action;
3635
use TYPO3\CMS\Backend\Tree\Repository\PageTreeRepository;
3736
use TYPO3\CMS\Backend\Utility\BackendUtility;
3837
use TYPO3\CMS\Backend\View\BackendViewFactory;

typo3/sysext/backend/Classes/Search/LiveSearch/DatabaseRecordProvider.php

Lines changed: 26 additions & 30 deletions
Original file line numberDiff line numberDiff line change
@@ -18,6 +18,7 @@
1818
namespace TYPO3\CMS\Backend\Search\LiveSearch;
1919

2020
use Doctrine\DBAL\ArrayParameterType;
21+
use Doctrine\DBAL\Platforms\PostgreSQLPlatform as DoctrinePostgreSQLPlatform;
2122
use Psr\EventDispatcher\EventDispatcherInterface;
2223
use TYPO3\CMS\Backend\Routing\UriBuilder;
2324
use TYPO3\CMS\Backend\Search\Event\BeforeSearchInDatabaseRecordProviderEvent;
@@ -339,9 +340,10 @@ protected function getPageIdList(): array
339340
*/
340341
protected function buildConstraintsForTable(string $queryString, QueryBuilder $queryBuilder, string $tableName): array
341342
{
343+
$platform = $queryBuilder->getConnection()->getDatabasePlatform();
344+
$isPostgres = $platform instanceof DoctrinePostgreSQLPlatform;
342345
$fieldsToSearchWithin = $this->searchableSchemaFieldsCollector->getFields($tableName);
343346
$constraints = [];
344-
345347
// If the search string is a simple integer, assemble an equality comparison
346348
if (MathUtility::canBeInterpretedAsInteger($queryString)) {
347349
// Add uid and pid constraint
@@ -372,46 +374,40 @@ protected function buildConstraintsForTable(string $queryString, QueryBuilder $q
372374
}
373375
} else {
374376
$like = '%' . $queryBuilder->escapeLikeWildcards($queryString) . '%';
375-
// Add uid and pid constraints
376-
$constraints[] = $queryBuilder->expr()->and(
377-
$queryBuilder->expr()->comparison(
378-
'LOWER(' . $queryBuilder->quoteIdentifier('uid') . ')',
379-
'LIKE',
380-
$queryBuilder->createNamedParameter(mb_strtolower($like))
381-
)
382-
);
383-
$constraints[] = $queryBuilder->expr()->and(
384-
$queryBuilder->expr()->comparison(
385-
'LOWER(' . $queryBuilder->quoteIdentifier('pid') . ')',
386-
'LIKE',
387-
$queryBuilder->createNamedParameter(mb_strtolower($like))
388-
)
389-
);
390377
foreach ($fieldsToSearchWithin as $fieldName => $field) {
391378
$fieldConfig = $field->getConfiguration();
392379

393-
// Check whether search should be case-sensitive or not
394-
$searchConstraint = $queryBuilder->expr()->and(
395-
$queryBuilder->expr()->comparison(
396-
'LOWER(' . $queryBuilder->quoteIdentifier($fieldName) . ')',
397-
'LIKE',
398-
$queryBuilder->createNamedParameter(mb_strtolower($like))
399-
)
380+
// Enforce case-insensitive comparison by lower-casing field and value, unrelated to charset/collation
381+
// on MySQL/MariaDB, for example if column collation is `utf8mb4_bin` - which would be case-sensitive.
382+
$preparedFieldName = $isPostgres
383+
? $queryBuilder->castFieldToTextType($fieldName)
384+
: $queryBuilder->quoteIdentifier($fieldName);
385+
$searchConstraint = $queryBuilder->expr()->comparison(
386+
'LOWER(' . $preparedFieldName . ')',
387+
'LIKE',
388+
$queryBuilder->createNamedParameter(mb_strtolower($like))
400389
);
401390

402391
if (is_array($fieldConfig['search'] ?? false)) {
403392
if (in_array('case', $fieldConfig['search'], true)) {
404-
// Replace case insensitive default constraint
405-
$searchConstraint = $queryBuilder->expr()->and(
406-
$queryBuilder->expr()->like(
407-
$fieldName,
408-
$queryBuilder->createNamedParameter($like)
409-
)
393+
// Replace case-insensitive default constraint with semi case-sensitive constraint.
394+
// @todo This is not really ensured, without a suiting collation on the field (`*_bin`) AND also
395+
// converting the like-value to the same binary collation, MySQL/MariaDB is not searching
396+
// case-sensitive. ExpressionBuilder->like() and notLike() has been adjusted to use same
397+
// case-insensitive search for PostgreSQL to adopt the same behaviour for the most cases.
398+
// Making this here obsolete and interchangeable with the general enforcement above.
399+
// @todo TCA Field search option `case` cannot be enforced easily, which needs deeper analysis
400+
// to find a possible way to do so - or deprecate the option at all.
401+
// https://docs.typo3.org/m/typo3/reference-tca/11.5/en-us/ColumnsConfig/CommonProperties/Search.html#confval-case
402+
$searchConstraint = $queryBuilder->expr()->like(
403+
$fieldName,
404+
$queryBuilder->createNamedParameter($like)
410405
);
411406
}
412407
// Apply additional condition, if any
413408
if ($fieldConfig['search']['andWhere'] ?? false) {
414-
$searchConstraint = $searchConstraint->with(
409+
$searchConstraint = $queryBuilder->expr()->and(
410+
$searchConstraint,
415411
QueryHelper::stripLogicalOperatorPrefix(QueryHelper::quoteDatabaseIdentifiers($queryBuilder->getConnection(), $fieldConfig['search']['andWhere']))
416412
);
417413
}

typo3/sysext/backend/Classes/Search/LiveSearch/PageRecordProvider.php

Lines changed: 26 additions & 29 deletions
Original file line numberDiff line numberDiff line change
@@ -18,6 +18,7 @@
1818
namespace TYPO3\CMS\Backend\Search\LiveSearch;
1919

2020
use Doctrine\DBAL\ArrayParameterType;
21+
use Doctrine\DBAL\Platforms\PostgreSQLPlatform as DoctrinePostgreSQLPlatform;
2122
use Psr\EventDispatcher\EventDispatcherInterface;
2223
use TYPO3\CMS\Backend\Routing\PreviewUriBuilder;
2324
use TYPO3\CMS\Backend\Routing\UriBuilder;
@@ -272,6 +273,8 @@ protected function getPageIdList(): array
272273
*/
273274
protected function buildConstraintsForTable(string $queryString, QueryBuilder $queryBuilder): array
274275
{
276+
$platform = $queryBuilder->getConnection()->getDatabasePlatform();
277+
$isPostgres = $platform instanceof DoctrinePostgreSQLPlatform;
275278
$fieldsToSearchWithin = $this->searchableSchemaFieldsCollector->getFields('pages');
276279
$constraints = [];
277280

@@ -305,46 +308,40 @@ protected function buildConstraintsForTable(string $queryString, QueryBuilder $q
305308
}
306309
} else {
307310
$like = '%' . $queryBuilder->escapeLikeWildcards($queryString) . '%';
308-
// Add uid and pid constraints
309-
$constraints[] = $queryBuilder->expr()->and(
310-
$queryBuilder->expr()->comparison(
311-
'LOWER(' . $queryBuilder->quoteIdentifier('uid') . ')',
312-
'LIKE',
313-
$queryBuilder->createNamedParameter(mb_strtolower($like))
314-
)
315-
);
316-
$constraints[] = $queryBuilder->expr()->and(
317-
$queryBuilder->expr()->comparison(
318-
'LOWER(' . $queryBuilder->quoteIdentifier('pid') . ')',
319-
'LIKE',
320-
$queryBuilder->createNamedParameter(mb_strtolower($like))
321-
)
322-
);
323311
foreach ($fieldsToSearchWithin as $fieldName => $field) {
324312
$fieldConfig = $field->getConfiguration();
325313

326-
// Check whether search should be case-sensitive or not
327-
$searchConstraint = $queryBuilder->expr()->and(
328-
$queryBuilder->expr()->comparison(
329-
'LOWER(' . $queryBuilder->quoteIdentifier($fieldName) . ')',
330-
'LIKE',
331-
$queryBuilder->createNamedParameter(mb_strtolower($like))
332-
)
314+
// Enforce case-insensitive comparison by lower-casing field and value, unrelated to charset/collation
315+
// on MySQL/MariaDB, for example if column collation is `utf8mb4_bin` - which would be case-sensitive.
316+
$preparedFieldName = $isPostgres
317+
? $queryBuilder->castFieldToTextType($fieldName)
318+
: $queryBuilder->quoteIdentifier($fieldName);
319+
$searchConstraint = $queryBuilder->expr()->comparison(
320+
'LOWER(' . $preparedFieldName . ')',
321+
'LIKE',
322+
$queryBuilder->createNamedParameter(mb_strtolower($like))
333323
);
334324

335325
if (is_array($fieldConfig['search'] ?? false)) {
336326
if (in_array('case', $fieldConfig['search'], true)) {
337-
// Replace case insensitive default constraint
338-
$searchConstraint = $queryBuilder->expr()->and(
339-
$queryBuilder->expr()->like(
340-
$fieldName,
341-
$queryBuilder->createNamedParameter($like)
342-
)
327+
// Replace case insensitive default constraint with semi case-sensitive constraint
328+
// @todo This is not really ensured, without a suiting collation on the field (`*_bin`) AND also
329+
// converting the like-value to the same binary collation, MySQL/MariaDB is not searching
330+
// case-sensitive. ExpressionBuilder->like() and notLike() has been adjusted to use same
331+
// case-insensitive search for PostgreSQL to adopt the same behaviour for the most cases.
332+
// Making this here obsolete and interchangeable with the general enforcement above.
333+
// @todo TCA Field search option `case` cannot be enforced easily, which needs deeper analysis
334+
// to find a possible way to do so - or deprecate the option at all.
335+
// https://docs.typo3.org/m/typo3/reference-tca/11.5/en-us/ColumnsConfig/CommonProperties/Search.html#confval-case
336+
$searchConstraint = $queryBuilder->expr()->like(
337+
$fieldName,
338+
$queryBuilder->createNamedParameter($like)
343339
);
344340
}
345341
// Apply additional condition, if any
346342
if ($fieldConfig['search']['andWhere'] ?? false) {
347-
$searchConstraint = $searchConstraint->with(
343+
$searchConstraint = $queryBuilder->expr()->and(
344+
$searchConstraint,
348345
QueryHelper::stripLogicalOperatorPrefix(QueryHelper::quoteDatabaseIdentifiers($queryBuilder->getConnection(), $fieldConfig['search']['andWhere']))
349346
);
350347
}

typo3/sysext/core/Classes/Database/Query/Expression/ExpressionBuilder.php

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -183,7 +183,7 @@ public function like(string $fieldName, mixed $value, ?string $escapeChar = null
183183
}
184184
if ($platform instanceof DoctrinePostgreSQLPlatform) {
185185
// Use ILIKE to mimic case-insensitive search like most people are trained from MySQL/MariaDB.
186-
return $this->comparison($fieldName, 'ILIKE', $value);
186+
return $this->comparison($this->castText($fieldName), 'ILIKE', $value);
187187
}
188188
// Note: SQLite does not properly work with non-ascii letters as search word for case-insensitive
189189
// matching, UPPER() and LOWER() have the same issue, it only works with ascii letters.
@@ -208,7 +208,7 @@ public function notLike(string $fieldName, mixed $value, ?string $escapeChar = n
208208
}
209209
if ($platform instanceof DoctrinePostgreSQLPlatform) {
210210
// Use ILIKE to mimic case-insensitive search like most people are trained from MySQL/MariaDB.
211-
return $this->comparison($fieldName, 'NOT ILIKE', $value);
211+
return $this->comparison($this->castText($fieldName), 'NOT ILIKE', $value);
212212
}
213213
// Note: SQLite does not properly work with non-ascii letters as search word for case-insensitive
214214
// matching, UPPER() and LOWER() have the same issue, it only works with ascii letters.

typo3/sysext/core/Tests/Functional/Database/Query/Expression/ExpressionBuilder/LikeTest.php

Lines changed: 0 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -19,7 +19,6 @@
1919

2020
use Doctrine\DBAL\Platforms\SQLitePlatform as DoctrineSQLitePlatform;
2121
use PHPUnit\Framework\Attributes\DataProvider;
22-
use PHPUnit\Framework\Attributes\Group;
2322
use PHPUnit\Framework\Attributes\Test;
2423
use TYPO3\CMS\Core\Database\ConnectionPool;
2524
use TYPO3\TestingFramework\Core\Functional\FunctionalTestCase;
@@ -604,14 +603,8 @@ public static function likeOnIntegerFieldDataSets(): \Generator
604603
];
605604
}
606605

607-
#[Group('not-postgres')]
608606
#[DataProvider('likeOnIntegerFieldDataSets')]
609607
#[Test]
610-
/**
611-
* @todo PostgreSQL is picky when using LIKE or ILIKE on a field or value not being a compatible text-type,
612-
* requiring explicitly type casting. MySQL, MariaDB and SQLite are more forgiving and supports LIKE
613-
* comparisons on these fields or values. Excluded for PostgresSQL until a solution is implemented.
614-
*/
615608
public function likeOnIntegerFieldReturnsExpectedDataSet(string $searchWord, bool $caseSensitive, array $expectedRows): void
616609
{
617610
if ($caseSensitive === true) {
@@ -670,14 +663,8 @@ public static function notLikeOnIntegerFieldDataSets(): \Generator
670663
];
671664
}
672665

673-
#[Group('not-postgres')]
674666
#[DataProvider('notLikeOnIntegerFieldDataSets')]
675667
#[Test]
676-
/**
677-
* @todo PostgreSQL is picky when using LIKE or ILIKE on a field or value not being a compatible text-type,
678-
* requiring explicitly type casting. MySQL, MariaDB and SQLite are more forgiving and supports LIKE
679-
* comparisons on these fields or values. Excluded for PostgresSQL until a solution is implemented.
680-
*/
681668
public function notLikeOnIntegerFieldReturnsExpectedDataSet(string $searchWord, bool $caseSensitive, array $expectedRows): void
682669
{
683670
if ($caseSensitive === true) {

0 commit comments

Comments
 (0)