SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Generate MERGE statements with Table data


Generate MERGE statements with Table data

Author
Message
danere
danere
SSC Journeyman
SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)

Group: General Forum Members
Points: 90 Visits: 157
Comments posted to this topic are about the item Generate MERGE statements with Table data
danere
danere
SSC Journeyman
SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)

Group: General Forum Members
Points: 90 Visits: 157
Thanks for providing that alternate implementation Celko.

I can definitely see advantages of your approach, but I have a question: how would one remove extraneous records with your script?

Say I work with a feline fanatic and she adds a cat to my Zoo. But my Zoo is very exclusive and only the most exotic animals should be allowed to stay inside. What I want is to eliminate any animal records that aren't included in my script, because my script represents the canonical source of my animal list (a sort of "Noah's Ark" to take the analogy one step further :-))

In the OP MERGE statement, the "IF NOT MATCHED THEN DELETE" clause takes care of removing the extraneous rows.

Given that a call to the "Zoo_Keeper" proc would be required for each record in your example, do you have any ideas how the DELETE might be achieved?
john.moreno
john.moreno
Right there with Babe
Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)

Group: General Forum Members
Points: 787 Visits: 1115
Needs a check for tables without primary keys.


IF IsNull(@PK_column_list, '') = ''
BEGIN
RAISERROR('Table has no primary keys. There should at least be one column in order to have a valid join',16,1)
RETURN -1 --Failure. Reason: looks like table doesn't have any primary keys
END


danere
danere
SSC Journeyman
SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)

Group: General Forum Members
Points: 90 Visits: 157
Thanks for that John, I've revised the script to include the Primary Key check.

Unfortunately I'm not able to edit the original article, so have zipped the SQL file here:
Attachments
master.dbo.sp_generate_merge.zip (25 views, 6.00 KB)
john.moreno
john.moreno
Right there with Babe
Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)

Group: General Forum Members
Points: 787 Visits: 1115
danere (4/3/2012)
Thanks for that John, I've revised the script to include the Primary Key check.

Unfortunately I'm not able to edit the original article, so have zipped the SQL file here:


You might also consider:

DECLARE @db varchar(120);
set @db = 'USE ' + DB_NAME();
print @db;
print '';
PRINT '--MERGE generated by ''sp_generate_merge'' stored procedure, Version 0.9'

....
@Actual_Values nvarchar(max)
....
SET @Actual_Values =
'SELECT @valuesOUT = IsNull(@valuesOUT, '''') + ' +
CASE WHEN @top IS NULL OR @top < 0 THEN '' ELSE ' TOP ' + LTRIM(STR(@top)) + ' ' END +
'''' +
' '' + char(10) + CASE WHEN ROW_NUMBER() OVER (ORDER BY ' + @PK_column_list + ') = 1 THEN '' '' ELSE '','' END + ''(''+ ' + @Actual_Values + '+'')''' + ' ' +
COALESCE(@from,' FROM ' + @Source_Table_Qualified + ' (NOLOCK)')
....
DECLARE @values nvarchar(max);
DECLARE @ParmDefinition nvarchar(500);
SET @ParmDefinition = N'@valuesOUT nvarchar(max) OUTPUT';

EXECUTE sp_executesql @actual_values, @ParmDefinition, @valuesOUT=@values OUTPUT;
print @values;
....



This skips outputing the results to a table, sets the DB, and goes directly to the messages window, ready to copy and run.
john.moreno
john.moreno
Right there with Babe
Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)

Group: General Forum Members
Points: 787 Visits: 1115
One final note, you're comparing the columns using <> which fails to produce a match when either column is NULL. I replaced your single SOURCE.Column <> TARGET.Column check with
NULLIF(SOURCE.Column, TARGET.Column) IS NOT NULL OR NULLIF(TARGET.Column, SOURCE.Column) IS NOT NULL

NULLIF will return a NOT null value when the first parameter is non null and the second is parameter is NULL or another value.
danere
danere
SSC Journeyman
SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)

Group: General Forum Members
Points: 90 Visits: 157
Thanks John!

I've made a few changes based on your suggestions and attached v0.92:

1) The generated script now includes a "USE [DatabaseName]" statement at the start, if the @include_use_db (bit) param is set to 1 (default).
2) Fixed "has data changed?" check in the WHEN MATCHED clause to correctly test for NULL equality, on both sides (source & target).
3) Dynamic query string variable (@Actual_Values) expanded to NVARCHAR(MAX) to cope with longer SELECT statements.

Regarding the PRINT statement enhancement you suggested, I ran into an issue with truncation of result sets over 4000 characters in length. Any ideas how to get around this?
Attachments
master.dbo.sp_generate_merge.zip (29 views, 7.00 KB)
john.moreno
john.moreno
Right there with Babe
Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)Right there with Babe (787 reputation)

Group: General Forum Members
Points: 787 Visits: 1115
danere (4/15/2012)
Regarding the PRINT statement enhancement you suggested, I ran into an issue with truncation of result sets over 4000 characters in length. Any ideas how to get around this?


The problem is that PRINT can only print 4000/8000 characters (depending upon whether it is varchar or nvarchar), so the solution depends upon your data.

If all of the textual representation of the data in a single row will always fit within the limit, it's easy enough to loop over the results, printing out one line at a time. If it can be more than limit then it gets more complicated as print always prints a line at a time, if a single column can be more than the limit, then it's more complicated -- something could be done with varbinary, but I don't have that worked out offhand. Basically varbinary can be easily split and joined together, but I'm not sure about the best general purpose solution in that case (if it's just one column at the end, it shouldn't be too difficult to do)...
danere
danere
SSC Journeyman
SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)SSC Journeyman (90 reputation)

Group: General Forum Members
Points: 90 Visits: 157
john.moreno (4/16/2012)
The problem is that PRINT can only print 4000/8000 characters (depending upon whether it is varchar or nvarchar), so the solution depends upon your data.

If all of the textual representation of the data in a single row will always fit within the limit, it's easy enough to loop over the results, printing out one line at a time.


I think for most cases a 4000/8000 character limit per row isn't going to be an issue (none of the tables I have come close to this). I'll take a look at incorporating a loop to print it out each row separately as you suggested.

Btw I just noticed that there is a "Maximum number of characters displayed in each column" setting in SSMS, which is limited to 8192 characters. Not sure how this might affect the varbinary solution you mentioned (?).
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum







































































































































































SQLServerCentral


Search