Commit 1e5f159f by Jan Waś Committed by Qiang Xue

override only mssql and sqlite QueryBuilder; throw an exception for composite in…

override only mssql and sqlite QueryBuilder; throw an exception for composite in condition with a subquery
parent f58d0969
...@@ -1067,22 +1067,7 @@ class QueryBuilder extends \yii\base\Object ...@@ -1067,22 +1067,7 @@ class QueryBuilder extends \yii\base\Object
} }
if ($values instanceof Query) { if ($values instanceof Query) {
// sub-query return $this->buildSubqueryInCondition($operator, $column, $values, $params);
list($sql, $params) = $this->build($values, $params);
$column = (array) $column;
if (is_array($column)) {
foreach ($column as $i => $col) {
if (strpos($col, '(') === false) {
$column[$i] = $this->db->quoteColumnName($col);
}
}
return '(' . implode(', ', $column) . ") $operator ($sql)";
} else {
if (strpos($column, '(') === false) {
$column = $this->db->quoteColumnName($column);
}
return "$column $operator ($sql)";
}
} }
$values = (array) $values; $values = (array) $values;
...@@ -1132,28 +1117,56 @@ class QueryBuilder extends \yii\base\Object ...@@ -1132,28 +1117,56 @@ class QueryBuilder extends \yii\base\Object
* @param array $params * @param array $params
* @return string SQL * @return string SQL
*/ */
protected function buildCompositeInCondition($operator, $columns, $values, &$params) protected function buildSubqueryInCondition($operator, $columns, $values, &$params)
{ {
$quotedColumns = []; list($sql, $params) = $this->build($values, $params);
foreach ($columns as $i => $column) { if (is_array($columns)) {
$quotedColumns[$i] = strpos($column, '(') === false ? $this->db->quoteColumnName($column) : $column; foreach ($columns as $i => $col) {
if (strpos($col, '(') === false) {
$columns[$i] = $this->db->quoteColumnName($col);
}
}
return '(' . implode(', ', $columns) . ") $operator ($sql)";
} else {
if (strpos($columns, '(') === false) {
$columns = $this->db->quoteColumnName($columns);
}
return "$columns $operator ($sql)";
} }
}
/**
* 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 = []; $vss = [];
foreach ($values as $value) { foreach ($values as $value) {
$vs = []; $vs = [];
foreach ($columns as $i => $column) { foreach ($columns as $column) {
if (isset($value[$column])) { if (isset($value[$column])) {
$phName = self::PARAM_PREFIX . count($params); $phName = self::PARAM_PREFIX . count($params);
$params[$phName] = $value[$column]; $params[$phName] = $value[$column];
$vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' = ' : ' != ') . $phName; $vs[] = $phName;
} else { } else {
$vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' IS' : ' IS NOT') . ' NULL'; $vs[] = '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($operator === 'IN' ? ' OR ' : ' AND ', $vss) . ')'; return '(' . implode(', ', $columns) . ") $operator (" . implode(', ', $vss) . ')';
} }
/** /**
......
...@@ -215,4 +215,54 @@ class QueryBuilder extends \yii\db\QueryBuilder ...@@ -215,4 +215,54 @@ class QueryBuilder extends \yii\db\QueryBuilder
} }
return $this->_oldMssql; return $this->_oldMssql;
} }
/**
* Builds SQL for IN condition
*
* @param string $operator
* @param array $columns
* @param array $values
* @param array $params
* @return string SQL
*/
protected function buildSubqueryInCondition($operator, $columns, $values, &$params)
{
if (is_array($columns)) {
throw new NotSupportedException(__METHOD__ . ' is not supported by SQLite.');
}
return parent::buildSubqueryInCondition($operator, $columns, $values, $params);
}
/**
* 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)
{
$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 $i => $column) {
if (isset($value[$column])) {
$phName = self::PARAM_PREFIX . count($params);
$params[$phName] = $value[$column];
$vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' = ' : ' != ') . $phName;
} else {
$vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' IS' : ' IS NOT') . ' NULL';
}
}
$vss[] = '(' . implode($operator === 'IN' ? ' AND ' : ' OR ', $vs) . ')';
}
return '(' . implode($operator === 'IN' ? ' OR ' : ' AND ', $vss) . ')';
}
} }
...@@ -204,38 +204,4 @@ class QueryBuilder extends \yii\db\QueryBuilder ...@@ -204,38 +204,4 @@ class QueryBuilder extends \yii\db\QueryBuilder
return 'INSERT INTO ' . $schema->quoteTableName($table) return 'INSERT INTO ' . $schema->quoteTableName($table)
. ' (' . implode(', ', $columns) . ') VALUES ' . implode(', ', $values); . ' (' . 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) . ')';
}
} }
...@@ -292,4 +292,54 @@ class QueryBuilder extends \yii\db\QueryBuilder ...@@ -292,4 +292,54 @@ class QueryBuilder extends \yii\db\QueryBuilder
return $sql; return $sql;
} }
/**
* Builds SQL for IN condition
*
* @param string $operator
* @param array $columns
* @param array $values
* @param array $params
* @return string SQL
*/
protected function buildSubqueryInCondition($operator, $columns, $values, &$params)
{
if (is_array($columns)) {
throw new NotSupportedException(__METHOD__ . ' is not supported by SQLite.');
}
return parent::buildSubqueryInCondition($operator, $columns, $values, $params);
}
/**
* 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)
{
$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 $i => $column) {
if (isset($value[$column])) {
$phName = self::PARAM_PREFIX . count($params);
$params[$phName] = $value[$column];
$vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' = ' : ' != ') . $phName;
} else {
$vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' IS' : ' IS NOT') . ' NULL';
}
}
$vss[] = '(' . implode($operator === 'IN' ? ' AND ' : ' OR ', $vs) . ')';
}
return '(' . implode($operator === 'IN' ? ' OR ' : ' AND ', $vss) . ')';
}
} }
...@@ -198,8 +198,8 @@ class QueryBuilderTest extends DatabaseTestCase ...@@ -198,8 +198,8 @@ class QueryBuilderTest extends DatabaseTestCase
// in // in
[ ['in', 'id', [1, 2, 3]], '`id` IN (:qp0, :qp1, :qp2)', [':qp0' => 1, ':qp1' => 2, ':qp2' => 3] ], [ ['in', 'id', [1, 2, 3]], '`id` IN (:qp0, :qp1, :qp2)', [':qp0' => 1, ':qp1' => 2, ':qp2' => 3] ],
[ ['not in', 'id', [1, 2, 3]], '`id` NOT IN (:qp0, :qp1, :qp2)', [':qp0' => 1, ':qp1' => 2, ':qp2' => 3] ], [ ['not in', 'id', [1, 2, 3]], '`id` NOT IN (:qp0, :qp1, :qp2)', [':qp0' => 1, ':qp1' => 2, ':qp2' => 3] ],
[ ['in', 'id', (new Query())->select('id')->from('users')->where(['active' => 1])], '(`id`) IN (SELECT `id` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], [ ['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] ], [ ['not in', 'id', (new Query())->select('id')->from('users')->where(['active' => 1])], '`id` NOT IN (SELECT `id` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ],
// exists // exists
[ ['exists', (new Query())->select('id')->from('users')->where(['active' => 1])], 'EXISTS (SELECT `id` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ], [ ['exists', (new Query())->select('id')->from('users')->where(['active' => 1])], 'EXISTS (SELECT `id` FROM `users` WHERE `active`=:qp0)', [':qp0' => 1] ],
...@@ -223,13 +223,16 @@ class QueryBuilderTest extends DatabaseTestCase ...@@ -223,13 +223,16 @@ class QueryBuilderTest extends DatabaseTestCase
]; ];
switch ($this->driverName) { switch ($this->driverName) {
default: case 'mssql':
case 'sqlite':
$conditions = array_merge($conditions, [ $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'] ], [ ['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'] ], [ ['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'] ],
//[ ['in', ['id', 'name'], (new Query())->select(['id', 'name'])->from('users')->where(['active' => 1])], 'EXISTS (SELECT 1 FROM (SELECT `id`, `name` FROM `users` WHERE `active`=:qp0) AS a WHERE a.`id` = `id AND a.`name` = `name`)', [':qp0' => 1] ],
//[ ['not in', ['id', 'name'], (new Query())->select(['id', 'name'])->from('users')->where(['active' => 1])], 'NOT EXISTS (SELECT 1 FROM (SELECT `id`, `name` FROM `users` WHERE `active`=:qp0) AS a WHERE a.`id` = `id` AND a.`name = `name`)', [':qp0' => 1] ],
]); ]);
break; break;
case 'pgsql': default:
$conditions = array_merge($conditions, [ $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'] ], [ ['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'] ], [ ['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'] ],
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment