From 98a95a45ba37c55dd8c79fae56ffdb4444e67f2e Mon Sep 17 00:00:00 2001 From: SilverFire - Dmitry Naumenko Date: Thu, 27 Apr 2017 10:23:11 +0300 Subject: [PATCH 1/2] Fixed Oracle SQL queries with `IN` condition and more than 1000 parameters --- framework/CHANGELOG.md | 1 + framework/db/oci/QueryBuilder.php | 52 +++++++++++++++++++ tests/framework/db/mssql/QueryBuilderTest.php | 2 - tests/framework/db/oci/QueryBuilderTest.php | 49 +++++++++++++++++ 4 files changed, 102 insertions(+), 2 deletions(-) diff --git a/framework/CHANGELOG.md b/framework/CHANGELOG.md index 38d992de230..4e55403dd7d 100644 --- a/framework/CHANGELOG.md +++ b/framework/CHANGELOG.md @@ -84,6 +84,7 @@ Yii Framework 2 Change Log - Enh #13981: `yii\caching\Cache::getOrSet()` now supports both `Closure` and `callable` (silverfire) - Enh #13911: Significantly enhanced MSSQL schema reading performance (paulzi, WebdevMerlion) - Enh #14059: Removed unused AR instantiating for calling of static methods (ElisDN) +- Bug #10305: Oracle SQL queries with `IN` condition and more than 1000 parameters are working now (silverfire) 2.0.11.2 February 08, 2017 -------------------------- diff --git a/framework/db/oci/QueryBuilder.php b/framework/db/oci/QueryBuilder.php index de4480edffb..81fcccfc6e7 100644 --- a/framework/db/oci/QueryBuilder.php +++ b/framework/db/oci/QueryBuilder.php @@ -331,4 +331,56 @@ public function buildLikeCondition($operator, $operands, &$params) } return parent::buildLikeCondition($operator, $operands, $params); } + + public function buildInCondition($operator, $operands, &$params) + { + $splitCondition = $this->splitInCondition($operator, $operands, $params); + if ($splitCondition !== null) { + return $splitCondition; + } + + return parent::buildInCondition($operator, $operands, $params); + } + + /** + * Oracle DBMS does not support more than 1000 parameters in `IN` condition. + * This method splits long `IN` condition into series of smaller ones. + * + * @param string $operator + * @param array $operands + * @param array $params + * @return null|string null when split is not required. Otherwise - built SQL condition. + * @throws Exception + * @since 2.0.12 + */ + protected function splitInCondition($operator, $operands, &$params) + { + if (!isset($operands[0], $operands[1])) { + throw new Exception("Operator '$operator' requires two operands."); + } + + list($column, $values) = $operands; + + if ($values instanceof \Traversable) { + $values = iterator_to_array($values); + } + + if (!is_array($values)) { + return null; + } + + $maxParameters = 1000; + $count = count($values); + if ($count <= $maxParameters) { + return null; + } + + $condition = [($operator === 'IN') ? 'OR' : 'AND']; + for ($i = 0; $i < $count; $i += $maxParameters) { + $condition[] = [$operator, $column, array_slice($values, $i, $maxParameters)]; + } + + return $this->buildCondition(['AND', $condition], $params); + } + } diff --git a/tests/framework/db/mssql/QueryBuilderTest.php b/tests/framework/db/mssql/QueryBuilderTest.php index e0df4b60d61..aa3484d6cc7 100644 --- a/tests/framework/db/mssql/QueryBuilderTest.php +++ b/tests/framework/db/mssql/QueryBuilderTest.php @@ -2,8 +2,6 @@ namespace yiiunit\framework\db\mssql; -use yii\db\Expression; -use yii\db\mssql\Schema; use yii\db\Query; /** diff --git a/tests/framework/db/oci/QueryBuilderTest.php b/tests/framework/db/oci/QueryBuilderTest.php index b0124982e50..aec87da6541 100644 --- a/tests/framework/db/oci/QueryBuilderTest.php +++ b/tests/framework/db/oci/QueryBuilderTest.php @@ -3,6 +3,7 @@ namespace yiiunit\framework\db\oci; use yii\db\oci\Schema; +use yiiunit\data\base\TraversableObject; /** * @group db @@ -86,4 +87,52 @@ public function likeConditionProvider() $this->likeParameterReplacements[$encodedBackslash] = '\\'; return parent::likeConditionProvider(); } + + public function conditionProvider() + { + return array_merge(parent::conditionProvider(), [ + [ + ['in', 'id', range(0, 2500)], + + ' (' + . '([[id]] IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 0, 999)) . '))' + . ' OR ([[id]] IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 1000, 1999)) . '))' + . ' OR ([[id]] IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 2000, 2500)) .'))' + . ')', + + array_flip($this->generateSprintfSeries(':qp%d', 0, 2500)) + ], + [ + ['not in', 'id', range(0, 2500)], + + '(' + . '([[id]] NOT IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 0, 999)) . '))' + . ' AND ([[id]] NOT IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 1000, 1999)) . '))' + . ' AND ([[id]] NOT IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 2000, 2500)) .'))' + . ')', + + array_flip($this->generateSprintfSeries(':qp%d', 0, 2500)) + ], + [ + ['not in', 'id', new TraversableObject(range(0, 2500))], + + '(' + . '([[id]] NOT IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 0, 999)) . '))' + . ' AND ([[id]] NOT IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 1000, 1999)) . '))' + . ' AND ([[id]] NOT IN (' . implode(', ', $this->generateSprintfSeries(':qp%d', 2000, 2500)) .'))' + . ')', + + array_flip($this->generateSprintfSeries(':qp%d', 0, 2500)) + ], + ]); + } + + protected function generateSprintfSeries ($pattern, $from, $to) { + $items = []; + for ($i = $from; $i <= $to; $i++) { + $items[] = sprintf($pattern, $i); + } + + return $items; + } } From 0258375fc719e1a9305c5f0cf39570752e009f45 Mon Sep 17 00:00:00 2001 From: SilverFire - Dmitry Naumenko Date: Thu, 27 Apr 2017 20:56:08 +0300 Subject: [PATCH 2/2] Updated PHPdoc --- framework/db/oci/QueryBuilder.php | 3 +++ 1 file changed, 3 insertions(+) diff --git a/framework/db/oci/QueryBuilder.php b/framework/db/oci/QueryBuilder.php index 81fcccfc6e7..57b31104f6a 100644 --- a/framework/db/oci/QueryBuilder.php +++ b/framework/db/oci/QueryBuilder.php @@ -332,6 +332,9 @@ public function buildLikeCondition($operator, $operands, &$params) return parent::buildLikeCondition($operator, $operands, $params); } + /** + * @inheritdoc + */ public function buildInCondition($operator, $operands, &$params) { $splitCondition = $this->splitInCondition($operator, $operands, $params);