December 21, 2010 at 9:26 pm
This is a good basic question, thank you. One thing I would like to point out is that the update script in question is more complex than it needs to be and it uses what Jeff Moden calls a triangular join, which is one of the most evil things one can do to kill performance of the T-SQL query. Of course back in the dark ages when we had to work with SQL Server 2000, the triangular joins were a necessary evil sometimes, but in nowadays when the end of support for SQL Server 2000 is long as ended and the end of support for SQL Server 2005 is looming (12 of April 2011), it is about time to stop the triangular joins insanity and take a look at the windowing functions instead. For example, the update in question can be easily restated like this:
;with records (RecID, Seq) as
(
select
RecID, row_number() over(partition by Value order by RecID)
from #Test
)
update #Test
set
Seq = records.Seq
from #Test inner join records
on #Test.RecID = records.RecID;
Please, please read Jeff's article: http://www.sqlservercentral.com/articles/T-SQL/61539/[/url]
It is a true eye opener!
Just my 2 cents.
Oleg
December 21, 2010 at 10:48 pm
Good question.
Thanks 'Oleg Netchaev' for query & link.
Thanks
December 22, 2010 at 1:08 am
Nice question, thanks also Oleg for the remark and link to Triangular Joins.
Regards,
Iulian
December 22, 2010 at 2:17 am
The question itself was OK, as a test to see what output the T-SQL would give.
But not OK for the purpose mentioned in the explanation, as there are other statements that will do it much better and faster (as Oleg has already mentioned).
Need an answer? No, you need a question
My blog at https://sqlkover.com.
MCSE Business Intelligence - Microsoft Data Platform MVP
December 22, 2010 at 3:59 am
I get a pile of errors when I run it - Cannot insert the value NULL into column 'Seq'.
I eventually worked out that this is because I have ANSI_NULL_DFLT_ON set to False, so Seq was added as a Not Null column.
This never normally affects me, as I always specify NULL or NOT NULL and don't rely on a default, but can anyone point me in the direction of where this might be set?
December 22, 2010 at 4:06 am
Good question.
Regards,
Jagan.
December 22, 2010 at 5:16 am
Toreador (12/22/2010)
I get a pile of errors when I run it - Cannot insert the value NULL into column 'Seq'.I eventually worked out that this is because I have ANSI_NULL_DFLT_ON set to False, so Seq was added as a Not Null column.
This never normally affects me, as I always specify NULL or NOT NULL and don't rely on a default, but can anyone point me in the direction of where this might be set?
Right-click on the database in SSMS, select properties and in the properties editor select the options tab. There you can set the value for 'ANSI NULL default'. You can also use the sp_dboption procedure.
Need an answer? No, you need a question
My blog at https://sqlkover.com.
MCSE Business Intelligence - Microsoft Data Platform MVP
December 22, 2010 at 7:14 am
I got it right based on the fact that an update statement shouldn't ever be able to change the number of records in a table - since 8 rows were inserted the only possible answer was the first one (assuming there was no error). I got it right but was I correct in making that assumption or did I just get lucky? I can't think of any circumstance where an update would do that but have I missed something?
Paul
December 22, 2010 at 8:13 am
paul.goldstraw (12/22/2010)
I got it right based on the fact that an update statement shouldn't ever be able to change the number of records in a table - since 8 rows were inserted the only possible answer was the first one (assuming there was no error). I got it right but was I correct in making that assumption or did I just get lucky? I can't think of any circumstance where an update would do that but have I missed something?Paul
Unless you implement the update as an delete and an insert and something goes horribly wrong in between, I would be very surprised 🙂
Need an answer? No, you need a question
My blog at https://sqlkover.com.
MCSE Business Intelligence - Microsoft Data Platform MVP
December 22, 2010 at 8:28 am
da-zero (12/22/2010)
paul.goldstraw (12/22/2010)
I got it right based on the fact that an update statement shouldn't ever be able to change the number of records in a table - since 8 rows were inserted the only possible answer was the first one (assuming there was no error). I got it right but was I correct in making that assumption or did I just get lucky? I can't think of any circumstance where an update would do that but have I missed something?Paul
Unless you implement the update as an delete and an insert and something goes horribly wrong in between, I would be very surprised 🙂
That's what I thought 🙂 Thanks for the confirmation
Paul
December 22, 2010 at 4:16 pm
Thanks for the question
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
December 24, 2010 at 6:25 pm
Thank you all for your comments. LIttle history behind why i came up with this querey. I work as a sql dba and report writer for a legal collections agency. we have tables were there are multiple rows for each account something to the nature of the below example
accoount field
1234 12345678
1234 90123456
1234 78901234
the field value is phone numbers or other data that was given to us by clients. what i was tasked to do was get all those numbers in one row
1234 12345678 90123456 78901234
using this statement i am able to get all instances of a sepcific account and line up the varios numbers given to us by clients. i am going to try the suggestions i have seen here to change the query for more effeciency. what i am doing is loading the different instances of accounts into temp tables updating the sequence so that i can join in my final report. i am out of the office until tuesday but once back in office i will post my final query that i use for my report and possibly that will shed more light as to my madness 🙂
Again thank you all for comments.
December 28, 2010 at 10:52 am
Thanks for the question.
December 28, 2010 at 1:03 pm
Oleg Netchaev (12/21/2010)
For example, the update in question can be easily restated like this:
Or, even more succinctly:
WITH Records (Old_Seq, New_Seq)
AS (
SELECT Seq,
ROW_NUMBER() OVER (PARTITION BY Value ORDER BY RecID)
FROM #Test
)
UPDATE Records
SET Old_Seq = New_Seq;
Paul
Viewing 15 posts - 1 through 15 (of 16 total)
You must be logged in to reply to this topic. Login to reply