February 26, 2013 at 12:49 pm
this is the code I used to retrieve a record set.
SELECT
p.HPROP,
p.STYPE,
p.SVALUE,
NSFFee = CASE WHEN p.STYPE = 'nsffee' THEN p.hvalue END,
SecDepIntRate = CASE WHEN p.STYPE = 'DDEPOSITINTEREST' THEN p.hvalue END
FROM PROPOPTIONS P
WHERE p.hprop = '240' and p.STYPE IN ('nsffee','DDEPOSITINTEREST')
my result is as followed
HPROPSTYPE SVALUENSFFeeSecDepIntRate
240DDEPOSITINTEREST0NULL3000.0000
240NSFFee 50.0000NULL
is there a way to get only one record or am i doint this wrong.
February 26, 2013 at 1:11 pm
You could use SELECT TOP 1, but I don't know if that's what you really want.
If you have more than one row meeting your search criteria, you should either want to return both or further refine your WHERE clause to return only the specific one you want. If you do want only one of them (say the last one added) and use TOP, make sure you include an ORDER BY clause to make the results consistent.
February 26, 2013 at 1:25 pm
That is not going to work for me.
February 26, 2013 at 1:35 pm
dmarz96 (2/26/2013)
That is not going to work for me.
So, what is it that you actually want? which of the two row do you want returned or do you want to somehow combine the rows? Be specific.
--Jeff Moden
Change is inevitable... Change for the better is not.
February 26, 2013 at 1:41 pm
The ladder I want to combine the rows into one record.
the code
SELECT
p.HPROP,
p.STYPE,
p.SVALUE,
NSFFee = CASE WHEN p.STYPE = 'nsffee' THEN p.hvalue END,
SecDepIntRate = CASE WHEN p.STYPE = 'DDEPOSITINTEREST' THEN p.hvalue END
FROM PROPOPTIONS P
WHERE p.hprop = '240' and p.STYPE IN ('nsffee','DDEPOSITINTEREST')
the result
HPROPSTYPE SVALUENSFFeeSecDepIntRate
240DDEPOSITINTEREST0NULL3000.0000
240NSFFee 50.0000NULL
what I'm looking for is
hprop nsffee SecDepIntRate
240 50.0000 3000.0000
February 26, 2013 at 6:45 pm
Like this?
WITH PriorResults (HPROP, STYPE, SVALUE, NSFFee, SecDepIntRate)
AS (
SELECT 240, 'DDEPOSITINTEREST', 0, NULL, 3000.0000
UNION ALL SELECT 240, 'NSFFee', 0, 50.0000, NULL
)
SELECT HPROP
,NSFFee=SUM(NSFFee)
,SecDepIntRate=SUM(SecDepIntRate)
FROM PriorResults
GROUP BY HPROP
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
February 26, 2013 at 8:29 pm
dwain.c (2/26/2013)
Like this?
Looks like it. Heh... we make a hell of a tag team. I'll flush out the requiremments, you write the code. ๐
--Jeff Moden
Change is inevitable... Change for the better is not.
February 26, 2013 at 8:36 pm
Jeff Moden (2/26/2013)
dwain.c (2/26/2013)
Like this?Looks like it. Heh... we make a hell of a tag team. I'll flush out the requiremments, you write the code. ๐
Yeah, aren't we though?
I did have to make an assumption (the 0 in the second row of the set up data) as the OP only provided 4 data columns in that row but 5 in the first row.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
February 26, 2013 at 8:44 pm
dwain.c (2/26/2013)
I did have to make an assumption (the 0 in the second row of the set up data) as the OP only provided 4 data columns in that row but 5 in the first row.
Agreed.
Just to give you a leg up for your future posts, take a look at the article at the first link in my signature line below. It'll really help you get a very high quality coded answer in a pretty short time.
--Jeff Moden
Change is inevitable... Change for the better is not.
February 27, 2013 at 1:14 am
Jeff Moden (2/26/2013)
dwain.c (2/26/2013)
I did have to make an assumption (the 0 in the second row of the set up data) as the OP only provided 4 data columns in that row but 5 in the first row.Agreed.
Just to give you a leg up for your future posts, take a look at the article at the first link in my signature line below. It'll really help you get a very high quality coded answer in a pretty short time.
Jeff, you and Dwain may have missed the preceeding part of this case.
@dmarz96, it's much easier to see what you are trying to do, now that I've seen both threads. Often, breaking a case up into different threads like this causes confusion and fragmented replies as no single thread has all of the information required to put together a solution.
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
February 27, 2013 at 1:28 am
, x.FAC_ACTIVITY [FAC_ACTIVITY]
, x.NUMMAINTEMP [NUMMAINTEMP]
, LH.dtLeaseFrom [LHdtLeaseFrom]
, LH.dtLeaseTo [LHdtleaseto]
, crp.destimated [crpdestimated]
--, pps.HValue [ppsNSFFEE]
,pps.NSFFee
,pps.MTMFee
,pps.SecDepIntRate
, m.stext [memoStext]
FROM vw_DK_RMMISCDATA x
LEFT JOIN Property p
ON x.RM_ID = p.sCode
OUTER APPLY ( -- flatten relevant rows from PropOptions
SELECT
HPROP= MAX(po.HPROP),
STYPE= MAX(po.STYPE),
SVALUE= MAX(po.SVALUE),
NSFFee= MAX(CASE WHEN po.STYPE = 'nsffee' THEN po.hvalue END),
MTMFee= MAX(CASE WHEN po.STYPE = 'MTMFee' THEN po.hvalue END),
SecDepIntRate = MAX(CASE WHEN po.STYPE = 'DDEPOSITINTEREST' THEN po.hvalue END)
FROM PROPOPTIONS po
WHERE po.HPROP = p.hmy -- outer reference
AND po.STYPE IN ('nsffee', 'MTMFee', 'DDEPOSITINTEREST') -- filter
) pps
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
February 27, 2013 at 4:50 am
ChrisM@Work (2/27/2013)
Jeff, you and Dwain may have missed the preceeding part of this case.@dmarz96, it's much easier to see what you are trying to do, now that I've seen both threads. Often, breaking a case up into different threads like this causes confusion and fragmented replies as no single thread has all of the information required to put together a solution.
Indeed I did but it looks like you've got it covered.
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?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
February 27, 2013 at 5:39 am
dmarz96 (2/26/2013)is there a way to get only one record or am i doint this wrong.
I think this is the statement that caused me to think only one of the rows was required.
February 27, 2013 at 5:41 am
Thank you, Jeff and Dwain, for following up.
Viewing 14 posts - 1 through 13 (of 13 total)
You must be logged in to reply to this topic. Login to reply