November 13, 2014 at 8:57 am
Hi All,
Possibly a simple answer but it has been a long day and I cannot get it working. Any help would be appreciated
Col1, col2,col3
AB , BC ,DA
I want to make it in so that the values in each of the columns are in a new row. Another column will be added with hardcoded text. Example is below:
Values , HardCoded
AB , ABC0
BC , ABC1
DA ,ABC20
Thank you
November 13, 2014 at 9:26 am
declare @t table (Col1 char(2), col2 char(2),col3 char(2))
INSERT INTO @t (col1, col2, col3) VALUES
('AB' , 'BC' ,'DA')
SELECT a AS [Values], x.val AS HardCoded
FROM @t
unpivot (a for col in (col1, col2, col3)) u
JOIN (
SELECT 'ab' as col, 'abc0' as val UNION all
SELECT 'bc', 'abc1' UNION ALL
SELECT 'da', 'abc20'
) x ON x.col = a
Gerald Britton, Pluralsight courses
November 13, 2014 at 2:23 pm
HI Thank you .. I have amended the code to get it working for getting the data from a table .. many thanks for your help!
DECLARE @t table (Col1 char(25), col2 char(25),col3 char(25))
INSERT INTO @t (col1, col2, col3)
(
SELECT column1,column2,column3
FROM [dbo].[TempAudit]
WHERE
column2 = 'Forecast'
)
SELECT a AS [Values], x.val AS HardCoded
FROM @t
unpivot (a for col in (col1, col2, col3)) u
JOIN (
SELECT (SELECT col1 FROM @t) as col, 'abc0' as val UNION all
SELECT (SELECT col2 FROM @t), 'abc1' UNION ALL
SELECT (SELECT col3 FROM @t), 'abc20'
) x ON x.col = a
November 13, 2014 at 11:04 pm
aarionsql (11/13/2014)
HI Thank you .. I have amended the code to get it working for getting the data from a table .. many thanks for your help!DECLARE @t table (Col1 char(25), col2 char(25),col3 char(25))
INSERT INTO @t (col1, col2, col3)
(
SELECT column1,column2,column3
FROM [dbo].[TempAudit]
WHERE
column2 = 'Forecast'
)
SELECT a AS [Values], x.val AS HardCoded
FROM @t
unpivot (a for col in (col1, col2, col3)) u
JOIN (
SELECT (SELECT col1 FROM @t) as col, 'abc0' as val UNION all
SELECT (SELECT col2 FROM @t), 'abc1' UNION ALL
SELECT (SELECT col3 FROM @t), 'abc20'
) x ON x.col = a
Probably not a good thing there. Instead of doing a single scan from @t, you've turned it into at least 4.
--Jeff Moden
Change is inevitable... Change for the better is not.
November 14, 2014 at 1:13 am
One alternative to the unpivot is to use the Cross apply method.
DECLARE @t table (Col1 char(25), col2 char(25),col3 char(25))
INSERT INTO @t (col1, col2, col3) VALUES
('AB' , 'BC' ,'DA')
SELECT
Cav.Value
,CASE Value
WHEN 'AB' THEN 'abc0'
WHEN 'BC' THEN 'abc1'
WHEN 'DA' THEN 'abc20'
END HardCoded
FROM
(
SELECT
Col1
,Col2
,Col3
FROM
@t
) X
CROSS APPLY
(VALUES
(Col1)
,(Col2)
,(Col3)
) CaV (Value)
This might also make it simpler to code a look up to replace the CASE statement with a JOIN to said look up.
_________________________________________________________________________
SSC Guide to Posting and Best Practices
November 14, 2014 at 2:00 am
Hi Jeff,
Thank you for your thoughts. I have been trying to make it set based but having no luck with the syntax. Do you have any suggestions please.
Thank you
November 14, 2014 at 2:00 am
Jason-299789 (11/14/2014)
One alternative to the unpivot is to use the Cross apply method.
DECLARE @t table (Col1 char(25), col2 char(25),col3 char(25))
INSERT INTO @t (col1, col2, col3) VALUES
('AB' , 'BC' ,'DA')
SELECT
Cav.Value
,CASE Value
WHEN 'AB' THEN 'abc0'
WHEN 'BC' THEN 'abc1'
WHEN 'DA' THEN 'abc20'
END HardCoded
FROM
(
SELECT
Col1
,Col2
,Col3
FROM
@t
) X
CROSS APPLY
(VALUES
(Col1)
,(Col2)
,(Col3)
) CaV (Value)
This might also make it simpler to code a look up to replace the CASE statement with a JOIN to said look up.
HJi Jason,,
Many thanks for this. I will try and give it ago.
November 14, 2014 at 2:13 am
Jason-299789 (11/14/2014)
One alternative to the unpivot is to use the Cross apply method.
DECLARE @t table (Col1 char(25), col2 char(25),col3 char(25))
INSERT INTO @t (col1, col2, col3) VALUES
('AB' , 'BC' ,'DA')
SELECT
Cav.Value
,CASE Value
WHEN 'AB' THEN 'abc0'
WHEN 'BC' THEN 'abc1'
WHEN 'DA' THEN 'abc20'
END HardCoded
FROM
(
SELECT
Col1
,Col2
,Col3
FROM
@t
) X
CROSS APPLY
(VALUES
(Col1)
,(Col2)
,(Col3)
) CaV (Value)
This might also make it simpler to code a look up to replace the CASE statement with a JOIN to said look up.
A minor note,
...
FROM @t
CROSS APPLY (VALUES
(Col1)
,(Col2)
,(Col3)
) CaV (Value)
is enough.
November 14, 2014 at 2:21 am
You are right you don't need the subselect :w00t:, Its just a quirk I have developed in regards to using this method especially when using multi-column tables.
_________________________________________________________________________
SSC Guide to Posting and Best Practices
Viewing 9 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply