Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[5.8] Sql Server issue with dropAllTables when foreign key constraints exist #28750

Merged
merged 4 commits into from Jun 8, 2019

Conversation

Projects
None yet
4 participants
@walliby
Copy link
Contributor

commented Jun 6, 2019

Issue

There is an issue with migrations while using a sqlsrv connection. The issue occurs in the SqlServerBuilder->dropAllTables() method when there are foreign key constraints in the database and the database will throw a foreign key constraint exception while running commands like php artisan migrate:fresh. The SqlServerGrammer class returns the following command for this method: EXEC sp_msforeachtable "ALTER TABLE ? NOCHECK CONSTRAINT all"; The problem is that this sql server command only disables the constraints on INSERT and DELETE and does not work for TRUNCATE or DROP TABLE.

Solution

The only solution I have found to dropping tables with foreign key constraints in SQL Server is to first drop the foreign keys on every table.

Reproduction

An example of this issue can be found in the following project when configured with a sqlsrv connection. https://github.com/walliby/sql-server-drop-table-issue. Running phpunit, on the ExampleTest which uses RefreshDatabase will throw a db foreign key constraint error every other time you run the test. The reason the test fails every other time is because it will throw the error on the users table but still drop the role_user table which has the foreign keys. The second time, it will succeed, as the role_user table was deleted by the previous run.

@walliby walliby changed the title Sql Server issue with dropAllTables when foreign key constraints exist [5.8] Sql Server issue with dropAllTables when foreign key constraints exist Jun 6, 2019

@laurencei

This comment has been minimized.

Copy link
Member

commented Jun 6, 2019

Lol - I literally ran into this issue yesterday myself. You can also just to Telescope to see the problem (since Telescope uses foreign keys).

ping @staudenmeir - thoughts?

@laurencei

This comment has been minimized.

Copy link
Member

commented Jun 6, 2019

@taylorotwell - if you can wait 24-48 hours - I can test this against a known real life example to confirm it solves it before merging.

@staudenmeir

This comment has been minimized.

Copy link
Contributor

commented Jun 6, 2019

We definitely need time to review this.

@walliby

This comment has been minimized.

Copy link
Contributor Author

commented Jun 6, 2019

FYI, I have only tested my proposed solution on SQL Server 2016 SP1. I used my example project with foreign key constraints: https://github.com/walliby/sql-server-drop-table-issue. The t-sql I used is fairly basic and should be correct back to at least SQL Server 2008.

@taylorotwell

This comment has been minimized.

Copy link
Member

commented Jun 7, 2019

@laurencei if you could test this that would be great.

public function compileDropAllForeignKeys()
{
return "DECLARE @sql NVARCHAR(MAX) = N'';
SELECT @sql += 'ALTER TABLE ' + QUOTENAME(OBJECT_SCHEMA_NAME(parent_object_id))

This comment has been minimized.

Copy link
@staudenmeir

staudenmeir Jun 7, 2019

Contributor

Do we need to specify the database name?

This comment has been minimized.

Copy link
@walliby

walliby Jun 7, 2019

Author Contributor

@staudenmeir I dont believe so because it's being called the same was as compileDropAllTables using $this->connection.

$this->connection->statement($this->grammar->compileDropAllForeignKeys());
$this->connection->statement($this->grammar->compileDropAllTables());

This comment has been minimized.

Copy link
@laurencei

laurencei Jun 8, 2019

Member

When I ran this code, it only removed the foreign keys on the one database (I checked the other one on the same server, and it's foreign keys are still intact).

@laurencei

This comment has been minimized.

Copy link
Member

commented Jun 8, 2019

@taylorotwell - worked for the example I have.

Was SQL Server 2016. Not sure if anyone wants to test on other versions first, but seems to be ok so far...

@walliby

This comment has been minimized.

Copy link
Contributor Author

commented Jun 8, 2019

@laurencei I just tested the pure sql in a SQL 2014 Azure instance and that worked fine dropping 12 foreign keys in the sample AdventureWorks database...

SELECT *
FROM sys.foreign_keys;
-- Query succeeded: Affected rows: 12. 

DECLARE @sql NVARCHAR(MAX) = N'';
SELECT @sql += 'ALTER TABLE ' + QUOTENAME(OBJECT_SCHEMA_NAME(parent_object_id))
    + '.' + QUOTENAME(OBJECT_NAME(parent_object_id)) + 
    ' DROP CONSTRAINT ' + QUOTENAME(name) + ';'
FROM sys.foreign_keys;

EXEC sp_executesql @sql;

SELECT *
FROM sys.foreign_keys;
-- Query succeeded: Affected rows: 0. 

@taylorotwell taylorotwell merged commit fa6faa6 into laravel:5.8 Jun 8, 2019

1 of 2 checks passed

continuous-integration/travis-ci/pr The Travis CI build is in progress
Details
continuous-integration/styleci/pr The analysis has passed
Details

staudenmeir added a commit to staudenmeir/framework that referenced this pull request Jun 8, 2019

staudenmeir added a commit to staudenmeir/framework that referenced this pull request Jun 8, 2019

@staudenmeir staudenmeir referenced this pull request Jun 8, 2019

Merged

[5.8] Simplify #28750 #28770

taylorotwell added a commit that referenced this pull request Jun 10, 2019

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
You can’t perform that action at this time.