From f58d0969200dc5018f40c597280d90a602ca0480 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Jan=20Wa=C5=9B?= Date: Tue, 27 Jan 2015 23:24:31 +0100 Subject: [PATCH] fixes #6792, use a simpler composite in condition implementation on dbs other than pgsql --- framework/db/QueryBuilder.php | 19 +++++------ framework/db/pgsql/QueryBuilder.php | 34 ++++++++++++++++++ tests/unit/framework/db/QueryBuilderTest.php | 36 ++++++++++++++++---- 3 files changed, 73 insertions(+), 16 deletions(-) diff --git a/framework/db/QueryBuilder.php b/framework/db/QueryBuilder.php index 561ffc56e54..d4cb67502ef 100644 --- a/framework/db/QueryBuilder.php +++ b/framework/db/QueryBuilder.php @@ -1134,27 +1134,26 @@ public function buildInCondition($operator, $operands, &$params) */ protected function buildCompositeInCondition($operator, $columns, $values, &$params) { + $quotedColumns = []; + foreach ($columns as $i => $column) { + $quotedColumns[$i] = strpos($column, '(') === false ? $this->db->quoteColumnName($column) : $column; + } $vss = []; foreach ($values as $value) { $vs = []; - foreach ($columns as $column) { + foreach ($columns as $i => $column) { if (isset($value[$column])) { $phName = self::PARAM_PREFIX . count($params); $params[$phName] = $value[$column]; - $vs[] = $phName; + $vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' = ' : ' != ') . $phName; } else { - $vs[] = 'NULL'; + $vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' IS' : ' IS NOT') . ' NULL'; } } - $vss[] = '(' . implode(', ', $vs) . ')'; - } - foreach ($columns as $i => $column) { - if (strpos($column, '(') === false) { - $columns[$i] = $this->db->quoteColumnName($column); - } + $vss[] = '(' . implode($operator === 'IN' ? ' AND ' : ' OR ', $vs) . ')'; } - return '(' . implode(', ', $columns) . ") $operator (" . implode(', ', $vss) . ')'; + return '(' . implode($operator === 'IN' ? ' OR ' : ' AND ', $vss) . ')'; } /** diff --git a/framework/db/pgsql/QueryBuilder.php b/framework/db/pgsql/QueryBuilder.php index df5ad615d3e..bc257db606e 100644 --- a/framework/db/pgsql/QueryBuilder.php +++ b/framework/db/pgsql/QueryBuilder.php @@ -204,4 +204,38 @@ public function batchInsert($table, $columns, $rows) return 'INSERT INTO ' . $schema->quoteTableName($table) . ' (' . implode(', ', $columns) . ') VALUES ' . implode(', ', $values); } + + /** + * Builds SQL for IN condition + * + * @param string $operator + * @param array $columns + * @param array $values + * @param array $params + * @return string SQL + */ + protected function buildCompositeInCondition($operator, $columns, $values, &$params) + { + $vss = []; + foreach ($values as $value) { + $vs = []; + foreach ($columns as $column) { + if (isset($value[$column])) { + $phName = self::PARAM_PREFIX . count($params); + $params[$phName] = $value[$column]; + $vs[] = $phName; + } else { + $vs[] = 'NULL'; + } + } + $vss[] = '(' . implode(', ', $vs) . ')'; + } + foreach ($columns as $i => $column) { + if (strpos($column, '(') === false) { + $columns[$i] = $this->db->quoteColumnName($column); + } + } + + return '(' . implode(', ', $columns) . ") $operator (" . implode(', ', $vss) . ')'; + } } diff --git a/tests/unit/framework/db/QueryBuilderTest.php b/tests/unit/framework/db/QueryBuilderTest.php index 86a879ec542..8b35d07d0f3 100644 --- a/tests/unit/framework/db/QueryBuilderTest.php +++ b/tests/unit/framework/db/QueryBuilderTest.php @@ -201,12 +201,6 @@ public function conditionProvider() [ ['in', 'id', (new Query())->select('id')->from('users')->where(['active' => 1])], '(`id`) IN (SELECT `id` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], [ ['not in', 'id', (new Query())->select('id')->from('users')->where(['active' => 1])], '(`id`) NOT IN (SELECT `id` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], - // composite in - [ ['in', ['id', 'name'], [['id' => 1, 'name' => 'foo'], ['id' => 2, 'name' => 'bar']]], '(`id`, `name`) IN ((:qp0, :qp1), (:qp2, :qp3))', [':qp0' => 1, ':qp1' => 'foo', ':qp2' => 2, ':qp3' => 'bar'] ], - [ ['not in', ['id', 'name'], [['id' => 1, 'name' => 'foo'], ['id' => 2, 'name' => 'bar']]], '(`id`, `name`) NOT IN ((:qp0, :qp1), (:qp2, :qp3))', [':qp0' => 1, ':qp1' => 'foo', ':qp2' => 2, ':qp3' => 'bar'] ], - [ ['in', ['id', 'name'], (new Query())->select(['id', 'name'])->from('users')->where(['active' => 1])], '(`id`, `name`) IN (SELECT `id`, `name` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], - [ ['not in', ['id', 'name'], (new Query())->select(['id', 'name'])->from('users')->where(['active' => 1])], '(`id`, `name`) NOT IN (SELECT `id`, `name` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], - // exists [ ['exists', (new Query())->select('id')->from('users')->where(['active' => 1])], 'EXISTS (SELECT `id` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], [ ['not exists', (new Query())->select('id')->from('users')->where(['active' => 1])], 'NOT EXISTS (SELECT `id` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], @@ -228,6 +222,23 @@ public function conditionProvider() ]; + switch ($this->driverName) { + default: + $conditions = array_merge($conditions, [ + [ ['in', ['id', 'name'], [['id' => 1, 'name' => 'foo'], ['id' => 2, 'name' => 'bar']]], '((`id` = :qp0 AND `name` = :qp1) OR (`id` = :qp2 AND `name` = :qp3))', [':qp0' => 1, ':qp1' => 'foo', ':qp2' => 2, ':qp3' => 'bar'] ], + [ ['not in', ['id', 'name'], [['id' => 1, 'name' => 'foo'], ['id' => 2, 'name' => 'bar']]], '((`id` != :qp0 OR `name` != :qp1) AND (`id` != :qp2 OR `name` != :qp3))', [':qp0' => 1, ':qp1' => 'foo', ':qp2' => 2, ':qp3' => 'bar'] ], + ]); + break; + case 'pgsql': + $conditions = array_merge($conditions, [ + [ ['in', ['id', 'name'], [['id' => 1, 'name' => 'foo'], ['id' => 2, 'name' => 'bar']]], '(`id`, `name`) IN ((:qp0, :qp1), (:qp2, :qp3))', [':qp0' => 1, ':qp1' => 'foo', ':qp2' => 2, ':qp3' => 'bar'] ], + [ ['not in', ['id', 'name'], [['id' => 1, 'name' => 'foo'], ['id' => 2, 'name' => 'bar']]], '(`id`, `name`) NOT IN ((:qp0, :qp1), (:qp2, :qp3))', [':qp0' => 1, ':qp1' => 'foo', ':qp2' => 2, ':qp3' => 'bar'] ], + [ ['in', ['id', 'name'], (new Query())->select(['id', 'name'])->from('users')->where(['active' => 1])], '(`id`, `name`) IN (SELECT `id`, `name` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], + [ ['not in', ['id', 'name'], (new Query())->select(['id', 'name'])->from('users')->where(['active' => 1])], '(`id`, `name`) NOT IN (SELECT `id`, `name` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], + ]); + break; + } + // adjust dbms specific escaping foreach($conditions as $i => $condition) { $conditions[$i][1] = $this->replaceQuotes($condition[1]); @@ -444,4 +455,17 @@ public function testSelectSubquery() $this->assertEquals($expected, $sql); $this->assertEmpty($params); } + + public function testCompositeInCondition() + { + $condition = [ + 'in', + ['id', 'name'], + [ + ['id' => 1, 'name' => 'foo'], + ['id' => 2, 'name' => 'bar'], + ], + ]; + (new Query())->from('customer')->where($condition)->all($this->getConnection()); + } }