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


Generate two columns from single column with alternating data


Generate two columns from single column with alternating data

Author
Message
michaellascuola
michaellascuola
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 181
I have what I thought would be a simple PIVOT example, but I have not yet solved it without using a temp table.
My input data looks like this:
1 John Smith
2 9/13/1961
3 Phony Persson
4 2/24/1943
5 Doc Galacawicz
6 11/11/1999
… …

And I want the SQL output to look like this:
Name Date
John Smith 9/13/1961
Phony Persson 2/24/1943
Doc Galacawicz 11/11/1999
… …

Any thoughts?
Thanks!
Lowell
Lowell
SSC Guru
SSC Guru (69K reputation)SSC Guru (69K reputation)SSC Guru (69K reputation)SSC Guru (69K reputation)SSC Guru (69K reputation)SSC Guru (69K reputation)SSC Guru (69K reputation)SSC Guru (69K reputation)

Group: General Forum Members
Points: 69510 Visits: 40917
you can join the table against itself, and use the modulus operator to limit it to the "odd" rows for the first value, leaving the second value as the date-ish type field:


/*
Val Val
John Smith 9/13/1961
Phony Persson 2/24/1943
Doc Galacawicz 11/11/1999
*/
With MyInputdata (ID,Val)
AS
(
SELECT 1,'John Smith' UNION ALL
SELECT 2,'9/13/1961' UNION ALL
SELECT 3,'Phony Persson' UNION ALL
SELECT 4,'2/24/1943' UNION ALL
SELECT 5,'Doc Galacawicz' UNION ALL
SELECT 6,'11/11/1999'
)
SELECT T1.Val, T2.Val
FROM MyInputdata T1
INNER JOIN MyInputdata T2 ON T1.ID + 1 = T2.ID
WHERE T1.ID %2 = 1



Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
Orlando Colamatteo
Orlando Colamatteo
SSC-Dedicated
SSC-Dedicated (38K reputation)SSC-Dedicated (38K reputation)SSC-Dedicated (38K reputation)SSC-Dedicated (38K reputation)SSC-Dedicated (38K reputation)SSC-Dedicated (38K reputation)SSC-Dedicated (38K reputation)SSC-Dedicated (38K reputation)

Group: General Forum Members
Points: 38212 Visits: 14411
Another option:

WITH    MyInputdata(ID, Val)
AS (
SELECT 1,
'John Smith'
UNION ALL
SELECT 2,
'9/13/1961'
UNION ALL
SELECT 3,
'Phony Persson'
UNION ALL
SELECT 4,
'2/24/1943'
UNION ALL
SELECT 5,
'Doc Galacawicz'
UNION ALL
SELECT 6,
'11/11/1999'
)
SELECT T1.Val,
T2.Val
FROM MyInputdata T1
CROSS APPLY (
SELECT Val
FROM MyInputdata
WHERE ID % 2 = 0
AND ID = T1.ID + 1
) AS T2 (Val);



__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
michaellascuola
michaellascuola
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 181
Great - these both work well for me. Thanks for the fast replies!
Steven Willis
Steven Willis
SSCommitted
SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)SSCommitted (2K reputation)

Group: General Forum Members
Points: 1955 Visits: 1721
Assuming that the PKs would always be in ODD/EVEN order would make me nervous. What if data has been inserted or deleted and the IDs are no longer sequential? What if one of the pairs is missing or out of order?

The code below isn't bulletproof, but it will at least pair the values correctly even if values are missing or the keys are not in sequential order by creating pseudo-keys. Otherwise, it's the same algorithm presented by Lowell.



USE LocalTestDB
GO

WITH MyInputdata (ID,Val)
AS
(
SELECT 1,'John Smith' UNION ALL
SELECT 2,'9/13/1961' UNION ALL
SELECT 4,'Phony Persson' UNION ALL
SELECT 5,'2/24/1943' UNION ALL
SELECT 15,'Doc Galacawicz' UNION ALL
SELECT 19,'11/11/1999' UNION ALL
SELECT 21,'Mary Jones' UNION ALL
SELECT 22,'' UNION ALL
SELECT 43,'3/22/1953' UNION ALL
SELECT 52,'Danny Jones' UNION ALL
SELECT 67,'John Paul' UNION ALL
SELECT 66,'12/18/1987'
)
SELECT
Name
,BDate
FROM
(
SELECT
ROW_NUMBER() OVER (ORDER BY ID) AS rn1
,ID
,NULLIF(Val,'') AS Name
FROM
MyInputdata
WHERE
ISDATE(Val) = 0
AND NULLIF(Val,'') IS NOT NULL
) a
LEFT OUTER JOIN
(
SELECT
ROW_NUMBER() OVER (ORDER BY ID) AS rn2
,ID
,NULLIF(Val,'') AS BDate
FROM
MyInputdata
WHERE
ISDATE(Val) = 1
OR NULLIF(Val,'') IS NULL
) b
ON a.rn1 = b.rn2





 
michaellascuola
michaellascuola
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 181
Thanks -- I always love robust code.

In this case, it's a (relatively) small data set, and the pattern never deviates.

(TMI)
The table is populated from the output of a powershell script that checks the password expiration date of SQL Server service accounts. So, the source data initially looks like this:
...
cn : MSSQL_INSTANCE01_SVC
...
PasswordExpires : 3/20/2014 1:09:02 PM
...


... my apologies, I'm losing some formatting here even though I changed to a mono-spaced font.

Next, I strip out the "cn:" and "PasswordExpires:" and am left with just the alternating data.

Smile
DAVNovak
DAVNovak
Right there with Babe
Right there with Babe (738 reputation)Right there with Babe (738 reputation)Right there with Babe (738 reputation)Right there with Babe (738 reputation)Right there with Babe (738 reputation)Right there with Babe (738 reputation)Right there with Babe (738 reputation)Right there with Babe (738 reputation)

Group: General Forum Members
Points: 738 Visits: 210
Provided the date rows are always valid dates and follow a row with a name, there is this solution:

create table #test (Id int, Value varchar(25))

insert into #test
select 1, 'John Smith'
union select 2, '9/13/1961'
union select 3, 'Phony Persson'
union select 4, '2/24/1943'
union select 5, 'Doc Galacawicz'
union select 6, '11/11/1999'

SELECT a.Value, b.Value
FROM #test a INNER JOIN #test b on a.Id = b.Id - 1
AND ISDATE(b.Value) = 1
WHERE ISDATE(a.Value) = 0
ORDER BY a.Id



Cadavre
Cadavre
SSCrazy Eights
SSCrazy Eights (8.8K reputation)SSCrazy Eights (8.8K reputation)SSCrazy Eights (8.8K reputation)SSCrazy Eights (8.8K reputation)SSCrazy Eights (8.8K reputation)SSCrazy Eights (8.8K reputation)SSCrazy Eights (8.8K reputation)SSCrazy Eights (8.8K reputation)

Group: General Forum Members
Points: 8754 Visits: 8490
So, using this sample data: -
SELECT ID, Val
INTO MyInputdata
FROM (SELECT 1,'John Smith' UNION ALL
SELECT 2,'9/13/1961' UNION ALL
SELECT 3,'Phony Persson' UNION ALL
SELECT 4,'2/24/1943' UNION ALL
SELECT 5,'Doc Galacawicz' UNION ALL
SELECT 6,'11/11/1999')a(ID, Val);



Anything wrong with just doing this: -
SELECT 
MAX(CASE WHEN pos % 2 = 1 THEN Val ELSE NULL END),
MAX(CASE WHEN pos % 2 = 0 THEN Val ELSE NULL END)
FROM (SELECT ROW_NUMBER() OVER(ORDER BY ID), Val
FROM MyInputdata
)a(pos,Val)
GROUP BY (pos + 1) / 2;




Forever trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


Craig Wilkinson - Software Engineer
LinkedIn
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