Skip to content
This repository

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP

Fix SQL Server default constraints #298

Merged
merged 1 commit into from over 1 year ago

3 participants

Steve Müller doctrinebot Benjamin Eberlei
Steve Müller
Collaborator

This PR fixes altering column default values. In SQL Server column default values are stored in constraints. CREATE TABLE statements with column declarations like some_column NVARCHAR(50) NOT NULL DEFAULT 'default value' internally creates a default constraint with an automatically generated name in the the system table sys.default_constraints. ALTER TABLE statements do not support the DEFAULT clause in column alteration declarations, leading in SQL syntax errors. Thus changing a column's default value is currently not possible.
To alter a column's default value, the old column's default constraint hast to be dropped and recreated again. As a default constraint has to be referenced by name to be dropped, we need to create each default constraint with an own unique name. This PR generates separate statements for default constraint declarations. It generates a unique name consisting of the table name and the column name the default constraint is created for.
DF_TABLE_NAME_HASH%_%COLUMN_NAME_HASH%

doctrinebot
Collaborator

Hello,

thank you for positing this Pull Request. I have automatically opened an issue on our Jira Bug Tracker for you with the details of this Pull-Request. See the Link:

http://doctrine-project.org/jira/browse/DBAL-484

Benjamin Eberlei beberlei merged commit fe04d1f into from
Benjamin Eberlei beberlei closed this
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Showing 1 unique commit by 1 author.

Apr 04, 2013
Steve Müller deeky666 fix SQL Server default constraints 9348da8
This page is out of date. Refresh to see the latest.
136 lib/Doctrine/DBAL/Platforms/SQLServerPlatform.php
@@ -194,12 +194,22 @@ public function getDropIndexSQL($index, $table = null)
194 194 */
195 195 protected function _getCreateTableSQL($tableName, array $columns, array $options = array())
196 196 {
  197 + $defaultConstraintsSql = array();
  198 +
197 199 // @todo does other code breaks because of this?
198 200 // force primary keys to be not null
199 201 foreach ($columns as &$column) {
200 202 if (isset($column['primary']) && $column['primary']) {
201 203 $column['notnull'] = true;
202 204 }
  205 +
  206 + /**
  207 + * Build default constraints SQL statements
  208 + */
  209 + if ( ! empty($column['default']) || is_numeric($column['default'])) {
  210 + $defaultConstraintsSql[] = 'ALTER TABLE ' . $tableName .
  211 + ' ADD' . $this->getDefaultConstraintDeclarationSQL($tableName, $column);
  212 + }
203 213 }
204 214
205 215 $columnListSql = $this->getColumnDeclarationListSQL($columns);
@@ -240,7 +250,7 @@ protected function _getCreateTableSQL($tableName, array $columns, array $options
240 250 }
241 251 }
242 252
243   - return $sql;
  253 + return array_merge($sql, $defaultConstraintsSql);
244 254 }
245 255
246 256 /**
@@ -256,6 +266,29 @@ public function getCreatePrimaryKeySQL(Index $index, $table)
256 266 }
257 267
258 268 /**
  269 + * Returns the SQL snippet for declaring a default constraint.
  270 + *
  271 + * @param string $table Name of the table to return the default constraint declaration for.
  272 + * @param array $column Column definition.
  273 + *
  274 + * @return string
  275 + *
  276 + * @throws \InvalidArgumentException
  277 + */
  278 + public function getDefaultConstraintDeclarationSQL($table, array $column)
  279 + {
  280 + if (empty($column['default']) && ! is_numeric($column['default'])) {
  281 + throw new \InvalidArgumentException("Incomplete column definition. 'default' required.");
  282 + }
  283 +
  284 + return
  285 + ' CONSTRAINT ' .
  286 + $this->generateDefaultConstraintName($table, $column['name']) .
  287 + $this->getDefaultValueDeclarationSQL($column) .
  288 + ' FOR ' . $column['name'];
  289 + }
  290 +
  291 + /**
259 292 * {@inheritDoc}
260 293 */
261 294 public function getUniqueConstraintDeclarationSQL($name, Index $index)
@@ -331,12 +364,19 @@ public function getAlterTableSQL(TableDiff $diff)
331 364 $sql = array();
332 365 $columnSql = array();
333 366
  367 + /** @var \Doctrine\DBAL\Schema\Column $column */
334 368 foreach ($diff->addedColumns as $column) {
335 369 if ($this->onSchemaAlterTableAddColumn($column, $diff, $columnSql)) {
336 370 continue;
337 371 }
338 372
339   - $queryParts[] = 'ADD ' . $this->getColumnDeclarationSQL($column->getQuotedName($this), $column->toArray());
  373 + $columnDef = $column->toArray();
  374 + $queryParts[] = 'ADD ' . $this->getColumnDeclarationSQL($column->getQuotedName($this), $columnDef);
  375 +
  376 + if ( ! empty($columnDef['default']) || is_numeric($columnDef['default'])) {
  377 + $columnDef['name'] = $column->getQuotedName($this);
  378 + $queryParts[] = 'ADD' . $this->getDefaultConstraintDeclarationSQL($diff->name, $columnDef);
  379 + }
340 380 }
341 381
342 382 foreach ($diff->removedColumns as $column) {
@@ -347,15 +387,35 @@ public function getAlterTableSQL(TableDiff $diff)
347 387 $queryParts[] = 'DROP COLUMN ' . $column->getQuotedName($this);
348 388 }
349 389
  390 + /* @var $columnDiff \Doctrine\DBAL\Schema\ColumnDiff */
350 391 foreach ($diff->changedColumns as $columnDiff) {
351 392 if ($this->onSchemaAlterTableChangeColumn($columnDiff, $diff, $columnSql)) {
352 393 continue;
353 394 }
354 395
355   - /* @var $columnDiff \Doctrine\DBAL\Schema\ColumnDiff */
  396 + $fromColumn = $columnDiff->fromColumn;
  397 + $fromColumnDefault = isset($fromColumn) ? $fromColumn->getDefault() : null;
356 398 $column = $columnDiff->column;
  399 + $columnDef = $column->toArray();
  400 + $columnDefaultHasChanged = $columnDiff->hasChanged('default');
  401 +
  402 + /**
  403 + * Drop existing column default constraint
  404 + * if default value has changed and another
  405 + * default constraint already exists for the column.
  406 + */
  407 + if ($columnDefaultHasChanged && ( ! empty($fromColumnDefault) || is_numeric($fromColumnDefault))) {
  408 + $queryParts[] = 'DROP CONSTRAINT ' .
  409 + $this->generateDefaultConstraintName($diff->name, $columnDiff->oldColumnName);
  410 + }
  411 +
357 412 $queryParts[] = 'ALTER COLUMN ' .
358   - $this->getColumnDeclarationSQL($column->getQuotedName($this), $column->toArray());
  413 + $this->getColumnDeclarationSQL($column->getQuotedName($this), $columnDef);
  414 +
  415 + if ($columnDefaultHasChanged && (! empty($columnDef['default']) || is_numeric($columnDef['default']))) {
  416 + $columnDef['name'] = $column->getQuotedName($this);
  417 + $queryParts[] = 'ADD' . $this->getDefaultConstraintDeclarationSQL($diff->name, $columnDef);
  418 + }
359 419 }
360 420
361 421 foreach ($diff->renamedColumns as $oldColumnName => $column) {
@@ -364,8 +424,28 @@ public function getAlterTableSQL(TableDiff $diff)
364 424 }
365 425
366 426 $sql[] = "sp_RENAME '". $diff->name. ".". $oldColumnName . "' , '".$column->getQuotedName($this)."', 'COLUMN'";
  427 +
  428 + $columnDef = $column->toArray();
  429 +
  430 + /**
  431 + * Drop existing default constraint for the old column name
  432 + * if column has default value.
  433 + */
  434 + if ( ! empty($columnDef['default']) || is_numeric($columnDef['default'])) {
  435 + $queryParts[] = 'DROP CONSTRAINT ' .
  436 + $this->generateDefaultConstraintName($diff->name, $oldColumnName);
  437 + }
  438 +
367 439 $queryParts[] = 'ALTER COLUMN ' .
368   - $this->getColumnDeclarationSQL($column->getQuotedName($this), $column->toArray());
  440 + $this->getColumnDeclarationSQL($column->getQuotedName($this), $columnDef);
  441 +
  442 + /**
  443 + * Readd default constraint for the new column name.
  444 + */
  445 + if ( ! empty($columnDef['default']) || is_numeric($columnDef['default'])) {
  446 + $columnDef['name'] = $column->getQuotedName($this);
  447 + $queryParts[] = 'ADD' . $this->getDefaultConstraintDeclarationSQL($diff->name, $columnDef);
  448 + }
369 449 }
370 450
371 451 $tableSql = array();
@@ -382,6 +462,23 @@ public function getAlterTableSQL(TableDiff $diff)
382 462
383 463 if ($diff->newName !== false) {
384 464 $sql[] = "sp_RENAME '" . $diff->name . "', '" . $diff->newName . "'";
  465 +
  466 + /**
  467 + * Rename table's default constraints names
  468 + * to match the new table name.
  469 + * This is necessary to ensure that the default
  470 + * constraints can be referenced in future table
  471 + * alterations as the table name is encoded in
  472 + * default constraints' names.
  473 + */
  474 + $sql[] = "DECLARE @sql NVARCHAR(MAX) = N''; " .
  475 + "SELECT @sql += N'EXEC sp_rename N''' + dc.name + ''', N''' " .
  476 + "+ REPLACE(dc.name, '" . $this->generateIdentifierName($diff->name) . "', " .
  477 + "'" . $this->generateIdentifierName($diff->newName) . "') + ''', ''OBJECT'';' " .
  478 + "FROM sys.default_constraints dc " .
  479 + "JOIN sys.tables tbl ON dc.parent_object_id = tbl.object_id " .
  480 + "WHERE tbl.name = '" . $diff->newName . "';" .
  481 + "EXEC sp_executesql @sql";
385 482 }
386 483
387 484 return array_merge($sql, $tableSql, $columnSql);
@@ -994,8 +1091,6 @@ public function getColumnDeclarationSQL($name, array $field)
994 1091 if (isset($field['columnDefinition'])) {
995 1092 $columnDef = $this->getCustomTypeDeclarationSQL($field);
996 1093 } else {
997   - $default = $this->getDefaultValueDeclarationSQL($field);
998   -
999 1094 $collation = (isset($field['collate']) && $field['collate']) ?
1000 1095 ' ' . $this->getColumnCollationDeclarationSQL($field['collate']) : '';
1001 1096
@@ -1008,9 +1103,34 @@ public function getColumnDeclarationSQL($name, array $field)
1008 1103 ' ' . $field['check'] : '';
1009 1104
1010 1105 $typeDecl = $field['type']->getSqlDeclaration($field, $this);
1011   - $columnDef = $typeDecl . $collation . $default . $notnull . $unique . $check;
  1106 + $columnDef = $typeDecl . $collation . $notnull . $unique . $check;
1012 1107 }
1013 1108
1014 1109 return $name . ' ' . $columnDef;
1015 1110 }
  1111 +
  1112 + /**
  1113 + * Returns a unique default constraint name for a table and column.
  1114 + *
  1115 + * @param string $table Name of the table to generate the unique default constraint name for.
  1116 + * @param string $column Name of the column in the table to generate the unique default constraint name for.
  1117 + *
  1118 + * @return string
  1119 + */
  1120 + private function generateDefaultConstraintName($table, $column)
  1121 + {
  1122 + return 'DF_' . $this->generateIdentifierName($table) . '_' . $this->generateIdentifierName($column);
  1123 + }
  1124 +
  1125 + /**
  1126 + * Returns a hash value for a given identifier.
  1127 + *
  1128 + * @param string $identifier Identifier to generate a hash value for.
  1129 + *
  1130 + * @return string
  1131 + */
  1132 + private function generateIdentifierName($identifier)
  1133 + {
  1134 + return strtoupper(dechex(crc32($identifier)));
  1135 + }
1016 1136 }
4 lib/Doctrine/DBAL/Schema/SQLServerSchemaManager.php
@@ -60,6 +60,10 @@ protected function _getPortableTableColumnDefinition($tableColumn)
60 60
61 61 while ($default != ($default2 = preg_replace("/^\((.*)\)$/", '$1', $default))) {
62 62 $default = trim($default2, "'");
  63 +
  64 + if ($default == 'getdate()') {
  65 + $default = $this->_platform->getCurrentTimestampSQL();
  66 + }
63 67 }
64 68
65 69 switch ($dbType) {
112 tests/Doctrine/Tests/DBAL/Functional/Schema/SQLServerSchemaManagerTest.php
@@ -52,4 +52,116 @@ public function testCollationCharset()
52 52
53 53 $this->assertEquals($collation, $columns[$columnName]->getPlatformOption('collate'));
54 54 }
  55 +
  56 + public function testDefaultContraints()
  57 + {
  58 + $table = new Table('sqlsrv_df_constraints');
  59 + $table->addColumn('no_default', 'string');
  60 + $table->addColumn('df_integer', 'integer', array('default' => 666));
  61 + $table->addColumn('df_string_1', 'string', array('default' => 'foobar'));
  62 + $table->addColumn('df_string_2', 'string', array('default' => 'Doctrine rocks!!!'));
  63 + $table->addColumn('df_string_3', 'string', array('default' => 'another default value'));
  64 + $table->addColumn('df_string_4', 'string', array('default' => 'column to rename'));
  65 + $table->addColumn('df_boolean', 'boolean', array('default' => true));
  66 +
  67 + $this->_sm->createTable($table);
  68 + $columns = $this->_sm->listTableColumns('sqlsrv_df_constraints');
  69 +
  70 + $this->assertNull($columns['no_default']->getDefault());
  71 + $this->assertEquals(666, $columns['df_integer']->getDefault());
  72 + $this->assertEquals('foobar', $columns['df_string_1']->getDefault());
  73 + $this->assertEquals('Doctrine rocks!!!', $columns['df_string_2']->getDefault());
  74 + $this->assertEquals('another default value', $columns['df_string_3']->getDefault());
  75 + $this->assertEquals(1, $columns['df_boolean']->getDefault());
  76 +
  77 + $diff = new TableDiff(
  78 + 'sqlsrv_df_constraints',
  79 + array(
  80 + new Column('df_current_timestamp', Type::getType('datetime'), array('default' => 'CURRENT_TIMESTAMP'))
  81 + ),
  82 + array(
  83 + 'df_integer' => new ColumnDiff(
  84 + 'df_integer',
  85 + new Column('df_integer', Type::getType('integer'), array('default' => 0)),
  86 + array('default'),
  87 + new Column('df_integer', Type::getType('integer'), array('default' => 666))
  88 + ),
  89 + 'df_string_2' => new ColumnDiff(
  90 + 'df_string_2',
  91 + new Column('df_string_2', Type::getType('string')),
  92 + array('default'),
  93 + new Column('df_string_2', Type::getType('string'), array('default' => 'Doctrine rocks!!!'))
  94 + ),
  95 + 'df_string_3' => new ColumnDiff(
  96 + 'df_string_3',
  97 + new Column('df_string_3', Type::getType('string'), array('length' => 50, 'default' => 'another default value')),
  98 + array('length'),
  99 + new Column('df_string_3', Type::getType('string'), array('length' => 50, 'default' => 'another default value'))
  100 + ),
  101 + 'df_boolean' => new ColumnDiff(
  102 + 'df_boolean',
  103 + new Column('df_boolean', Type::getType('boolean'), array('default' => false)),
  104 + array('default'),
  105 + new Column('df_boolean', Type::getType('boolean'), array('default' => true))
  106 + )
  107 + ),
  108 + array(
  109 + 'df_string_1' => new Column('df_string_1', Type::getType('string'))
  110 + ),
  111 + array(),
  112 + array(),
  113 + array(),
  114 + $table
  115 + );
  116 + $diff->newName = 'sqlsrv_default_constraints';
  117 + $diff->renamedColumns['df_string_4'] = new Column(
  118 + 'df_string_renamed',
  119 + Type::getType('string'),
  120 + array('default' => 'column to rename')
  121 + );
  122 +
  123 + $this->_sm->alterTable($diff);
  124 + $columns = $this->_sm->listTableColumns('sqlsrv_default_constraints');
  125 +
  126 + $this->assertNull($columns['no_default']->getDefault());
  127 + $this->assertEquals('CURRENT_TIMESTAMP', $columns['df_current_timestamp']->getDefault());
  128 + $this->assertEquals(0, $columns['df_integer']->getDefault());
  129 + $this->assertNull($columns['df_string_2']->getDefault());
  130 + $this->assertEquals('another default value', $columns['df_string_3']->getDefault());
  131 + $this->assertEquals(0, $columns['df_boolean']->getDefault());
  132 + $this->assertEquals('column to rename', $columns['df_string_renamed']->getDefault());
  133 +
  134 + /**
  135 + * Test that column default constraints can still be referenced after table rename
  136 + */
  137 + $diff = new TableDiff(
  138 + 'sqlsrv_default_constraints',
  139 + array(),
  140 + array(
  141 + 'df_current_timestamp' => new ColumnDiff(
  142 + 'df_current_timestamp',
  143 + new Column('df_current_timestamp', Type::getType('datetime')),
  144 + array('default'),
  145 + new Column('df_current_timestamp', Type::getType('datetime'), array('default' => 'CURRENT_TIMESTAMP'))
  146 + ),
  147 + 'df_integer' => new ColumnDiff(
  148 + 'df_integer',
  149 + new Column('df_integer', Type::getType('integer'), array('default' => 666)),
  150 + array('default'),
  151 + new Column('df_integer', Type::getType('integer'), array('default' => 0))
  152 + )
  153 + ),
  154 + array(),
  155 + array(),
  156 + array(),
  157 + array(),
  158 + $table
  159 + );
  160 +
  161 + $this->_sm->alterTable($diff);
  162 + $columns = $this->_sm->listTableColumns('sqlsrv_default_constraints');
  163 +
  164 + $this->assertNull($columns['df_current_timestamp']->getDefault());
  165 + $this->assertEquals(666, $columns['df_integer']->getDefault());
  166 + }
55 167 }
18 tests/Doctrine/Tests/DBAL/Platforms/SQLServerPlatformTest.php
@@ -14,13 +14,13 @@ public function createPlatform()
14 14
15 15 public function getGenerateTableSql()
16 16 {
17   - return 'CREATE TABLE test (id INT IDENTITY NOT NULL, test NVARCHAR(255) NULL, PRIMARY KEY (id))';
  17 + return 'CREATE TABLE test (id INT IDENTITY NOT NULL, test NVARCHAR(255), PRIMARY KEY (id))';
18 18 }
19 19
20 20 public function getGenerateTableWithMultiColumnUniqueIndexSql()
21 21 {
22 22 return array(
23   - 'CREATE TABLE test (foo NVARCHAR(255) NULL, bar NVARCHAR(255) NULL)',
  23 + 'CREATE TABLE test (foo NVARCHAR(255), bar NVARCHAR(255))',
24 24 'CREATE UNIQUE INDEX UNIQ_D87F7E0C8C73652176FF8CAA ON test (foo, bar) WHERE foo IS NOT NULL AND bar IS NOT NULL'
25 25 );
26 26 }
@@ -28,11 +28,19 @@ public function getGenerateTableWithMultiColumnUniqueIndexSql()
28 28 public function getGenerateAlterTableSql()
29 29 {
30 30 return array(
31   - 'ALTER TABLE mytable ADD quota INT NULL',
  31 + 'ALTER TABLE mytable ADD quota INT',
32 32 'ALTER TABLE mytable DROP COLUMN foo',
33   - 'ALTER TABLE mytable ALTER COLUMN baz NVARCHAR(255) DEFAULT \'def\' NOT NULL',
34   - 'ALTER TABLE mytable ALTER COLUMN bloo BIT DEFAULT \'0\' NOT NULL',
  33 + 'ALTER TABLE mytable ALTER COLUMN baz NVARCHAR(255) NOT NULL',
  34 + "ALTER TABLE mytable ADD CONSTRAINT DF_6B2BD609_78240498 DEFAULT 'def' FOR baz",
  35 + 'ALTER TABLE mytable ALTER COLUMN bloo BIT NOT NULL',
35 36 "sp_RENAME 'mytable', 'userlist'",
  37 + "DECLARE @sql NVARCHAR(MAX) = N''; " .
  38 + "SELECT @sql += N'EXEC sp_rename N''' + dc.name + ''', N''' " .
  39 + "+ REPLACE(dc.name, '6B2BD609', 'E2B58069') + ''', ''OBJECT'';' " .
  40 + "FROM sys.default_constraints dc " .
  41 + "JOIN sys.tables tbl ON dc.parent_object_id = tbl.object_id " .
  42 + "WHERE tbl.name = 'userlist';" .
  43 + "EXEC sp_executesql @sql"
36 44 );
37 45 }
38 46

Tip: You can add notes to lines in a file. Hover to the left of a line to make a note

Something went wrong with that request. Please try again.