SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Changing the table structure


Changing the table structure

Author
Message
Solitary Reaper
Solitary Reaper
SSC Veteran
SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)

Group: General Forum Members
Points: 276 Visits: 250
Hi,

The below table is my source

Skill BU1 BU2 BU3
Skill1 0 0 0
Skill2 2 6 0
Skill3 0 0 7
Skill4 4 0 0
Skill5 0 7 8

I would like to convert it into the below table

BU Skill Value
BU1 Skill1 0
BU1 Skill2 2
BU1 Skill3 0
BU1 Skill4 4
BU1 Skill5 0
BU2 Skill1 0
BU2 Skill2 6
BU2 Skill3 0
BU2 Skill4 0
BU2 Skill5 7
BU3 Skill1 0
BU3 Skill2 0
BU3 Skill3 7
BU3 Skill4 0
BU3 Skill5 8

How can this be done using SSIS and/or T-SQL?
Please help.
_simon_
_simon_
SSC Eights!
SSC Eights! (919 reputation)SSC Eights! (919 reputation)SSC Eights! (919 reputation)SSC Eights! (919 reputation)SSC Eights! (919 reputation)SSC Eights! (919 reputation)SSC Eights! (919 reputation)SSC Eights! (919 reputation)

Group: General Forum Members
Points: 919 Visits: 776
You should probably use pivot operation (I hope somebody will post an example), but this should also work:


use tempdb

declare @t table (
Skill varchar(10) not null,
BU1 int not null,
BU2 int not null,
Bu3 int not null
)

insert into @t
values
('Skill1', 0, 0, 0),
('Skill2', 2, 6, 0),
('Skill3', 0, 0, 7),
('Skill4', 4, 0, 0),
('Skill5', 0, 7, 8)

;with temp as (
select 'BU1' BU, Skill, BU1 Value from @t union all
select 'BU2' BU, Skill, BU2 Value from @t union all
select 'BU3' BU, Skill, BU3 Value from @t
)
select *
from temp
order by BU, Skill



Solitary Reaper
Solitary Reaper
SSC Veteran
SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)

Group: General Forum Members
Points: 276 Visits: 250
Hi Simon,
Thanks for ur input.

But, the no. and name of columns BU1, BU2 etc... and the rows Skill1, Skill2 etc... is also fixed.
I cannot hardcode any values.Hence I cannot use pivot.

Kindly help when all the column names and rows are dynamic.
Terry300577
Terry300577
SSCrazy
SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)SSCrazy (2.3K reputation)

Group: General Forum Members
Points: 2305 Visits: 516
i am sure i have seen a script on SSC for a dynamic pivot function; think this is the one : CLR Pivot
SimonH
SimonH
SSCrazy
SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)

Group: General Forum Members
Points: 2719 Visits: 1053
Hi, This should work for you.

IF EXISTS (Select Name FROM Utility.sys.objects Where name ='tfnStringParser')
BEGIN
DROP FUNCTION dbo.tfnStringParser
END


GO
CREATE FUNCTION [dbo].[tfnStringParser]
(
@inputString Varchar(8000),
@Delimiter CHAR(1)
)
RETURNS

@parsedValues TABLE (ParsedColumn VARCHAR(200))

AS
BEGIN

DECLARE @spos INT
DECLARE @epos INT


IF RIGHT(@inputString,1)<> @Delimiter
SET @inputString= @InputString + @Delimiter

SET @spos =1


WHILE CHARINDEX(@delimiter,@InputString,@spos) <> 0
BEGIN

SET @epos=CHARINDEX(@delimiter,@inputString,@spos)

Insert into @parsedValues
SELECT SUBSTRING(@InputString,@spos,@epos - @spos)

SET @spos =@epos +1

END

RETURN

END

GO

DECLARE @Columns NVARCHAR(4000)
DECLARE @SQLstr NVARCHAR(MAX)


SET @Columns =''
SET @SQLstr = ''
--Just using your example, this table could be any size.

CREATE TABLE skill(Skill VARCHAR(15),BU1 INT,BU2 INT , BU3 INT)


INSERT INTO skill (Skill,BU1,BU2,BU3)
VALUES

('Skill1', 0, 0, 0),
('Skill2', 2, 6, 0),
('Skill3', 0, 0, 7),
('Skill4', 4, 0, 0),
('Skill5', 0, 7, 8)


SELECT @Columns = @Columns + COLUMN_NAME +','
FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_NAME ='SKILL' and COLUMN_NAME Like 'BU%'

SELECT @Columns= LEFT(@Columns,LEN(@Columns)-1)

SELECT @SQLstr = @SQLstr + 'SELECT ''' +[ParsedColumn] +''',SKILL,' + [ParsedColumn] + ' as [Value] FROM Skill UNION ALL' +CHAR(13)
FROM [Utility].[dbo].[tfnStringParser] (@Columns,',')

SELECT @SQLStr =LEFT(@SQLStr,LEN(@SQLStr)- (LEN('UNION ALL')+1))


EXEC(@SQLSTR)



DROP TABLE skill
Solitary Reaper
Solitary Reaper
SSC Veteran
SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)SSC Veteran (276 reputation)

Group: General Forum Members
Points: 276 Visits: 250
Thanks a lot Simon!!
Your code worked perfectly!! :-)
SimonH
SimonH
SSCrazy
SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)

Group: General Forum Members
Points: 2719 Visits: 1053
glad i could help
Sean Lange
Sean Lange
SSC Guru
SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)

Group: General Forum Members
Points: 101531 Visits: 18186
Terry300577 (12/19/2012)
i am sure i have seen a script on SSC for a dynamic pivot function; think this is the one : CLR Pivot


Or if you want a completely t-sql dynamic pivot take a look at the links in my signature about cross tabs.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Sean Lange
Sean Lange
SSC Guru
SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)

Group: General Forum Members
Points: 101531 Visits: 18186
Solitary Reaper (12/19/2012)
Thanks a lot Simon!!
Your code worked perfectly!! :-)


I would recommend to both you and Simon that you take a look at the link in my signature about splitting strings. The while loop method is very slow in comparison to the function you will find when reading that article.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Modens splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
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