Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Dealing with Incomplete Data - A T-SQL Puzzle 1


Dealing with Incomplete Data - A T-SQL Puzzle 1

Author
Message
Suresh Kumar Maganti
Suresh Kumar Maganti
SSC-Enthusiastic
SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)

Group: General Forum Members
Points: 169 Visits: 125
Comments posted to this topic are about the item Dealing with Incomplete Data - A T-SQL Puzzle 1


Kindest Regards,

M Suresh Kumar

ChrisM@Work
ChrisM@Work
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10170 Visits: 19212
What a really nicely written article to start the day off with, very enjoyable.

Suresh, have you tried using CROSS APPLY to partition the rows into "records" as an alternative to calculating the upper and lower bound? You can then sequence the rows within each "record", then by joining the result to itself (staggered by one row), identification of missing data is quite simple:

;WITH OrderedData AS (
SELECT
Seq_No,
cdata,
x.RowID,
rn = ROW_NUMBER() OVER(PARTITION BY x.RowID ORDER BY p.Seq_No)
FROM #Test_Table p
CROSS APPLY (
SELECT RowID = MAX(Seq_No)
FROM #Test_Table
WHERE CData = '*********************************************' AND Seq_No <= p.Seq_No
) x
)
SELECT t.*
FROM OrderedData t
WHERE t.RowID IN (
SELECT r1.RowID
FROM OrderedData r1
INNER JOIN OrderedData r2
ON r2.RowID = r1.RowID AND r2.rn = r1.rn + 1
WHERE r1.CData = 'RateQuote' AND r2.CData = ' ')



I wonder how this would perform against the original?

Cheers

ChrisM

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
aspiring_dba
aspiring_dba
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 68
Dear Sir,
Very good use of CTE. I learn to know the real strength of CTE after reading this article.

The best thing about CTE is that it keeps the readability of the code. Its very easy to understand the approach of a developer in the solutions based on CTE feature.

and also the real life Scenario u have given here helps me to understand the kind of problems and real world situation that can arise before DBA.

I am new in this forum and I want to be good DBA.

Now i know that i am going to learn a lot here.


Thanks...
aspiring_dba
aspiring_dba
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 68
Dear Sir,
This is really very good alternative solution.

Can't I delete the selected bad rows in the same statement like this....


WITH OrderedData AS (
SELECT
Seq_No,
cdata,
x.RowID,
rn = ROW_NUMBER() OVER(PARTITION BY x.RowID ORDER BY p.Seq_No)
FROM #Test_Table p
CROSS APPLY (
SELECT RowID = MAX(Seq_No)
FROM #Test_Table
WHERE CData = '*********************************************' AND Seq_No <= p.Seq_No
) x
)
Delete from t
output deleted.Seq_No, deleted.CData
into dbo.Test_Table_Bad_Records
FROM OrderedData t
WHERE t.RowID IN (
SELECT r1.RowID
FROM OrderedData r1
INNER JOIN OrderedData r2
ON r2.RowID = r1.RowID AND r2.rn = r1.rn + 1
WHERE r1.CData = 'RateQuote' AND r2.CData = ' ')




Thanks..
Suresh Kumar Maganti
Suresh Kumar Maganti
SSC-Enthusiastic
SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)

Group: General Forum Members
Points: 169 Visits: 125
Hi Chris,
Thanks for the nice feedback.
I appreciate and like the solution you have provided. Your code is shorter too for which I like it even more.
Just to see from a performance perspective, I tried executing both the code snippets in the same batch. The Query cost (relative to the batch) was 17% for the one in the article. The same for the alternative version was 83%.
Notwithstanding the minor performance difference since the data volume in the code is very limited, I still like your code for its brevity.

------Thanks and Best Regards,
Suresh.


Kindest Regards,

M Suresh Kumar

Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)SSC Guru (51K reputation)

Group: General Forum Members
Points: 51491 Visits: 40305
Suresh Kumar Maganti (11/22/2011)
The Query cost (relative to the batch) was 17% for the one in the article. The same for the alternative version was 83%.


The query cost relative to the batch actually doesn't mean much. It's quite easy to write queries that doe the same thing where one will be 100% of the batch and the other will be 0% and yet, when you run them, the 0% query take take several seconds where the 100% query runs so fast it almost isn't measureable.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
floresg2
floresg2
Grasshopper
Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)Grasshopper (13 reputation)

Group: General Forum Members
Points: 13 Visits: 584
Jeff Moden (11/22/2011)
Suresh Kumar Maganti (11/22/2011)
The Query cost (relative to the batch) was 17% for the one in the article. The same for the alternative version was 83%.


The query cost relative to the batch actually doesn't mean much. It's quite easy to write queries that doe the same thing where one will be 100% of the batch and the other will be 0% and yet, when you run them, the 0% query take take several seconds where the 100% query runs so fast it almost isn't measureable.


I'm relatively new to SQL tuning. I haven't heard of that happening. Can you explain how or why that might happen? Thank you.
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