I have two normalized SQL Server 2008 tables, one for names and another for emails:
create table Name (NameId int, Name varchar(50))
create table Email (NameId int, Email varchar(50))
go
insert into Name values (1, 'JOHN SMITH')
insert into Name values (2, 'MARY SMITH')
insert into Name values (3, 'PHILL TAYLOR')
go
insert into Email values (1, 'john@hotmail.com')
insert into Email values (1, 'john@gmail.com')
insert into Email values (1, 'john.smith@hotmail.com')
insert into Email values (2, 'mary@hotmail.com')
insert into Email values (3, 'phill@hotmail.com')
insert into Email values (3, 'phill@gmail.com')
insert into Email values (3, 'taylor.phill@hotmail.com')
insert into Email values (3, 'taylor.phill@gmail.com')
go
When I join those tables I have several rows, which row with just one email:
Select name, email
from Name inner join Email on name.NameId=email.NameId
NAME EMAIL
------------- --------------------------
JOHN SMITH john@hotmail.com
JOHN SMITH john@gmail.com
JOHN SMITH john.smith@hotmail.com
MARY SMITH mary@hotmail.com
PHILL TAYLOR phill@hotmail.com
PHILL TAYLOR phill@gmail.com
PHILL TAYLOR taylor.phill@hotmail.com
PHILL TAYLOR taylor.phill@gmail.com
But I need to have all the emails in the same row to satisfy a predefined layout:
NAME EMAIL1 EMAIL2 EMAIL3 EMAIL4
------------- ----------------- --------------- ----------------------- -----------------
JOHN SMITH john@hotmail.com john@gmail.com john.smith@hotmail.com
MARY SMITH mary@hotmail.com
PHILL TAYLOR phill@hotmail.com phill@gmail.com taylor.phill@hotmail.com taylor.phill@hotmail.com
Is it possible using a single select?
Any ideas would be very appreciated
TIA
Ricardo Nogueira
It can be done in 1 select. If you only want the first 4 email addresses and use them as specific columns. Use the RowNumber function on the email table to number the mailaddresses per user. This example assumes the email addresses should be sorted alphabetically:
with m as (
select
ROW_NUMBER() over (partition by nameId order by email) as Nr,
email.NameId, email.Email
from email
)
select
name.NameId,
name.Name,
m1.Email as Mail1,
m2.Email as Mail2,
m3.Email as Mail3,
m4.Email as Mail4
from name
left join m m1 on (m1.Nr=1 and m1.NameId=name.NameId)
left join m m2 on (m2.Nr=2 and m2.NameId=name.NameId)
left join m m3 on (m3.Nr=3 and m3.NameId=name.NameId)
left join m m4 on (m4.Nr=4 and m4.NameId=name.NameId)