If you split a table into two tables in a database schema, it involves creating a new table and removing columns from the original table. However, the deployment will lead to data loss of the dropped table.
Solution: To prevent data loss, you need to create a migration script to copy the data from the original table to the new table before you delete columns from the original table. The process involves the following steps:
Note
The comparison engine of the tools doesn’t handle all cases automatically, which is why the cases mentioned above must be resolved manually.
The screenshot displays the Schema Comparison document and the scripts generated by Schema Compare Engine and a migration script, which should be created manually to perform errorless data migration.
The table provides source and target table script examples to illustrate the case:
Source table script example | Target table script example |
---|---|
CREATE TABLE [dbo].[Person] ( [PersonNumber] [INT] NOT NULL, [PersonName] [NVARCHAR](50) NULL, PRIMARY KEY CLUSTERED ([PersonNumber]) ) GO CREATE TABLE [dbo].[PersonAddress] ( [AddressID] [INT] IDENTITY PRIMARY KEY ,[PersonNumber] [INT] NOT NULL ,[AddressLine] [NVARCHAR](50) NULL ,[State] [NVARCHAR](50) NULL ,[Zip] [NVARCHAR](50) NULL ) GO ALTER TABLE [dbo].[PersonAddress] ADD FOREIGN KEY ([PersonNumber]) REFERENCES [dbo].[Person] ([PersonNumber]); GO |
CREATE TABLE [dbo].[Person] ( [PersonNumber] [INT] PRIMARY KEY, [PersonName] [NVARCHAR](50) NULL, [PersonAddress] [NVARCHAR](150) NULL ) GO INSERT INTO [dbo].[Person] ([PersonNumber], [PersonName], [PersonAddress]) VALUES (74, 'Alan Dou', '2590 Main St. Bernalillo, Albuquerque, New Mexico, NM, 87102'); INSERT INTO [dbo].[Person] ([PersonNumber], [PersonName], [PersonAddress]) VALUES (75, 'Jordan Sanders', '1234 Broadway Street, Apt. 77, New York, NY, 10101'); GO |
The table provides examples of scripts generated by the Schema Comparison engine and those that should be generated manually for errorless data migration to illustrate the case:
Script generated by the Schema Comparison engine | Script that should be generated manually for errorless data migration |
---|---|
ALTER TABLE [dbo].[Person] DROP COLUMN [PersonAddress]; GO CREATE TABLE [dbo].[PersonAddress] ( [AddressID] [INT] IDENTITY PRIMARY KEY ,[PersonNumber] [INT] NOT NULL ,[AddressLine] [NVARCHAR](50) NULL ,[State] [NVARCHAR](50) NULL ,[Zip] [NVARCHAR](50) NULL ) GO ALTER TABLE [dbo].[PersonAddress] ADD FOREIGN KEY ([PersonNumber]) REFERENCES [dbo].[Person] ([PersonNumber]); GO |
CREATE TABLE [dbo].[PersonAddress] ( [AddressID] [INT] IDENTITY PRIMARY KEY ,[PersonNumber] [INT] NOT NULL ,[AddressLine] [NVARCHAR](50) NULL ,[State] [NVARCHAR](50) NULL ,[Zip] [NVARCHAR](50) NULL ) GO ALTER TABLE [dbo].[PersonAddress] ADD FOREIGN KEY ([PersonNumber]) REFERENCES [dbo].[Person] ([PersonNumber]); GO -- migration script. INSERT INTO [dbo].[PersonAddress] ([PersonNumber], [AddressLine], [State], [Zip]) SELECT [PersonNumber], TRIM(LEFT([PersonAddress], CHARINDEX(',', [PersonAddress], (CHARINDEX(',', [PersonAddress]) ) + 1) - 1)) AS [Address], LEFT(TRIM(RIGHT([PersonAddress], LEN([PersonAddress]) - CHARINDEX(',', [PersonAddress], (CHARINDEX(',', [PersonAddress])) + 1))), CHARINDEX(',', TRIM(RIGHT([PersonAddress], LEN([PersonAddress]) - CHARINDEX(',', [PersonAddress], (CHARINDEX(',', [PersonAddress]) ) + 1)))) - 1) AS [State], TRIM(RIGHT([PersonAddress], LEN([PersonAddress]) - CHARINDEX(',', [PersonAddress], (CHARINDEX(',', [PersonAddress], (CHARINDEX(',', [PersonAddress], (CHARINDEX(',', [PersonAddress]) ) + 1)) + 1)) + 1))) AS [Zip] FROM [dbo].[Person]; -- migration script. ALTER TABLE [dbo].[Person] DROP COLUMN [PersonAddress]; GO |