Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 SQL Server 2008 Forums
 Transact-SQL (2008)
 Need Help on MIN and MAX

Author  Topic 

Sql_forum
Yak Posting Veteran

50 Posts

Posted - 2012-01-12 : 23:19:23
ITEMITEM AGE_FRM AGE_TO
ABCD 10 20
ABCD 21 30
ABCD 31 40
ABCD 0 0
ABCD 0 0
PQRS 0 0
PQRS 0 0
PQRS 0 0
PQRS 0 0
PQRS 0 0

I have above ITEMS in a table, for each ITEM i have 5 Age Min and Max values.

Case 1 :
If i give component as ABCD and @Age as 45, i don't get any records, in that case i want to return MIN(AGE_FRM),MAX(AGE_TO) fot that ITEM,
i don't want ZERO to be taken in MIN value.

Case 2 :
For PQRS Item also , i want MIN(AGE_FRM), MAX(AGE_TO). Here i am ok, if i get ZERO in MIN value as there are Zeroes in all age bands for PQRS


Please help me to build the query

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-01-13 : 03:31:06
[code]
SELECT t.ITEMITEM,COALESCE(AGE_FRM,MinAge,0) AS AGE_FRM,
COALESCE(AGE_TO,MaxAge,0) AS AGE_TO
FROM
(
SELECT DISTINCT ITEMITEM
FROM table
WHERE ITEMITEM = @Yourpasseditem
)t
OUTER APPLY(SELECT AGE_FRM, AGE_TO
FROM table
WHERE ITEMITEM = t.ITEMITEM
AND @Age BETWEEN AGE_FRM AND AGE_TO
)t1
OUTER APPLY (SELECT MIN(CASE WHEN AGE_FRM >0 THEN AGE_FRM END) AS MinAge,
MAX(CASE WHEN AGE_TO >0 THEN AGE_TO END) AS MaxAge
FROM table
WHERE ITEMITEM = t.ITEMITEM
)t1
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

30421 Posts

Posted - 2012-01-13 : 04:51:26
If you prefer a one-pass solution over a three-pass solution, try this
DECLARE	@Sample TABLE
(
ITEMITEM VARCHAR(10),
AGE_FRM INT,
AGE_TO INT
)

INSERT @Sample
VALUES ('ABCD', 10, 20),
('ABCD', 21, 30),
('ABCD', 31, 40),
('ABCD', 0, 0),
('ABCD', 0, 0),
('PQRS', 0, 0),
('PQRS', 0, 0),
('PQRS', 0, 0),
('PQRS', 0, 0),
('PQRS', 0, 0)


DECLARE @ItemItem VARCHAR(10) = 'ABCD',
@Age INT = 45

-- SwePeso
SELECT ItemItem,
ISNULL(MAX(AgeFrom), 0) AS Age_Frm,
ISNULL(MIN(AgeTo), 0) AS Age_To
FROM (
SELECT ItemItem,
CASE
WHEN @Age BETWEEN Age_Frm AND Age_To THEN Age_Frm
ELSE MIN(NULLIF(Age_Frm, 0)) OVER (PARTITION BY ItemItem)
END AS AgeFrom,
CASE
WHEN @Age BETWEEN Age_Frm AND Age_To THEN Age_To
ELSE MAX(NULLIF(Age_To, 0)) OVER (PARTITION BY ItemItem)
END AS AgeTo
FROM @Sample
WHERE ItemItem = @ItemItem
) AS d
GROUP BY ItemItem



N 56°04'39.26"
E 12°55'05.63"
Go to Top of Page
   

- Advertisement -