[DBAL-255] On SQL SERVER Trying to drop a column throws error because of auto generated Constraints Created: 13/Apr/12  Updated: 17/Apr/14  Resolved: 05/May/12

Status: Resolved
Project: Doctrine DBAL
Component/s: Platforms
Affects Version/s: 2.2.2
Fix Version/s: None
Security Level: All

Type: Bug Priority: Major
Reporter: Fryderyk Benigni Assignee: Benjamin Eberlei
Resolution: Fixed Votes: 0
Labels: None
Environment:

MS SQL Server + Windows Server 2008



 Description   

Whenever Doctrine tries to drop a column that has some implicit constraints the system the SQL Native Client throws the message:

The Object 'Name_Of_The_Object' is dependent on column 'Column_To_Drop';

This is probably because columns such as Decimal Numbers have an automatice generated constraint that need to be dropped in order to drop a column.

A possible Solution is to add a platform specific getConstratintForTableSQL that queries the database to get all the constraint for the given column, than override the 'alterTable' method in the SQLServer Schema Manager to first drop the constraint than the columns in question by going and checking all the Columns that needs to be dropped in the TableDiff passed.

Something similar to this but better refactored I guess:

Changes in SQLServerPlatform.php

Add a method similar to this:

    /**
     * This function retrieves the constraints for a given column that is going to be droppped 
     */
    public function getColumnConstraintSQL($table, $column)
    {
        return "SELECT SysObjects.[Name]
                From SysObjects Inner Join (Select [Name],[ID] From SysObjects Where XType = 'U') As Tab
                On Tab.[ID] = Sysobjects.[Parent_Obj] 
                Inner Join sysconstraints On sysconstraints.Constid = Sysobjects.[ID] 
                Inner Join SysColumns Col On Col.[ColID] = sysconstraints.[ColID] And Col.[ID] = Tab.[ID]
                Where Col.[Name] = '$column' and Tab.[Name] = '$table'
                order by Col.[Name]";
    }

Changes on SqlServerChemaManager.php

       /**
	* Override
	*/
	public function alterTable(TableDiff $tableDiff)
	{
		if(count($tableDiff->removedColumns) > 0){
			$constraintsSql = array();
			foreach($tableDiff->removedColumns as $col){
				$constraintsSql[] = $this->_platform->getColumnConstraintSQL($tableDiff->name, $col->oldColumnName);
			}
			$constraintsToDrop = array();
			foreach($constraintsSql as $sql){
				 $constraintsToDrop[] = $this->_conn->execute($sql);
			}
			foreach($constraintsToDrop as $constraint){
				$this->_conn->execute("ALTER TABLE $tableDiff->name DROP CONSTRAINT $constraint");
			}
		}
		return parent::alterTable($tableDiff);
	}

Hope this helps

Thx



 Comments   
Comment by Fryderyk Benigni [ 13/Apr/12 ]

This version of the getColumnConstraintSQL seems better:

       /**
	* Override
	*/
	public function alterTable(TableDiff $tableDiff)
	{
		if(isset($tableDiff->removedColumns) && count($tableDiff->removedColumns) > 0){
			$constraintsSql = array();
			foreach($tableDiff->removedColumns as $col){
				$constraintsSql[] = $this->_platform->getColumnConstraintSQL($tableDiff->name, $col->getName());
			}
			$constraintsToDrop = array();
			foreach($constraintsSql as $sql){
				 $constraintData = $this->_conn->fetchAll($sql);
				 foreach($constraintData as $keyCostr => $costraint){
					$constraintsToDrop[] = $costraint['Name'];
				 }
			}
			
			foreach($constraintsToDrop as $key => $constraint){
				$this->_conn->exec("ALTER TABLE $tableDiff->name DROP CONSTRAINT ".$constraint);
			}
		}
		return parent::alterTable($tableDiff);
	}
Comment by Benjamin Eberlei [ 05/May/12 ]

Fixed formatting

Comment by Benjamin Eberlei [ 05/May/12 ]

Fixed.

I had to adjust your SQL a little since "sysconstraints" is deprecated and not exists anymore on SQL Azure for example.

Generated at Fri Apr 18 23:39:34 UTC 2014 using JIRA 6.2.3#6260-sha1:63ef1d6dac3f4f4d7db4c1effd405ba38ccdc558.