Commit a60d2952 by Qiang Xue

Added support for using sub-queries when building a DB query with `IN` condition

parent 46cbe63c
......@@ -172,6 +172,20 @@ results in this WHERE clause:
WHERE (`status` IS NULL)
```
You can also create sub-queries with `Query` objects like the following,
```php
$userQuery = (new Query)->select('id')->from('user');
$query->where(['id' => $userQuery]);
```
which will generate the following SQL:
```sql
WHERE `id` IN (SELECT `id` FROM `user`)
```
Another way to use the method is the operand format which is `[operator, operand1, operand2, ...]`.
Operator can be one of the following:
......@@ -187,10 +201,14 @@ Operator can be one of the following:
For example, `['between', 'id', 1, 10]` will generate `id BETWEEN 1 AND 10`.
- `not between`: similar to `between` except the `BETWEEN` is replaced with `NOT BETWEEN`
in the generated condition.
- `in`: operand 1 should be a column or DB expression, and operand 2 be an array representing
the range of the values that the column or DB expression should be in. For example,
- `in`: operand 1 should be a column or DB expression. Operand 2 can be either an array or a `Query` object.
It will generate an `IN` condition. If Operand 2 is an array, it will represent the range of the values
that the column or DB expression should be; If Operand 2 is a `Query` object, a sub-query will be generated
and used as the range of the column or DB expression. For example,
`['in', 'id', [1, 2, 3]]` will generate `id IN (1, 2, 3)`.
The method will properly quote the column name and escape values in the range.
The `in` operator also supports composite columns. In this case, operand 1 should be an array of the columns,
while operand 2 should be an array of arrays or a `Query` object representing the range of the columns.
- `not in`: similar to the `in` operator except that `IN` is replaced with `NOT IN` in the generated condition.
- `like`: operand 1 should be a column or DB expression, and operand 2 be a string or an array representing
the values that the column or DB expression should be like.
......
......@@ -4,7 +4,7 @@ Yii Framework 2 sphinx extension Change Log
2.0.0-rc under development
--------------------------
- no changes in this release.
- Enh: Added support for using sub-queries when building a DB query with `IN` condition (qiangxue)
2.0.0-beta April 13, 2014
......
......@@ -404,13 +404,14 @@ class Query extends Component implements QueryInterface
* - operator format: `[operator, operand1, operand2, ...]`
*
* A condition in hash format represents the following SQL expression in general:
* `column1=value1 AND column2=value2 AND ...`. In case when a value is an array,
* `column1=value1 AND column2=value2 AND ...`. In case when a value is an array or a Query object,
* an `IN` expression will be generated. And if a value is null, `IS NULL` will be used
* in the generated expression. Below are some examples:
*
* - `['type' => 1, 'status' => 2]` generates `(type = 1) AND (status = 2)`.
* - `['id' => [1, 2, 3], 'status' => 2]` generates `(id IN (1, 2, 3)) AND (status = 2)`.
* - `['status' => null] generates `status IS NULL`.
* - `['id' => $query]` generates `id IN (...sub-query...)`
*
* A condition in operator format generates the SQL expression according to the specified operator, which
* can be one of the followings:
......@@ -430,10 +431,14 @@ class Query extends Component implements QueryInterface
* - `not between`: similar to `between` except the `BETWEEN` is replaced with `NOT BETWEEN`
* in the generated condition.
*
* - `in`: operand 1 should be a column or DB expression, and operand 2 be an array representing
* the range of the values that the column or DB expression should be in. For example,
* `['in', 'id', [1, 2, 3]]` will generate `id IN (1, 2, 3)`.
* The method will properly quote the column name and escape values in the range.
* - `in`: operand 1 should be a column or DB expression with parenthesis. Operand 2 can be an array
* or a Query object. If the former, the array represents the range of the values that the column
* or DB expression should be in. If the latter, a sub-query will be generated to represent the range.
* For example, `['in', 'id', [1, 2, 3]]` will generate `id IN (1, 2, 3)`;
* `['in', 'id', (new Query)->select('id')->from('user'))]` will generate
* `id IN (SELECT id FROM user)`. The method will properly quote the column name and escape values in the range.
* The `in` operator also supports composite columns. In this case, operand 1 should be an array of the columns,
* while operand 2 should be an array of arrays or a `Query` object representing the range of the columns.
*
* - `not in`: similar to the `in` operator except that `IN` is replaced with `NOT IN` in the generated condition.
*
......
......@@ -634,7 +634,8 @@ class QueryBuilder extends Object
{
$parts = [];
foreach ($condition as $column => $value) {
if (is_array($value)) { // IN condition
if (is_array($value) || $value instanceof Query) {
// IN condition
$parts[] = $this->buildInCondition($indexes, 'IN', [$column, $value], $params);
} else {
if (strpos($column, '(') === false) {
......@@ -729,15 +730,35 @@ class QueryBuilder extends Object
list($column, $values) = $operands;
$values = (array) $values;
if (empty($values) || $column === []) {
if ($values === [] || $column === []) {
return $operator === 'IN' ? '0=1' : '';
}
if ($values instanceof Query) {
// sub-query
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;
if (count($column) > 1) {
return $this->buildCompositeInCondition($indexes, $operator, $column, $values, $params);
} elseif (is_array($column)) {
}
if (is_array($column)) {
$column = reset($column);
}
foreach ($values as $i => $value) {
......
......@@ -7,6 +7,7 @@ Yii Framework 2 Change Log
- Bug #3091: Fixed inconsistent treatment of `Widget::run()` when a widget is used as a container and as a self-contained object (qiangxue)
- Enh #3103: debugger panel is now not displayed when printing a page (githubjeka)
- Enh #3108: Added `yii\debug\Module::enableDebugLogs` to disable logging debug logs by default (qiangxue)
- Enh: Added support for using sub-queries when building a DB query with `IN` condition (qiangxue)
- Chg: Replaced `clearAll()` and `clearAllAssignments()` in `yii\rbac\ManagerInterface` with `removeAll()`, `removeAllRoles()`, `removeAllPermissions()`, `removeAllRules()` and `removeAllAssignments()` (qiangxue)
......
......@@ -479,13 +479,14 @@ class Query extends Component implements QueryInterface
* - operator format: `[operator, operand1, operand2, ...]`
*
* A condition in hash format represents the following SQL expression in general:
* `column1=value1 AND column2=value2 AND ...`. In case when a value is an array,
* `column1=value1 AND column2=value2 AND ...`. In case when a value is an array or a Query object,
* an `IN` expression will be generated. And if a value is null, `IS NULL` will be used
* in the generated expression. Below are some examples:
*
* - `['type' => 1, 'status' => 2]` generates `(type = 1) AND (status = 2)`.
* - `['id' => [1, 2, 3], 'status' => 2]` generates `(id IN (1, 2, 3)) AND (status = 2)`.
* - `['status' => null] generates `status IS NULL`.
* - `['id' => $query]` generates `id IN (...sub-query...)`
*
* A condition in operator format generates the SQL expression according to the specified operator, which
* can be one of the followings:
......@@ -505,10 +506,12 @@ class Query extends Component implements QueryInterface
* - `not between`: similar to `between` except the `BETWEEN` is replaced with `NOT BETWEEN`
* in the generated condition.
*
* - `in`: operand 1 should be a column or DB expression, and operand 2 be an array representing
* the range of the values that the column or DB expression should be in. For example,
* `['in', 'id', [1, 2, 3]]` will generate `id IN (1, 2, 3)`.
* The method will properly quote the column name and escape values in the range.
* - `in`: operand 1 should be a column or DB expression with parenthesis. Operand 2 can be an array
* or a Query object. If the former, the array represents the range of the values that the column
* or DB expression should be in. If the latter, a sub-query will be generated to represent the range.
* For example, `['in', 'id', [1, 2, 3]]` will generate `id IN (1, 2, 3)`;
* `['in', 'id', (new Query)->select('id')->from('user'))]` will generate
* `id IN (SELECT id FROM user)`. The method will properly quote the column name and escape values in the range.
*
* - `not in`: similar to the `in` operator except that `IN` is replaced with `NOT IN` in the generated condition.
*
......
......@@ -891,7 +891,8 @@ class QueryBuilder extends \yii\base\Object
{
$parts = [];
foreach ($condition as $column => $value) {
if (is_array($value)) { // IN condition
if (is_array($value) || $value instanceof Query) {
// IN condition
$parts[] = $this->buildInCondition('IN', [$column, $value], $params);
} else {
if (strpos($column, '(') === false) {
......@@ -1013,15 +1014,36 @@ class QueryBuilder extends \yii\base\Object
list($column, $values) = $operands;
$values = (array) $values;
if (empty($values) || $column === []) {
if ($values === [] || $column === []) {
return $operator === 'IN' ? '0=1' : '';
}
if ($values instanceof Query) {
// sub-query
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;
if (count($column) > 1) {
return $this->buildCompositeInCondition($operator, $column, $values, $params);
} elseif (is_array($column)) {
}
if (is_array($column)) {
$column = reset($column);
}
foreach ($values as $i => $value) {
......
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