. */ namespace Doctrine\DBAL\Platforms; use Doctrine\DBAL\Schema\TableDiff; use Doctrine\DBAL\DBALException; use Doctrine\DBAL\Schema\ForeignKeyConstraint; use Doctrine\DBAL\Schema\Index; use Doctrine\DBAL\Schema\Table; /** * The SQLServerPlatform provides the behavior, features and SQL dialect of the * Microsoft SQL Server database platform. * * @since 2.0 * @author Roman Borschel * @author Jonathan H. Wage * @author Benjamin Eberlei */ class SQLServerPlatform extends AbstractPlatform { /** * {@inheritDoc} */ public function getDateDiffExpression($date1, $date2) { return 'DATEDIFF(day, ' . $date2 . ',' . $date1 . ')'; } /** * {@inheritDoc} */ public function getDateAddDaysExpression($date, $days) { return 'DATEADD(day, ' . $days . ', ' . $date . ')'; } /** * {@inheritDoc} */ public function getDateSubDaysExpression($date, $days) { return 'DATEADD(day, -1 * ' . $days . ', ' . $date . ')'; } /** * {@inheritDoc} */ public function getDateAddMonthExpression($date, $months) { return 'DATEADD(month, ' . $months . ', ' . $date . ')'; } /** * {@inheritDoc} */ public function getDateSubMonthExpression($date, $months) { return 'DATEADD(month, -1 * ' . $months . ', ' . $date . ')'; } /** * {@inheritDoc} * * MsSql prefers "autoincrement" identity columns since sequences can only * be emulated with a table. */ public function prefersIdentityColumns() { return true; } /** * {@inheritDoc} * * MsSql supports this through AUTO_INCREMENT columns. */ public function supportsIdentityColumns() { return true; } /** * {@inheritDoc} */ public function supportsReleaseSavepoints() { return false; } /** * {@inheritDoc} */ public function getCreateDatabaseSQL($name) { return 'CREATE DATABASE ' . $name; } /** * {@inheritDoc} */ public function getDropDatabaseSQL($name) { return 'DROP DATABASE ' . $name; } /** * {@inheritDoc} */ public function supportsCreateDropDatabase() { return false; } /** * {@inheritDoc} */ public function getDropForeignKeySQL($foreignKey, $table) { if ($foreignKey instanceof ForeignKeyConstraint) { $foreignKey = $foreignKey->getQuotedName($this); } if ($table instanceof Table) { $table = $table->getQuotedName($this); } return 'ALTER TABLE ' . $table . ' DROP CONSTRAINT ' . $foreignKey; } /** * {@inheritDoc} */ public function getDropIndexSQL($index, $table = null) { if ($index instanceof Index) { $index = $index->getQuotedName($this); } else if (!is_string($index)) { throw new \InvalidArgumentException('AbstractPlatform::getDropIndexSQL() expects $index parameter to be string or \Doctrine\DBAL\Schema\Index.'); } if (!isset($table)) { return 'DROP INDEX ' . $index; } if ($table instanceof Table) { $table = $table->getQuotedName($this); } return "IF EXISTS (SELECT * FROM sysobjects WHERE name = '$index') ALTER TABLE " . $table . " DROP CONSTRAINT " . $index . " ELSE DROP INDEX " . $index . " ON " . $table; } /** * {@inheritDoc} */ protected function _getCreateTableSQL($tableName, array $columns, array $options = array()) { // @todo does other code breaks because of this? // force primary keys to be not null foreach ($columns as &$column) { if (isset($column['primary']) && $column['primary']) { $column['notnull'] = true; } } $columnListSql = $this->getColumnDeclarationListSQL($columns); if (isset($options['uniqueConstraints']) && !empty($options['uniqueConstraints'])) { foreach ($options['uniqueConstraints'] as $name => $definition) { $columnListSql .= ', ' . $this->getUniqueConstraintDeclarationSQL($name, $definition); } } if (isset($options['primary']) && !empty($options['primary'])) { $flags = ''; if (isset($options['primary_index']) && $options['primary_index']->hasFlag('nonclustered')) { $flags = ' NONCLUSTERED'; } $columnListSql .= ', PRIMARY KEY' . $flags . ' (' . implode(', ', array_unique(array_values($options['primary']))) . ')'; } $query = 'CREATE TABLE ' . $tableName . ' (' . $columnListSql; $check = $this->getCheckDeclarationSQL($columns); if (!empty($check)) { $query .= ', ' . $check; } $query .= ')'; $sql[] = $query; if (isset($options['indexes']) && !empty($options['indexes'])) { foreach ($options['indexes'] as $index) { $sql[] = $this->getCreateIndexSQL($index, $tableName); } } if (isset($options['foreignKeys'])) { foreach ((array) $options['foreignKeys'] as $definition) { $sql[] = $this->getCreateForeignKeySQL($definition, $tableName); } } return $sql; } /** * {@inheritDoc} */ public function getCreatePrimaryKeySQL(Index $index, $table) { $flags = ''; if ($index->hasFlag('nonclustered')) { $flags = ' NONCLUSTERED'; } return 'ALTER TABLE ' . $table . ' ADD PRIMARY KEY' . $flags . ' (' . $this->getIndexFieldDeclarationListSQL($index->getColumns()) . ')'; } /** * {@inheritDoc} */ public function getUniqueConstraintDeclarationSQL($name, Index $index) { $constraint = parent::getUniqueConstraintDeclarationSQL($name, $index); $constraint = $this->_appendUniqueConstraintDefinition($constraint, $index); return $constraint; } /** * {@inheritDoc} */ public function getCreateIndexSQL(Index $index, $table) { $constraint = parent::getCreateIndexSQL($index, $table); if ($index->isUnique()) { $constraint = $this->_appendUniqueConstraintDefinition($constraint, $index); } return $constraint; } /** * {@inheritDoc} */ protected function getCreateIndexSQLFlags(Index $index) { $type = ''; if ($index->isUnique()) { $type .= 'UNIQUE '; } if ($index->hasFlag('clustered')) { $type .= 'CLUSTERED '; } else if ($index->hasFlag('nonclustered')) { $type .= 'NONCLUSTERED '; } return $type; } /** * Extend unique key constraint with required filters * * @param string $sql * @param Index $index * * @return string */ private function _appendUniqueConstraintDefinition($sql, Index $index) { $fields = array(); foreach ($index->getColumns() as $field => $definition) { if (!is_array($definition)) { $field = $definition; } $fields[] = $field . ' IS NOT NULL'; } return $sql . ' WHERE ' . implode(' AND ', $fields); } /** * {@inheritDoc} */ public function getAlterTableSQL(TableDiff $diff) { $queryParts = array(); $sql = array(); $columnSql = array(); foreach ($diff->addedColumns as $column) { if ($this->onSchemaAlterTableAddColumn($column, $diff, $columnSql)) { continue; } $queryParts[] = 'ADD ' . $this->getColumnDeclarationSQL($column->getQuotedName($this), $column->toArray()); } foreach ($diff->removedColumns as $column) { if ($this->onSchemaAlterTableRemoveColumn($column, $diff, $columnSql)) { continue; } $queryParts[] = 'DROP COLUMN ' . $column->getQuotedName($this); } foreach ($diff->changedColumns as $columnDiff) { if ($this->onSchemaAlterTableChangeColumn($columnDiff, $diff, $columnSql)) { continue; } /* @var $columnDiff \Doctrine\DBAL\Schema\ColumnDiff */ $column = $columnDiff->column; $queryParts[] = 'ALTER COLUMN ' . $this->getColumnDeclarationSQL($column->getQuotedName($this), $column->toArray()); } foreach ($diff->renamedColumns as $oldColumnName => $column) { if ($this->onSchemaAlterTableRenameColumn($oldColumnName, $column, $diff, $columnSql)) { continue; } $sql[] = "sp_RENAME '". $diff->name. ".". $oldColumnName . "' , '".$column->getQuotedName($this)."', 'COLUMN'"; $queryParts[] = 'ALTER COLUMN ' . $this->getColumnDeclarationSQL($column->getQuotedName($this), $column->toArray()); } $tableSql = array(); if ($this->onSchemaAlterTable($diff, $tableSql)) { return array_merge($tableSql, $columnSql); } foreach ($queryParts as $query) { $sql[] = 'ALTER TABLE ' . $diff->name . ' ' . $query; } $sql = array_merge($sql, $this->_getAlterTableIndexForeignKeySQL($diff)); if ($diff->newName !== false) { $sql[] = "sp_RENAME '" . $diff->name . "', '" . $diff->newName . "'"; } return array_merge($sql, $tableSql, $columnSql); } /** * {@inheritDoc} */ public function getEmptyIdentityInsertSQL($quotedTableName, $quotedIdentifierColumnName) { return 'INSERT INTO ' . $quotedTableName . ' DEFAULT VALUES'; } /** * {@inheritDoc} */ public function getShowDatabasesSQL() { return 'SHOW DATABASES'; } /** * {@inheritDoc} */ public function getListTablesSQL() { // "sysdiagrams" table must be ignored as it's internal SQL Server table for Database Diagrams return "SELECT name FROM sysobjects WHERE type = 'U' AND name != 'sysdiagrams' ORDER BY name"; } /** * {@inheritDoc} */ public function getListTableColumnsSQL($table, $database = null) { return "exec sp_columns @table_name = '" . $table . "'"; } /** * {@inheritDoc} */ public function getListTableForeignKeysSQL($table, $database = null) { return "SELECT f.name AS ForeignKey, SCHEMA_NAME (f.SCHEMA_ID) AS SchemaName, OBJECT_NAME (f.parent_object_id) AS TableName, COL_NAME (fc.parent_object_id,fc.parent_column_id) AS ColumnName, SCHEMA_NAME (o.SCHEMA_ID) ReferenceSchemaName, OBJECT_NAME (f.referenced_object_id) AS ReferenceTableName, COL_NAME(fc.referenced_object_id,fc.referenced_column_id) AS ReferenceColumnName, f.delete_referential_action_desc, f.update_referential_action_desc FROM sys.foreign_keys AS f INNER JOIN sys.foreign_key_columns AS fc INNER JOIN sys.objects AS o ON o.OBJECT_ID = fc.referenced_object_id ON f.OBJECT_ID = fc.constraint_object_id WHERE OBJECT_NAME (f.parent_object_id) = '" . $table . "'"; } /** * {@inheritDoc} */ public function getListTableIndexesSQL($table, $currentDatabase = null) { return "exec sp_helpindex '" . $table . "'"; } /** * {@inheritDoc} */ public function getCreateViewSQL($name, $sql) { return 'CREATE VIEW ' . $name . ' AS ' . $sql; } /** * {@inheritDoc} */ public function getListViewsSQL($database) { return "SELECT name FROM sysobjects WHERE type = 'V' ORDER BY name"; } /** * {@inheritDoc} */ public function getDropViewSQL($name) { return 'DROP VIEW ' . $name; } /** * {@inheritDoc} */ public function getRegexpExpression() { return 'RLIKE'; } /** * {@inheritDoc} */ public function getGuidExpression() { return 'UUID()'; } /** * {@inheritDoc} */ public function getLocateExpression($str, $substr, $startPos = false) { if ($startPos == false) { return 'CHARINDEX(' . $substr . ', ' . $str . ')'; } return 'CHARINDEX(' . $substr . ', ' . $str . ', ' . $startPos . ')'; } /** * {@inheritDoc} */ public function getModExpression($expression1, $expression2) { return $expression1 . ' % ' . $expression2; } /** * {@inheritDoc} */ public function getTrimExpression($str, $pos = self::TRIM_UNSPECIFIED, $char = false) { if ( ! $char) { switch ($pos) { case self::TRIM_LEADING: $trimFn = 'LTRIM'; break; case self::TRIM_TRAILING: $trimFn = 'RTRIM'; break; default: return 'LTRIM(RTRIM(' . $str . '))'; } return $trimFn . '(' . $str . ')'; } /** Original query used to get those expressions declare @c varchar(100) = 'xxxBarxxx', @trim_char char(1) = 'x'; declare @pat varchar(10) = '%[^' + @trim_char + ']%'; select @c as string , @trim_char as trim_char , stuff(@c, 1, patindex(@pat, @c) - 1, null) as trim_leading , reverse(stuff(reverse(@c), 1, patindex(@pat, reverse(@c)) - 1, null)) as trim_trailing , reverse(stuff(reverse(stuff(@c, 1, patindex(@pat, @c) - 1, null)), 1, patindex(@pat, reverse(stuff(@c, 1, patindex(@pat, @c) - 1, null))) - 1, null)) as trim_both; */ $pattern = "'%[^' + $char + ']%'"; if ($pos == self::TRIM_LEADING) { return 'stuff(' . $str . ', 1, patindex(' . $pattern . ', ' . $str . ') - 1, null)'; } if ($pos == self::TRIM_TRAILING) { return 'reverse(stuff(reverse(' . $str . '), 1, patindex(' . $pattern . ', reverse(' . $str . ')) - 1, null))'; } return 'reverse(stuff(reverse(stuff(' . $str . ', 1, patindex(' . $pattern . ', ' . $str . ') - 1, null)), 1, patindex(' . $pattern . ', reverse(stuff(' . $str . ', 1, patindex(' . $pattern . ', ' . $str . ') - 1, null))) - 1, null))'; } /** * {@inheritDoc} */ public function getConcatExpression() { $args = func_get_args(); return '(' . implode(' + ', $args) . ')'; } public function getListDatabasesSQL() { return 'SELECT * FROM SYS.DATABASES'; } /** * {@inheritDoc} */ public function getSubstringExpression($value, $from, $length = null) { if (!is_null($length)) { return 'SUBSTRING(' . $value . ', ' . $from . ', ' . $length . ')'; } return 'SUBSTRING(' . $value . ', ' . $from . ', LEN(' . $value . ') - ' . $from . ' + 1)'; } /** * {@inheritDoc} */ public function getLengthExpression($column) { return 'LEN(' . $column . ')'; } /** * {@inheritDoc} */ public function getSetTransactionIsolationSQL($level) { return 'SET TRANSACTION ISOLATION LEVEL ' . $this->_getTransactionIsolationLevelSQL($level); } /** * {@inheritDoc} */ public function getIntegerTypeDeclarationSQL(array $field) { return 'INT' . $this->_getCommonIntegerTypeDeclarationSQL($field); } /** * {@inheritDoc} */ public function getBigIntTypeDeclarationSQL(array $field) { return 'BIGINT' . $this->_getCommonIntegerTypeDeclarationSQL($field); } /** * {@inheritDoc} */ public function getSmallIntTypeDeclarationSQL(array $field) { return 'SMALLINT' . $this->_getCommonIntegerTypeDeclarationSQL($field); } /** * {@inheritDoc} */ public function getGuidTypeDeclarationSQL(array $field) { return 'UNIQUEIDENTIFIER'; } /** * {@inheritDoc} */ protected function getVarcharTypeDeclarationSQLSnippet($length, $fixed) { return $fixed ? ($length ? 'NCHAR(' . $length . ')' : 'CHAR(255)') : ($length ? 'NVARCHAR(' . $length . ')' : 'NVARCHAR(255)'); } /** * {@inheritDoc} */ public function getClobTypeDeclarationSQL(array $field) { return 'TEXT'; } /** * {@inheritDoc} */ protected function _getCommonIntegerTypeDeclarationSQL(array $columnDef) { $autoinc = ''; if (!empty($columnDef['autoincrement'])) { $autoinc = ' IDENTITY'; } $unsigned = (isset($columnDef['unsigned']) && $columnDef['unsigned']) ? ' UNSIGNED' : ''; return $unsigned . $autoinc; } /** * {@inheritDoc} */ public function getDateTimeTypeDeclarationSQL(array $fieldDeclaration) { return 'DATETIME'; } /** * {@inheritDoc} */ public function getDateTypeDeclarationSQL(array $fieldDeclaration) { return 'DATETIME'; } /** * {@inheritDoc} */ public function getTimeTypeDeclarationSQL(array $fieldDeclaration) { return 'DATETIME'; } /** * {@inheritDoc} */ public function getBooleanTypeDeclarationSQL(array $field) { return 'BIT'; } /** * {@inheritDoc} * * @link http://lists.bestpractical.com/pipermail/rt-devel/2005-June/007339.html */ protected function doModifyLimitQuery($query, $limit, $offset = null) { if ($limit > 0) { if ($offset == 0) { $query = preg_replace('/^(SELECT\s(DISTINCT\s)?)/i', '\1TOP ' . $limit . ' ', $query); } else { $orderby = stristr($query, 'ORDER BY'); if ( ! $orderby) { $over = 'ORDER BY (SELECT 0)'; } else { $over = preg_replace('/\"[^,]*\".\"([^,]*)\"/i', '"inner_tbl"."$1"', $orderby); } // Remove ORDER BY clause from $query $query = preg_replace('/\s+ORDER BY(.*)/', '', $query); $query = preg_replace('/^SELECT\s/', '', $query); $start = $offset + 1; $end = $offset + $limit; $query = "SELECT * FROM (SELECT ROW_NUMBER() OVER ($over) AS doctrine_rownum, $query) AS doctrine_tbl WHERE doctrine_rownum BETWEEN $start AND $end"; } } return $query; } /** * {@inheritDoc} */ public function supportsLimitOffset() { return false; } /** * {@inheritDoc} */ public function convertBooleans($item) { if (is_array($item)) { foreach ($item as $key => $value) { if (is_bool($value) || is_numeric($item)) { $item[$key] = ($value) ? 1 : 0; } } } else if (is_bool($item) || is_numeric($item)) { $item = ($item) ? 1 : 0; } return $item; } /** * {@inheritDoc} */ public function getCreateTemporaryTableSnippetSQL() { return "CREATE TABLE"; } /** * {@inheritDoc} */ public function getTemporaryTableName($tableName) { return '#' . $tableName; } /** * {@inheritDoc} */ public function getDateTimeFormatString() { return 'Y-m-d H:i:s.000'; } /** * {@inheritDoc} */ public function getDateFormatString() { return 'Y-m-d H:i:s.000'; } /** * {@inheritDoc} */ public function getTimeFormatString() { return 'Y-m-d H:i:s.000'; } /** * {@inheritDoc} */ public function getDateTimeTzFormatString() { return $this->getDateTimeFormatString(); } /** * {@inheritDoc} */ public function getName() { return 'mssql'; } /** * {@inheritDoc} */ protected function initializeDoctrineTypeMappings() { $this->doctrineTypeMapping = array( 'bigint' => 'bigint', 'numeric' => 'decimal', 'bit' => 'boolean', 'smallint' => 'smallint', 'decimal' => 'decimal', 'smallmoney' => 'integer', 'int' => 'integer', 'tinyint' => 'smallint', 'money' => 'integer', 'float' => 'float', 'real' => 'float', 'double' => 'float', 'double precision' => 'float', 'datetimeoffset' => 'datetimetz', 'smalldatetime' => 'datetime', 'datetime' => 'datetime', 'char' => 'string', 'varchar' => 'string', 'text' => 'text', 'nchar' => 'string', 'nvarchar' => 'string', 'ntext' => 'text', 'binary' => 'text', 'varbinary' => 'blob', 'image' => 'text', 'uniqueidentifier' => 'guid', ); } /** * {@inheritDoc} */ public function createSavePoint($savepoint) { return 'SAVE TRANSACTION ' . $savepoint; } /** * {@inheritDoc} */ public function releaseSavePoint($savepoint) { return ''; } /** * {@inheritDoc} */ public function rollbackSavePoint($savepoint) { return 'ROLLBACK TRANSACTION ' . $savepoint; } /** * {@inheritDoc} */ public function appendLockHint($fromClause, $lockMode) { // @todo coorect if ($lockMode == \Doctrine\DBAL\LockMode::PESSIMISTIC_READ) { return $fromClause . ' WITH (tablockx)'; } if ($lockMode == \Doctrine\DBAL\LockMode::PESSIMISTIC_WRITE) { return $fromClause . ' WITH (tablockx)'; } return $fromClause; } /** * {@inheritDoc} */ public function getForUpdateSQL() { return ' '; } /** * {@inheritDoc} */ protected function getReservedKeywordsClass() { return 'Doctrine\DBAL\Platforms\Keywords\MsSQLKeywords'; } /** * {@inheritDoc} */ public function quoteSingleIdentifier($str) { return "[" . str_replace("]", "][", $str) . "]"; } /** * {@inheritDoc} */ public function getTruncateTableSQL($tableName, $cascade = false) { return 'TRUNCATE TABLE '.$tableName; } /** * {@inheritDoc} */ public function getBlobTypeDeclarationSQL(array $field) { return 'VARBINARY(MAX)'; } }