QueryBuilder.php 26 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639
  1. <?php
  2. /**
  3. * @link http://www.yiiframework.com/
  4. * @copyright Copyright (c) 2008 Yii Software LLC
  5. * @license http://www.yiiframework.com/license/
  6. */
  7. namespace yii\db\mssql;
  8. use yii\base\InvalidArgumentException;
  9. use yii\base\NotSupportedException;
  10. use yii\db\Constraint;
  11. use yii\db\Expression;
  12. /**
  13. * QueryBuilder is the query builder for MS SQL Server databases (version 2008 and above).
  14. *
  15. * @author Timur Ruziev <resurtm@gmail.com>
  16. * @since 2.0
  17. */
  18. class QueryBuilder extends \yii\db\QueryBuilder
  19. {
  20. /**
  21. * @var array mapping from abstract column types (keys) to physical column types (values).
  22. */
  23. public $typeMap = [
  24. Schema::TYPE_PK => 'int IDENTITY PRIMARY KEY',
  25. Schema::TYPE_UPK => 'int IDENTITY PRIMARY KEY',
  26. Schema::TYPE_BIGPK => 'bigint IDENTITY PRIMARY KEY',
  27. Schema::TYPE_UBIGPK => 'bigint IDENTITY PRIMARY KEY',
  28. Schema::TYPE_CHAR => 'nchar(1)',
  29. Schema::TYPE_STRING => 'nvarchar(255)',
  30. Schema::TYPE_TEXT => 'nvarchar(max)',
  31. Schema::TYPE_TINYINT => 'tinyint',
  32. Schema::TYPE_SMALLINT => 'smallint',
  33. Schema::TYPE_INTEGER => 'int',
  34. Schema::TYPE_BIGINT => 'bigint',
  35. Schema::TYPE_FLOAT => 'float',
  36. Schema::TYPE_DOUBLE => 'float',
  37. Schema::TYPE_DECIMAL => 'decimal(18,0)',
  38. Schema::TYPE_DATETIME => 'datetime',
  39. Schema::TYPE_TIMESTAMP => 'datetime',
  40. Schema::TYPE_TIME => 'time',
  41. Schema::TYPE_DATE => 'date',
  42. Schema::TYPE_BINARY => 'varbinary(max)',
  43. Schema::TYPE_BOOLEAN => 'bit',
  44. Schema::TYPE_MONEY => 'decimal(19,4)',
  45. ];
  46. /**
  47. * {@inheritdoc}
  48. */
  49. protected function defaultExpressionBuilders()
  50. {
  51. return array_merge(parent::defaultExpressionBuilders(), [
  52. 'yii\db\conditions\InCondition' => 'yii\db\mssql\conditions\InConditionBuilder',
  53. 'yii\db\conditions\LikeCondition' => 'yii\db\mssql\conditions\LikeConditionBuilder',
  54. ]);
  55. }
  56. /**
  57. * {@inheritdoc}
  58. */
  59. public function buildOrderByAndLimit($sql, $orderBy, $limit, $offset)
  60. {
  61. if (!$this->hasOffset($offset) && !$this->hasLimit($limit)) {
  62. $orderBy = $this->buildOrderBy($orderBy);
  63. return $orderBy === '' ? $sql : $sql . $this->separator . $orderBy;
  64. }
  65. if (version_compare($this->db->getSchema()->getServerVersion(), '11', '<')) {
  66. return $this->oldBuildOrderByAndLimit($sql, $orderBy, $limit, $offset);
  67. }
  68. return $this->newBuildOrderByAndLimit($sql, $orderBy, $limit, $offset);
  69. }
  70. /**
  71. * Builds the ORDER BY/LIMIT/OFFSET clauses for SQL SERVER 2012 or newer.
  72. * @param string $sql the existing SQL (without ORDER BY/LIMIT/OFFSET)
  73. * @param array $orderBy the order by columns. See [[\yii\db\Query::orderBy]] for more details on how to specify this parameter.
  74. * @param int $limit the limit number. See [[\yii\db\Query::limit]] for more details.
  75. * @param int $offset the offset number. See [[\yii\db\Query::offset]] for more details.
  76. * @return string the SQL completed with ORDER BY/LIMIT/OFFSET (if any)
  77. */
  78. protected function newBuildOrderByAndLimit($sql, $orderBy, $limit, $offset)
  79. {
  80. $orderBy = $this->buildOrderBy($orderBy);
  81. if ($orderBy === '') {
  82. // ORDER BY clause is required when FETCH and OFFSET are in the SQL
  83. $orderBy = 'ORDER BY (SELECT NULL)';
  84. }
  85. $sql .= $this->separator . $orderBy;
  86. // http://technet.microsoft.com/en-us/library/gg699618.aspx
  87. $offset = $this->hasOffset($offset) ? $offset : '0';
  88. $sql .= $this->separator . "OFFSET $offset ROWS";
  89. if ($this->hasLimit($limit)) {
  90. $sql .= $this->separator . "FETCH NEXT $limit ROWS ONLY";
  91. }
  92. return $sql;
  93. }
  94. /**
  95. * Builds the ORDER BY/LIMIT/OFFSET clauses for SQL SERVER 2005 to 2008.
  96. * @param string $sql the existing SQL (without ORDER BY/LIMIT/OFFSET)
  97. * @param array $orderBy the order by columns. See [[\yii\db\Query::orderBy]] for more details on how to specify this parameter.
  98. * @param int $limit the limit number. See [[\yii\db\Query::limit]] for more details.
  99. * @param int $offset the offset number. See [[\yii\db\Query::offset]] for more details.
  100. * @return string the SQL completed with ORDER BY/LIMIT/OFFSET (if any)
  101. */
  102. protected function oldBuildOrderByAndLimit($sql, $orderBy, $limit, $offset)
  103. {
  104. $orderBy = $this->buildOrderBy($orderBy);
  105. if ($orderBy === '') {
  106. // ROW_NUMBER() requires an ORDER BY clause
  107. $orderBy = 'ORDER BY (SELECT NULL)';
  108. }
  109. $sql = preg_replace('/^([\s(])*SELECT(\s+DISTINCT)?(?!\s*TOP\s*\()/i', "\\1SELECT\\2 rowNum = ROW_NUMBER() over ($orderBy),", $sql);
  110. if ($this->hasLimit($limit)) {
  111. $sql = "SELECT TOP $limit * FROM ($sql) sub";
  112. } else {
  113. $sql = "SELECT * FROM ($sql) sub";
  114. }
  115. if ($this->hasOffset($offset)) {
  116. $sql .= $this->separator . "WHERE rowNum > $offset";
  117. }
  118. return $sql;
  119. }
  120. /**
  121. * Builds a SQL statement for renaming a DB table.
  122. * @param string $oldName the table to be renamed. The name will be properly quoted by the method.
  123. * @param string $newName the new table name. The name will be properly quoted by the method.
  124. * @return string the SQL statement for renaming a DB table.
  125. */
  126. public function renameTable($oldName, $newName)
  127. {
  128. return 'sp_rename ' . $this->db->quoteTableName($oldName) . ', ' . $this->db->quoteTableName($newName);
  129. }
  130. /**
  131. * Builds a SQL statement for renaming a column.
  132. * @param string $table the table whose column is to be renamed. The name will be properly quoted by the method.
  133. * @param string $oldName the old name of the column. The name will be properly quoted by the method.
  134. * @param string $newName the new name of the column. The name will be properly quoted by the method.
  135. * @return string the SQL statement for renaming a DB column.
  136. */
  137. public function renameColumn($table, $oldName, $newName)
  138. {
  139. $table = $this->db->quoteTableName($table);
  140. $oldName = $this->db->quoteColumnName($oldName);
  141. $newName = $this->db->quoteColumnName($newName);
  142. return "sp_rename '{$table}.{$oldName}', {$newName}, 'COLUMN'";
  143. }
  144. /**
  145. * Builds a SQL statement for changing the definition of a column.
  146. * @param string $table the table whose column is to be changed. The table name will be properly quoted by the method.
  147. * @param string $column the name of the column to be changed. The name will be properly quoted by the method.
  148. * @param string $type the new column type. The [[getColumnType]] method will be invoked to convert abstract column type (if any)
  149. * into the physical one. Anything that is not recognized as abstract type will be kept in the generated SQL.
  150. * For example, 'string' will be turned into 'varchar(255)', while 'string not null' will become 'varchar(255) not null'.
  151. * @return string the SQL statement for changing the definition of a column.
  152. * @throws NotSupportedException if this is not supported by the underlying DBMS.
  153. */
  154. public function alterColumn($table, $column, $type)
  155. {
  156. $sqlAfter = [];
  157. $columnName = $this->db->quoteColumnName($column);
  158. $tableName = $this->db->quoteTableName($table);
  159. $constraintBase = preg_replace('/[^a-z0-9_]/i', '', $table . '_' . $column);
  160. $type = $this->getColumnType($type);
  161. if (preg_match('/\s+DEFAULT\s+(["\']?\w*["\']?)/i', $type, $matches)) {
  162. $type = preg_replace('/\s+DEFAULT\s+(["\']?\w*["\']?)/i', '', $type);
  163. $sqlAfter[] = $this->dropConstraintsForColumn($table, $column, 'D');
  164. $sqlAfter[] = $this->addDefaultValue("DF_{$constraintBase}", $table, $column, $matches[1]);
  165. } else {
  166. $sqlAfter[] = $this->dropConstraintsForColumn($table, $column, 'D');
  167. }
  168. if (preg_match('/\s+CHECK\s+\((.+)\)/i', $type, $matches)) {
  169. $type = preg_replace('/\s+CHECK\s+\((.+)\)/i', '', $type);
  170. $sqlAfter[] = "ALTER TABLE {$tableName} ADD CONSTRAINT " . $this->db->quoteColumnName("CK_{$constraintBase}") . " CHECK ({$matches[1]})";
  171. }
  172. $type = preg_replace('/\s+UNIQUE/i', '', $type, -1, $count);
  173. if ($count) {
  174. $sqlAfter[] = "ALTER TABLE {$tableName} ADD CONSTRAINT " . $this->db->quoteColumnName("UQ_{$constraintBase}") . " UNIQUE ({$columnName})";
  175. }
  176. return 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' ALTER COLUMN '
  177. . $this->db->quoteColumnName($column) . ' '
  178. . $this->getColumnType($type) . "\n"
  179. . implode("\n", $sqlAfter);
  180. }
  181. /**
  182. * {@inheritdoc}
  183. */
  184. public function addDefaultValue($name, $table, $column, $value)
  185. {
  186. return 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' ADD CONSTRAINT '
  187. . $this->db->quoteColumnName($name) . ' DEFAULT ' . $this->db->quoteValue($value) . ' FOR '
  188. . $this->db->quoteColumnName($column);
  189. }
  190. /**
  191. * {@inheritdoc}
  192. */
  193. public function dropDefaultValue($name, $table)
  194. {
  195. return 'ALTER TABLE ' . $this->db->quoteTableName($table)
  196. . ' DROP CONSTRAINT ' . $this->db->quoteColumnName($name);
  197. }
  198. /**
  199. * Creates a SQL statement for resetting the sequence value of a table's primary key.
  200. * The sequence will be reset such that the primary key of the next new row inserted
  201. * will have the specified value or 1.
  202. * @param string $tableName the name of the table whose primary key sequence will be reset
  203. * @param mixed $value the value for the primary key of the next new row inserted. If this is not set,
  204. * the next new row's primary key will have a value 1.
  205. * @return string the SQL statement for resetting sequence
  206. * @throws InvalidArgumentException if the table does not exist or there is no sequence associated with the table.
  207. */
  208. public function resetSequence($tableName, $value = null)
  209. {
  210. $table = $this->db->getTableSchema($tableName);
  211. if ($table !== null && $table->sequenceName !== null) {
  212. $tableName = $this->db->quoteTableName($tableName);
  213. if ($value === null) {
  214. $key = $this->db->quoteColumnName(reset($table->primaryKey));
  215. $value = "(SELECT COALESCE(MAX({$key}),0) FROM {$tableName})+1";
  216. } else {
  217. $value = (int) $value;
  218. }
  219. return "DBCC CHECKIDENT ('{$tableName}', RESEED, {$value})";
  220. } elseif ($table === null) {
  221. throw new InvalidArgumentException("Table not found: $tableName");
  222. }
  223. throw new InvalidArgumentException("There is not sequence associated with table '$tableName'.");
  224. }
  225. /**
  226. * Builds a SQL statement for enabling or disabling integrity check.
  227. * @param bool $check whether to turn on or off the integrity check.
  228. * @param string $schema the schema of the tables.
  229. * @param string $table the table name.
  230. * @return string the SQL statement for checking integrity
  231. */
  232. public function checkIntegrity($check = true, $schema = '', $table = '')
  233. {
  234. $enable = $check ? 'CHECK' : 'NOCHECK';
  235. $schema = $schema ?: $this->db->getSchema()->defaultSchema;
  236. $tableNames = $this->db->getTableSchema($table) ? [$table] : $this->db->getSchema()->getTableNames($schema);
  237. $viewNames = $this->db->getSchema()->getViewNames($schema);
  238. $tableNames = array_diff($tableNames, $viewNames);
  239. $command = '';
  240. foreach ($tableNames as $tableName) {
  241. $tableName = $this->db->quoteTableName("{$schema}.{$tableName}");
  242. $command .= "ALTER TABLE $tableName $enable CONSTRAINT ALL; ";
  243. }
  244. return $command;
  245. }
  246. /**
  247. * Builds a SQL command for adding or updating a comment to a table or a column. The command built will check if a comment
  248. * already exists. If so, it will be updated, otherwise, it will be added.
  249. *
  250. * @param string $comment the text of the comment to be added. The comment will be properly quoted by the method.
  251. * @param string $table the table to be commented or whose column is to be commented. The table name will be
  252. * properly quoted by the method.
  253. * @param string $column optional. The name of the column to be commented. If empty, the command will add the
  254. * comment to the table instead. The column name will be properly quoted by the method.
  255. * @return string the SQL statement for adding a comment.
  256. * @throws InvalidArgumentException if the table does not exist.
  257. * @since 2.0.24
  258. */
  259. protected function buildAddCommentSql($comment, $table, $column = null)
  260. {
  261. $tableSchema = $this->db->schema->getTableSchema($table);
  262. if ($tableSchema === null) {
  263. throw new InvalidArgumentException("Table not found: $table");
  264. }
  265. $schemaName = $tableSchema->schemaName ? "N'" . $tableSchema->schemaName . "'": 'SCHEMA_NAME()';
  266. $tableName = "N" . $this->db->quoteValue($tableSchema->name);
  267. $columnName = $column ? "N" . $this->db->quoteValue($column) : null;
  268. $comment = "N" . $this->db->quoteValue($comment);
  269. $functionParams = "
  270. @name = N'MS_description',
  271. @value = $comment,
  272. @level0type = N'SCHEMA', @level0name = $schemaName,
  273. @level1type = N'TABLE', @level1name = $tableName"
  274. . ($column ? ", @level2type = N'COLUMN', @level2name = $columnName" : '') . ';';
  275. return "
  276. IF NOT EXISTS (
  277. SELECT 1
  278. FROM fn_listextendedproperty (
  279. N'MS_description',
  280. 'SCHEMA', $schemaName,
  281. 'TABLE', $tableName,
  282. " . ($column ? "'COLUMN', $columnName " : ' DEFAULT, DEFAULT ') . "
  283. )
  284. )
  285. EXEC sys.sp_addextendedproperty $functionParams
  286. ELSE
  287. EXEC sys.sp_updateextendedproperty $functionParams
  288. ";
  289. }
  290. /**
  291. * {@inheritdoc}
  292. * @since 2.0.8
  293. */
  294. public function addCommentOnColumn($table, $column, $comment)
  295. {
  296. return $this->buildAddCommentSql($comment, $table, $column);
  297. }
  298. /**
  299. * {@inheritdoc}
  300. * @since 2.0.8
  301. */
  302. public function addCommentOnTable($table, $comment)
  303. {
  304. return $this->buildAddCommentSql($comment, $table);
  305. }
  306. /**
  307. * Builds a SQL command for removing a comment from a table or a column. The command built will check if a comment
  308. * already exists before trying to perform the removal.
  309. *
  310. * @param string $table the table that will have the comment removed or whose column will have the comment removed.
  311. * The table name will be properly quoted by the method.
  312. * @param string $column optional. The name of the column whose comment will be removed. If empty, the command
  313. * will remove the comment from the table instead. The column name will be properly quoted by the method.
  314. * @return string the SQL statement for removing the comment.
  315. * @throws InvalidArgumentException if the table does not exist.
  316. * @since 2.0.24
  317. */
  318. protected function buildRemoveCommentSql($table, $column = null)
  319. {
  320. $tableSchema = $this->db->schema->getTableSchema($table);
  321. if ($tableSchema === null) {
  322. throw new InvalidArgumentException("Table not found: $table");
  323. }
  324. $schemaName = $tableSchema->schemaName ? "N'" . $tableSchema->schemaName . "'": 'SCHEMA_NAME()';
  325. $tableName = "N" . $this->db->quoteValue($tableSchema->name);
  326. $columnName = $column ? "N" . $this->db->quoteValue($column) : null;
  327. return "
  328. IF EXISTS (
  329. SELECT 1
  330. FROM fn_listextendedproperty (
  331. N'MS_description',
  332. 'SCHEMA', $schemaName,
  333. 'TABLE', $tableName,
  334. " . ($column ? "'COLUMN', $columnName " : ' DEFAULT, DEFAULT ') . "
  335. )
  336. )
  337. EXEC sys.sp_dropextendedproperty
  338. @name = N'MS_description',
  339. @level0type = N'SCHEMA', @level0name = $schemaName,
  340. @level1type = N'TABLE', @level1name = $tableName"
  341. . ($column ? ", @level2type = N'COLUMN', @level2name = $columnName" : '') . ';';
  342. }
  343. /**
  344. * {@inheritdoc}
  345. * @since 2.0.8
  346. */
  347. public function dropCommentFromColumn($table, $column)
  348. {
  349. return $this->buildRemoveCommentSql($table, $column);
  350. }
  351. /**
  352. * {@inheritdoc}
  353. * @since 2.0.8
  354. */
  355. public function dropCommentFromTable($table)
  356. {
  357. return $this->buildRemoveCommentSql($table);
  358. }
  359. /**
  360. * Returns an array of column names given model name.
  361. *
  362. * @param string $modelClass name of the model class
  363. * @return array|null array of column names
  364. */
  365. protected function getAllColumnNames($modelClass = null)
  366. {
  367. if (!$modelClass) {
  368. return null;
  369. }
  370. /* @var $modelClass \yii\db\ActiveRecord */
  371. $schema = $modelClass::getTableSchema();
  372. return array_keys($schema->columns);
  373. }
  374. /**
  375. * @return bool whether the version of the MSSQL being used is older than 2012.
  376. * @throws \yii\base\InvalidConfigException
  377. * @throws \yii\db\Exception
  378. * @deprecated 2.0.14 Use [[Schema::getServerVersion]] with [[\version_compare()]].
  379. */
  380. protected function isOldMssql()
  381. {
  382. return version_compare($this->db->getSchema()->getServerVersion(), '11', '<');
  383. }
  384. /**
  385. * {@inheritdoc}
  386. * @since 2.0.8
  387. */
  388. public function selectExists($rawSql)
  389. {
  390. return 'SELECT CASE WHEN EXISTS(' . $rawSql . ') THEN 1 ELSE 0 END';
  391. }
  392. /**
  393. * Normalizes data to be saved into the table, performing extra preparations and type converting, if necessary.
  394. * @param string $table the table that data will be saved into.
  395. * @param array $columns the column data (name => value) to be saved into the table.
  396. * @return array normalized columns
  397. */
  398. private function normalizeTableRowData($table, $columns, &$params)
  399. {
  400. if (($tableSchema = $this->db->getSchema()->getTableSchema($table)) !== null) {
  401. $columnSchemas = $tableSchema->columns;
  402. foreach ($columns as $name => $value) {
  403. // @see https://github.com/yiisoft/yii2/issues/12599
  404. if (isset($columnSchemas[$name]) && $columnSchemas[$name]->type === Schema::TYPE_BINARY && $columnSchemas[$name]->dbType === 'varbinary' && (is_string($value) || $value === null)) {
  405. $phName = $this->bindParam($value, $params);
  406. // @see https://github.com/yiisoft/yii2/issues/12599
  407. $columns[$name] = new Expression("CONVERT(VARBINARY(MAX), $phName)", $params);
  408. }
  409. }
  410. }
  411. return $columns;
  412. }
  413. /**
  414. * {@inheritdoc}
  415. * Added OUTPUT construction for getting inserted data (for SQL Server 2005 or later)
  416. * OUTPUT clause - The OUTPUT clause is new to SQL Server 2005 and has the ability to access
  417. * the INSERTED and DELETED tables as is the case with a trigger.
  418. */
  419. public function insert($table, $columns, &$params)
  420. {
  421. $columns = $this->normalizeTableRowData($table, $columns, $params);
  422. $version2005orLater = version_compare($this->db->getSchema()->getServerVersion(), '9', '>=');
  423. list($names, $placeholders, $values, $params) = $this->prepareInsertValues($table, $columns, $params);
  424. $sql = 'INSERT INTO ' . $this->db->quoteTableName($table)
  425. . (!empty($names) ? ' (' . implode(', ', $names) . ')' : '')
  426. . ($version2005orLater ? ' OUTPUT INSERTED.* INTO @temporary_inserted' : '')
  427. . (!empty($placeholders) ? ' VALUES (' . implode(', ', $placeholders) . ')' : $values);
  428. if ($version2005orLater) {
  429. $schema = $this->db->getTableSchema($table);
  430. $cols = [];
  431. foreach ($schema->columns as $column) {
  432. $cols[] = $this->db->quoteColumnName($column->name) . ' '
  433. . $column->dbType
  434. . (in_array($column->dbType, ['char', 'varchar', 'nchar', 'nvarchar', 'binary', 'varbinary']) ? "(MAX)" : "")
  435. . ' ' . ($column->allowNull ? "NULL" : "");
  436. }
  437. $sql = "SET NOCOUNT ON;DECLARE @temporary_inserted TABLE (" . implode(", ", $cols) . ");" . $sql . ";SELECT * FROM @temporary_inserted";
  438. }
  439. return $sql;
  440. }
  441. /**
  442. * {@inheritdoc}
  443. * @see https://docs.microsoft.com/en-us/sql/t-sql/statements/merge-transact-sql
  444. * @see http://weblogs.sqlteam.com/dang/archive/2009/01/31/UPSERT-Race-Condition-With-MERGE.aspx
  445. */
  446. public function upsert($table, $insertColumns, $updateColumns, &$params)
  447. {
  448. /** @var Constraint[] $constraints */
  449. list($uniqueNames, $insertNames, $updateNames) = $this->prepareUpsertColumns($table, $insertColumns, $updateColumns, $constraints);
  450. if (empty($uniqueNames)) {
  451. return $this->insert($table, $insertColumns, $params);
  452. }
  453. if ($updateNames === []) {
  454. // there are no columns to update
  455. $updateColumns = false;
  456. }
  457. $onCondition = ['or'];
  458. $quotedTableName = $this->db->quoteTableName($table);
  459. foreach ($constraints as $constraint) {
  460. $constraintCondition = ['and'];
  461. foreach ($constraint->columnNames as $name) {
  462. $quotedName = $this->db->quoteColumnName($name);
  463. $constraintCondition[] = "$quotedTableName.$quotedName=[EXCLUDED].$quotedName";
  464. }
  465. $onCondition[] = $constraintCondition;
  466. }
  467. $on = $this->buildCondition($onCondition, $params);
  468. list(, $placeholders, $values, $params) = $this->prepareInsertValues($table, $insertColumns, $params);
  469. $mergeSql = 'MERGE ' . $this->db->quoteTableName($table) . ' WITH (HOLDLOCK) '
  470. . 'USING (' . (!empty($placeholders) ? 'VALUES (' . implode(', ', $placeholders) . ')' : ltrim($values, ' ')) . ') AS [EXCLUDED] (' . implode(', ', $insertNames) . ') '
  471. . "ON ($on)";
  472. $insertValues = [];
  473. foreach ($insertNames as $name) {
  474. $quotedName = $this->db->quoteColumnName($name);
  475. if (strrpos($quotedName, '.') === false) {
  476. $quotedName = '[EXCLUDED].' . $quotedName;
  477. }
  478. $insertValues[] = $quotedName;
  479. }
  480. $insertSql = 'INSERT (' . implode(', ', $insertNames) . ')'
  481. . ' VALUES (' . implode(', ', $insertValues) . ')';
  482. if ($updateColumns === false) {
  483. return "$mergeSql WHEN NOT MATCHED THEN $insertSql;";
  484. }
  485. if ($updateColumns === true) {
  486. $updateColumns = [];
  487. foreach ($updateNames as $name) {
  488. $quotedName = $this->db->quoteColumnName($name);
  489. if (strrpos($quotedName, '.') === false) {
  490. $quotedName = '[EXCLUDED].' . $quotedName;
  491. }
  492. $updateColumns[$name] = new Expression($quotedName);
  493. }
  494. }
  495. list($updates, $params) = $this->prepareUpdateSets($table, $updateColumns, $params);
  496. $updateSql = 'UPDATE SET ' . implode(', ', $updates);
  497. return "$mergeSql WHEN MATCHED THEN $updateSql WHEN NOT MATCHED THEN $insertSql;";
  498. }
  499. /**
  500. * {@inheritdoc}
  501. */
  502. public function update($table, $columns, $condition, &$params)
  503. {
  504. return parent::update($table, $this->normalizeTableRowData($table, $columns, $params), $condition, $params);
  505. }
  506. /**
  507. * {@inheritdoc}
  508. */
  509. public function getColumnType($type)
  510. {
  511. $columnType = parent::getColumnType($type);
  512. // remove unsupported keywords
  513. $columnType = preg_replace("/\s*comment '.*'/i", '', $columnType);
  514. $columnType = preg_replace('/ first$/i', '', $columnType);
  515. return $columnType;
  516. }
  517. /**
  518. * {@inheritdoc}
  519. */
  520. protected function extractAlias($table)
  521. {
  522. if (preg_match('/^\[.*\]$/', $table)) {
  523. return false;
  524. }
  525. return parent::extractAlias($table);
  526. }
  527. /**
  528. * Builds a SQL statement for dropping constraints for column of table.
  529. *
  530. * @param string $table the table whose constraint is to be dropped. The name will be properly quoted by the method.
  531. * @param string $column the column whose constraint is to be dropped. The name will be properly quoted by the method.
  532. * @param string $type type of constraint, leave empty for all type of constraints(for example: D - default, 'UQ' - unique, 'C' - check)
  533. * @see https://docs.microsoft.com/sql/relational-databases/system-catalog-views/sys-objects-transact-sql
  534. * @return string the DROP CONSTRAINTS SQL
  535. */
  536. private function dropConstraintsForColumn($table, $column, $type='')
  537. {
  538. return "DECLARE @tableName VARCHAR(MAX) = '" . $this->db->quoteTableName($table) . "'
  539. DECLARE @columnName VARCHAR(MAX) = '{$column}'
  540. WHILE 1=1 BEGIN
  541. DECLARE @constraintName NVARCHAR(128)
  542. SET @constraintName = (SELECT TOP 1 OBJECT_NAME(cons.[object_id])
  543. FROM (
  544. SELECT sc.[constid] object_id
  545. FROM [sys].[sysconstraints] sc
  546. JOIN [sys].[columns] c ON c.[object_id]=sc.[id] AND c.[column_id]=sc.[colid] AND c.[name]=@columnName
  547. WHERE sc.[id] = OBJECT_ID(@tableName)
  548. UNION
  549. SELECT object_id(i.[name]) FROM [sys].[indexes] i
  550. JOIN [sys].[columns] c ON c.[object_id]=i.[object_id] AND c.[name]=@columnName
  551. JOIN [sys].[index_columns] ic ON ic.[object_id]=i.[object_id] AND i.[index_id]=ic.[index_id] AND c.[column_id]=ic.[column_id]
  552. WHERE i.[is_unique_constraint]=1 and i.[object_id]=OBJECT_ID(@tableName)
  553. ) cons
  554. JOIN [sys].[objects] so ON so.[object_id]=cons.[object_id]
  555. " . (!empty($type) ? " WHERE so.[type]='{$type}'" : "") . ")
  556. IF @constraintName IS NULL BREAK
  557. EXEC (N'ALTER TABLE ' + @tableName + ' DROP CONSTRAINT [' + @constraintName + ']')
  558. END";
  559. }
  560. /**
  561. * Drop all constraints before column delete
  562. * {@inheritdoc}
  563. */
  564. public function dropColumn($table, $column)
  565. {
  566. return $this->dropConstraintsForColumn($table, $column) . "\nALTER TABLE " . $this->db->quoteTableName($table)
  567. . " DROP COLUMN " . $this->db->quoteColumnName($column);
  568. }
  569. }