Browse Source

Fixes #13879: Added upsert support for `yii\db\QueryBuilder` and `yii\db\Command`

tags/2.0.14
Dmitry Naumenko 7 years ago committed by Alexander Makarov
parent
commit
de1750228d
  1. 1
      framework/CHANGELOG.md
  2. 36
      framework/db/Command.php
  3. 10
      framework/db/Connection.php
  4. 125
      framework/db/ConstraintFinderInterface.php
  5. 186
      framework/db/QueryBuilder.php
  6. 81
      framework/db/Schema.php
  7. 58
      framework/db/cubrid/QueryBuilder.php
  8. 29
      framework/db/cubrid/Schema.php
  9. 75
      framework/db/mssql/QueryBuilder.php
  10. 34
      framework/db/mssql/Schema.php
  11. 66
      framework/db/mysql/QueryBuilder.php
  12. 34
      framework/db/mysql/Schema.php
  13. 106
      framework/db/oci/QueryBuilder.php
  14. 8
      framework/db/oci/Schema.php
  15. 145
      framework/db/pgsql/QueryBuilder.php
  16. 19
      framework/db/pgsql/Schema.php
  17. 50
      framework/db/sqlite/QueryBuilder.php
  18. 34
      framework/db/sqlite/Schema.php
  19. 7
      tests/IsOneOfAssert.php
  20. 14
      tests/data/cubrid.sql
  21. 14
      tests/data/mssql.sql
  22. 15
      tests/data/mysql.sql
  23. 23
      tests/data/oci.sql
  24. 14
      tests/data/postgres.sql
  25. 14
      tests/data/sqlite.sql
  26. 263
      tests/framework/db/CommandTest.php
  27. 223
      tests/framework/db/QueryBuilderTest.php
  28. 44
      tests/framework/db/cubrid/QueryBuilderTest.php
  29. 44
      tests/framework/db/mssql/QueryBuilderTest.php
  30. 2
      tests/framework/db/mysql/CommandTest.php
  31. 44
      tests/framework/db/mysql/QueryBuilderTest.php
  32. 56
      tests/framework/db/oci/QueryBuilderTest.php
  33. 94
      tests/framework/db/pgsql/QueryBuilderTest.php
  34. 15
      tests/framework/db/sqlite/CommandTest.php
  35. 44
      tests/framework/db/sqlite/QueryBuilderTest.php

1
framework/CHANGELOG.md

@ -84,6 +84,7 @@ Yii Framework 2 Change Log
- Enh #15221: Added support for specifying `--camelCase` console options in `--kebab-case` (brandonkelly) - Enh #15221: Added support for specifying `--camelCase` console options in `--kebab-case` (brandonkelly)
- Enh #15221: Added support for the `--<option> <value>` console option syntax (brandonkelly) - Enh #15221: Added support for the `--<option> <value>` console option syntax (brandonkelly)
- Enh #15221: Improved the `help/list-action-options` console command output for command options without a description (brandonkelly) - Enh #15221: Improved the `help/list-action-options` console command output for command options without a description (brandonkelly)
- Enh #13879: Added upsert support for `yii\db\QueryBuilder` and `yii\db\Command` (sergeymakinen)
- Enh #15226: Auto generate placeholder from fields (vladis84) - Enh #15226: Auto generate placeholder from fields (vladis84)
- Enh #15332: Always check for availability of `openssl_pseudo_random_bytes`, even if LibreSSL is available (sammousa) - Enh #15332: Always check for availability of `openssl_pseudo_random_bytes`, even if LibreSSL is available (sammousa)
- Enh #15335: Added `FileHelper::unlink()` that works well under all OSes (samdark) - Enh #15335: Added `FileHelper::unlink()` that works well under all OSes (samdark)

36
framework/db/Command.php

@ -508,6 +508,42 @@ class Command extends Component
} }
/** /**
* Creates a command to insert rows into a database table if
* they do not already exist (matching unique constraints),
* or update them if they do.
*
* For example,
*
* ```php
* $sql = $queryBuilder->upsert('pages', [
* 'name' => 'Front page',
* 'url' => 'http://example.com/', // url is unique
* 'visits' => 0,
* ], [
* 'visits' => new \yii\db\Expression('visits + 1'),
* ], $params);
* ```
*
* The method will properly escape the table and column names.
*
* @param string $table the table that new rows will be inserted into/updated in.
* @param array|Query $insertColumns the column data (name => value) to be inserted into the table or instance
* of [[Query]] to perform `INSERT INTO ... SELECT` SQL statement.
* @param array|bool $updateColumns the column data (name => value) to be updated if they already exist.
* If `true` is passed, the column data will be updated to match the insert column data.
* If `false` is passed, no update will be performed if the column data already exists.
* @param array $params the parameters to be bound to the command.
* @return $this the command object itself.
* @since 2.0.14
*/
public function upsert($table, $insertColumns, $updateColumns = true, $params = [])
{
$sql = $this->db->getQueryBuilder()->upsert($table, $insertColumns, $updateColumns, $params);
return $this->setSql($sql)->bindValues($params);
}
/**
* Creates an UPDATE command. * Creates an UPDATE command.
* *
* For example, * For example,

10
framework/db/Connection.php

@ -957,6 +957,16 @@ class Connection extends Component
} }
/** /**
* Returns a server version as a string comparable by [[\version_compare()]].
* @return string server version as a string.
* @since 2.0.14
*/
public function getServerVersion()
{
return $this->getSchema()->getServerVersion();
}
/**
* Returns the PDO instance for the currently active slave connection. * Returns the PDO instance for the currently active slave connection.
* When [[enableSlaves]] is true, one of the slaves will be used for read queries, and its PDO instance * When [[enableSlaves]] is true, one of the slaves will be used for read queries, and its PDO instance
* will be returned by this method. * will be returned by this method.

125
framework/db/ConstraintFinderInterface.php

@ -0,0 +1,125 @@
<?php
/**
* @link http://www.yiiframework.com/
* @copyright Copyright (c) 2008 Yii Software LLC
* @license http://www.yiiframework.com/license/
*/
namespace yii\db;
/**
* ConstraintFinderInterface defines methods for getting a table constraint information.
*
* @author Sergey Makinen <sergey@makinen.ru>
* @since 2.0.14
*/
interface ConstraintFinderInterface
{
/**
* Obtains the primary key for the named table.
* @param string $name table name. The table name may contain schema name if any. Do not quote the table name.
* @param bool $refresh whether to reload the information even if it is found in the cache.
* @return Constraint|null table primary key, `null` if the table has no primary key.
*/
public function getTablePrimaryKey($name, $refresh = false);
/**
* Returns primary keys for all tables in the database.
* @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema name.
* @param bool $refresh whether to fetch the latest available table schemas. If this is `false`,
* cached data may be returned if available.
* @return Constraint[] primary keys for all tables in the database.
* Each array element is an instance of [[Constraint]] or its child class.
*/
public function getSchemaPrimaryKeys($schema = '', $refresh = false);
/**
* Obtains the foreign keys information for the named table.
* @param string $name table name. The table name may contain schema name if any. Do not quote the table name.
* @param bool $refresh whether to reload the information even if it is found in the cache.
* @return ForeignKeyConstraint[] table foreign keys.
*/
public function getTableForeignKeys($name, $refresh = false);
/**
* Returns foreign keys for all tables in the database.
* @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema name.
* @param bool $refresh whether to fetch the latest available table schemas. If this is false,
* cached data may be returned if available.
* @return ForeignKeyConstraint[][] foreign keys for all tables in the database.
* Each array element is an array of [[ForeignKeyConstraint]] or its child classes.
*/
public function getSchemaForeignKeys($schema = '', $refresh = false);
/**
* Obtains the indexes information for the named table.
* @param string $name table name. The table name may contain schema name if any. Do not quote the table name.
* @param bool $refresh whether to reload the information even if it is found in the cache.
* @return IndexConstraint[] table indexes.
*/
public function getTableIndexes($name, $refresh = false);
/**
* Returns indexes for all tables in the database.
* @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema name.
* @param bool $refresh whether to fetch the latest available table schemas. If this is false,
* cached data may be returned if available.
* @return IndexConstraint[][] indexes for all tables in the database.
* Each array element is an array of [[IndexConstraint]] or its child classes.
*/
public function getSchemaIndexes($schema = '', $refresh = false);
/**
* Obtains the unique constraints information for the named table.
* @param string $name table name. The table name may contain schema name if any. Do not quote the table name.
* @param bool $refresh whether to reload the information even if it is found in the cache.
* @return Constraint[] table unique constraints.
*/
public function getTableUniques($name, $refresh = false);
/**
* Returns unique constraints for all tables in the database.
* @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema name.
* @param bool $refresh whether to fetch the latest available table schemas. If this is false,
* cached data may be returned if available.
* @return Constraint[][] unique constraints for all tables in the database.
* Each array element is an array of [[Constraint]] or its child classes.
*/
public function getSchemaUniques($schema = '', $refresh = false);
/**
* Obtains the check constraints information for the named table.
* @param string $name table name. The table name may contain schema name if any. Do not quote the table name.
* @param bool $refresh whether to reload the information even if it is found in the cache.
* @return CheckConstraint[] table check constraints.
*/
public function getTableChecks($name, $refresh = false);
/**
* Returns check constraints for all tables in the database.
* @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema name.
* @param bool $refresh whether to fetch the latest available table schemas. If this is false,
* cached data may be returned if available.
* @return CheckConstraint[][] check constraints for all tables in the database.
* Each array element is an array of [[CheckConstraint]] or its child classes.
*/
public function getSchemaChecks($schema = '', $refresh = false);
/**
* Obtains the default value constraints information for the named table.
* @param string $name table name. The table name may contain schema name if any. Do not quote the table name.
* @param bool $refresh whether to reload the information even if it is found in the cache.
* @return DefaultValueConstraint[] table default value constraints.
*/
public function getTableDefaultValues($name, $refresh = false);
/**
* Returns default value constraints for all tables in the database.
* @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema name.
* @param bool $refresh whether to fetch the latest available table schemas. If this is false,
* cached data may be returned if available.
* @return DefaultValueConstraint[] default value constraints for all tables in the database.
* Each array element is an array of [[DefaultValueConstraint]] or its child classes.
*/
public function getSchemaDefaultValues($schema = '', $refresh = false);
}

186
framework/db/QueryBuilder.php

@ -295,20 +295,17 @@ class QueryBuilder extends \yii\base\BaseObject
/** /**
* Creates an INSERT SQL statement. * Creates an INSERT SQL statement.
*
* For example, * For example,
*
* ```php * ```php
* $sql = $queryBuilder->insert('user', [ * $sql = $queryBuilder->insert('user', [
* 'name' => 'Sam', * 'name' => 'Sam',
* 'age' => 30, * 'age' => 30,
* ], $params); * ], $params);
* ``` * ```
*
* The method will properly escape the table and column names. * The method will properly escape the table and column names.
* *
* @param string $table the table that new rows will be inserted into. * @param string $table the table that new rows will be inserted into.
* @param array|\yii\db\Query $columns the column data (name => value) to be inserted into the table or instance * @param array|Query $columns the column data (name => value) to be inserted into the table or instance
* of [[yii\db\Query|Query]] to perform INSERT INTO ... SELECT SQL statement. * of [[yii\db\Query|Query]] to perform INSERT INTO ... SELECT SQL statement.
* Passing of [[yii\db\Query|Query]] is available since version 2.0.11. * Passing of [[yii\db\Query|Query]] is available since version 2.0.11.
* @param array $params the binding parameters that will be generated by this method. * @param array $params the binding parameters that will be generated by this method.
@ -317,16 +314,32 @@ class QueryBuilder extends \yii\base\BaseObject
*/ */
public function insert($table, $columns, &$params) public function insert($table, $columns, &$params)
{ {
list($names, $placeholders, $values, $params) = $this->prepareInsertValues($table, $columns, $params);
return 'INSERT INTO ' . $this->db->quoteTableName($table)
. (!empty($names) ? ' (' . implode(', ', $names) . ')' : '')
. (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : $values);
}
/**
* Prepares a `VALUES` part for an `INSERT` SQL statement.
*
* @param string $table the table that new rows will be inserted into.
* @param array|Query $columns the column data (name => value) to be inserted into the table or instance
* of [[yii\db\Query|Query]] to perform INSERT INTO ... SELECT SQL statement.
* @param array $params the binding parameters that will be generated by this method.
* They should be bound to the DB command later.
* @return array array of column names, placeholders, values and params.
* @since 2.0.14
*/
protected function prepareInsertValues($table, $columns, $params = [])
{
$schema = $this->db->getSchema(); $schema = $this->db->getSchema();
if (($tableSchema = $schema->getTableSchema($table)) !== null) { $tableSchema = $schema->getTableSchema($table);
$columnSchemas = $tableSchema->columns; $columnSchemas = $tableSchema !== null ? $tableSchema->columns : [];
} else {
$columnSchemas = [];
}
$names = []; $names = [];
$placeholders = []; $placeholders = [];
$values = ' DEFAULT VALUES'; $values = ' DEFAULT VALUES';
if ($columns instanceof \yii\db\Query) { if ($columns instanceof Query) {
list($names, $values, $params) = $this->prepareInsertSelectSubQuery($columns, $schema, $params); list($names, $values, $params) = $this->prepareInsertSelectSubQuery($columns, $schema, $params);
} else { } else {
foreach ($columns as $name => $value) { foreach ($columns as $name => $value) {
@ -343,20 +356,17 @@ class QueryBuilder extends \yii\base\BaseObject
} }
} }
} }
return [$names, $placeholders, $values, $params];
return 'INSERT INTO ' . $schema->quoteTableName($table)
. (!empty($names) ? ' (' . implode(', ', $names) . ')' : '')
. (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : $values);
} }
/** /**
* Prepare select-subquery and field names for INSERT INTO ... SELECT SQL statement. * Prepare select-subquery and field names for INSERT INTO ... SELECT SQL statement.
* *
* @param \yii\db\Query $columns Object, which represents select query. * @param Query $columns Object, which represents select query.
* @param \yii\db\Schema $schema Schema object to quote column name. * @param \yii\db\Schema $schema Schema object to quote column name.
* @param array $params the parameters to be bound to the generated SQL statement. These parameters will * @param array $params the parameters to be bound to the generated SQL statement. These parameters will
* be included in the result with the additional parameters generated during the query building process. * be included in the result with the additional parameters generated during the query building process.
* @return array * @return array array of column names, values and params.
* @throws InvalidParamException if query's select does not contain named parameters only. * @throws InvalidParamException if query's select does not contain named parameters only.
* @since 2.0.11 * @since 2.0.11
*/ */
@ -451,6 +461,115 @@ class QueryBuilder extends \yii\base\BaseObject
} }
/** /**
* Creates an SQL statement to insert rows into a database table if
* they do not already exist (matching unique constraints),
* or update them if they do.
*
* For example,
*
* ```php
* $sql = $queryBuilder->upsert('pages', [
* 'name' => 'Front page',
* 'url' => 'http://example.com/', // url is unique
* 'visits' => 0,
* ], [
* 'visits' => new \yii\db\Expression('visits + 1'),
* ], $params);
* ```
*
* The method will properly escape the table and column names.
*
* @param string $table the table that new rows will be inserted into/updated in.
* @param array|Query $insertColumns the column data (name => value) to be inserted into the table or instance
* of [[Query]] to perform `INSERT INTO ... SELECT` SQL statement.
* @param array|bool $updateColumns the column data (name => value) to be updated if they already exist.
* If `true` is passed, the column data will be updated to match the insert column data.
* If `false` is passed, no update will be performed if the column data already exists.
* @param array $params the binding parameters that will be generated by this method.
* They should be bound to the DB command later.
* @return string the resulting SQL.
* @throws NotSupportedException if this is not supported by the underlying DBMS.
* @since 2.0.14
*/
public function upsert($table, $insertColumns, $updateColumns, &$params)
{
throw new NotSupportedException($this->db->getDriverName() . ' does not support upsert statements.');
}
/**
* @param string $table
* @param array|Query $insertColumns
* @param array|bool $updateColumns
* @param Constraint[] $constraints this parameter recieves a matched constraint list.
* The constraints will be unique by their column names.
* @return array
* @since 2.0.14
*/
protected function prepareUpsertColumns($table, $insertColumns, $updateColumns, &$constraints = [])
{
if ($insertColumns instanceof Query) {
list($insertNames) = $this->prepareInsertSelectSubQuery($insertColumns, $this->db->getSchema());
} else {
$insertNames = array_map([$this->db, 'quoteColumnName'], array_keys($insertColumns));
}
$uniqueNames = $this->getTableUniqueColumnNames($table, $insertNames, $constraints);
$uniqueNames = array_map([$this->db, 'quoteColumnName'], $uniqueNames);
if ($updateColumns !== true) {
return [$uniqueNames, $insertNames, null];
}
return [$uniqueNames, $insertNames, array_diff($insertNames, $uniqueNames)];
}
/**
* Returns all column names belonging to constraints enforcing uniqueness (`PRIMARY KEY`, `UNIQUE INDEX`, etc.)
* for the named table removing constraints which did not cover the specified column list.
* The column list will be unique by column names.
*
* @param string $name table name. The table name may contain schema name if any. Do not quote the table name.
* @param string[] $columns source column list.
* @param Constraint[] $constraints this parameter optionally recieves a matched constraint list.
* The constraints will be unique by their column names.
* @return string[] column list.
*/
private function getTableUniqueColumnNames($name, $columns, &$constraints = [])
{
$schema = $this->db->getSchema();
if (!$schema instanceof ConstraintFinderInterface) {
return [];
}
$constraints = [];
$primaryKey = $schema->getTablePrimaryKey($name);
if ($primaryKey !== null) {
$constraints[] = $primaryKey;
}
foreach ($schema->getTableIndexes($name) as $constraint) {
if ($constraint->isUnique) {
$constraints[] = $constraint;
}
}
$constraints = array_merge($constraints, $schema->getTableUniques($name));
// Remove duplicates
$constraints = array_combine(array_map(function (Constraint $constraint) {
$columns = $constraint->columnNames;
sort($columns, SORT_STRING);
return json_encode($columns);
}, $constraints), $constraints);
$columnNames = [];
// Remove all constraints which do not cover the specified column list
$constraints = array_values(array_filter($constraints, function (Constraint $constraint) use ($schema, $columns, &$columnNames) {
$constraintColumnNames = array_map([$schema, 'quoteColumnName'], $constraint->columnNames);
$result = !array_diff($constraintColumnNames, $columns);
if ($result) {
$columnNames = array_merge($columnNames, $constraintColumnNames);
}
return $result;
}));
return array_unique($columnNames);
}
/**
* Creates an UPDATE SQL statement. * Creates an UPDATE SQL statement.
* *
* For example, * For example,
@ -472,29 +591,38 @@ class QueryBuilder extends \yii\base\BaseObject
*/ */
public function update($table, $columns, $condition, &$params) public function update($table, $columns, $condition, &$params)
{ {
if (($tableSchema = $this->db->getTableSchema($table)) !== null) { list($lines, $params) = $this->prepareUpdateSets($table, $columns, $params);
$columnSchemas = $tableSchema->columns; $sql = 'UPDATE ' . $this->db->quoteTableName($table) . ' SET ' . implode(', ', $lines);
} else { $where = $this->buildWhere($condition, $params);
$columnSchemas = []; return $where === '' ? $sql : $sql . ' ' . $where;
} }
$lines = []; /**
* Prepares a `SET` parts for an `UPDATE` SQL statement.
* @param string $table the table to be updated.
* @param array $columns the column data (name => value) to be updated.
* @param array $params the binding parameters that will be modified by this method
* so that they can be bound to the DB command later.
* @return array an array `SET` parts for an `UPDATE` SQL statement (the first array element) and params (the second array element).
* @since 2.0.14
*/
protected function prepareUpdateSets($table, $columns, $params = [])
{
$tableSchema = $this->db->getTableSchema($table);
$columnSchemas = $tableSchema !== null ? $tableSchema->columns : [];
$sets = [];
foreach ($columns as $name => $value) { foreach ($columns as $name => $value) {
if ($value instanceof ExpressionInterface) { if ($value instanceof ExpressionInterface) {
$lines[] = $this->db->quoteColumnName($name) . '=' . $this->buildExpression($value, $params); $sets[] = $this->db->quoteColumnName($name) . '=' . $this->buildExpression($value, $params);
} else { } else {
$phName = $this->bindParam( $phName = $this->bindParam(
isset($columnSchemas[$name]) ? $columnSchemas[$name]->dbTypecast($value) : $value, isset($columnSchemas[$name]) ? $columnSchemas[$name]->dbTypecast($value) : $value,
$params $params
); );
$lines[] = $this->db->quoteColumnName($name) . '=' . $phName; $sets[] = $this->db->quoteColumnName($name) . '=' . $phName;
} }
} }
return [$sets, $params];
$sql = 'UPDATE ' . $this->db->quoteTableName($table) . ' SET ' . implode(', ', $lines);
$where = $this->buildWhere($condition, $params);
return $where === '' ? $sql : $sql . ' ' . $where;
} }
/** /**

81
framework/db/Schema.php

@ -15,6 +15,7 @@ use yii\base\NotSupportedException;
use yii\caching\Cache; use yii\caching\Cache;
use yii\caching\CacheInterface; use yii\caching\CacheInterface;
use yii\caching\TagDependency; use yii\caching\TagDependency;
use yii\helpers\StringHelper;
/** /**
* Schema is the base class for concrete DBMS-specific schema classes. * Schema is the base class for concrete DBMS-specific schema classes.
@ -90,6 +91,19 @@ abstract class Schema extends BaseObject
public $columnSchemaClass = 'yii\db\ColumnSchema'; public $columnSchemaClass = 'yii\db\ColumnSchema';
/** /**
* @var string|string[] character used to quote schema, table, etc. names.
* An array of 2 characters can be used in case starting and ending characters are different.
* @since 2.0.14
*/
protected $tableQuoteCharacter = "'";
/**
* @var string|string[] character used to quote column names.
* An array of 2 characters can be used in case starting and ending characters are different.
* @since 2.0.14
*/
protected $columnQuoteCharacter = '"';
/**
* @var array list of ALL schema names in the database, except system schemas * @var array list of ALL schema names in the database, except system schemas
*/ */
private $_schemaNames; private $_schemaNames;
@ -105,6 +119,10 @@ abstract class Schema extends BaseObject
* @var QueryBuilder the query builder for this database * @var QueryBuilder the query builder for this database
*/ */
private $_builder; private $_builder;
/**
* @var string server version as a string.
*/
private $_serverVersion;
/** /**
@ -509,7 +527,12 @@ abstract class Schema extends BaseObject
*/ */
public function quoteSimpleTableName($name) public function quoteSimpleTableName($name)
{ {
return strpos($name, "'") !== false ? $name : "'" . $name . "'"; if (is_string($this->tableQuoteCharacter)) {
$startingCharacter = $endingCharacter = $this->tableQuoteCharacter;
} else {
list($startingCharacter, $endingCharacter) = $this->tableQuoteCharacter;
}
return strpos($name, $startingCharacter) !== false ? $name : $startingCharacter . $name . $endingCharacter;
} }
/** /**
@ -521,7 +544,48 @@ abstract class Schema extends BaseObject
*/ */
public function quoteSimpleColumnName($name) public function quoteSimpleColumnName($name)
{ {
return strpos($name, '"') !== false || $name === '*' ? $name : '"' . $name . '"'; if (is_string($this->tableQuoteCharacter)) {
$startingCharacter = $endingCharacter = $this->columnQuoteCharacter;
} else {
list($startingCharacter, $endingCharacter) = $this->columnQuoteCharacter;
}
return $name === '*' || strpos($name, $startingCharacter) !== false ? $name : $startingCharacter . $name . $endingCharacter;
}
/**
* Unquotes a simple table name.
* A simple table name should contain the table name only without any schema prefix.
* If the table name is not quoted, this method will do nothing.
* @param string $name table name.
* @return string unquoted table name.
* @since 2.0.14
*/
public function unquoteSimpleTableName($name)
{
if (is_string($this->tableQuoteCharacter)) {
$startingCharacter = $this->tableQuoteCharacter;
} else {
$startingCharacter = $this->tableQuoteCharacter[0];
}
return strpos($name, $startingCharacter) === false ? $name : substr($name, 1, -1);
}
/**
* Unquotes a simple column name.
* A simple column name should contain the column name only without any prefix.
* If the column name is not quoted or is the asterisk character '*', this method will do nothing.
* @param string $name column name.
* @return string unquoted column name.
* @since 2.0.14
*/
public function unquoteSimpleColumnName($name)
{
if (is_string($this->columnQuoteCharacter)) {
$startingCharacter = $this->columnQuoteCharacter;
} else {
$startingCharacter = $this->columnQuoteCharacter[0];
}
return strpos($name, $startingCharacter) === false ? $name : substr($name, 1, -1);
} }
/** /**
@ -609,6 +673,19 @@ abstract class Schema extends BaseObject
} }
/** /**
* Returns a server version as a string comparable by [[\version_compare()]].
* @return string server version as a string.
* @since 2.0.14
*/
public function getServerVersion()
{
if ($this->_serverVersion === null) {
$this->_serverVersion = $this->db->getSlavePdo()->getAttribute(\PDO::ATTR_SERVER_VERSION);
}
return $this->_serverVersion;
}
/**
* Returns the cache key for the specified table name. * Returns the cache key for the specified table name.
* @param string $name the table name. * @param string $name the table name.
* @return mixed the cache key. * @return mixed the cache key.

58
framework/db/cubrid/QueryBuilder.php

@ -9,7 +9,9 @@ namespace yii\db\cubrid;
use yii\base\InvalidParamException; use yii\base\InvalidParamException;
use yii\base\NotSupportedException; use yii\base\NotSupportedException;
use yii\db\Constraint;
use yii\db\Exception; use yii\db\Exception;
use yii\db\Expression;
/** /**
* QueryBuilder is the query builder for CUBRID databases (version 9.3.x and higher). * QueryBuilder is the query builder for CUBRID databases (version 9.3.x and higher).
@ -56,6 +58,62 @@ class QueryBuilder extends \yii\db\QueryBuilder
} }
/** /**
* @inheritdoc
* @see https://www.cubrid.org/manual/en/9.3.0/sql/query/merge.html
*/
public function upsert($table, $insertColumns, $updateColumns, &$params)
{
/** @var Constraint[] $constraints */
list($uniqueNames, $insertNames, $updateNames) = $this->prepareUpsertColumns($table, $insertColumns, $updateColumns, $constraints);
if (empty($uniqueNames)) {
return $this->insert($table, $insertColumns, $params);
}
$onCondition = ['or'];
$quotedTableName = $this->db->quoteTableName($table);
foreach ($constraints as $constraint) {
$constraintCondition = ['and'];
foreach ($constraint->columnNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
$constraintCondition[] = "$quotedTableName.$quotedName=\"EXCLUDED\".$quotedName";
}
$onCondition[] = $constraintCondition;
}
$on = $this->buildCondition($onCondition, $params);
list(, $placeholders, $values, $params) = $this->prepareInsertValues($table, $insertColumns, $params);
$mergeSql = 'MERGE INTO ' . $this->db->quoteTableName($table) . ' '
. 'USING (' . (!empty($placeholders) ? 'VALUES (' . implode(', ', $placeholders) . ')' : ltrim($values, ' ')) . ') AS "EXCLUDED" (' . implode(', ', $insertNames) . ') '
. 'ON ' . $on;
$insertValues = [];
foreach ($insertNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
if (strrpos($quotedName, '.') === false) {
$quotedName = '"EXCLUDED".' . $quotedName;
}
$insertValues[] = $quotedName;
}
$insertSql = 'INSERT (' . implode(', ', $insertNames) . ')'
. ' VALUES (' . implode(', ', $insertValues) . ')';
if ($updateColumns === false) {
return "$mergeSql WHEN NOT MATCHED THEN $insertSql";
}
if ($updateColumns === true) {
$updateColumns = [];
foreach ($updateNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
if (strrpos($quotedName, '.') === false) {
$quotedName = '"EXCLUDED".' . $quotedName;
}
$updateColumns[$name] = new Expression($quotedName);
}
}
list($updates, $params) = $this->prepareUpdateSets($table, $updateColumns, $params);
$updateSql = 'UPDATE SET ' . implode(', ', $updates);
return "$mergeSql WHEN MATCHED THEN $updateSql WHEN NOT MATCHED THEN $insertSql";
}
/**
* Creates a SQL statement for resetting the sequence value of a table's primary key. * Creates a SQL statement for resetting the sequence value of a table's primary key.
* The sequence will be reset such that the primary key of the next new row inserted * The sequence will be reset such that the primary key of the next new row inserted
* will have the specified value or 1. * will have the specified value or 1.

29
framework/db/cubrid/Schema.php

@ -9,6 +9,7 @@ namespace yii\db\cubrid;
use yii\base\NotSupportedException; use yii\base\NotSupportedException;
use yii\db\Constraint; use yii\db\Constraint;
use yii\db\ConstraintFinderInterface;
use yii\db\ConstraintFinderTrait; use yii\db\ConstraintFinderTrait;
use yii\db\Expression; use yii\db\Expression;
use yii\db\ForeignKeyConstraint; use yii\db\ForeignKeyConstraint;
@ -23,7 +24,7 @@ use yii\helpers\ArrayHelper;
* @author Carsten Brandt <mail@cebe.cc> * @author Carsten Brandt <mail@cebe.cc>
* @since 2.0 * @since 2.0
*/ */
class Schema extends \yii\db\Schema class Schema extends \yii\db\Schema implements ConstraintFinderInterface
{ {
use ConstraintFinderTrait; use ConstraintFinderTrait;
@ -79,6 +80,10 @@ class Schema extends \yii\db\Schema
'Operation would have caused one or more unique constraint violations' => 'yii\db\IntegrityException', 'Operation would have caused one or more unique constraint violations' => 'yii\db\IntegrityException',
]; ];
/**
* @inheritDoc
*/
protected $tableQuoteCharacter = '"';
/** /**
* @inheritDoc * @inheritDoc
@ -237,28 +242,6 @@ class Schema extends \yii\db\Schema
} }
/** /**
* Quotes a table name for use in a query.
* A simple table name has no schema prefix.
* @param string $name table name
* @return string the properly quoted table name
*/
public function quoteSimpleTableName($name)
{
return strpos($name, '"') !== false ? $name : '"' . $name . '"';
}
/**
* Quotes a column name for use in a query.
* A simple column name has no prefix.
* @param string $name column name
* @return string the properly quoted column name
*/
public function quoteSimpleColumnName($name)
{
return strpos($name, '"') !== false || $name === '*' ? $name : '"' . $name . '"';
}
/**
* Creates a query builder for the CUBRID database. * Creates a query builder for the CUBRID database.
* @return QueryBuilder query builder instance * @return QueryBuilder query builder instance
*/ */

75
framework/db/mssql/QueryBuilder.php

@ -8,7 +8,7 @@
namespace yii\db\mssql; namespace yii\db\mssql;
use yii\base\InvalidParamException; use yii\base\InvalidParamException;
use yii\base\NotSupportedException; use yii\db\Constraint;
use yii\db\Expression; use yii\db\Expression;
/** /**
@ -66,7 +66,7 @@ class QueryBuilder extends \yii\db\QueryBuilder
return $orderBy === '' ? $sql : $sql . $this->separator . $orderBy; return $orderBy === '' ? $sql : $sql . $this->separator . $orderBy;
} }
if ($this->isOldMssql()) { if (version_compare($this->db->getSchema()->getServerVersion(), '11', '<')) {
return $this->oldBuildOrderByAndLimit($sql, $orderBy, $limit, $offset); return $this->oldBuildOrderByAndLimit($sql, $orderBy, $limit, $offset);
} }
@ -301,24 +301,14 @@ class QueryBuilder extends \yii\db\QueryBuilder
} }
/** /**
* @var bool whether MSSQL used is old.
*/
private $_oldMssql;
/**
* @return bool whether the version of the MSSQL being used is older than 2012. * @return bool whether the version of the MSSQL being used is older than 2012.
* @throws \yii\base\InvalidConfigException * @throws \yii\base\InvalidConfigException
* @throws \yii\db\Exception * @throws \yii\db\Exception
* @deprecated 2.0.14 Use [[Schema::getServerVersion]] with [[\version_compare()]].
*/ */
protected function isOldMssql() protected function isOldMssql()
{ {
if ($this->_oldMssql === null) { return version_compare($this->db->getSchema()->getServerVersion(), '11', '<');
$pdo = $this->db->getSlavePdo();
$version = explode('.', $pdo->getAttribute(\PDO::ATTR_SERVER_VERSION));
$this->_oldMssql = $version[0] < 11;
}
return $this->_oldMssql;
} }
/** /**
@ -362,6 +352,63 @@ class QueryBuilder extends \yii\db\QueryBuilder
} }
/** /**
* @inheritdoc
* @see https://docs.microsoft.com/en-us/sql/t-sql/statements/merge-transact-sql
* @see http://weblogs.sqlteam.com/dang/archive/2009/01/31/UPSERT-Race-Condition-With-MERGE.aspx
*/
public function upsert($table, $insertColumns, $updateColumns, &$params)
{
/** @var Constraint[] $constraints */
list($uniqueNames, $insertNames, $updateNames) = $this->prepareUpsertColumns($table, $insertColumns, $updateColumns, $constraints);
if (empty($uniqueNames)) {
return $this->insert($table, $insertColumns, $params);
}
$onCondition = ['or'];
$quotedTableName = $this->db->quoteTableName($table);
foreach ($constraints as $constraint) {
$constraintCondition = ['and'];
foreach ($constraint->columnNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
$constraintCondition[] = "$quotedTableName.$quotedName=[EXCLUDED].$quotedName";
}
$onCondition[] = $constraintCondition;
}
$on = $this->buildCondition($onCondition, $params);
list(, $placeholders, $values, $params) = $this->prepareInsertValues($table, $insertColumns, $params);
$mergeSql = 'MERGE ' . $this->db->quoteTableName($table) . ' WITH (HOLDLOCK) '
. 'USING (' . (!empty($placeholders) ? 'VALUES (' . implode(', ', $placeholders) . ')' : ltrim($values, ' ')) . ') AS [EXCLUDED] (' . implode(', ', $insertNames) . ') '
. 'ON ' . $on;
$insertValues = [];
foreach ($insertNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
if (strrpos($quotedName, '.') === false) {
$quotedName = '[EXCLUDED].' . $quotedName;
}
$insertValues[] = $quotedName;
}
$insertSql = 'INSERT (' . implode(', ', $insertNames) . ')'
. ' VALUES (' . implode(', ', $insertValues) . ')';
if ($updateColumns === false) {
return "$mergeSql WHEN NOT MATCHED THEN $insertSql;";
}
if ($updateColumns === true) {
$updateColumns = [];
foreach ($updateNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
if (strrpos($quotedName, '.') === false) {
$quotedName = '[EXCLUDED].' . $quotedName;
}
$updateColumns[$name] = new Expression($quotedName);
}
}
list($updates, $params) = $this->prepareUpdateSets($table, $updateColumns, $params);
$updateSql = 'UPDATE SET ' . implode(', ', $updates);
return "$mergeSql WHEN MATCHED THEN $updateSql WHEN NOT MATCHED THEN $insertSql;";
}
/**
* {@inheritdoc} * {@inheritdoc}
*/ */
public function update($table, $columns, $condition, &$params) public function update($table, $columns, $condition, &$params)

34
framework/db/mssql/Schema.php

@ -10,6 +10,7 @@ namespace yii\db\mssql;
use yii\db\CheckConstraint; use yii\db\CheckConstraint;
use yii\db\ColumnSchema; use yii\db\ColumnSchema;
use yii\db\Constraint; use yii\db\Constraint;
use yii\db\ConstraintFinderInterface;
use yii\db\ConstraintFinderTrait; use yii\db\ConstraintFinderTrait;
use yii\db\DefaultValueConstraint; use yii\db\DefaultValueConstraint;
use yii\db\ForeignKeyConstraint; use yii\db\ForeignKeyConstraint;
@ -23,7 +24,7 @@ use yii\helpers\ArrayHelper;
* @author Timur Ruziev <resurtm@gmail.com> * @author Timur Ruziev <resurtm@gmail.com>
* @since 2.0 * @since 2.0
*/ */
class Schema extends \yii\db\Schema class Schema extends \yii\db\Schema implements ConstraintFinderInterface
{ {
use ViewFinderTrait; use ViewFinderTrait;
use ConstraintFinderTrait; use ConstraintFinderTrait;
@ -79,6 +80,15 @@ class Schema extends \yii\db\Schema
'table' => self::TYPE_STRING, 'table' => self::TYPE_STRING,
]; ];
/**
* @inheritDoc
*/
protected $tableQuoteCharacter = ['[', ']'];
/**
* @inheritDoc
*/
protected $columnQuoteCharacter = ['[', ']'];
/** /**
* Resolves the table name and schema name (if any). * Resolves the table name and schema name (if any).
@ -272,28 +282,6 @@ SQL;
} }
/** /**
* Quotes a table name for use in a query.
* A simple table name has no schema prefix.
* @param string $name table name.
* @return string the properly quoted table name.
*/
public function quoteSimpleTableName($name)
{
return strpos($name, '[') === false ? "[{$name}]" : $name;
}
/**
* Quotes a column name for use in a query.
* A simple column name has no prefix.
* @param string $name column name.
* @return string the properly quoted column name.
*/
public function quoteSimpleColumnName($name)
{
return strpos($name, '[') === false && $name !== '*' ? "[{$name}]" : $name;
}
/**
* Creates a query builder for the MSSQL database. * Creates a query builder for the MSSQL database.
* @return QueryBuilder query builder interface. * @return QueryBuilder query builder interface.
*/ */

66
framework/db/mysql/QueryBuilder.php

@ -10,7 +10,8 @@ namespace yii\db\mysql;
use yii\base\InvalidParamException; use yii\base\InvalidParamException;
use yii\base\NotSupportedException; use yii\base\NotSupportedException;
use yii\db\Exception; use yii\db\Exception;
use yii\db\ExpressionInterface; use yii\db\Expression;
use yii\db\Query;
/** /**
* QueryBuilder is the query builder for MySQL databases. * QueryBuilder is the query builder for MySQL databases.
@ -241,46 +242,45 @@ class QueryBuilder extends \yii\db\QueryBuilder
/** /**
* {@inheritdoc} * {@inheritdoc}
*/ */
public function insert($table, $columns, &$params) protected function prepareInsertValues($table, $columns, $params = [])
{ {
$schema = $this->db->getSchema(); list($names, $placeholders, $values, $params) = parent::prepareInsertValues($table, $columns, $params);
if (($tableSchema = $schema->getTableSchema($table)) !== null) { if (!$columns instanceof Query && empty($names)) {
$columnSchemas = $tableSchema->columns; $tableSchema = $this->db->getSchema()->getTableSchema($table);
} else { if ($tableSchema !== null) {
$columnSchemas = [];
}
$names = [];
$placeholders = [];
$values = ' DEFAULT VALUES';
if ($columns instanceof \yii\db\Query) {
list($names, $values, $params) = $this->prepareInsertSelectSubQuery($columns, $schema, $params);
} else {
foreach ($columns as $name => $value) {
$names[] = $schema->quoteColumnName($name);
if ($value instanceof ExpressionInterface) {
$placeholders[] = $this->buildExpression($value, $params);
} elseif ($value instanceof \yii\db\Query) {
list($sql, $params) = $this->build($value, $params);
$placeholders[] = "($sql)";
} else {
$placeholders[] = $this->bindParam(
isset($columnSchemas[$name]) ? $columnSchemas[$name]->dbTypecast($value) : $value,
$params
);
}
}
if (empty($names) && $tableSchema !== null) {
$columns = !empty($tableSchema->primaryKey) ? $tableSchema->primaryKey : [reset($tableSchema->columns)->name]; $columns = !empty($tableSchema->primaryKey) ? $tableSchema->primaryKey : [reset($tableSchema->columns)->name];
foreach ($columns as $name) { foreach ($columns as $name) {
$names[] = $schema->quoteColumnName($name); $names[] = $this->db->quoteColumnName($name);
$placeholders[] = 'DEFAULT'; $placeholders[] = 'DEFAULT';
} }
} }
} }
return [$names, $placeholders, $values, $params];
}
return 'INSERT INTO ' . $schema->quoteTableName($table) /**
. (!empty($names) ? ' (' . implode(', ', $names) . ')' : '') * @inheritdoc
. (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : $values); * @see https://downloads.mysql.com/docs/refman-5.1-en.pdf
*/
public function upsert($table, $insertColumns, $updateColumns, &$params)
{
$insertSql = $this->insert($table, $insertColumns, $params);
list($uniqueNames, , $updateNames) = $this->prepareUpsertColumns($table, $insertColumns, $updateColumns);
if (empty($uniqueNames)) {
return $insertSql;
}
if ($updateColumns === true) {
$updateColumns = [];
foreach ($updateNames as $name) {
$updateColumns[$name] = new Expression('VALUES(' . $this->db->quoteColumnName($name) . ')');
}
} elseif ($updateColumns === false) {
$name = $this->db->quoteColumnName(reset($uniqueNames));
$updateColumns = [$name => new Expression($this->db->quoteTableName($table) . '.' . $name)];
}
list($updates, $params) = $this->prepareUpdateSets($table, $updateColumns, $params);
return $insertSql . ' ON DUPLICATE KEY UPDATE ' . implode(', ', $updates);
} }
/** /**

34
framework/db/mysql/Schema.php

@ -11,6 +11,7 @@ use yii\base\InvalidConfigException;
use yii\base\NotSupportedException; use yii\base\NotSupportedException;
use yii\db\ColumnSchema; use yii\db\ColumnSchema;
use yii\db\Constraint; use yii\db\Constraint;
use yii\db\ConstraintFinderInterface;
use yii\db\ConstraintFinderTrait; use yii\db\ConstraintFinderTrait;
use yii\db\Exception; use yii\db\Exception;
use yii\db\Expression; use yii\db\Expression;
@ -25,7 +26,7 @@ use yii\helpers\ArrayHelper;
* @author Qiang Xue <qiang.xue@gmail.com> * @author Qiang Xue <qiang.xue@gmail.com>
* @since 2.0 * @since 2.0
*/ */
class Schema extends \yii\db\Schema class Schema extends \yii\db\Schema implements ConstraintFinderInterface
{ {
use ConstraintFinderTrait; use ConstraintFinderTrait;
@ -73,6 +74,15 @@ class Schema extends \yii\db\Schema
/** /**
* @inheritDoc * @inheritDoc
*/ */
protected $tableQuoteCharacter = '`';
/**
* @inheritDoc
*/
protected $columnQuoteCharacter = '`';
/**
* @inheritDoc
*/
protected function resolveTableName($name) protected function resolveTableName($name)
{ {
$resolvedName = new TableSchema(); $resolvedName = new TableSchema();
@ -196,28 +206,6 @@ SQL;
} }
/** /**
* Quotes a table name for use in a query.
* A simple table name has no schema prefix.
* @param string $name table name
* @return string the properly quoted table name
*/
public function quoteSimpleTableName($name)
{
return strpos($name, '`') !== false ? $name : "`$name`";
}
/**
* Quotes a column name for use in a query.
* A simple column name has no prefix.
* @param string $name column name
* @return string the properly quoted column name
*/
public function quoteSimpleColumnName($name)
{
return strpos($name, '`') !== false || $name === '*' ? $name : "`$name`";
}
/**
* Creates a query builder for the MySQL database. * Creates a query builder for the MySQL database.
* @return QueryBuilder query builder instance * @return QueryBuilder query builder instance
*/ */

106
framework/db/oci/QueryBuilder.php

@ -9,8 +9,10 @@ namespace yii\db\oci;
use yii\base\InvalidParamException; use yii\base\InvalidParamException;
use yii\db\Connection; use yii\db\Connection;
use yii\db\Constraint;
use yii\db\Exception; use yii\db\Exception;
use yii\db\Expression; use yii\db\Expression;
use yii\db\Query;
use yii\helpers\StringHelper; use yii\helpers\StringHelper;
use yii\db\ExpressionInterface; use yii\db\ExpressionInterface;
@ -180,46 +182,86 @@ EOD;
/** /**
* {@inheritdoc} * {@inheritdoc}
*/ */
public function insert($table, $columns, &$params) protected function prepareInsertValues($table, $columns, $params = [])
{ {
$schema = $this->db->getSchema(); list($names, $placeholders, $values, $params) = parent::prepareInsertValues($table, $columns, $params);
if (($tableSchema = $schema->getTableSchema($table)) !== null) { if (!$columns instanceof Query && empty($names)) {
$columnSchemas = $tableSchema->columns; $tableSchema = $this->db->getSchema()->getTableSchema($table);
} else { if ($tableSchema !== null) {
$columnSchemas = [];
}
$names = [];
$placeholders = [];
$values = ' DEFAULT VALUES';
if ($columns instanceof \yii\db\Query) {
list($names, $values, $params) = $this->prepareInsertSelectSubQuery($columns, $schema, $params);
} else {
foreach ($columns as $name => $value) {
$names[] = $schema->quoteColumnName($name);
if ($value instanceof ExpressionInterface) {
$placeholders[] = $this->buildExpression($value, $params);
} elseif ($value instanceof \yii\db\Query) {
list($sql, $params) = $this->build($value, $params);
$placeholders[] = "($sql)";
} else {
$placeholders[] = $this->bindParam(
isset($columnSchemas[$name]) ? $columnSchemas[$name]->dbTypecast($value) : $value,
$params
);
}
}
if (empty($names) && $tableSchema !== null) {
$columns = !empty($tableSchema->primaryKey) ? $tableSchema->primaryKey : [reset($tableSchema->columns)->name]; $columns = !empty($tableSchema->primaryKey) ? $tableSchema->primaryKey : [reset($tableSchema->columns)->name];
foreach ($columns as $name) { foreach ($columns as $name) {
$names[] = $schema->quoteColumnName($name); $names[] = $this->db->quoteColumnName($name);
$placeholders[] = 'DEFAULT'; $placeholders[] = 'DEFAULT';
} }
} }
} }
return [$names, $placeholders, $values, $params];
}
/**
* @inheritdoc
* @see https://docs.oracle.com/cd/B28359_01/server.111/b28286/statements_9016.htm#SQLRF01606
*/
public function upsert($table, $insertColumns, $updateColumns, &$params)
{
/** @var Constraint[] $constraints */
list($uniqueNames, $insertNames, $updateNames) = $this->prepareUpsertColumns($table, $insertColumns, $updateColumns, $constraints);
if (empty($uniqueNames)) {
return $this->insert($table, $insertColumns, $params);
}
$onCondition = ['or'];
$quotedTableName = $this->db->quoteTableName($table);
foreach ($constraints as $constraint) {
$constraintCondition = ['and'];
foreach ($constraint->columnNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
$constraintCondition[] = "$quotedTableName.$quotedName=\"EXCLUDED\".$quotedName";
}
$onCondition[] = $constraintCondition;
}
$on = $this->buildCondition($onCondition, $params);
list(, $placeholders, $values, $params) = $this->prepareInsertValues($table, $insertColumns, $params);
if (!empty($placeholders)) {
$usingSelectValues = [];
foreach ($insertNames as $index => $name) {
$usingSelectValues[$name] = new Expression($placeholders[$index]);
}
$usingSubQuery = (new Query())
->select($usingSelectValues)
->from('DUAL');
list($usingValues, $params) = $this->build($usingSubQuery, $params);
}
$mergeSql = 'MERGE INTO ' . $this->db->quoteTableName($table) . ' '
. 'USING (' . (isset($usingValues) ? $usingValues : ltrim($values, ' ')) . ') "EXCLUDED" '
. 'ON ' . $on;
$insertValues = [];
foreach ($insertNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
if (strrpos($quotedName, '.') === false) {
$quotedName = '"EXCLUDED".' . $quotedName;
}
$insertValues[] = $quotedName;
}
$insertSql = 'INSERT (' . implode(', ', $insertNames) . ')'
. ' VALUES (' . implode(', ', $insertValues) . ')';
if ($updateColumns === false) {
return "$mergeSql WHEN NOT MATCHED THEN $insertSql";
}
return 'INSERT INTO ' . $schema->quoteTableName($table) if ($updateColumns === true) {
. (!empty($names) ? ' (' . implode(', ', $names) . ')' : '') $updateColumns = [];
. (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : $values); foreach ($updateNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
if (strrpos($quotedName, '.') === false) {
$quotedName = '"EXCLUDED".' . $quotedName;
}
$updateColumns[$name] = new Expression($quotedName);
}
}
list($updates, $params) = $this->prepareUpdateSets($table, $updateColumns, $params);
$updateSql = 'UPDATE SET ' . implode(', ', $updates);
return "$mergeSql WHEN MATCHED THEN $updateSql WHEN NOT MATCHED THEN $insertSql";
} }
/** /**

8
framework/db/oci/Schema.php

@ -13,6 +13,7 @@ use yii\db\CheckConstraint;
use yii\db\ColumnSchema; use yii\db\ColumnSchema;
use yii\db\Connection; use yii\db\Connection;
use yii\db\Constraint; use yii\db\Constraint;
use yii\db\ConstraintFinderInterface;
use yii\db\ConstraintFinderTrait; use yii\db\ConstraintFinderTrait;
use yii\db\Expression; use yii\db\Expression;
use yii\db\ForeignKeyConstraint; use yii\db\ForeignKeyConstraint;
@ -29,7 +30,7 @@ use yii\helpers\ArrayHelper;
* @author Qiang Xue <qiang.xue@gmail.com> * @author Qiang Xue <qiang.xue@gmail.com>
* @since 2.0 * @since 2.0
*/ */
class Schema extends \yii\db\Schema class Schema extends \yii\db\Schema implements ConstraintFinderInterface
{ {
use ConstraintFinderTrait; use ConstraintFinderTrait;
@ -41,6 +42,11 @@ class Schema extends \yii\db\Schema
'ORA-00001: unique constraint' => 'yii\db\IntegrityException', 'ORA-00001: unique constraint' => 'yii\db\IntegrityException',
]; ];
/**
* @inheritDoc
*/
protected $tableQuoteCharacter = '"';
/** /**
* {@inheritdoc} * {@inheritdoc}

145
framework/db/pgsql/QueryBuilder.php

@ -8,9 +8,10 @@
namespace yii\db\pgsql; namespace yii\db\pgsql;
use yii\base\InvalidParamException; use yii\base\InvalidParamException;
use yii\db\ExpressionInterface; use yii\db\Constraint;
use yii\db\PdoValue; use yii\db\Expression;
use yii\db\Query; use yii\db\Query;
use yii\db\PdoValue;
use yii\helpers\StringHelper; use yii\helpers\StringHelper;
/** /**
@ -251,6 +252,141 @@ class QueryBuilder extends \yii\db\QueryBuilder
} }
/** /**
* @inheritdoc
* @see https://www.postgresql.org/docs/9.5/static/sql-insert.html#SQL-ON-CONFLICT
* @see https://stackoverflow.com/questions/1109061/insert-on-duplicate-update-in-postgresql/8702291#8702291
*/
public function upsert($table, $insertColumns, $updateColumns, &$params)
{
$insertColumns = $this->normalizeTableRowData($table, $insertColumns);
if (!is_bool($updateColumns)) {
$updateColumns = $this->normalizeTableRowData($table, $updateColumns);
}
if (version_compare($this->db->getServerVersion(), '9.5', '<')) {
return $this->oldUpsert($table, $insertColumns, $updateColumns, $params);
}
return $this->newUpsert($table, $insertColumns, $updateColumns, $params);
}
/**
* [[upsert()]] implementation for PostgreSQL 9.5 or higher.
* @param string $table
* @param array|Query $insertColumns
* @param array|bool $updateColumns
* @param array $params
* @return string
*/
private function newUpsert($table, $insertColumns, $updateColumns, &$params)
{
$insertSql = $this->insert($table, $insertColumns, $params);
list($uniqueNames, , $updateNames) = $this->prepareUpsertColumns($table, $insertColumns, $updateColumns);
if (empty($uniqueNames)) {
return $insertSql;
}
if ($updateColumns === false) {
return "$insertSql ON CONFLICT DO NOTHING";
}
if ($updateColumns === true) {
$updateColumns = [];
foreach ($updateNames as $name) {
$updateColumns[$name] = new Expression('EXCLUDED.' . $this->db->quoteColumnName($name));
}
}
list($updates, $params) = $this->prepareUpdateSets($table, $updateColumns, $params);
return $insertSql . ' ON CONFLICT (' . implode(', ', $uniqueNames) . ') DO UPDATE SET ' . implode(', ', $updates);
}
/**
* [[upsert()]] implementation for PostgreSQL older than 9.5.
* @param string $table
* @param array|Query $insertColumns
* @param array|bool $updateColumns
* @param array $params
* @return string
*/
private function oldUpsert($table, $insertColumns, $updateColumns, &$params)
{
/** @var Constraint[] $constraints */
list($uniqueNames, $insertNames, $updateNames) = $this->prepareUpsertColumns($table, $insertColumns, $updateColumns, $constraints);
if (empty($uniqueNames)) {
return $this->insert($table, $insertColumns, $params);
}
/** @var Schema $schema */
$schema = $this->db->getSchema();
if (!$insertColumns instanceof Query) {
$tableSchema = $schema->getTableSchema($table);
$columnSchemas = $tableSchema !== null ? $tableSchema->columns : [];
foreach ($insertColumns as $name => $value) {
// NULLs and numeric values must be type hinted in order to be used in SET assigments
// NVM, let's cast them all
if (isset($columnSchemas[$name])) {
$phName = self::PARAM_PREFIX . count($params);
$params[$phName] = $value;
$insertColumns[$name] = new Expression("CAST($phName AS {$columnSchemas[$name]->dbType})");
}
}
}
list(, $placeholders, $values, $params) = $this->prepareInsertValues($table, $insertColumns, $params);
$updateCondition = ['or'];
$insertCondition = ['or'];
$quotedTableName = $schema->quoteTableName($table);
foreach ($constraints as $constraint) {
$constraintUpdateCondition = ['and'];
$constraintInsertCondition = ['and'];
foreach ($constraint->columnNames as $name) {
$quotedName = $schema->quoteColumnName($name);
$constraintUpdateCondition[] = "$quotedTableName.$quotedName=\"EXCLUDED\".$quotedName";
$constraintInsertCondition[] = "\"upsert\".$quotedName=\"EXCLUDED\".$quotedName";
}
$updateCondition[] = $constraintUpdateCondition;
$insertCondition[] = $constraintInsertCondition;
}
$withSql = 'WITH "EXCLUDED" (' . implode(', ', $insertNames)
. ') AS (' . (!empty($placeholders) ? 'VALUES (' . implode(', ', $placeholders) . ')' : ltrim($values, ' ')) . ')';
if ($updateColumns === false) {
$selectSubQuery = (new Query())
->select(new Expression('1'))
->from($table)
->where($updateCondition);
$insertSelectSubQuery = (new Query())
->select($insertNames)
->from('EXCLUDED')
->where(['not exists', $selectSubQuery]);
$insertSql = $this->insert($table, $insertSelectSubQuery, $params);
return "$withSql $insertSql";
}
if ($updateColumns === true) {
$updateColumns = [];
foreach ($updateNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
if (strrpos($quotedName, '.') === false) {
$quotedName = '"EXCLUDED".' . $quotedName;
}
$updateColumns[$name] = new Expression($quotedName);
}
}
list($updates, $params) = $this->prepareUpdateSets($table, $updateColumns, $params);
$updateSql = 'UPDATE ' . $this->db->quoteTableName($table) . ' SET ' . implode(', ', $updates)
. ' FROM "EXCLUDED" ' . $this->buildWhere($updateCondition, $params)
. ' RETURNING ' . $this->db->quoteTableName($table) .'.*';
$selectUpsertSubQuery = (new Query())
->select(new Expression('1'))
->from('upsert')
->where($insertCondition);
$insertSelectSubQuery = (new Query())
->select($insertNames)
->from('EXCLUDED')
->where(['not exists', $selectUpsertSubQuery]);
$insertSql = $this->insert($table, $insertSelectSubQuery, $params);
return "$withSql, \"upsert\" AS ($updateSql) $insertSql";
}
/**
* {@inheritdoc} * {@inheritdoc}
*/ */
public function update($table, $columns, $condition, &$params) public function update($table, $columns, $condition, &$params)
@ -260,8 +396,9 @@ class QueryBuilder extends \yii\db\QueryBuilder
/** /**
* Normalizes data to be saved into the table, performing extra preparations and type converting, if necessary. * Normalizes data to be saved into the table, performing extra preparations and type converting, if necessary.
*
* @param string $table the table that data will be saved into. * @param string $table the table that data will be saved into.
* @param array|\yii\db\Query $columns the column data (name => value) to be saved into the table or instance * @param array|Query $columns the column data (name => value) to be saved into the table or instance
* of [[yii\db\Query|Query]] to perform INSERT INTO ... SELECT SQL statement. * of [[yii\db\Query|Query]] to perform INSERT INTO ... SELECT SQL statement.
* Passing of [[yii\db\Query|Query]] is available since version 2.0.11. * Passing of [[yii\db\Query|Query]] is available since version 2.0.11.
* @return array normalized columns * @return array normalized columns
@ -269,7 +406,7 @@ class QueryBuilder extends \yii\db\QueryBuilder
*/ */
private function normalizeTableRowData($table, $columns) private function normalizeTableRowData($table, $columns)
{ {
if ($columns instanceof \yii\db\Query) { if ($columns instanceof Query) {
return $columns; return $columns;
} }

19
framework/db/pgsql/Schema.php

@ -10,6 +10,7 @@ namespace yii\db\pgsql;
use yii\base\NotSupportedException; use yii\base\NotSupportedException;
use yii\db\CheckConstraint; use yii\db\CheckConstraint;
use yii\db\Constraint; use yii\db\Constraint;
use yii\db\ConstraintFinderInterface;
use yii\db\ConstraintFinderTrait; use yii\db\ConstraintFinderTrait;
use yii\db\Expression; use yii\db\Expression;
use yii\db\ForeignKeyConstraint; use yii\db\ForeignKeyConstraint;
@ -25,7 +26,7 @@ use yii\helpers\ArrayHelper;
* @author Gevik Babakhani <gevikb@gmail.com> * @author Gevik Babakhani <gevikb@gmail.com>
* @since 2.0 * @since 2.0
*/ */
class Schema extends \yii\db\Schema class Schema extends \yii\db\Schema implements ConstraintFinderInterface
{ {
use ViewFinderTrait; use ViewFinderTrait;
use ConstraintFinderTrait; use ConstraintFinderTrait;
@ -124,6 +125,11 @@ class Schema extends \yii\db\Schema
'xml' => self::TYPE_STRING, 'xml' => self::TYPE_STRING,
]; ];
/**
* @inheritDoc
*/
protected $tableQuoteCharacter = '"';
/** /**
* @inheritDoc * @inheritDoc
@ -306,17 +312,6 @@ SQL;
} }
/** /**
* Quotes a table name for use in a query.
* A simple table name has no schema prefix.
* @param string $name table name
* @return string the properly quoted table name
*/
public function quoteSimpleTableName($name)
{
return strpos($name, '"') !== false ? $name : '"' . $name . '"';
}
/**
* {@inheritdoc] * {@inheritdoc]
*/ */
protected function findViewNames($schema = '') protected function findViewNames($schema = '')

50
framework/db/sqlite/QueryBuilder.php

@ -10,6 +10,8 @@ namespace yii\db\sqlite;
use yii\base\InvalidParamException; use yii\base\InvalidParamException;
use yii\base\NotSupportedException; use yii\base\NotSupportedException;
use yii\db\Connection; use yii\db\Connection;
use yii\db\Constraint;
use yii\db\Expression;
use yii\db\ExpressionInterface; use yii\db\ExpressionInterface;
use yii\db\Query; use yii\db\Query;
use yii\helpers\StringHelper; use yii\helpers\StringHelper;
@ -60,6 +62,52 @@ class QueryBuilder extends \yii\db\QueryBuilder
} }
/** /**
* @inheritdoc
* @see https://stackoverflow.com/questions/15277373/sqlite-upsert-update-or-insert/15277374#15277374
*/
public function upsert($table, $insertColumns, $updateColumns, &$params)
{
/** @var Constraint[] $constraints */
list($uniqueNames, $insertNames, $updateNames) = $this->prepareUpsertColumns($table, $insertColumns, $updateColumns, $constraints);
if (empty($uniqueNames)) {
return $this->insert($table, $insertColumns, $params);
}
list(, $placeholders, $values, $params) = $this->prepareInsertValues($table, $insertColumns, $params);
$insertSql = 'INSERT OR IGNORE INTO ' . $this->db->quoteTableName($table)
. (!empty($insertNames) ? ' (' . implode(', ', $insertNames) . ')' : '')
. (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : $values);
if ($updateColumns === false) {
return $insertSql;
}
$updateCondition = ['or'];
$quotedTableName = $this->db->quoteTableName($table);
foreach ($constraints as $constraint) {
$constraintCondition = ['and'];
foreach ($constraint->columnNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
$constraintCondition[] = "$quotedTableName.$quotedName=(SELECT $quotedName FROM `EXCLUDED`)";
}
$updateCondition[] = $constraintCondition;
}
if ($updateColumns === true) {
$updateColumns = [];
foreach ($updateNames as $name) {
$quotedName = $this->db->quoteColumnName($name);
if (strrpos($quotedName, '.') === false) {
$quotedName = "(SELECT $quotedName FROM `EXCLUDED`)";
}
$updateColumns[$name] = new Expression($quotedName);
}
}
$updateSql = 'WITH "EXCLUDED" (' . implode(', ', $insertNames)
. ') AS (' . (!empty($placeholders) ? 'VALUES (' . implode(', ', $placeholders) . ')' : ltrim($values, ' ')) . ') '
. $this->update($table, $updateColumns, $updateCondition, $params);
return "$updateSql; $insertSql;";
}
/**
* Generates a batch INSERT SQL statement. * Generates a batch INSERT SQL statement.
* *
* For example, * For example,
@ -88,7 +136,7 @@ class QueryBuilder extends \yii\db\QueryBuilder
// SQLite supports batch insert natively since 3.7.11 // SQLite supports batch insert natively since 3.7.11
// http://www.sqlite.org/releaselog/3_7_11.html // http://www.sqlite.org/releaselog/3_7_11.html
$this->db->open(); // ensure pdo is not null $this->db->open(); // ensure pdo is not null
if (version_compare($this->db->pdo->getAttribute(\PDO::ATTR_SERVER_VERSION), '3.7.11', '>=')) { if (version_compare($this->db->getServerVersion(), '3.7.11', '>=')) {
return parent::batchInsert($table, $columns, $rows); return parent::batchInsert($table, $columns, $rows);
} }

34
framework/db/sqlite/Schema.php

@ -11,6 +11,7 @@ use yii\base\NotSupportedException;
use yii\db\CheckConstraint; use yii\db\CheckConstraint;
use yii\db\ColumnSchema; use yii\db\ColumnSchema;
use yii\db\Constraint; use yii\db\Constraint;
use yii\db\ConstraintFinderInterface;
use yii\db\ConstraintFinderTrait; use yii\db\ConstraintFinderTrait;
use yii\db\Expression; use yii\db\Expression;
use yii\db\ForeignKeyConstraint; use yii\db\ForeignKeyConstraint;
@ -29,7 +30,7 @@ use yii\helpers\ArrayHelper;
* @author Qiang Xue <qiang.xue@gmail.com> * @author Qiang Xue <qiang.xue@gmail.com>
* @since 2.0 * @since 2.0
*/ */
class Schema extends \yii\db\Schema class Schema extends \yii\db\Schema implements ConstraintFinderInterface
{ {
use ConstraintFinderTrait; use ConstraintFinderTrait;
@ -67,6 +68,15 @@ class Schema extends \yii\db\Schema
'enum' => self::TYPE_STRING, 'enum' => self::TYPE_STRING,
]; ];
/**
* @inheritDoc
*/
protected $tableQuoteCharacter = '`';
/**
* @inheritDoc
*/
protected $columnQuoteCharacter = '`';
/** /**
* @inheritDoc * @inheritDoc
@ -190,28 +200,6 @@ class Schema extends \yii\db\Schema
} }
/** /**
* Quotes a table name for use in a query.
* A simple table name has no schema prefix.
* @param string $name table name
* @return string the properly quoted table name
*/
public function quoteSimpleTableName($name)
{
return strpos($name, '`') !== false ? $name : "`$name`";
}
/**
* Quotes a column name for use in a query.
* A simple column name has no prefix.
* @param string $name column name
* @return string the properly quoted column name
*/
public function quoteSimpleColumnName($name)
{
return strpos($name, '`') !== false || $name === '*' ? $name : "`$name`";
}
/**
* Creates a query builder for the MySQL database. * Creates a query builder for the MySQL database.
* This method may be overridden by child classes to create a DBMS-specific query builder. * This method may be overridden by child classes to create a DBMS-specific query builder.
* @return QueryBuilder query builder instance * @return QueryBuilder query builder instance

7
tests/IsOneOfAssert.php

@ -7,6 +7,8 @@
namespace yiiunit; namespace yiiunit;
use yii\helpers\VarDumper;
/** /**
* IsOneOfAssert asserts that the value is one of the expected values. * IsOneOfAssert asserts that the value is one of the expected values.
*/ */
@ -32,7 +34,10 @@ class IsOneOfAssert extends \PHPUnit\Framework\Constraint\Constraint
*/ */
public function toString() public function toString()
{ {
$expectedAsString = "'" . implode("', '", $this->allowedValues) . "'"; $allowedValues = array_map(function ($value) {
return VarDumper::dumpAsString($value);
}, $this->allowedValues);
$expectedAsString = implode(', ', $allowedValues);
return "is one of $expectedAsString"; return "is one of $expectedAsString";
} }

14
tests/data/cubrid.sql

@ -24,6 +24,7 @@ DROP TABLE IF EXISTS "T_constraints_4";
DROP TABLE IF EXISTS "T_constraints_3"; DROP TABLE IF EXISTS "T_constraints_3";
DROP TABLE IF EXISTS "T_constraints_2"; DROP TABLE IF EXISTS "T_constraints_2";
DROP TABLE IF EXISTS "T_constraints_1"; DROP TABLE IF EXISTS "T_constraints_1";
DROP TABLE IF EXISTS "T_upsert";
CREATE TABLE "constraints" CREATE TABLE "constraints"
( (
@ -256,3 +257,16 @@ CREATE TABLE "T_constraints_4"
"C_col_2" INT NOT NULL, "C_col_2" INT NOT NULL,
CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2") CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2")
); );
CREATE TABLE "T_upsert"
(
"id" INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
"ts" INT NULL,
"email" VARCHAR(128) NOT NULL UNIQUE,
"recovery_email" VARCHAR(128) NULL,
"address" STRING NULL,
"status" TINYINT NOT NULL DEFAULT 0,
"orders" INT NOT NULL DEFAULT 0,
"profile_id" INT NULL,
UNIQUE ("email", "recovery_email")
);

14
tests/data/mssql.sql

@ -17,6 +17,7 @@ IF OBJECT_ID('[T_constraints_4]', 'U') IS NOT NULL DROP TABLE [T_constraints_4];
IF OBJECT_ID('[T_constraints_3]', 'U') IS NOT NULL DROP TABLE [T_constraints_3]; IF OBJECT_ID('[T_constraints_3]', 'U') IS NOT NULL DROP TABLE [T_constraints_3];
IF OBJECT_ID('[T_constraints_2]', 'U') IS NOT NULL DROP TABLE [T_constraints_2]; IF OBJECT_ID('[T_constraints_2]', 'U') IS NOT NULL DROP TABLE [T_constraints_2];
IF OBJECT_ID('[T_constraints_1]', 'U') IS NOT NULL DROP TABLE [T_constraints_1]; IF OBJECT_ID('[T_constraints_1]', 'U') IS NOT NULL DROP TABLE [T_constraints_1];
IF OBJECT_ID('[T_upsert]', 'U') IS NOT NULL DROP TABLE [T_upsert];
CREATE TABLE [dbo].[profile] ( CREATE TABLE [dbo].[profile] (
[id] [int] IDENTITY NOT NULL, [id] [int] IDENTITY NOT NULL,
@ -248,3 +249,16 @@ CREATE TABLE [T_constraints_4]
[C_col_2] INT NOT NULL, [C_col_2] INT NOT NULL,
CONSTRAINT [CN_constraints_4] UNIQUE ([C_col_1], [C_col_2]) CONSTRAINT [CN_constraints_4] UNIQUE ([C_col_1], [C_col_2])
); );
CREATE TABLE [T_upsert]
(
[id] INT NOT NULL IDENTITY PRIMARY KEY,
[ts] INT NULL,
[email] VARCHAR(128) NOT NULL UNIQUE,
[recovery_email] VARCHAR(128) NULL,
[address] TEXT NULL,
[status] TINYINT NOT NULL DEFAULT 0,
[orders] INT NOT NULL DEFAULT 0,
[profile_id] INT NULL,
UNIQUE ([email], [recovery_email])
);

15
tests/data/mysql.sql

@ -25,6 +25,7 @@ DROP TABLE IF EXISTS `T_constraints_4` CASCADE;
DROP TABLE IF EXISTS `T_constraints_3` CASCADE; DROP TABLE IF EXISTS `T_constraints_3` CASCADE;
DROP TABLE IF EXISTS `T_constraints_2` CASCADE; DROP TABLE IF EXISTS `T_constraints_2` CASCADE;
DROP TABLE IF EXISTS `T_constraints_1` CASCADE; DROP TABLE IF EXISTS `T_constraints_1` CASCADE;
DROP TABLE IF EXISTS `T_upsert` CASCADE;
CREATE TABLE `constraints` CREATE TABLE `constraints`
( (
@ -305,3 +306,17 @@ CREATE TABLE `T_constraints_4`
CONSTRAINT `CN_constraints_4` UNIQUE (`C_col_1`, `C_col_2`) CONSTRAINT `CN_constraints_4` UNIQUE (`C_col_1`, `C_col_2`)
) )
ENGINE = 'InnoDB' DEFAULT CHARSET = 'utf8'; ENGINE = 'InnoDB' DEFAULT CHARSET = 'utf8';
CREATE TABLE `T_upsert`
(
`id` INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
`ts` INT NULL,
`email` VARCHAR(128) NOT NULL UNIQUE,
`recovery_email` VARCHAR(128) NULL,
`address` TEXT NULL,
`status` TINYINT NOT NULL DEFAULT 0,
`orders` INT NOT NULL DEFAULT 0,
`profile_id` INT NULL,
UNIQUE (`email`, `recovery_email`)
)
ENGINE = 'InnoDB' DEFAULT CHARSET = 'utf8';

23
tests/data/oci.sql

@ -27,6 +27,7 @@ BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_4"'; EXCEPTION WHEN OTHERS TH
BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_3"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;-- BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_3"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_2"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;-- BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_2"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_1"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;-- BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_constraints_1"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
BEGIN EXECUTE IMMEDIATE 'DROP TABLE "T_upsert"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -942 THEN RAISE; END IF; END;--
BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "profile_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;-- BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "profile_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "customer_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;-- BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "customer_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
@ -38,6 +39,7 @@ BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "null_values_SEQ"'; EXCEPTION WHEN OTHERS
BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "bool_values_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;-- BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "bool_values_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "animal_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;-- BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "animal_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "document_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;-- BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "document_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE "T_upsert_SEQ"'; EXCEPTION WHEN OTHERS THEN IF SQLCODE != -2289 THEN RAISE; END IF; END;--
/* STATEMENTS */ /* STATEMENTS */
@ -57,7 +59,7 @@ CREATE SEQUENCE "profile_SEQ";
CREATE TABLE "customer" ( CREATE TABLE "customer" (
"id" integer not null, "id" integer not null,
"email" varchar2(128) NOT NULL, "email" varchar2(128) NOT NULL UNIQUE,
"name" varchar2(128), "name" varchar2(128),
"address" varchar(4000), "address" varchar(4000),
"status" integer DEFAULT 0, "status" integer DEFAULT 0,
@ -242,6 +244,20 @@ CREATE TABLE "T_constraints_4"
CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2") CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2")
); );
CREATE TABLE "T_upsert"
(
"id" INT NOT NULL PRIMARY KEY,
"ts" INT NULL,
"email" VARCHAR(128) NOT NULL UNIQUE,
"recovery_email" VARCHAR(128) NULL,
"address" CLOB NULL,
"status" NUMBER(5,0) DEFAULT 0 NOT NULL,
"orders" INT DEFAULT 0 NOT NULL,
"profile_id" INT NULL,
CONSTRAINT "CN_T_upsert_multi" UNIQUE ("email", "recovery_email")
);
CREATE SEQUENCE "T_upsert_SEQ";
/** /**
* (Postgres-)Database Schema for validator tests * (Postgres-)Database Schema for validator tests
*/ */
@ -311,6 +327,11 @@ CREATE TRIGGER "document_TRG" BEFORE INSERT ON "document" FOR EACH ROW BEGIN <<C
END COLUMN_SEQUENCES; END COLUMN_SEQUENCES;
END; END;
/ /
CREATE TRIGGER "T_upsert_TRG" BEFORE INSERT ON "T_upsert" FOR EACH ROW BEGIN <<COLUMN_SEQUENCES>> BEGIN
IF INSERTING AND :NEW."id" IS NULL THEN SELECT "T_upsert_SEQ".NEXTVAL INTO :NEW."id" FROM SYS.DUAL; END IF;
END COLUMN_SEQUENCES;
END;
/
/* TRIGGERS */ /* TRIGGERS */

14
tests/data/postgres.sql

@ -27,6 +27,7 @@ DROP TABLE IF EXISTS "T_constraints_4";
DROP TABLE IF EXISTS "T_constraints_3"; DROP TABLE IF EXISTS "T_constraints_3";
DROP TABLE IF EXISTS "T_constraints_2"; DROP TABLE IF EXISTS "T_constraints_2";
DROP TABLE IF EXISTS "T_constraints_1"; DROP TABLE IF EXISTS "T_constraints_1";
DROP TABLE IF EXISTS "T_upsert";
DROP SCHEMA IF EXISTS "schema1" CASCADE; DROP SCHEMA IF EXISTS "schema1" CASCADE;
DROP SCHEMA IF EXISTS "schema2" CASCADE; DROP SCHEMA IF EXISTS "schema2" CASCADE;
@ -333,3 +334,16 @@ CREATE TABLE "T_constraints_4"
"C_col_2" INT NOT NULL, "C_col_2" INT NOT NULL,
CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2") CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2")
); );
CREATE TABLE "T_upsert"
(
"id" SERIAL NOT NULL PRIMARY KEY,
"ts" INT NULL,
"email" VARCHAR(128) NOT NULL UNIQUE,
"recovery_email" VARCHAR(128) NULL,
"address" TEXT NULL,
"status" SMALLINT NOT NULL DEFAULT 0,
"orders" INT NOT NULL DEFAULT 0,
"profile_id" INT NULL,
UNIQUE ("email", "recovery_email")
);

14
tests/data/sqlite.sql

@ -23,6 +23,7 @@ DROP TABLE IF EXISTS "T_constraints_4";
DROP TABLE IF EXISTS "T_constraints_3"; DROP TABLE IF EXISTS "T_constraints_3";
DROP TABLE IF EXISTS "T_constraints_2"; DROP TABLE IF EXISTS "T_constraints_2";
DROP TABLE IF EXISTS "T_constraints_1"; DROP TABLE IF EXISTS "T_constraints_1";
DROP TABLE IF EXISTS "T_upsert";
CREATE TABLE "profile" ( CREATE TABLE "profile" (
id INTEGER NOT NULL, id INTEGER NOT NULL,
@ -270,3 +271,16 @@ CREATE TABLE "T_constraints_4"
"C_col_2" INT NOT NULL, "C_col_2" INT NOT NULL,
CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2") CONSTRAINT "CN_constraints_4" UNIQUE ("C_col_1", "C_col_2")
); );
CREATE TABLE "T_upsert"
(
"id" INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
"ts" INT NULL,
"email" VARCHAR(128) NOT NULL UNIQUE,
"recovery_email" VARCHAR(128) NULL,
"address" TEXT NULL,
"status" SMALLINT NOT NULL DEFAULT 0,
"orders" INT NOT NULL DEFAULT 0,
"profile_id" INT NULL,
UNIQUE ("email", "recovery_email")
);

263
tests/framework/db/CommandTest.php

@ -12,10 +12,13 @@ use yii\db\Connection;
use yii\db\DataReader; use yii\db\DataReader;
use yii\db\Exception; use yii\db\Exception;
use yii\db\Expression; use yii\db\Expression;
use yii\db\Query;
use yii\db\Schema; use yii\db\Schema;
abstract class CommandTest extends DatabaseTestCase abstract class CommandTest extends DatabaseTestCase
{ {
protected $upsertTestCharCast = 'CAST([[address]] AS VARCHAR(255))';
public function testConstruct() public function testConstruct()
{ {
$db = $this->getConnection(false); $db = $this->getConnection(false);
@ -762,6 +765,260 @@ SQL;
$this->assertNotNull($db->getSchema()->getTableSchema($toTableName, true)); $this->assertNotNull($db->getSchema()->getTableSchema($toTableName, true));
} }
public function upsertProvider()
{
return [
'regular values' => [
[
'params' => [
'T_upsert',
[
'email' => 'foo@example.com',
'address' => 'Earth',
'status' => 3,
]
]
],
[
'params' => [
'T_upsert',
[
'email' => 'foo@example.com',
'address' => 'Universe',
'status' => 1,
]
]
],
],
'regular values with update part' => [
[
'params' => [
'T_upsert',
[
'email' => 'foo@example.com',
'address' => 'Earth',
'status' => 3,
],
[
'address' => 'Moon',
'status' => 2,
],
],
],
[
'params' => [
'T_upsert',
[
'email' => 'foo@example.com',
'address' => 'Universe',
'status' => 1,
],
[
'address' => 'Moon',
'status' => 2,
],
],
'expected' => [
'email' => 'foo@example.com',
'address' => 'Moon',
'status' => 2,
],
],
],
'regular values without update part' => [
[
'params' => [
'T_upsert',
[
'email' => 'foo@example.com',
'address' => 'Earth',
'status' => 3,
],
false,
]
],
[
'params' => [
'T_upsert',
[
'email' => 'foo@example.com',
'address' => 'Universe',
'status' => 1,
],
false,
],
'expected' => [
'email' => 'foo@example.com',
'address' => 'Earth',
'status' => 3,
],
],
],
'query' => [
[
'params' => [
'T_upsert',
(new Query())
->select([
'email',
'address',
'status' => new Expression('1'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1)
],
'expected' => [
'email' => 'user1@example.com',
'address' => 'address1',
'status' => 1,
],
],
[
'params' => [
'T_upsert',
(new Query())
->select([
'email',
'address',
'status' => new Expression('2'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1)
],
'expected' => [
'email' => 'user1@example.com',
'address' => 'address1',
'status' => 2,
],
],
],
'query with update part' => [
[
'params' => [
'T_upsert',
(new Query())
->select([
'email',
'address',
'status' => new Expression('1'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1),
[
'address' => 'Moon',
'status' => 2,
],
],
'expected' => [
'email' => 'user1@example.com',
'address' => 'address1',
'status' => 1,
],
],
[
'params' => [
'T_upsert',
(new Query())
->select([
'email',
'address',
'status' => new Expression('3'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1),
[
'address' => 'Moon',
'status' => 2,
],
],
'expected' => [
'email' => 'user1@example.com',
'address' => 'Moon',
'status' => 2,
],
],
],
'query without update part' => [
[
'params' => [
'T_upsert',
(new Query())
->select([
'email',
'address',
'status' => new Expression('1'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1),
false,
],
'expected' => [
'email' => 'user1@example.com',
'address' => 'address1',
'status' => 1,
],
],
[
'params' => [
'T_upsert',
(new Query())
->select([
'email',
'address',
'status' => new Expression('2'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1),
false,
],
'expected' => [
'email' => 'user1@example.com',
'address' => 'address1',
'status' => 1,
],
],
],
];
}
/**
* @dataProvider upsertProvider
* @param array $firstData
* @param array $secondData
*/
public function testUpsert(array $firstData, array $secondData)
{
$db = $this->getConnection();
$this->assertEquals(0, $db->createCommand('SELECT COUNT(*) FROM {{T_upsert}}')->queryScalar());
$this->performAndCompareUpsertResult($db, $firstData);
$this->assertEquals(1, $db->createCommand('SELECT COUNT(*) FROM {{T_upsert}}')->queryScalar());
$this->performAndCompareUpsertResult($db, $secondData);
}
protected function performAndCompareUpsertResult(Connection $db, array $data)
{
$params = $data['params'];
$expected = isset($data['expected']) ? $data['expected'] : $params[1];
$command = $db->createCommand();
call_user_func_array([$command, 'upsert'], $params);
$command->execute();
$actual = (new Query())
->select([
'email',
'address' => new Expression($this->upsertTestCharCast),
'status',
])
->from('T_upsert')
->one($db);
$this->assertEquals($expected, $actual);
}
/* /*
public function testUpdate() public function testUpdate()
{ {
@ -1137,9 +1394,6 @@ SQL;
$this->assertNull($db->getSchema()->getTableSchema($tableName)); $this->assertNull($db->getSchema()->getTableSchema($tableName));
} }
/**
* @group iss
*/
public function testTransaction() public function testTransaction()
{ {
$connection = $this->getConnection(false); $connection = $this->getConnection(false);
@ -1151,9 +1405,6 @@ SQL;
$this->assertEquals(1, $connection->createCommand("SELECT COUNT(*) FROM {{profile}} WHERE [[description]] = 'command transaction'")->queryScalar()); $this->assertEquals(1, $connection->createCommand("SELECT COUNT(*) FROM {{profile}} WHERE [[description]] = 'command transaction'")->queryScalar());
} }
/**
* @group iss
*/
public function testRetryHandler() public function testRetryHandler()
{ {
$connection = $this->getConnection(false); $connection = $this->getConnection(false);

223
tests/framework/db/QueryBuilderTest.php

@ -18,6 +18,7 @@ use yii\db\QueryBuilder;
use yii\db\Schema; use yii\db\Schema;
use yii\db\SchemaBuilderTrait; use yii\db\SchemaBuilderTrait;
use yii\db\sqlite\QueryBuilder as SqliteQueryBuilder; use yii\db\sqlite\QueryBuilder as SqliteQueryBuilder;
use yii\helpers\ArrayHelper;
use yiiunit\data\base\TraversableObject; use yiiunit\data\base\TraversableObject;
abstract class QueryBuilderTest extends DatabaseTestCase abstract class QueryBuilderTest extends DatabaseTestCase
@ -1870,6 +1871,228 @@ abstract class QueryBuilderTest extends DatabaseTestCase
$this->assertSame($expectedParams, $actualParams); $this->assertSame($expectedParams, $actualParams);
} }
/**
* Dummy test to speed up QB's tests which rely on DB schema
*/
public function testInitFixtures()
{
$this->assertInstanceOf('yii\db\QueryBuilder', $this->getQueryBuilder(true, true));
}
public function upsertProvider()
{
return [
'regular values' => [
'T_upsert',
[
'email' => 'test@example.com',
'address' => 'bar {{city}}',
'status' => 1,
'profile_id' => null,
],
true,
null,
[
':qp0' => 'test@example.com',
':qp1' => 'bar {{city}}',
':qp2' => 1,
':qp3' => null,
],
],
'regular values with update part' => [
'T_upsert',
[
'email' => 'test@example.com',
'address' => 'bar {{city}}',
'status' => 1,
'profile_id' => null,
],
[
'address' => 'foo {{city}}',
'status' => 2,
'orders' => new Expression('T_upsert.orders + 1'),
],
null,
[
':qp0' => 'test@example.com',
':qp1' => 'bar {{city}}',
':qp2' => 1,
':qp3' => null,
':qp4' => 'foo {{city}}',
':qp5' => 2,
],
],
'regular values without update part' => [
'T_upsert',
[
'email' => 'test@example.com',
'address' => 'bar {{city}}',
'status' => 1,
'profile_id' => null,
],
false,
null,
[
':qp0' => 'test@example.com',
':qp1' => 'bar {{city}}',
':qp2' => 1,
':qp3' => null,
],
],
'query' => [
'T_upsert',
(new Query())
->select([
'email',
'status' => new Expression('2'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1),
true,
null,
[
':qp0' => 'user1',
],
],
'query with update part' => [
'T_upsert',
(new Query())
->select([
'email',
'status' => new Expression('2'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1),
[
'address' => 'foo {{city}}',
'status' => 2,
'orders' => new Expression('T_upsert.orders + 1'),
],
null,
[
':qp0' => 'user1',
':qp1' => 'foo {{city}}',
':qp2' => 2,
],
],
'query without update part' => [
'T_upsert',
(new Query())
->select([
'email',
'status' => new Expression('2'),
])
->from('customer')
->where(['name' => 'user1'])
->limit(1),
false,
null,
[
':qp0' => 'user1',
],
],
'values and expressions' => [
'{{%T_upsert}}',
[
'{{%T_upsert}}.[[email]]' => 'dynamic@example.com',
'[[ts]]' => new Expression('now()'),
],
true,
null,
[
':qp0' => 'dynamic@example.com',
],
],
'values and expressions with update part' => [
'{{%T_upsert}}',
[
'{{%T_upsert}}.[[email]]' => 'dynamic@example.com',
'[[ts]]' => new Expression('now()'),
],
[
'[[orders]]' => new Expression('T_upsert.orders + 1'),
],
null,
[
':qp0' => 'dynamic@example.com',
],
],
'values and expressions without update part' => [
'{{%T_upsert}}',
[
'{{%T_upsert}}.[[email]]' => 'dynamic@example.com',
'[[ts]]' => new Expression('now()'),
],
false,
null,
[
':qp0' => 'dynamic@example.com',
],
],
'query, values and expressions with update part' => [
'{{%T_upsert}}',
(new Query())
->select([
'email' => new Expression(':phEmail', [':phEmail' => 'dynamic@example.com']),
'[[time]]' => new Expression('now()'),
]),
[
'ts' => 0,
'[[orders]]' => new Expression('T_upsert.orders + 1'),
],
null,
[
':phEmail' => 'dynamic@example.com',
':qp1' => 0,
],
],
'query, values and expressions without update part' => [
'{{%T_upsert}}',
(new Query())
->select([
'email' => new Expression(':phEmail', [':phEmail' => 'dynamic@example.com']),
'[[time]]' => new Expression('now()'),
]),
[
'ts' => 0,
'[[orders]]' => new Expression('T_upsert.orders + 1'),
],
null,
[
':phEmail' => 'dynamic@example.com',
':qp1' => 0,
],
],
];
}
/**
* @depends testInitFixtures
* @dataProvider upsertProvider
* @param string $table
* @param array $insertColumns
* @param array|null $updateColumns
* @param string|string[] $expectedSQL
* @param array $expectedParams
*/
public function testUpsert($table, $insertColumns, $updateColumns, $expectedSQL, $expectedParams)
{
$actualParams = [];
$actualSQL = $this->getQueryBuilder(true, $this->driverName === 'sqlite')->upsert($table, $insertColumns, $updateColumns, $actualParams);
if (is_string($expectedSQL)) {
$this->assertSame($expectedSQL, $actualSQL);
} else {
$this->assertContains($actualSQL, $expectedSQL);
}
if (ArrayHelper::isAssociative($expectedParams)) {
$this->assertSame($expectedParams, $actualParams);
} else {
$this->assertIsOneOf($actualParams, $expectedParams);
}
}
public function batchInsertProvider() public function batchInsertProvider()
{ {
return [ return [

44
tests/framework/db/cubrid/QueryBuilderTest.php

@ -65,4 +65,48 @@ class QueryBuilderTest extends \yiiunit\framework\db\QueryBuilderTest
parent::testCommentColumn(); parent::testCommentColumn();
} }
public function upsertProvider()
{
$concreteData = [
'regular values' => [
3 => 'MERGE INTO "T_upsert" USING (VALUES (:qp0, :qp1, :qp2, :qp3)) AS "EXCLUDED" ("email", "address", "status", "profile_id") ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "address"="EXCLUDED"."address", "status"="EXCLUDED"."status", "profile_id"="EXCLUDED"."profile_id" WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")',
],
'regular values with update part' => [
3 => 'MERGE INTO "T_upsert" USING (VALUES (:qp0, :qp1, :qp2, :qp3)) AS "EXCLUDED" ("email", "address", "status", "profile_id") ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "address"=:qp4, "status"=:qp5, "orders"=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")',
],
'regular values without update part' => [
3 => 'MERGE INTO "T_upsert" USING (VALUES (:qp0, :qp1, :qp2, :qp3)) AS "EXCLUDED" ("email", "address", "status", "profile_id") ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")',
],
'query' => [
3 => 'MERGE INTO "T_upsert" USING (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1) AS "EXCLUDED" ("email", "status") ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "status"="EXCLUDED"."status" WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")',
],
'query with update part' => [
3 => 'MERGE INTO "T_upsert" USING (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1) AS "EXCLUDED" ("email", "status") ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "address"=:qp1, "status"=:qp2, "orders"=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")',
],
'query without update part' => [
3 => 'MERGE INTO "T_upsert" USING (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1) AS "EXCLUDED" ("email", "status") ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")',
],
'values and expressions' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions with update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions without update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'query, values and expressions with update part' => [
3 => 'MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", now() AS [[time]]) AS "EXCLUDED" ("email", [[time]]) ON (({{%T_upsert}}."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", [[time]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[time]])',
],
'query, values and expressions without update part' => [
3 => 'MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", now() AS [[time]]) AS "EXCLUDED" ("email", [[time]]) ON (({{%T_upsert}}."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", [[time]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[time]])',
],
];
$newData = parent::upsertProvider();
foreach ($concreteData as $testName => $data) {
$newData[$testName] = array_replace($newData[$testName], $data);
}
return $newData;
}
} }

44
tests/framework/db/mssql/QueryBuilderTest.php

@ -125,4 +125,48 @@ class QueryBuilderTest extends \yiiunit\framework\db\QueryBuilderTest
$sql = $qb->resetSequence('item', 4); $sql = $qb->resetSequence('item', 4);
$this->assertEquals($expected, $sql); $this->assertEquals($expected, $sql);
} }
public function upsertProvider()
{
$concreteData = [
'regular values' => [
3 => 'MERGE [T_upsert] WITH (HOLDLOCK) USING (VALUES (:qp0, :qp1, :qp2, :qp3)) AS [EXCLUDED] ([email], [address], [status], [profile_id]) ON (([T_upsert].[email]=[EXCLUDED].[email])) WHEN MATCHED THEN UPDATE SET [address]=[EXCLUDED].[address], [status]=[EXCLUDED].[status], [profile_id]=[EXCLUDED].[profile_id] WHEN NOT MATCHED THEN INSERT ([email], [address], [status], [profile_id]) VALUES ([EXCLUDED].[email], [EXCLUDED].[address], [EXCLUDED].[status], [EXCLUDED].[profile_id]);',
],
'regular values with update part' => [
3 => 'MERGE [T_upsert] WITH (HOLDLOCK) USING (VALUES (:qp0, :qp1, :qp2, :qp3)) AS [EXCLUDED] ([email], [address], [status], [profile_id]) ON (([T_upsert].[email]=[EXCLUDED].[email])) WHEN MATCHED THEN UPDATE SET [address]=:qp4, [status]=:qp5, [orders]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ([email], [address], [status], [profile_id]) VALUES ([EXCLUDED].[email], [EXCLUDED].[address], [EXCLUDED].[status], [EXCLUDED].[profile_id]);',
],
'regular values without update part' => [
3 => 'MERGE [T_upsert] WITH (HOLDLOCK) USING (VALUES (:qp0, :qp1, :qp2, :qp3)) AS [EXCLUDED] ([email], [address], [status], [profile_id]) ON (([T_upsert].[email]=[EXCLUDED].[email])) WHEN NOT MATCHED THEN INSERT ([email], [address], [status], [profile_id]) VALUES ([EXCLUDED].[email], [EXCLUDED].[address], [EXCLUDED].[status], [EXCLUDED].[profile_id]);',
],
'query' => [
3 => 'MERGE [T_upsert] WITH (HOLDLOCK) USING (SELECT [email], 2 AS [status] FROM [customer] WHERE [name]=:qp0 ORDER BY (SELECT NULL) OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY) AS [EXCLUDED] ([email], [status]) ON (([T_upsert].[email]=[EXCLUDED].[email])) WHEN MATCHED THEN UPDATE SET [status]=[EXCLUDED].[status] WHEN NOT MATCHED THEN INSERT ([email], [status]) VALUES ([EXCLUDED].[email], [EXCLUDED].[status]);',
],
'query with update part' => [
3 => 'MERGE [T_upsert] WITH (HOLDLOCK) USING (SELECT [email], 2 AS [status] FROM [customer] WHERE [name]=:qp0 ORDER BY (SELECT NULL) OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY) AS [EXCLUDED] ([email], [status]) ON (([T_upsert].[email]=[EXCLUDED].[email])) WHEN MATCHED THEN UPDATE SET [address]=:qp1, [status]=:qp2, [orders]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ([email], [status]) VALUES ([EXCLUDED].[email], [EXCLUDED].[status]);',
],
'query without update part' => [
3 => 'MERGE [T_upsert] WITH (HOLDLOCK) USING (SELECT [email], 2 AS [status] FROM [customer] WHERE [name]=:qp0 ORDER BY (SELECT NULL) OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY) AS [EXCLUDED] ([email], [status]) ON (([T_upsert].[email]=[EXCLUDED].[email])) WHEN NOT MATCHED THEN INSERT ([email], [status]) VALUES ([EXCLUDED].[email], [EXCLUDED].[status]);',
],
'values and expressions' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions with update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions without update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'query, values and expressions with update part' => [
3 => 'MERGE {{%T_upsert}} WITH (HOLDLOCK) USING (SELECT :phEmail AS [email], now() AS [[time]]) AS [EXCLUDED] ([email], [[time]]) ON (({{%T_upsert}}.[email]=[EXCLUDED].[email])) WHEN MATCHED THEN UPDATE SET [ts]=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ([email], [[time]]) VALUES ([EXCLUDED].[email], [EXCLUDED].[[time]]);',
],
'query, values and expressions without update part' => [
3 => 'MERGE {{%T_upsert}} WITH (HOLDLOCK) USING (SELECT :phEmail AS [email], now() AS [[time]]) AS [EXCLUDED] ([email], [[time]]) ON (({{%T_upsert}}.[email]=[EXCLUDED].[email])) WHEN MATCHED THEN UPDATE SET [ts]=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ([email], [[time]]) VALUES ([EXCLUDED].[email], [EXCLUDED].[[time]]);',
],
];
$newData = parent::upsertProvider();
foreach ($concreteData as $testName => $data) {
$newData[$testName] = array_replace($newData[$testName], $data);
}
return $newData;
}
} }

2
tests/framework/db/mysql/CommandTest.php

@ -15,6 +15,8 @@ class CommandTest extends \yiiunit\framework\db\CommandTest
{ {
public $driverName = 'mysql'; public $driverName = 'mysql';
protected $upsertTestCharCast = 'CONVERT([[address]], CHAR)';
public function testAddDropCheck() public function testAddDropCheck()
{ {
$this->markTestSkipped('MySQL does not support adding/dropping check constraints.'); $this->markTestSkipped('MySQL does not support adding/dropping check constraints.');

44
tests/framework/db/mysql/QueryBuilderTest.php

@ -137,6 +137,50 @@ class QueryBuilderTest extends \yiiunit\framework\db\QueryBuilderTest
$this->assertEquals($expected, $sql); $this->assertEquals($expected, $sql);
} }
public function upsertProvider()
{
$concreteData = [
'regular values' => [
3 => 'INSERT INTO `T_upsert` (`email`, `address`, `status`, `profile_id`) VALUES (:qp0, :qp1, :qp2, :qp3) ON DUPLICATE KEY UPDATE `address`=VALUES(`address`), `status`=VALUES(`status`), `profile_id`=VALUES(`profile_id`)',
],
'regular values with update part' => [
3 => 'INSERT INTO `T_upsert` (`email`, `address`, `status`, `profile_id`) VALUES (:qp0, :qp1, :qp2, :qp3) ON DUPLICATE KEY UPDATE `address`=:qp4, `status`=:qp5, `orders`=T_upsert.orders + 1',
],
'regular values without update part' => [
3 => 'INSERT INTO `T_upsert` (`email`, `address`, `status`, `profile_id`) VALUES (:qp0, :qp1, :qp2, :qp3) ON DUPLICATE KEY UPDATE `email`=`T_upsert`.`email`',
],
'query' => [
3 => 'INSERT INTO `T_upsert` (`email`, `status`) SELECT `email`, 2 AS `status` FROM `customer` WHERE `name`=:qp0 LIMIT 1 ON DUPLICATE KEY UPDATE `status`=VALUES(`status`)',
],
'query with update part' => [
3 => 'INSERT INTO `T_upsert` (`email`, `status`) SELECT `email`, 2 AS `status` FROM `customer` WHERE `name`=:qp0 LIMIT 1 ON DUPLICATE KEY UPDATE `address`=:qp1, `status`=:qp2, `orders`=T_upsert.orders + 1',
],
'query without update part' => [
3 => 'INSERT INTO `T_upsert` (`email`, `status`) SELECT `email`, 2 AS `status` FROM `customer` WHERE `name`=:qp0 LIMIT 1 ON DUPLICATE KEY UPDATE `email`=`T_upsert`.`email`',
],
'values and expressions' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions with update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions without update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'query, values and expressions with update part' => [
3 => 'INSERT INTO {{%T_upsert}} (`email`, [[time]]) SELECT :phEmail AS `email`, now() AS [[time]] ON DUPLICATE KEY UPDATE `ts`=:qp1, [[orders]]=T_upsert.orders + 1',
],
'query, values and expressions without update part' => [
3 => 'INSERT INTO {{%T_upsert}} (`email`, [[time]]) SELECT :phEmail AS `email`, now() AS [[time]] ON DUPLICATE KEY UPDATE `ts`=:qp1, [[orders]]=T_upsert.orders + 1',
],
];
$newData = parent::upsertProvider();
foreach ($concreteData as $testName => $data) {
$newData[$testName] = array_replace($newData[$testName], $data);
}
return $newData;
}
public function conditionProvider() public function conditionProvider()
{ {
return array_merge(parent::conditionProvider(), [ return array_merge(parent::conditionProvider(), [

56
tests/framework/db/oci/QueryBuilderTest.php

@ -180,4 +180,60 @@ class QueryBuilderTest extends \yiiunit\framework\db\QueryBuilderTest
return $items; return $items;
} }
public function upsertProvider()
{
$concreteData = [
'regular values' => [
3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "address"="EXCLUDED"."address", "status"="EXCLUDED"."status", "profile_id"="EXCLUDED"."profile_id" WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")',
],
'regular values with update part' => [
3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "address"=:qp4, "status"=:qp5, "orders"=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")',
],
'regular values without update part' => [
3 => 'MERGE INTO "T_upsert" USING (SELECT :qp0 AS "email", :qp1 AS "address", :qp2 AS "status", :qp3 AS "profile_id" FROM "DUAL") "EXCLUDED" ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN NOT MATCHED THEN INSERT ("email", "address", "status", "profile_id") VALUES ("EXCLUDED"."email", "EXCLUDED"."address", "EXCLUDED"."status", "EXCLUDED"."profile_id")',
],
'query' => [
3 => 'MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0),
PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL)
SELECT *
FROM PAGINATION
WHERE rownum <= 1) "EXCLUDED" ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "status"="EXCLUDED"."status" WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")',
],
'query with update part' => [
3 => 'MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0),
PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL)
SELECT *
FROM PAGINATION
WHERE rownum <= 1) "EXCLUDED" ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "address"=:qp1, "status"=:qp2, "orders"=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")',
],
'query without update part' => [
3 => 'MERGE INTO "T_upsert" USING (WITH USER_SQL AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0),
PAGINATION AS (SELECT USER_SQL.*, rownum as rowNumId FROM USER_SQL)
SELECT *
FROM PAGINATION
WHERE rownum <= 1) "EXCLUDED" ON (("T_upsert"."email"="EXCLUDED"."email")) WHEN NOT MATCHED THEN INSERT ("email", "status") VALUES ("EXCLUDED"."email", "EXCLUDED"."status")',
],
'values and expressions' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions with update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions without update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'query, values and expressions with update part' => [
3 => 'MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", now() AS [[time]]) "EXCLUDED" ON (({{%T_upsert}}."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", [[time]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[time]])',
],
'query, values and expressions without update part' => [
3 => 'MERGE INTO {{%T_upsert}} USING (SELECT :phEmail AS "email", now() AS [[time]]) "EXCLUDED" ON (({{%T_upsert}}."email"="EXCLUDED"."email")) WHEN MATCHED THEN UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 WHEN NOT MATCHED THEN INSERT ("email", [[time]]) VALUES ("EXCLUDED"."email", "EXCLUDED".[[time]])',
],
];
$newData = parent::upsertProvider();
foreach ($concreteData as $testName => $data) {
$newData[$testName] = array_replace($newData[$testName], $data);
}
return $newData;
}
} }

94
tests/framework/db/pgsql/QueryBuilderTest.php

@ -237,4 +237,98 @@ class QueryBuilderTest extends \yiiunit\framework\db\QueryBuilderTest
$sql = $qb->resetSequence('item', 4); $sql = $qb->resetSequence('item', 4);
$this->assertEquals($expected, $sql); $this->assertEquals($expected, $sql);
} }
public function upsertProvider()
{
$concreteData = [
'regular values' => [
3 => [
'WITH "EXCLUDED" ("email", "address", "status", "profile_id") AS (VALUES (CAST(:qp0 AS varchar), CAST(:qp1 AS text), CAST(:qp2 AS int2), CAST(:qp3 AS int4))), "upsert" AS (UPDATE "T_upsert" SET "address"="EXCLUDED"."address", "status"="EXCLUDED"."status", "profile_id"="EXCLUDED"."profile_id" FROM "EXCLUDED" WHERE (("T_upsert"."email"="EXCLUDED"."email")) RETURNING "T_upsert".*) INSERT INTO "T_upsert" ("email", "address", "status", "profile_id") SELECT "email", "address", "status", "profile_id" FROM "EXCLUDED" WHERE NOT EXISTS (SELECT 1 FROM "upsert" WHERE (("upsert"."email"="EXCLUDED"."email")))',
'INSERT INTO "T_upsert" ("email", "address", "status", "profile_id") VALUES (:qp0, :qp1, :qp2, :qp3) ON CONFLICT ("email") DO UPDATE SET "address"=EXCLUDED."address", "status"=EXCLUDED."status", "profile_id"=EXCLUDED."profile_id"',
],
4 => [
[
':qp0' => 'test@example.com',
':qp1' => 'bar {{city}}',
':qp2' => 1,
':qp3' => null,
],
],
],
'regular values with update part' => [
3 => [
'WITH "EXCLUDED" ("email", "address", "status", "profile_id") AS (VALUES (CAST(:qp0 AS varchar), CAST(:qp1 AS text), CAST(:qp2 AS int2), CAST(:qp3 AS int4))), "upsert" AS (UPDATE "T_upsert" SET "address"=:qp4, "status"=:qp5, "orders"=T_upsert.orders + 1 FROM "EXCLUDED" WHERE (("T_upsert"."email"="EXCLUDED"."email")) RETURNING "T_upsert".*) INSERT INTO "T_upsert" ("email", "address", "status", "profile_id") SELECT "email", "address", "status", "profile_id" FROM "EXCLUDED" WHERE NOT EXISTS (SELECT 1 FROM "upsert" WHERE (("upsert"."email"="EXCLUDED"."email")))',
'INSERT INTO "T_upsert" ("email", "address", "status", "profile_id") VALUES (:qp0, :qp1, :qp2, :qp3) ON CONFLICT ("email") DO UPDATE SET "address"=:qp4, "status"=:qp5, "orders"=T_upsert.orders + 1',
],
4 => [
[
':qp0' => 'test@example.com',
':qp1' => 'bar {{city}}',
':qp2' => 1,
':qp3' => null,
':qp4' => 'foo {{city}}',
':qp5' => 2,
],
],
],
'regular values without update part' => [
3 => [
'WITH "EXCLUDED" ("email", "address", "status", "profile_id") AS (VALUES (CAST(:qp0 AS varchar), CAST(:qp1 AS text), CAST(:qp2 AS int2), CAST(:qp3 AS int4))) INSERT INTO "T_upsert" ("email", "address", "status", "profile_id") SELECT "email", "address", "status", "profile_id" FROM "EXCLUDED" WHERE NOT EXISTS (SELECT 1 FROM "T_upsert" WHERE (("T_upsert"."email"="EXCLUDED"."email")))',
'INSERT INTO "T_upsert" ("email", "address", "status", "profile_id") VALUES (:qp0, :qp1, :qp2, :qp3) ON CONFLICT DO NOTHING',
],
4 => [
[
':qp0' => 'test@example.com',
':qp1' => 'bar {{city}}',
':qp2' => 1,
':qp3' => null,
],
],
],
'query' => [
3 => [
'WITH "EXCLUDED" ("email", "status") AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1), "upsert" AS (UPDATE "T_upsert" SET "status"="EXCLUDED"."status" FROM "EXCLUDED" WHERE (("T_upsert"."email"="EXCLUDED"."email")) RETURNING "T_upsert".*) INSERT INTO "T_upsert" ("email", "status") SELECT "email", "status" FROM "EXCLUDED" WHERE NOT EXISTS (SELECT 1 FROM "upsert" WHERE (("upsert"."email"="EXCLUDED"."email")))',
'INSERT INTO "T_upsert" ("email", "status") SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1 ON CONFLICT ("email") DO UPDATE SET "status"=EXCLUDED."status"',
],
],
'query with update part' => [
3 => [
'WITH "EXCLUDED" ("email", "status") AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1), "upsert" AS (UPDATE "T_upsert" SET "address"=:qp1, "status"=:qp2, "orders"=T_upsert.orders + 1 FROM "EXCLUDED" WHERE (("T_upsert"."email"="EXCLUDED"."email")) RETURNING "T_upsert".*) INSERT INTO "T_upsert" ("email", "status") SELECT "email", "status" FROM "EXCLUDED" WHERE NOT EXISTS (SELECT 1 FROM "upsert" WHERE (("upsert"."email"="EXCLUDED"."email")))',
'INSERT INTO "T_upsert" ("email", "status") SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1 ON CONFLICT ("email") DO UPDATE SET "address"=:qp1, "status"=:qp2, "orders"=T_upsert.orders + 1',
],
],
'query without update part' => [
3 => [
'WITH "EXCLUDED" ("email", "status") AS (SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1) INSERT INTO "T_upsert" ("email", "status") SELECT "email", "status" FROM "EXCLUDED" WHERE NOT EXISTS (SELECT 1 FROM "T_upsert" WHERE (("T_upsert"."email"="EXCLUDED"."email")))',
'INSERT INTO "T_upsert" ("email", "status") SELECT "email", 2 AS "status" FROM "customer" WHERE "name"=:qp0 LIMIT 1 ON CONFLICT DO NOTHING',
],
],
'values and expressions' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions with update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions without update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'query, values and expressions with update part' => [
3 => [
'WITH "EXCLUDED" ("email", [[time]]) AS (SELECT :phEmail AS "email", now() AS [[time]]), "upsert" AS (UPDATE {{%T_upsert}} SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 FROM "EXCLUDED" WHERE (({{%T_upsert}}."email"="EXCLUDED"."email")) RETURNING {{%T_upsert}}.*) INSERT INTO {{%T_upsert}} ("email", [[time]]) SELECT "email", [[time]] FROM "EXCLUDED" WHERE NOT EXISTS (SELECT 1 FROM "upsert" WHERE (("upsert"."email"="EXCLUDED"."email")))',
'INSERT INTO {{%T_upsert}} ("email", [[time]]) SELECT :phEmail AS "email", now() AS [[time]] ON CONFLICT ("email") DO UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1',
],
],
'query, values and expressions without update part' => [
3 => [
'WITH "EXCLUDED" ("email", [[time]]) AS (SELECT :phEmail AS "email", now() AS [[time]]), "upsert" AS (UPDATE {{%T_upsert}} SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1 FROM "EXCLUDED" WHERE (({{%T_upsert}}."email"="EXCLUDED"."email")) RETURNING {{%T_upsert}}.*) INSERT INTO {{%T_upsert}} ("email", [[time]]) SELECT "email", [[time]] FROM "EXCLUDED" WHERE NOT EXISTS (SELECT 1 FROM "upsert" WHERE (("upsert"."email"="EXCLUDED"."email")))',
'INSERT INTO {{%T_upsert}} ("email", [[time]]) SELECT :phEmail AS "email", now() AS [[time]] ON CONFLICT ("email") DO UPDATE SET "ts"=:qp1, [[orders]]=T_upsert.orders + 1',
],
],
];
$newData = parent::upsertProvider();
foreach ($concreteData as $testName => $data) {
$newData[$testName] = array_replace($newData[$testName], $data);
}
return $newData;
}
} }

15
tests/framework/db/sqlite/CommandTest.php

@ -24,6 +24,21 @@ class CommandTest extends \yiiunit\framework\db\CommandTest
$this->assertEquals('SELECT `id`, `t`.`name` FROM `customer` t', $command->sql); $this->assertEquals('SELECT `id`, `t`.`name` FROM `customer` t', $command->sql);
} }
/**
* @dataProvider upsertProvider
* @param array $firstData
* @param array $secondData
*/
public function testUpsert(array $firstData, array $secondData)
{
if (version_compare($this->getConnection(false)->getServerVersion(), '3.8.3', '<')) {
$this->markTestSkipped('SQLite < 3.8.3 does nt support "WITH" keyword.');
return;
}
parent::testUpsert($firstData, $secondData);
}
public function testAddDropPrimaryKey() public function testAddDropPrimaryKey()
{ {
$this->markTestSkipped('SQLite does not support adding/dropping primary keys.'); $this->markTestSkipped('SQLite does not support adding/dropping primary keys.');

44
tests/framework/db/sqlite/QueryBuilderTest.php

@ -155,4 +155,48 @@ class QueryBuilderTest extends \yiiunit\framework\db\QueryBuilderTest
$sql = $qb->resetSequence('item', 4); $sql = $qb->resetSequence('item', 4);
$this->assertEquals($expected, $sql); $this->assertEquals($expected, $sql);
} }
public function upsertProvider()
{
$concreteData = [
'regular values' => [
3 => 'WITH "EXCLUDED" (`email`, `address`, `status`, `profile_id`) AS (VALUES (:qp0, :qp1, :qp2, :qp3)) UPDATE `T_upsert` SET `address`=(SELECT `address` FROM `EXCLUDED`), `status`=(SELECT `status` FROM `EXCLUDED`), `profile_id`=(SELECT `profile_id` FROM `EXCLUDED`) WHERE ((`T_upsert`.`email`=(SELECT `email` FROM `EXCLUDED`))); INSERT OR IGNORE INTO `T_upsert` (`email`, `address`, `status`, `profile_id`) VALUES (:qp0, :qp1, :qp2, :qp3);',
],
'regular values with update part' => [
3 => 'WITH "EXCLUDED" (`email`, `address`, `status`, `profile_id`) AS (VALUES (:qp0, :qp1, :qp2, :qp3)) UPDATE `T_upsert` SET `address`=:qp4, `status`=:qp5, `orders`=T_upsert.orders + 1 WHERE ((`T_upsert`.`email`=(SELECT `email` FROM `EXCLUDED`))); INSERT OR IGNORE INTO `T_upsert` (`email`, `address`, `status`, `profile_id`) VALUES (:qp0, :qp1, :qp2, :qp3);',
],
'regular values without update part' => [
3 => 'INSERT OR IGNORE INTO `T_upsert` (`email`, `address`, `status`, `profile_id`) VALUES (:qp0, :qp1, :qp2, :qp3)',
],
'query' => [
3 => 'WITH "EXCLUDED" (`email`, `status`) AS (SELECT `email`, 2 AS `status` FROM `customer` WHERE `name`=:qp0 LIMIT 1) UPDATE `T_upsert` SET `status`=(SELECT `status` FROM `EXCLUDED`) WHERE ((`T_upsert`.`email`=(SELECT `email` FROM `EXCLUDED`))); INSERT OR IGNORE INTO `T_upsert` (`email`, `status`) SELECT `email`, 2 AS `status` FROM `customer` WHERE `name`=:qp0 LIMIT 1;',
],
'query with update part' => [
3 => 'WITH "EXCLUDED" (`email`, `status`) AS (SELECT `email`, 2 AS `status` FROM `customer` WHERE `name`=:qp0 LIMIT 1) UPDATE `T_upsert` SET `address`=:qp1, `status`=:qp2, `orders`=T_upsert.orders + 1 WHERE ((`T_upsert`.`email`=(SELECT `email` FROM `EXCLUDED`))); INSERT OR IGNORE INTO `T_upsert` (`email`, `status`) SELECT `email`, 2 AS `status` FROM `customer` WHERE `name`=:qp0 LIMIT 1;',
],
'query without update part' => [
3 => 'INSERT OR IGNORE INTO `T_upsert` (`email`, `status`) SELECT `email`, 2 AS `status` FROM `customer` WHERE `name`=:qp0 LIMIT 1',
],
'values and expressions' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions with update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'values and expressions without update part' => [
3 => 'INSERT INTO {{%T_upsert}} ({{%T_upsert}}.[[email]], [[ts]]) VALUES (:qp0, now())',
],
'query, values and expressions with update part' => [
3 => 'WITH "EXCLUDED" (`email`, [[time]]) AS (SELECT :phEmail AS `email`, now() AS [[time]]) UPDATE {{%T_upsert}} SET `ts`=:qp1, [[orders]]=T_upsert.orders + 1 WHERE (({{%T_upsert}}.`email`=(SELECT `email` FROM `EXCLUDED`))); INSERT OR IGNORE INTO {{%T_upsert}} (`email`, [[time]]) SELECT :phEmail AS `email`, now() AS [[time]];',
],
'query, values and expressions without update part' => [
3 => 'WITH "EXCLUDED" (`email`, [[time]]) AS (SELECT :phEmail AS `email`, now() AS [[time]]) UPDATE {{%T_upsert}} SET `ts`=:qp1, [[orders]]=T_upsert.orders + 1 WHERE (({{%T_upsert}}.`email`=(SELECT `email` FROM `EXCLUDED`))); INSERT OR IGNORE INTO {{%T_upsert}} (`email`, [[time]]) SELECT :phEmail AS `email`, now() AS [[time]];',
],
];
$newData = parent::upsertProvider();
foreach ($concreteData as $testName => $data) {
$newData[$testName] = array_replace($newData[$testName], $data);
}
return $newData;
}
} }

Loading…
Cancel
Save