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


Convert the stored procedure to "Standard SQL Select"


Convert the stored procedure to "Standard SQL Select"

Author
Message
halifaxdal
halifaxdal
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1999 Visits: 1744
Lynn Pettis (4/13/2014)
As much as I hate saying this, since semicolons are statement terminators not statement begininators, try putting a semicolon in front of the WITH of the CTE declaration. I.E. ;with ... .

Thank you, that's a good point.
halifaxdal
halifaxdal
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1999 Visits: 1744
As WITH is not allowed in this case, I did some replacement:
  FYStart = DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0))

FYPrevStart = DateAdd(yy,-1,FYStart)
FYPrevStart = DateAdd(yy,-1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)))

FYNextStart = DateAdd(yy,1,FYStart)
FYNextStart = DateAdd(yy,1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)))



The final working code is:


SELECT ITSDivisionID
,A = Sum(Case When d.DocStatus = 'Retired' and d.RetiredDate >= DateAdd(yy,-1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0))) and d.RetiredDate < DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)) Then 1 Else 0 End)
,B = Sum(Case When d.DocStatus = 'Active' Then 1 Else 0 End)
,C = Sum(Case When d.DocStatus = 'Active' and d.TargetClosureDate >= DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)) and d.TargetClosureDate < DateAdd(yy,1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0))) Then 1 Else 0 End)
,D = Sum(Case When d.DocStatus = 'Active' and d.TargetClosureDate >= DateAdd(yy,1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0))) Then 1 Else 0 End)
,Critical = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 4 Then 1 Else 0 End)
,High = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 3 Then 1 Else 0 End)
,Medium = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 2 Then 1 Else 0 End)
,Low = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 1 Then 1 Else 0 End)
,TBD = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 0 Then 1 Else 0 End)
FROM dbo.Document d
WHERE DocType = 1
AND DocStatus IN ('Active','Retired')
GROUP BY ITSDivisionID


It makes the whole query [highlight=#ffff11]much more difficult to read and maintain[/highlight], but good thing is it will accepted by the rule to manually create a Virtual Table in Dundas Dashboard.

I have not figured out how to do the math.
Lynn Pettis
Lynn Pettis
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40462 Visits: 38567
halifaxdal (4/14/2014)
As WITH is not allowed in this case, I did some replacement:
  FYStart = DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0))

FYPrevStart = DateAdd(yy,-1,FYStart)
FYPrevStart = DateAdd(yy,-1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)))

FYNextStart = DateAdd(yy,1,FYStart)
FYNextStart = DateAdd(yy,1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)))



The final working code is:


SELECT ITSDivisionID
,A = Sum(Case When d.DocStatus = 'Retired' and d.RetiredDate >= DateAdd(yy,-1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0))) and d.RetiredDate < DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)) Then 1 Else 0 End)
,B = Sum(Case When d.DocStatus = 'Active' Then 1 Else 0 End)
,C = Sum(Case When d.DocStatus = 'Active' and d.TargetClosureDate >= DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)) and d.TargetClosureDate < DateAdd(yy,1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0))) Then 1 Else 0 End)
,D = Sum(Case When d.DocStatus = 'Active' and d.TargetClosureDate >= DateAdd(yy,1,DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0))) Then 1 Else 0 End)
,Critical = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 4 Then 1 Else 0 End)
,High = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 3 Then 1 Else 0 End)
,Medium = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 2 Then 1 Else 0 End)
,Low = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 1 Then 1 Else 0 End)
,TBD = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 0 Then 1 Else 0 End)
FROM dbo.Document d
WHERE DocType = 1
AND DocStatus IN ('Active','Retired')
GROUP BY ITSDivisionID


It makes the whole query [highlight=#ffff11]much more difficult to read and maintain[/highlight], but good thing is it will accepted by the rule to manually create a Virtual Table in Dundas Dashboard.

I have not figured out how to do the math.


Here is the code rewritten without the CTE, curious to see if the derived tables will work in Dundas.



SELECT
ITSDivisionID
,A = Sum(Case When d.DocStatus = 'Retired' and d.RetiredDate >= fy.FYPrevStart and d.RetiredDate < fy.FYStart Then 1 Else 0 End)
,B = Sum(Case When d.DocStatus = 'Active' Then 1 Else 0 End)
,C = Sum(Case When d.DocStatus = 'Active' and d.TargetClosureDate >= fy.FYStart and d.TargetClosureDate < fy.FYNextStart Then 1 Else 0 End)
,D = Sum(Case When d.DocStatus = 'Active' and d.TargetClosureDate >= fy.FYNextStart Then 1 Else 0 End)
,Critical = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 4 Then 1 Else 0 End)
,High = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 3 Then 1 Else 0 End)
,Medium = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 2 Then 1 Else 0 End)
,Low = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 1 Then 1 Else 0 End)
,TBD = Sum(Case When d.DocStatus = 'Active' and d.RiskRating = 0 Then 1 Else 0 End)
FROM
dbo.Document d
CROSS JOIN (SELECT
FYStart
,FYNextStart = DateAdd(yy,1,FYStart)
,FYPrevStart = DateAdd(yy,-1,FYStart)
FROM
(SELECT FYStart = DateAdd(mm,-2,DateAdd(yy,DateDiff(yy,0,DateAdd(mm,2,Getdate())),0)))dt1
) fy
WHERE
DocType = 1
AND DocStatus IN ('Active','Retired')
GROUP BY
ITSDivisionID;




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)

Group: General Forum Members
Points: 88588 Visits: 41130
halifaxdal (4/13/2014)
[quote]Jeff Moden (4/13/2014)
There's a reason why it takes 2 weeks to get something into production. I suspect it's because people need time to test your code. So now YOU stop and think about it... YOU had an error in your code that mixed up the Fiscal Year with the Calendar Year. If YOU had put that into production, you might be looking for a new place to work! ;-)
[quote]

In my company, any changes must go through UAT and then PROD (IST is not rigorously required but is suggested), they are on different domains that are not communicable and require different user id to test and UAT does not have PROD data and we are not allowed to use PROD data in UAT. There is weekly meeting to approve those change request. For database change it involves four departments + at least 5 forms to be created and approved by up to Director.

I hope you can imagine the lengthy process and understand why I think sometimes Option 3 is the one I like to go (and also my manager), reason is very simple, I don't need to go through the bureaucratic and debatable procedures.



Actually, you do because that's the company policy and, right now, you're in violation of company policy. The logical error you wrote into the original cursor code is proof positive as to why the process is necessary. If you really want to do some good, spend some time to help streamline the process.

What you are currently doing is known as "cowboying" and if the people at the company find out, you could be out of a job and have one hell of a black mark against your name. The IT community is very well connected and the world is a whole lot smaller than you can imagine. Such a black mark will dog you for the rest of your career. Remember that just one "ah, crap!" can wipe out a thousand "atta-boys".

The only thing that I hope is that you don't write additional logical errors so that your actions don't actually hurt the company that's paying you.

--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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
halifaxdal
halifaxdal
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1999 Visits: 1744
Thank you Lynn and Jeff for your time, it's much appreciated.
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