Commit a4ec309d authored by Christian Kuhn's avatar Christian Kuhn Committed by Markus Klein
Browse files

[BUGFIX] mssql: ExpressionBuilder inSet() support

mssql does not support FIND_IN_SET(). The patch adds a
solution based on LIKE.
Since the query fiddling in this area is a bit tricky,
this area is now supported by a bunch of functional tests.
A postgres bug those new functional tests reveal is fixed
along the way.

Change-Id: I5e94ad8df7a37a680b457eff1b5b16a0c14dba39
Resolves: #81488
Releases: master, 8.7
Reviewed-on: https://review.typo3.org/53141


Reviewed-by: default avatarMorton Jonuschat <m.jonuschat@mojocode.de>
Tested-by: default avatarMorton Jonuschat <m.jonuschat@mojocode.de>
Tested-by: default avatarTYPO3com <no-reply@typo3.com>
Reviewed-by: Markus Klein's avatarMarkus Klein <markus.klein@typo3.org>
Tested-by: Markus Klein's avatarMarkus Klein <markus.klein@typo3.org>
parent 2da4e3d2
......@@ -270,7 +270,7 @@ class ExpressionBuilder
/**
* Returns a comparison that can find a value in a list field (CSV).
*
* @param string $fieldName The fieldname. Will be quoted according to database platform automatically.
* @param string $fieldName The field name. Will be quoted according to database platform automatically.
* @param string $value Argument to be used in FIND_IN_SET() comparison. No automatic quoting/escaping is done.
* @param bool $isColumn Set when the value to compare is a column on a table to activate casting
* @return string
......@@ -297,7 +297,7 @@ class ExpressionBuilder
case 'postgresql':
case 'pdo_postgresql':
return $this->comparison(
$isColumn ? $value . '::text' : $value,
$isColumn ? $value . '::text' : $this->literal($this->unquoteLiteral((string)$value)),
self::EQ,
sprintf(
'ANY(string_to_array(%s, %s))',
......@@ -315,11 +315,29 @@ class ExpressionBuilder
break;
case 'sqlsrv':
case 'pdo_sqlsrv':
throw new \RuntimeException(
'FIND_IN_SET support for database platform "SQLServer" not yet implemented.',
1459696681
);
break;
case 'mssql':
// See unit and functional tests for details
if ($isColumn) {
$expression = $this->orX(
$this->eq($fieldName, $value),
$this->like($fieldName, $value . ' + \',%\''),
$this->like($fieldName, '\'%,\' + ' . $value),
$this->like($fieldName, '\'%,\' + ' . $value . ' + \',%\'')
);
} else {
$likeEscapedValue = str_replace(
['[', '%'],
['[[]', '[%]'],
$this->unquoteLiteral($value)
);
$expression = $this->orX(
$this->eq($fieldName, $this->literal($this->unquoteLiteral((string)$value))),
$this->like($fieldName, $this->literal($likeEscapedValue . ',%')),
$this->like($fieldName, $this->literal('%,' . $likeEscapedValue)),
$this->like($fieldName, $this->literal('%,' . $likeEscapedValue . ',%'))
);
}
return (string)$expression;
case 'sqlite':
case 'sqlite3':
case 'pdo_sqlite':
......
"tx_expressionbuildertest"
,"uid","pid","aField","aCsvField"
,1,0,"match","match"
,2,0,"match","match,nomatch"
,3,0,"match","nomatch,match"
,4,0,"match","nomatch1,match,nomatch2"
,5,0,"match","nomatch"
,6,0,"2","2"
,7,0,"2","2,3"
,8,0,"2","1,2"
,9,0,"2","1,2,3"
,10,0,"2","4"
,11,0,"wild%card","wild%card"
,12,0,"wild%card","wild%card,nowild%card"
,13,0,"wild%card","nowild%card,wild%card"
,14,0,"wild%card","nowild%card1,wild%card,nowild%card2"
,15,0,"wild%card","nowild%card"
,16,0,"kokolores","wild[card"
,17,0,"kokolores","wild[card,nowild[card"
,18,0,"kokolores","nowild[card,wild[card"
,19,0,"kokolores","nowild[card1,wild[card,nowild[card2"
,20,0,"kokolores","nowild[card"
,21,0,"kokolores","wild]card"
,22,0,"kokolores","wild]card,nowild]card"
,23,0,"kokolores","nowild]card,wild]card"
,24,0,"kokolores","nowild]card1,wild]card,nowild]card2"
,25,0,"kokolores","nowild]card"
,26,0,"kokolores","wild[]card"
,27,0,"kokolores","wild[]card,nowild[]card"
,28,0,"kokolores","nowild[]card,wild[]card"
,29,0,"kokolores","nowild[]card1,wild[]card,nowild[]card2"
,30,0,"kokolores","nowild[]card"
,31,0,"kokolores","wild[foo]card"
,32,0,"kokolores","wild[foo]card,nowild[foo]card"
,33,0,"kokolores","nowild[foo]card,wild[foo]card"
,34,0,"kokolores","nowild[foo]card1,wild[foo]card,nowild[foo]card2"
,35,0,"kokolores","nowild[foo]card"
,36,0,"kokolores","wild[%]card"
,37,0,"kokolores","wild[%]card,nowild[%]card"
,38,0,"kokolores","nowild[%]card,wild[%]card"
,39,0,"kokolores","nowild[%]card1,wild[%]card,nowild[%]card2"
,40,0,"kokolores","nowild[%]card"
\ No newline at end of file
<?php
$EM_CONF[$_EXTKEY] = [
'title' => 'ExpressionBuilder Test',
'description' => 'ExpressionBuilder Test',
'category' => 'example',
'version' => '0.0.1',
'state' => 'beta',
'uploadfolder' => 0,
'createDirs' => '',
'clearcacheonload' => 0,
'author' => 'Christian Kuhn',
'author_email' => 'lolli@schwarzu.ch',
'constraints' => [
'depends' => [
'typo3' => '8.7.0-0.0.0',
],
'conflicts' => [
],
'suggests' => [
],
],
];
#
# Table structure for table 'tx_expressionbuildertest'
#
CREATE TABLE tx_expressionbuildertest (
uid int(11) NOT NULL auto_increment,
pid int(11) DEFAULT '0' NOT NULL,
aField text,
aCsvField text,
PRIMARY KEY (uid),
KEY parent (pid)
);
<?php
declare(strict_types=1);
namespace TYPO3\CMS\Core\Tests\Functional\Database\Query\Expression;
/*
* This file is part of the TYPO3 CMS project.
*
* It is free software; you can redistribute it and/or modify it under
* the terms of the GNU General Public License, either version 2
* of the License, or any later version.
*
* For the full copyright and license information, please read the
* LICENSE.txt file that was distributed with this source code.
*
* The TYPO3 project - inspiring people to share!
*/
use TYPO3\CMS\Core\Database\ConnectionPool;
use TYPO3\TestingFramework\Core\Functional\FunctionalTestCase;
/**
* Test case
*/
class ExpressionBuilderTest extends FunctionalTestCase
{
/**
* @var array Extension comes with table setup to test inSet() methods of ExpressionBuilder
*/
protected $testExtensionsToLoad = [
'typo3/sysext/core/Tests/Functional/Database/Fixtures/Extensions/test_expressionbuilder',
];
/**
* @test
*/
public function inSetReturnsExpectedDataSetsWithColumn()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', $queryBuilder->quoteIdentifier('aField'), true)
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 1,
'aCsvField' => 'match',
],
1 => [
'uid' => 2,
'aCsvField' => 'match,nomatch',
],
2 => [
'uid' => 3,
'aCsvField' => 'nomatch,match',
],
3 => [
'uid' => 4,
'aCsvField' => 'nomatch1,match,nomatch2',
],
// uid 5 missing here!
4 => [
'uid' => 6,
'aCsvField' => '2',
],
5 => [
'uid' => 7,
'aCsvField' => '2,3',
],
6 => [
'uid' => 8,
'aCsvField' => '1,2',
],
7 => [
'uid' => 9,
'aCsvField' => '1,2,3',
],
// uid 10 missing here!
8 => [
'uid' => 11,
'aCsvField' => 'wild%card',
],
9 => [
'uid' => 12,
'aCsvField' => 'wild%card,nowild%card',
],
10 => [
'uid' => 13,
'aCsvField' => 'nowild%card,wild%card',
],
11 => [
'uid' => 14,
'aCsvField' => 'nowild%card1,wild%card,nowild%card2',
],
];
$this->assertEquals($expected, $result);
}
/**
* @test
*/
public function inSetReturnsExpectedDataSets()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', $queryBuilder->expr()->literal('match'))
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 1,
'aCsvField' => 'match',
],
1 => [
'uid' => 2,
'aCsvField' => 'match,nomatch',
],
2 => [
'uid' => 3,
'aCsvField' => 'nomatch,match',
],
3 => [
'uid' => 4,
'aCsvField' => 'nomatch1,match,nomatch2',
],
];
$this->assertEquals($expected, $result);
}
/**
* @test
*/
public function inSetReturnsExpectedDataSetsWithInts()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', (string)2)
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 6,
'aCsvField' => '2',
],
1 => [
'uid' => 7,
'aCsvField' => '2,3',
],
2 => [
'uid' => 8,
'aCsvField' => '1,2',
],
3 => [
'uid' => 9,
'aCsvField' => '1,2,3',
],
];
$this->assertEquals($expected, $result);
}
/**
* @test
*/
public function inSetReturnsExpectedDataSetsIfValueContainsLikeWildcard()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', $queryBuilder->expr()->literal('wild%card'))
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 11,
'aCsvField' => 'wild%card',
],
1 => [
'uid' => 12,
'aCsvField' => 'wild%card,nowild%card',
],
2 => [
'uid' => 13,
'aCsvField' => 'nowild%card,wild%card',
],
3 => [
'uid' => 14,
'aCsvField' => 'nowild%card1,wild%card,nowild%card2',
],
];
$this->assertEquals($expected, $result);
}
/**
* @test
*/
public function inSetReturnsExpectedDataSetsIfValueContainsBracket()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', $queryBuilder->expr()->literal('wild[card'))
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 16,
'aCsvField' => 'wild[card',
],
1 => [
'uid' => 17,
'aCsvField' => 'wild[card,nowild[card',
],
2 => [
'uid' => 18,
'aCsvField' => 'nowild[card,wild[card',
],
3 => [
'uid' => 19,
'aCsvField' => 'nowild[card1,wild[card,nowild[card2',
],
];
$this->assertEquals($expected, $result);
}
/**
* @test
*/
public function inSetReturnsExpectedDataSetsIfValueContainsClosingBracket()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', $queryBuilder->expr()->literal('wild]card'))
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 21,
'aCsvField' => 'wild]card',
],
1 => [
'uid' => 22,
'aCsvField' => 'wild]card,nowild]card',
],
2 => [
'uid' => 23,
'aCsvField' => 'nowild]card,wild]card',
],
3 => [
'uid' => 24,
'aCsvField' => 'nowild]card1,wild]card,nowild]card2',
],
];
$this->assertEquals($expected, $result);
}
/**
* @test
*/
public function inSetReturnsExpectedDataSetsIfValueContainsOpeningAndClosingBracket()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', $queryBuilder->expr()->literal('wild[]card'))
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 26,
'aCsvField' => 'wild[]card',
],
1 => [
'uid' => 27,
'aCsvField' => 'wild[]card,nowild[]card',
],
2 => [
'uid' => 28,
'aCsvField' => 'nowild[]card,wild[]card',
],
3 => [
'uid' => 29,
'aCsvField' => 'nowild[]card1,wild[]card,nowild[]card2',
],
];
$this->assertEquals($expected, $result);
}
/**
* @test
*/
public function inSetReturnsExpectedDataSetsIfValueContainsBracketsAroundWord()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', $queryBuilder->expr()->literal('wild[foo]card'))
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 31,
'aCsvField' => 'wild[foo]card',
],
1 => [
'uid' => 32,
'aCsvField' => 'wild[foo]card,nowild[foo]card',
],
2 => [
'uid' => 33,
'aCsvField' => 'nowild[foo]card,wild[foo]card',
],
3 => [
'uid' => 34,
'aCsvField' => 'nowild[foo]card1,wild[foo]card,nowild[foo]card2',
],
];
$this->assertEquals($expected, $result);
}
/**
* @test
*/
public function inSetReturnsExpectedDataSetsIfValueContainsBracketsAroundLikeWildcard()
{
$this->importCSVDataSet(__DIR__ . '/../../Fixtures/DataSet/TestExpressionBuilderInSet.csv');
$queryBuilder = (new ConnectionPool())->getQueryBuilderForTable('tx_expressionbuildertest');
$result = $queryBuilder
->select('uid', 'aCsvField')
->from('tx_expressionbuildertest')
->where(
$queryBuilder->expr()->inSet('aCsvField', $queryBuilder->expr()->literal('wild[%]card'))
)
->orderBy('uid')
->execute()
->fetchAll();
$expected = [
0 => [
'uid' => 36,
'aCsvField' => 'wild[%]card',
],
1 => [
'uid' => 37,
'aCsvField' => 'wild[%]card,nowild[%]card',
],
2 => [
'uid' => 38,
'aCsvField' => 'nowild[%]card,wild[%]card',
],
3 => [
'uid' => 39,
'aCsvField' => 'nowild[%]card1,wild[%]card,nowild[%]card2',
],
];
$this->assertEquals($expected, $result);
}
}
......@@ -230,6 +230,26 @@ class ExpressionBuilderTest extends \TYPO3\TestingFramework\Core\Unit\UnitTestCa
$this->assertSame('aField NOT IN (1, 2, 3)', $result);
}
/**
* @test
*/
public function inSetThrowsExceptionWithEmptyValue()
{
$this->expectException(\InvalidArgumentException::class);
$this->expectExceptionCode(1459696089);
$this->subject->inSet('aField', '');
}
/**
* @test
*/
public function inSetThrowsExceptionWithInvalidValue()
{
$this->expectException(\InvalidArgumentException::class);
$this->expectExceptionCode(1459696090);
$this->subject->inSet('aField', 'an,Invalid,Value');
}
/**
* @test
*/
......@@ -256,8 +276,10 @@ class ExpressionBuilderTest extends \TYPO3\TestingFramework\Core\Unit\UnitTestCa
{
$databasePlatform = $this->prophesize(MockPlatform::class);
$databasePlatform->getName()->willReturn('postgresql');
$databasePlatform->getStringLiteralQuoteCharacter()->willReturn('"');
$this->connectionProphet->quote(',', Argument::cetera())->shouldBeCalled()->willReturn("','");
$this->connectionProphet->quote("'1'", null)->shouldBeCalled()->willReturn("'1'");
$this->connectionProphet->quoteIdentifier(Argument::cetera())->will(function ($args) {
return '"' . $args[0] . '"';
});
......@@ -368,6 +390,30 @@ class ExpressionBuilderTest extends \TYPO3\TestingFramework\Core\Unit\UnitTestCa
$this->subject->inSet('aField', ':dcValue1');
}
/**
* @test
*/