SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2000 Forums
 SQL Server Development (2000)
 how to do this where is error
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

creatives
Starting Member

Norway
1 Posts

Posted - 11/19/2012 :  03:56:35  Show Profile  Reply with Quote
select a.memberid,sum(a.MonthlyBonus)as MonthlyBonus,sum(a.FestivalBonus)as FestivalBonus,(a.OfficerBonus)as OfficerBonus from a
(
select memberid,sum(amount)as MonthlyBonus,0 as FestivalBonus,0 as OfficerBonus from tblmember_comission where tag='MB' group by memberid,amount
union all
select memberid,0 as MonthlyBonus,sum(amount)as FestivalBonus,0 as OfficerBonus from tblmember_comission where tag='FB' group by memberid
union all
select memberid,0 as MonthlyBonus,0 as FestivalBonus,sum(amount)as OfficerBonus from tblmember_comission where tag='OB' group by memberid) a

Edited by - creatives on 11/19/2012 03:58:05

sunitabeck
Flowing Fount of Yak Knowledge

5155 Posts

Posted - 11/19/2012 :  06:40:08  Show Profile  Reply with Quote
Remove the "a" at the end of the first line - see in red below:
select a.memberid,sum(a.MonthlyBonus)as MonthlyBonus,sum(a.FestivalBonus)as FestivalBonus,(a.OfficerBonus)as OfficerBonus from a
(
...
You can shorten the code as shown below, which would avoid the UNION ALL and the subquery, and so is likely to be more efficient as well
SELECT
	memberid,
	SUM(CASE WHEN tag = 'MB' THEN amount ELSE 0 END) AS MonthlyBonus,
	SUM(CASE WHEN tag = 'FB' THEN amount ELSE 0 END) AS FestivalBonus,
	SUM(CASE WHEN tag = 'OB' THEN amount ELSE 0 END) AS OfficerBonus
FROM
	tblmember_comission
GROUP BY
	memberid;

Edited by - sunitabeck on 11/19/2012 06:40:27
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

India
52325 Posts

Posted - 11/20/2012 :  03:00:37  Show Profile  Reply with Quote
or even this if sql 2005 and above


SELECT member_id,
[MB] AS MonthlyBonus,
[FB] AS FestivalBonus,
[OB] AS OfficerBonus
FROM (SELECT member_id,tag,amount FROM tblmember_comission)t
PIVOT(SUM(amount) FOR tag IN ([MB],[FB],[OB]))p


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

Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.06 seconds. Powered By: Snitz Forums 2000