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


How to get The Rows Count for 'With' table before using it ??


How to get The Rows Count for 'With' table before using it ??

Author
Message
ahmedhussein874
ahmedhussein874
SSC-Enthusiastic
SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)

Group: General Forum Members
Points: 183 Visits: 56
I want to get the total number of records for with Table before using it in a variable .. So any Ideas for how can I handle that
DECLARE @totalCount int
;WITH tmpTable AS (SELECT DISTINCT * ,ROW_NUMBER() OVER ( ORDER BY InventorySys ) AS RowNumber FROM dbo.Inventory)

SELECT @totalCount = Count(*) FROM tmpTable

SELECT * , @totalCount as RecordsCount
FROM tmpTable
WHERE (RowNumber BETWEEN @StartIndex AND @EndIndex) OR @StartIndex = 0 OR @EndIndex = 0
ORDER BY RowNumber



but I get this error Invalid object name 'tmpTable'.

I can handle it using SubQuery but i don't like that way a lot "SubQuery"

 ;WITH tmpTable AS (SELECT DISTINCT *  ,ROW_NUMBER() OVER (  ORDER BY  InventorySys  ) AS RowNumber  FROM dbo.Inventory) 

SELECT * , (SELECT Count(*) FROM tmpTable) as RecordsCount
FROM tmpTable
WHERE (RowNumber BETWEEN @StartIndex AND @EndIndex) OR @StartIndex = 0 OR @EndIndex = 0
ORDER BY RowNumber



So any Ideas for how can I handle that without using subquery Solution ???
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)

Group: General Forum Members
Points: 72606 Visits: 20464
It's basically the same as using the subquery but using another CTE.

WITH tmpTable AS (
SELECT DISTINCT *,
ROW_NUMBER() OVER ( ORDER BY InventorySys ) AS RowNumber
FROM dbo.Inventory
),
Total AS(
SELECT totalCount = Count(*)
FROM tmpTable
)
SELECT tmp.* , tot.totalCount as RecordsCount
FROM tmpTable tmp
CROSS JOIN Total tot
WHERE (tmp.RowNumber BETWEEN 1 AND 6) OR 1 = 0 OR 6 = 0
ORDER BY tmp.RowNumber




Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
Luis Cazares
Luis Cazares
SSC Guru
SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)SSC Guru (72K reputation)

Group: General Forum Members
Points: 72606 Visits: 20464
I just noticed the additional conditions on your WHERE clause that will always evaluate to false
 OR 1 = 0 OR 6 = 0 


Why do you even have them? What were you trying to accomplish?


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
dwain.c
dwain.c
SSC-Dedicated
SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)SSC-Dedicated (31K reputation)

Group: General Forum Members
Points: 31851 Visits: 6431
And then there's this:


SELECT DISTINCT * ,ROW_NUMBER() OVER ( ORDER BY InventorySys )




The DISTINCT has no meaning here (just drags down the performance) because the ROW_NUMBER() will ensure that each record is distinct.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
ahmedhussein874
ahmedhussein874
SSC-Enthusiastic
SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)

Group: General Forum Members
Points: 183 Visits: 56
Yes ..sorry for that ..It shall be startIndex and EndIndex Paramaters
ahmedhussein874
ahmedhussein874
SSC-Enthusiastic
SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)SSC-Enthusiastic (183 reputation)

Group: General Forum Members
Points: 183 Visits: 56
OK ..Thanks a lot "dwain.c" .. Yes your are right ..but that was just try to simplify my real script .. The Real Script has another columns order by ..But thanks a lot for your note Smile
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