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
 General SQL Server Forums
 New to SQL Server Programming
 How to pivot only few selected columns in SQL serv

Author  Topic 

rjv1704
Starting Member

1 Post

Posted - 2011-08-05 : 05:10:28
How to pivot only few selected columns in SQL server?
I have query output with 3 records as follows

A B 1
A B 2
A B 3

Now I need to pivot the table in such a way that the output is one line with non-unique (repeating) columns form first 2 columns and unique values each form one column value each

eg

A B 1 2 3


Rjv

Transact Charlie
Master Smack Fu Yak Hacker

3451 Posts

Posted - 2011-08-05 : 05:50:14
You could do something like this:

DECLARE @sample TABLE (
[fieldA] CHAR(1)
, [fieldB] CHAR(1)
, [value] INT
)

INSERT @sample
VALUES
('A', 'B', 1), ('A', 'B', 2), ('A', 'B', 3)
, ('A', 'C', 4), ('A', 'C', 25), ('A', 'C', -10)

-- SELECT * FROM @sample

SELECT
rs.[fieldA]
, rs.[fieldB]
, MAX(CASE rs.[idx] WHEN 1 THEN [value] ELSE NULL END) AS [1]
, MAX(CASE rs.[idx] WHEN 2 THEN [value] ELSE NULL END) AS [2]
, MAX(CASE rs.[idx] WHEN 3 THEN [value] ELSE NULL END) AS [3]
FROM
(
SELECT
[fieldA]
, [fieldB]
, [value]
, ROW_NUMBER() OVER ( PARTITION BY [fieldA], [fieldB] ORDER BY [value] ) AS [idx]
FROM
@sample
)
AS rs
GROUP BY
[fieldA]
, [fieldB]

Results

fieldA fieldB 1 2 3
------ ------ ----------- ----------- -----------
A B 1 2 3
A C -10 4 25


Charlie
===============================================================
Msg 3903, Level 16, State 1, Line 1736
The ROLLBACK TRANSACTION request has no corresponding BEGIN TRANSACTION
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2011-08-08 : 04:26:15
will the number of values to be pivoted be static? else you might need to use dynamic sql

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

Go to Top of Page
   

- Advertisement -