469,133 Members | 1,363 Online
Bytes | Developer Community
New Post

Home Posts Topics Members FAQ

Post your question to a community of 469,133 developers. It's quick & easy.

PIVOT

Hi everyone,

I have 3 tables:
Telbook(Id:int,Name:char,address:char,comment:ntex t,owneruserid:int),
PK:id
TelNumbers(telbookid:int,telno:char,telNotype:int, syscode:int),PK:syscode,F*K:telNumbers.telbookid=t elbook.id

Teltypes(teltypes:char,fk:int),FK:telnumbers.telno type=teltypes.fk
The question is here that I can create a query which results are:
(id,Name,telno,telnotype,teltypes,address,comment)
(4,nassa,091463738,2,Mobile,XXX,Null)
(4,nassa,071163738,1,Tellphone,XXX,Nul)
But,I want a query which shows the results in a way below:
(id,Name,tellephone,mobile,Fax,e-mail,address,comment)
(4,nassa,071163738,091463738,Null,Null,XXX,Null)

I run SQL server 2005, and I want to use PIVOT but I dnt know how!.

Thanks,
Nassa

Dec 30 '06 #1
3 5783
Hi Nassa
"Nassa" <na*************@gmail.comwrote in message
news:11**********************@v33g2000cwv.googlegr oups.com...
Hi everyone,

I have 3 tables:
Telbook(Id:int,Name:char,address:char,comment:ntex t,owneruserid:int),
PK:id
TelNumbers(telbookid:int,telno:char,telNotype:int, syscode:int),PK:syscode,F*K:telNumbers.telbookid=t elbook.id

Teltypes(teltypes:char,fk:int),FK:telnumbers.telno type=teltypes.fk
The question is here that I can create a query which results are:
(id,Name,telno,telnotype,teltypes,address,comment)
(4,nassa,091463738,2,Mobile,XXX,Null)
(4,nassa,071163738,1,Tellphone,XXX,Nul)
But,I want a query which shows the results in a way below:
(id,Name,tellephone,mobile,Fax,e-mail,address,comment)
(4,nassa,071163738,091463738,Null,Null,XXX,Null)

I run SQL server 2005, and I want to use PIVOT but I dnt know how!.

Thanks,
Nassa

Check out http://www.aspfaq.com/etiquette.asp?id=5006 on how to post DDL and
Sample data that is useful such as

CREATE TABLE Telbook(Id int not null constraint PK_telbook PRIMARY KEY,

[Name] varchar(20),

[address] varchar(60),

comment nvarchar(MAX),

owneruserid int)

CREATE TABLE Teltypes(teltypes varchar(30),

[fk] int not null constraint PK_Teltypes PRIMARY KEY)

CREATE TABLE TelNumbers(

telbookid int NOT NULL CONSTRAINT FK_TelNumbers_Telbook FOREIGN KEY
REFERENCES Telbook(id),

telno char(15),

telNotype int CONSTRAINT FK_TelNumbers_Teltypes FOREIGN KEY REFERENCES
Teltypes(fk),

syscode int not null CONSTRAINT PK_TelNumbers PRIMARY KEY)

INSERT INTO Teltypes(teltypes, [fk] )

SELECT 'Tellphone', 0

UNION ALL SELECT 'Mobile', 1

UNION ALL SELECT 'Fax', 2

INSERT INTO Telbook(Id, [Name], [address], comment, owneruserid)

SELECT 1, 'Fred', 'The Burrow', NULL, 1

UNION ALL SELECT 2, 'George', 'The Burrow', NULL, 2

UNION ALL SELECT 3, 'Ron', 'The Burrow', NULL, 3

UNION ALL SELECT 4, 'Ginny', 'The Burrow', NULL, 4

UNION ALL SELECT 5, 'Percy', 'The Burrow', NULL, 5

INSERT INTO TelNumbers(telbookid, telno, telNotype, syscode)

SELECT 1, '0921323123', 1, 1

UNION ALL SELECT 1, '0123323123', 0, 2

UNION ALL SELECT 2, '0123323123', 0, 3

UNION ALL SELECT 3, '0123323123', 0, 4

UNION ALL SELECT 4, '0123323123', 0, 5

UNION ALL SELECT 5, '0123323123', 0, 6

UNION ALL SELECT 2, '0944423123', 1, 7

UNION ALL SELECT 5, '0955423123', 1, 8

UNION ALL SELECT 5, '0123323125', 2, 9

It would have been useful to post the query you did have for:

The question is here that I can create a query which results are:
(id,Name,telno,telnotype,teltypes,address,comment)
Such as:

SELECT b.id, b.name, n.telno, n.telnotype, t.teltypes, b.address, b.comment

FROM Telbook b

JOIN TelNumbers n on n.telbookid = b.id

JOIN Teltypes t ON t.fk = n.telNotype

And for the following query, if you have set types you can self join instead
of using a Pivot such as

But,I want a query which shows the results in a way below:
(id,Name,tellephone,mobile,Fax,e-mail,address,comment)
(4,nassa,071163738,091463738,Null,Null,XXX,Null)
SELECT b.id, b.name, n1.telno AS [Tellphone], n2.telno AS [Mobile],

n3.telno AS [Fax], b.address, b.comment

FROM Telbook b

LEFT JOIN ( TelNumbers n1

JOIN Teltypes t1 ON t1.fk = n1.telNotype AND t1.teltypes = 'Tellphone' ) on
n1.telbookid = b.id

LEFT JOIN ( TelNumbers n2

JOIN Teltypes t2 ON t2.fk = n2.telNotype AND t2.teltypes = 'Mobile' ) on
n2.telbookid = b.id

LEFT JOIN ( TelNumbers n3

JOIN Teltypes t3 ON t3.fk = n3.telNotype AND t3.teltypes = 'Fax' ) on
n3.telbookid = b.id

But if you do want to use a pivot try something like:

SELECT id, name, [Tellphone], [Mobile], [Fax], address, comment

FROM

( SELECT b.id, b.name, b.address, b.comment, t.teltypes, n.telno

FROM Telbook b

JOIN TelNumbers n on n.telbookid = b.id

JOIN Teltypes t ON t.fk = n.telNotype

) AS SourceTable

PIVOT

(

MAX(telno)

FOR teltypes IN ( [Tellphone], [Mobile], [Fax] )

) AS pvt

ORDER BY id

John
Dec 30 '06 #2
John Bell (jb************@hotmail.com) writes:
But,I want a query which shows the results in a way below:
(id,Name,tellephone,mobile,Fax,e-mail,address,comment)
(4,nassa,071163738,091463738,Null,Null,XXX,Null)
SELECT b.id, b.name, n1.telno AS [Tellphone], n2.telno AS [Mobile],
n3.telno AS [Fax], b.address, b.comment
FROM Telbook b
LEFT JOIN ( TelNumbers n1
JOIN Teltypes t1 ON t1.fk = n1.telNotype AND t1.teltypes = 'Tellphone' )
on n1.telbookid = b.id
LEFT JOIN ( TelNumbers n2
JOIN Teltypes t2 ON t2.fk = n2.telNotype AND t2.teltypes = 'Mobile' ) on
n2.telbookid = b.id
LEFT JOIN ( TelNumbers n3
JOIN Teltypes t3 ON t3.fk = n3.telNotype AND t3.teltypes = 'Fax' ) on
n3.telbookid = b.id
John, here is a way to write that query with a single join:

SELECT b.id, b.Name, a.Tellphone, a.Mobile, a.Fax, b.address, b.comment
FROM Telbook b
JOIN (SELECT n.telbookid,
Tellphone = MAX(CASE WHEN t.teltypes = 'Tellphone'
THEN n.telno
END),
Mobile = MAX(CASE WHEN t.teltypes = 'Mobile'
THEN n.telno
END),
Fax = MAX(CASE WHEN t.teltypes = 'Fax'
THEN n.telno
END)
FROM TelNumbers n
JOIN Teltypes t ON n.telNotype = t.fk
GROUP BY n.telbookid) AS a ON a.telbookid = b.id

This is, in my opinion, *the* way to write a pivot query. It's uses
ANSI SQL, so it has a chance of being portable. And once you have learnt
the principle, it's easy to remember.

The trick is the use of MAX. Each CASE expression will return at most
one non-NULL value. So whether we use MAX or MIN does not matter

The syntax with the PIVOT keyword introduced in SQL 2005, on the other
hand, is useless in my opinion. The syntax is not any more compact than
the above, nor even any easier to use or remember. And top of that it's
propritary and not portable. Possibly, it helps the optimizer so a query
with PIVOT could execute faster than using CASE and GROUP BY. Personally,
I haven't even bothered to learn the PIVOT/UNPIVOT syntax.

Also, the PIVOT query you posted, will not work for Nassa because he/she
uses ntext which cannot be used with PIVOT. I see in your tables that
you use nvarchar(MAX), but I tried yesterday in
microsoft.public.sqlserver.programming to convince Nassa to use
nvarchar(MAX) instead, but he/she did not even comment on it.
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Dec 30 '06 #3
Hi Erland
Also, the PIVOT query you posted, will not work for Nassa because he/she
uses ntext which cannot be used with PIVOT. I see in your tables that
you use nvarchar(MAX), but I tried yesterday in
microsoft.public.sqlserver.programming to convince Nassa to use
nvarchar(MAX) instead, but he/she did not even comment on it.
I would hope that a lack of comment would not mean that Nassa was opposed to
using this new feature, which would probably be more benificial than using
PIVOT.

I would hope that the design was not restricted to a single number for a
given type of number e.g. multiple mobile numbers, which would show that all
the methods have their limitations.

Neither of us suggested doing this on the client, which is still probably
the best place to do this regardless of SQL Server's capability.

John
Dec 30 '06 #4

This discussion thread is closed

Replies have been disabled for this discussion.

Similar topics

reply views Thread by Prasad Patil | last post: by
2 posts views Thread by Rob | last post: by
2 posts views Thread by Carl Gilbert | last post: by
3 posts views Thread by Jerry K via DotNetMonster.com | last post: by
3 posts views Thread by GoalieGW | last post: by
3 posts views Thread by nikila | last post: by
9 posts views Thread by PeteCresswell | last post: by
1 post views Thread by CARIGAR | last post: by
By using this site, you agree to our Privacy Policy and Terms of Use.