* @since 2.0 */ class QueryBuilder extends \yii\db\QueryBuilder { /** * @var array mapping from abstract column types (keys) to physical column types (values). */ public $typeMap = [ Schema::TYPE_PK => 'int IDENTITY PRIMARY KEY', Schema::TYPE_UPK => 'int IDENTITY PRIMARY KEY', Schema::TYPE_BIGPK => 'bigint IDENTITY PRIMARY KEY', Schema::TYPE_UBIGPK => 'bigint IDENTITY PRIMARY KEY', Schema::TYPE_CHAR => 'nchar(1)', Schema::TYPE_STRING => 'nvarchar(255)', Schema::TYPE_TEXT => 'nvarchar(max)', Schema::TYPE_SMALLINT => 'smallint', Schema::TYPE_INTEGER => 'int', Schema::TYPE_BIGINT => 'bigint', Schema::TYPE_FLOAT => 'float', Schema::TYPE_DOUBLE => 'float', Schema::TYPE_DECIMAL => 'decimal(18,0)', Schema::TYPE_DATETIME => 'datetime', Schema::TYPE_TIMESTAMP => 'datetime', Schema::TYPE_TIME => 'time', Schema::TYPE_DATE => 'date', Schema::TYPE_BINARY => 'varbinary(max)', Schema::TYPE_BOOLEAN => 'bit', Schema::TYPE_MONEY => 'decimal(19,4)', ]; /** * @inheritdoc */ protected $likeEscapingReplacements = [ '%' => '[%]', '_' => '[_]', '[' => '[[]', ']' => '[]]', '\\' => '[\\]', ]; /** * @inheritdoc */ public function buildOrderByAndLimit($sql, $orderBy, $limit, $offset) { if (!$this->hasOffset($offset) && !$this->hasLimit($limit)) { $orderBy = $this->buildOrderBy($orderBy); return $orderBy === '' ? $sql : $sql . $this->separator . $orderBy; } if ($this->isOldMssql()) { return $this->oldBuildOrderByAndLimit($sql, $orderBy, $limit, $offset); } return $this->newBuildOrderByAndLimit($sql, $orderBy, $limit, $offset); } /** * Builds the ORDER BY/LIMIT/OFFSET clauses for SQL SERVER 2012 or newer. * @param string $sql the existing SQL (without ORDER BY/LIMIT/OFFSET) * @param array $orderBy the order by columns. See [[\yii\db\Query::orderBy]] for more details on how to specify this parameter. * @param int $limit the limit number. See [[\yii\db\Query::limit]] for more details. * @param int $offset the offset number. See [[\yii\db\Query::offset]] for more details. * @return string the SQL completed with ORDER BY/LIMIT/OFFSET (if any) */ protected function newBuildOrderByAndLimit($sql, $orderBy, $limit, $offset) { $orderBy = $this->buildOrderBy($orderBy); if ($orderBy === '') { // ORDER BY clause is required when FETCH and OFFSET are in the SQL $orderBy = 'ORDER BY (SELECT NULL)'; } $sql .= $this->separator . $orderBy; // http://technet.microsoft.com/en-us/library/gg699618.aspx $offset = $this->hasOffset($offset) ? $offset : '0'; $sql .= $this->separator . "OFFSET $offset ROWS"; if ($this->hasLimit($limit)) { $sql .= $this->separator . "FETCH NEXT $limit ROWS ONLY"; } return $sql; } /** * Builds the ORDER BY/LIMIT/OFFSET clauses for SQL SERVER 2005 to 2008. * @param string $sql the existing SQL (without ORDER BY/LIMIT/OFFSET) * @param array $orderBy the order by columns. See [[\yii\db\Query::orderBy]] for more details on how to specify this parameter. * @param int $limit the limit number. See [[\yii\db\Query::limit]] for more details. * @param int $offset the offset number. See [[\yii\db\Query::offset]] for more details. * @return string the SQL completed with ORDER BY/LIMIT/OFFSET (if any) */ protected function oldBuildOrderByAndLimit($sql, $orderBy, $limit, $offset) { $orderBy = $this->buildOrderBy($orderBy); if ($orderBy === '') { // ROW_NUMBER() requires an ORDER BY clause $orderBy = 'ORDER BY (SELECT NULL)'; } $sql = preg_replace('/^([\s(])*SELECT(\s+DISTINCT)?(?!\s*TOP\s*\()/i', "\\1SELECT\\2 rowNum = ROW_NUMBER() over ($orderBy),", $sql); if ($this->hasLimit($limit)) { $sql = "SELECT TOP $limit * FROM ($sql) sub"; } else { $sql = "SELECT * FROM ($sql) sub"; } if ($this->hasOffset($offset)) { $sql .= $this->separator . "WHERE rowNum > $offset"; } return $sql; } /** * Builds a SQL statement for renaming a DB table. * @param string $oldName the table to be renamed. The name will be properly quoted by the method. * @param string $newName the new table name. The name will be properly quoted by the method. * @return string the SQL statement for renaming a DB table. */ public function renameTable($oldName, $newName) { return 'sp_rename ' . $this->db->quoteTableName($oldName) . ', ' . $this->db->quoteTableName($newName); } /** * Builds a SQL statement for renaming a column. * @param string $table the table whose column is to be renamed. The name will be properly quoted by the method. * @param string $oldName the old name of the column. The name will be properly quoted by the method. * @param string $newName the new name of the column. The name will be properly quoted by the method. * @return string the SQL statement for renaming a DB column. */ public function renameColumn($table, $oldName, $newName) { $table = $this->db->quoteTableName($table); $oldName = $this->db->quoteColumnName($oldName); $newName = $this->db->quoteColumnName($newName); return "sp_rename '{$table}.{$oldName}', {$newName}, 'COLUMN'"; } /** * Builds a SQL statement for changing the definition of a column. * @param string $table the table whose column is to be changed. The table name will be properly quoted by the method. * @param string $column the name of the column to be changed. The name will be properly quoted by the method. * @param string $type the new column type. The [[getColumnType]] method will be invoked to convert abstract column type (if any) * into the physical one. Anything that is not recognized as abstract type will be kept in the generated SQL. * For example, 'string' will be turned into 'varchar(255)', while 'string not null' will become 'varchar(255) not null'. * @return string the SQL statement for changing the definition of a column. */ public function alterColumn($table, $column, $type) { $type = $this->getColumnType($type); $sql = 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' ALTER COLUMN ' . $this->db->quoteColumnName($column) . ' ' . $this->getColumnType($type); return $sql; } /** * @inheritDoc */ public function addDefaultValue($name, $table, $column, $value) { return 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' ADD CONSTRAINT ' . $this->db->quoteColumnName($name) . ' DEFAULT ' . $this->db->quoteValue($value) . ' FOR ' . $this->db->quoteColumnName($column); } /** * @inheritDoc */ public function dropDefaultValue($name, $table) { return 'ALTER TABLE ' . $this->db->quoteTableName($table) . ' DROP CONSTRAINT ' . $this->db->quoteColumnName($name); } /** * 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 * will have the specified value or 1. * @param string $tableName the name of the table whose primary key sequence will be reset * @param mixed $value the value for the primary key of the next new row inserted. If this is not set, * the next new row's primary key will have a value 1. * @return string the SQL statement for resetting sequence * @throws InvalidParamException if the table does not exist or there is no sequence associated with the table. */ public function resetSequence($tableName, $value = null) { $table = $this->db->getTableSchema($tableName); if ($table !== null && $table->sequenceName !== null) { $tableName = $this->db->quoteTableName($tableName); if ($value === null) { $key = $this->db->quoteColumnName(reset($table->primaryKey)); $value = "(SELECT COALESCE(MAX({$key}),0) FROM {$tableName})+1"; } else { $value = (int) $value; } return "DBCC CHECKIDENT ('{$tableName}', RESEED, {$value})"; } elseif ($table === null) { throw new InvalidParamException("Table not found: $tableName"); } throw new InvalidParamException("There is not sequence associated with table '$tableName'."); } /** * Builds a SQL statement for enabling or disabling integrity check. * @param bool $check whether to turn on or off the integrity check. * @param string $schema the schema of the tables. * @param string $table the table name. * @return string the SQL statement for checking integrity */ public function checkIntegrity($check = true, $schema = '', $table = '') { $enable = $check ? 'CHECK' : 'NOCHECK'; $schema = $schema ?: $this->db->getSchema()->defaultSchema; $tableNames = $this->db->getTableSchema($table) ? [$table] : $this->db->getSchema()->getTableNames($schema); $viewNames = $this->db->getSchema()->getViewNames($schema); $tableNames = array_diff($tableNames, $viewNames); $command = ''; foreach ($tableNames as $tableName) { $tableName = $this->db->quoteTableName("{$schema}.{$tableName}"); $command .= "ALTER TABLE $tableName $enable CONSTRAINT ALL; "; } return $command; } /** * @inheritdoc * @since 2.0.8 */ public function addCommentOnColumn($table, $column, $comment) { return "sp_updateextendedproperty @name = N'MS_Description', @value = {$this->db->quoteValue($comment)}, @level1type = N'Table', @level1name = {$this->db->quoteTableName($table)}, @level2type = N'Column', @level2name = {$this->db->quoteColumnName($column)}"; } /** * @inheritdoc * @since 2.0.8 */ public function addCommentOnTable($table, $comment) { return "sp_updateextendedproperty @name = N'MS_Description', @value = {$this->db->quoteValue($comment)}, @level1type = N'Table', @level1name = {$this->db->quoteTableName($table)}"; } /** * @inheritdoc * @since 2.0.8 */ public function dropCommentFromColumn($table, $column) { return "sp_dropextendedproperty @name = N'MS_Description', @level1type = N'Table', @level1name = {$this->db->quoteTableName($table)}, @level2type = N'Column', @level2name = {$this->db->quoteColumnName($column)}"; } /** * @inheritdoc * @since 2.0.8 */ public function dropCommentFromTable($table) { return "sp_dropextendedproperty @name = N'MS_Description', @level1type = N'Table', @level1name = {$this->db->quoteTableName($table)}"; } /** * Returns an array of column names given model name * * @param string $modelClass name of the model class * @return array|null array of column names */ protected function getAllColumnNames($modelClass = null) { if (!$modelClass) { return null; } /* @var $modelClass \yii\db\ActiveRecord */ $schema = $modelClass::getTableSchema(); return array_keys($schema->columns); } /** * @var bool whether MSSQL used is old. */ private $_oldMssql; /** * @return bool whether the version of the MSSQL being used is older than 2012. * @throws \yii\base\InvalidConfigException * @throws \yii\db\Exception */ protected function isOldMssql() { if ($this->_oldMssql === null) { $pdo = $this->db->getSlavePdo(); $version = explode('.', $pdo->getAttribute(\PDO::ATTR_SERVER_VERSION)); $this->_oldMssql = $version[0] < 11; } return $this->_oldMssql; } /** * @inheritdoc * @throws NotSupportedException if `$columns` is an array */ protected function buildSubqueryInCondition($operator, $columns, $values, &$params) { if (is_array($columns)) { throw new NotSupportedException(__METHOD__ . ' is not supported by MSSQL.'); } return parent::buildSubqueryInCondition($operator, $columns, $values, $params); } /** * Builds SQL for IN condition * * @param string $operator * @param array $columns * @param array $values * @param array $params * @return string SQL */ protected function buildCompositeInCondition($operator, $columns, $values, &$params) { $quotedColumns = []; foreach ($columns as $i => $column) { $quotedColumns[$i] = strpos($column, '(') === false ? $this->db->quoteColumnName($column) : $column; } $vss = []; foreach ($values as $value) { $vs = []; foreach ($columns as $i => $column) { if (isset($value[$column])) { $phName = self::PARAM_PREFIX . count($params); $params[$phName] = $value[$column]; $vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' = ' : ' != ') . $phName; } else { $vs[] = $quotedColumns[$i] . ($operator === 'IN' ? ' IS' : ' IS NOT') . ' NULL'; } } $vss[] = '(' . implode($operator === 'IN' ? ' AND ' : ' OR ', $vs) . ')'; } return '(' . implode($operator === 'IN' ? ' OR ' : ' AND ', $vss) . ')'; } /** * @inheritdoc * @since 2.0.8 */ public function selectExists($rawSql) { return 'SELECT CASE WHEN EXISTS(' . $rawSql . ') THEN 1 ELSE 0 END'; } /** * 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 array $columns the column data (name => value) to be saved into the table. * @return array normalized columns */ private function normalizeTableRowData($table, $columns, &$params) { if (($tableSchema = $this->db->getSchema()->getTableSchema($table)) !== null) { $columnSchemas = $tableSchema->columns; foreach ($columns as $name => $value) { // @see https://github.com/yiisoft/yii2/issues/12599 if (isset($columnSchemas[$name]) && $columnSchemas[$name]->type === Schema::TYPE_BINARY && $columnSchemas[$name]->dbType === 'varbinary' && is_string($value)) { $phName = self::PARAM_PREFIX . count($params); $columns[$name] = new Expression("CONVERT(VARBINARY, $phName)", [$phName => $value]); } } } return $columns; } /** * @inheritdoc */ public function insert($table, $columns, &$params) { return parent::insert($table, $this->normalizeTableRowData($table, $columns, $params), $params); } /** * @inheritdoc */ public function update($table, $columns, $condition, &$params) { return parent::update($table, $this->normalizeTableRowData($table, $columns, $params), $condition, $params); } }