Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Assistance with PIVOT


Assistance with PIVOT

Author
Message
Mark Briscombe
Mark Briscombe
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 27
I have looked through many examples on the web for PIVOT commands, but am still struggling to find the right way of doing it. Its probably somehitng really simple that i am missing, but if you could help me that would be great Smile

I am creating a database to handle ranking points for Badminton, and have created a table with the following structure:

create table tempstore(
tmp_agegrp varchar(5), -- age group of the players U12 / U14 etc
tmp_event varchar(5), -- event type MS, WS, MD, WD, XD
tmp_event_id numeric (3,0), -- Event code (numeric which is a FK to the events table)
tmp_playerno numeric (5,0), -- Unique player number (numeric which is a FK to the players table)
tmp_points numeric (5,0) -- ranking points obtained in that event.
)

the format that has been requested by my provincial body is:

Age_group Event Player_number Event1 Event2 Total
U12 MS 1 100 100 200

etc.


All the examples i have seen online tend to have one field as the key on the left side, where as here i have 3 (age, event, playernumber) and this is where i am having problems as i cant seem to find the right syntax in the TSQL to merge these together.

As i said, might be something stupidly simple that i am missing, but its gone midnight now and brain is shutting down!

If anyone has done anything similar and would like to share their code your help would be very much appreciated before i resort to manual extracts and EXCEL VLOOKUPS! Smile

Thanks in advance.
ChrisM@Work
ChrisM@Work
SSCrazy Eights
SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)SSCrazy Eights (9K reputation)

Group: General Forum Members
Points: 9011 Visits: 19028
Hi Mark, this looks like a straightforward CROSSTAB query. Have a quick read of this article which will show you how to set up a few rows of sample data. You can read about crosstab queries here.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

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
Exploring Recursive CTEs by Example Dwain Camps
Mark Briscombe
Mark Briscombe
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 27
Thanks for the tip Chris, I have never come across the CASE command before.

was easy in the end Smile

select r.r_age_group, r.r_event, p.firstname + ' ' + p.surname,
sum(case when r.r_event_id=1 then r.r_points else 0 END) as 'Event1',
sum(case when r.r_event_id=2 then r.r_points else 0 END) as 'Event2',
sum(r.r_points) as 'Total'
from results r, player p
where r.r_player_number = p.player_number
group by r.r_age_group, r.r_event, p.firstname + ' ' + p.surname
order by r.r_age_group, r.r_event, total desc



Thanks again Smile
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