August 9, 2007 at 8:51 pm
Hi,
Im trying to output a column saying the kpi_desc of a sale depending on the conditions, however my case statement is wrong, Im not sure if this sort of conditioning is allowed by SQL, can someone please help or point me in another direction
SELECT Sum(dbo.tbl_kpi_sales.Value) AS SumOfValue, dbo.tblCampaign.idMacroSegment, dbo.tblCampaign.idCampaignType, dbo.tbl_kpi_sales.idKPI, dbo.tbl_kpi_sales.State,
kpi_desc = case dbo.when dbo.tblCampaign.idMacroSegment = 1 then
case dbo.tbl_kpi_sales.idKPI
when 2509 then 'Con Std'
when 2513 then 'Con Std'
Else
when 2500 then 'SME Std'
when 2507 then 'SME Std'
end
elseif case dbo.when dbo.tblCampaign.idMacroSegment = 2 then
case dbo.tbl_kpi_sales.idKPI
when 2509 then 'Con Acc'
when 2513 then 'Con Acc'
Else
when 2500 then 'SME Acc'
when 2507 then 'SME Acc'
end
end
FROM ((dbo.tbl_kpi_sales INNER JOIN dbo.vw_SalesRepsByState_Unique ON dbo.tbl_kpi_sales.Consultant = dbo.vw_SalesRepsByState_Unique.UserID) INNER JOIN dbo.tblCampaign ON dbo.tbl_kpi_sales.idCampaign = dbo.tblCampaign.idCampaign) INNER JOIN dbo.tblCampaignType ON dbo.tblCampaign.idCampaignType = dbo.tblCampaignType.idCampaignType
WHERE (((dbo.tbl_kpi_sales.State) Is Not Null) AND ((dbo.tbl_kpi_sales.idKPI)=2500 Or (dbo.tbl_kpi_sales.idKPI)=2507 Or (dbo.tbl_kpi_sales.idKPI)=2509 Or (dbo.tbl_kpi_sales.idKPI)=2513 Or (dbo.tbl_kpi_sales.idKPI)=3007 Or (dbo.tbl_kpi_sales.idKPI)=3006 Or (dbo.tbl_kpi_sales.idKPI)=3004 Or (dbo.tbl_kpi_sales.idKPI)=3005))
GROUP BY dbo.tblCampaign.idMacroSegment, dbo.tblCampaign.idCampaignType, dbo.tbl_kpi_sales.idKPI, dbo.tbl_kpi_sales.State
ORDER BY dbo.tblCampaign.idMacroSegment
August 9, 2007 at 9:44 pm
kpi_desc = case dbo.tblCampaign.idMacroSegment
when 1
then
case dbo.tbl_kpi_sales.idKPI
when 2509 then 'Con Std'
when 2513 then 'Con Std'
when 2500 then 'SME Std'
when 2507 then 'SME Std'
end
when 2
then
case dbo.tbl_kpi_sales.idKPI
when 2509 then 'Con Acc'
when 2513 then 'Con Acc'
when 2500 then 'SME Acc'
when 2507 then 'SME Acc'
end
END
_____________
Code for TallyGenerator
August 9, 2007 at 11:01 pm
Thanks a heaps Sergiy
August 10, 2007 at 2:09 am
August 10, 2007 at 7:50 am
Pretty sure "OR" can't be used here....
SELECT CASE RowNum
WHEN 1 OR 10 THEN '1 or 10'
ELSE 'Not 1 or 10'
END
FROM jbmTest
WHERE RowNum <=10
Server: Msg 156, Level 15, State 1, Line 3
Incorrect syntax near the keyword 'or'.
--Jeff Moden
Change is inevitable... Change for the better is not.
August 10, 2007 at 8:24 am
August 10, 2007 at 8:32 am
No, not with this type of CASE statement. It could be done like this:
SELECT CASE
WHEN RowNum IN(1, 10) THEN '1 or 10'
ELSE 'Not 1 or 10'
END
FROM jbmTest
WHERE RowNum <=10
or, to use the CASE that was being asked about:
kpi_desc = CASE WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (2509,2513) THEN 'Con Std'
WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (2500,2507) THEN 'SME Std'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (2509,2513) THEN 'Con Acc'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (2500,2507) THEN 'SME Acc'
END
I have no idea whether there is some performance difference when compared with the statement Sergiy posted, but both statements would return the same result (unless I misread something..)
August 10, 2007 at 9:20 am
August 10, 2007 at 9:26 am
August 14, 2007 at 8:12 pm
Thanks for the help guys, I did a performance test and to render my report the query below took 31 secs - the query below this one using the nested cases took abt 35 secs...so im sticking with the IN clause as it is also much neater...
kpi_desc = CASE WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (2509,2513) AND dbo.tblCampaign.idCampaignType IN (16,17,21,22,24,30,31) THEN 'SME Std'
WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (2509,2513) AND dbo.tblCampaign.idCampaignType IN (18,20,23) THEN 'SME Acc'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (2509,2513) AND dbo.tblCampaign.idCampaignType IN (16,17,21,22,24,30,31) THEN 'Con Std'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (2509,2513) AND dbo.tblCampaign.idCampaignType IN (18,20,23) THEN 'Con Acc'
WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (2500,2507) AND dbo.tblCampaign.idCampaignType IN (16,17,18,21,22,24,30,31) THEN 'SME Std'
WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (2500,2507) AND dbo.tblCampaign.idCampaignType IN (20,23) THEN 'SME Acc'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (2500,2507) AND dbo.tblCampaign.idCampaignType IN (16,17,22,21,24,30,31) THEN 'Con Std'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (2500,2507) AND dbo.tblCampaign.idCampaignType IN (18,20,23) THEN 'Con Acc'
WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (3004) THEN 'Mob New'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (3004) THEN 'Mob New'
WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (3005) THEN 'Mob Ret'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (3005) THEN 'Mob Ret'
WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (3006) THEN 'Brd Band'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (3006) THEN 'Brd Band'
WHEN dbo.tblCampaign.idMacroSegment = 1 AND dbo.tbl_kpi_sales.idKPI IN (3007) THEN 'Pay TV'
WHEN dbo.tblCampaign.idMacroSegment = 2 AND dbo.tbl_kpi_sales.idKPI IN (3007) THEN 'Pay TV'
END
against this query
kpi_desc = case dbo.tbl_kpi_sales.idKPI
when 3004 then '11. Mob New'
when 3005 then '12. Mob Ret'
when 3006 then '9. Brd Band'
when 3007 then '10. Pay TV'
when 2509
then
case dbo.tblCampaign.idMacroSegment
when 1
then
Case dbo.tblCampaign.idCampaignType
when 18 then '6. SME Acc'
when 20 then '6. SME Acc'
when 23 then '4. SF Acc'
when 16 then '5. SME Std'
when 17 then '5. SME Std'
when 21 then '3. SF Std'
when 22 then '3. SF Std'
when 24 then '5. SME Std'
when 30 then '5. SME Std'
when 31 then '5. SME Std'
end
when 2
then
Case dbo.tblCampaign.idCampaignType
when 18 then '2. Con Acc'
when 20 then '2. Con Acc'
when 23 then '4. SF Acc'
when 16 then '1. Con Std'
when 17 then '1. Con Std'
when 22 then '3. SF Std'
when 21 then '3. SF Std'
when 24 then '1. Con Std'
when 30 then '1. Con Std'
when 31 then '1. Con Std'
end
end
when 2513
then
case dbo.tblCampaign.idMacroSegment
when 1
then
Case dbo.tblCampaign.idCampaignType
when 18 then '6. SME Acc'
when 20 then '6. SME Acc'
when 23 then '4. SF Acc'
when 16 then '5. SME Std'
when 17 then '5. SME Std'
when 21 then '3. SF Std'
when 22 then '3. SF Std'
when 24 then '5. SME Std'
when 30 then '5. SME Std'
when 31 then '5. SME Std'
end
when 2
then
Case dbo.tblCampaign.idCampaignType
when 18 then '2. Con Acc'
when 20 then '2. Con Acc'
when 23 then '4. SF Acc'
when 16 then '1. Con Std'
when 17 then '1. Con Std'
when 22 then '3. SF Std'
when 21 then '3. SF Std'
when 24 then '1. Con Std'
when 30 then '1. Con Std'
when 31 then '1. Con Std'
end
end
when 2500
then
case dbo.tblCampaign.idMacroSegment
when 1
then
Case dbo.tblCampaign.idCampaignType
when 16 then '5. SME Std'
when 17 then '5. SME Std'
when 18 then '5. SME Std'
when 20 then '6. SME Acc'
when 21 then '3. SF Std'
when 22 then '3. SF Std'
when 23 then '4. SF Acc'
when 24 then '5. SME Std'
when 30 then '5. SME Std'
when 31 then '5. SME Std'
end
when 2
then
Case dbo.tblCampaign.idCampaignType
when 16 then '1. Con Std'
when 17 then '1. Con Std'
when 21 then '3. SF Std'
when 22 then '3. SF Std'
when 24 then '1. Con Std'
when 30 then '1. Con Std'
when 31 then '1. Con Std'
when 20 then '2. Con Acc'
when 18 then '2. Con Acc'
when 23 then '4. SF Acc'
end
end
when 2507
then
case dbo.tblCampaign.idMacroSegment
when 1
then
Case dbo.tblCampaign.idCampaignType
when 16 then '5. SME Std'
when 17 then '5. SME Std'
when 18 then '5. SME Std'
when 20 then '6. SME Acc'
when 21 then '3. SF Std'
when 22 then '3. SF Std'
when 23 then '4. SF Acc'
when 24 then '5. SME Std'
when 30 then '5. SME Std'
when 31 then '5. SME Std'
end
when 2
then
Case dbo.tblCampaign.idCampaignType
when 16 then '1. Con Std'
when 17 then '1. Con Std'
when 21 then '3. SF Std'
when 22 then '3. SF Std'
when 24 then '1. Con Std'
when 30 then '1. Con Std'
when 31 then '1. Con Std'
when 20 then '2. Con Acc'
when 18 then '2. Con Acc'
when 23 then '4. SF Acc'
end
end
end
August 14, 2007 at 8:31 pm
If you would use 30% of effort you wasted on this script for building tables holding all those conditions you'd get clean, short script implementing manageable solution.
By "manageable" I mean a solution when users don't need you to change a rule, they can do it by themselves from UI by adding or removing records in look-up tables.
_____________
Code for TallyGenerator
Viewing 11 posts - 1 through 10 (of 10 total)
You must be logged in to reply to this topic. Login to reply