Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

SQL Query help required Expand / Collapse
Author
Message
Posted Thursday, March 25, 2010 4:52 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, March 30, 2010 12:34 AM
Points: 2, Visits: 16
Hello Friends,

I have three tables are there as mentioned below, tblCommon, tblSkill and tblCommon_tblSkills. TblSkills is master table and tblCommon_tblSkills table. Here my requirement is a report, it should be like all tblCommon columns should require and all rows of the tblSkills should become the columns, and value for these columns should be Yes or No depending on the tblCommon_tblSkills table. Please find the attached spread sheet for more details.

Please can anyone build the SQL query get the output. Please do the needful at the earliest.


1) TableName: tblCommon
ID Fname Lname Age Sex Location
1 Kishore P 37 M HYD
2 Koti R 28 M HYD
3 Ramesh B 30 M HYD


2) Table Name: tblSkills
ID SkillName
1 MSOffice
2 SharePoint
3 ASP.Net
4 C#
5 J2EE
6 SQLServer
7 Oracle


3) Table Name: tblCommon_tblSkills
Common_ID Skill_ID
1 1
1 2
1 3
1 4
1 6
2 1
2 2
2 3
2 4
2 5
2 6
2 7
3 1
3 3
3 4
3 6


The required out put from these tables should be in the following format.

Output
ID Fname Lname Age Sex Location MSOffice SharePoint ASP.Net C# J2EE SQLServer Oracle
1 Kishore P 37 M HYD Yes Yes Yes Yes No Yes No
2 Koti R 28 M HYD Yes Yes Yes Yes Yes Yes Yes
3 Ramesh B 30 M HYD Yes No Yes Yes No Yes No


  Post Attachments 
Requirement.xls (9 views, 15.00 KB)
Post #889657
Posted Thursday, March 25, 2010 5:22 AM


Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Sunday, November 23, 2014 8:16 AM
Points: 60, Visits: 376
Hi,

You find below a solution:


SELECT
com.ID AS ID,
com.Fname AS Fname,
com.Lname AS Lname,
com.Age AS Age,
com.Sex AS Sex,
com.Location AS Location,
CASE WHEN EXISTS (SELECT '1' FROM tblCommon_tblSkills comski
left JOIN tblskills ski ON comski.skill_id=ski.id WHERE comski.common_id=com.id AND ski.id=1) THEN 'Yes' ELSE 'No' END AS MSOffice,
CASE WHEN EXISTS (SELECT '1' FROM tblCommon_tblSkills comski
left JOIN tblskills ski ON comski.skill_id=ski.id WHERE comski.common_id=com.id AND ski.id=2) THEN 'Yes' ELSE 'No' END AS SharePoint,
CASE WHEN EXISTS (SELECT '1' FROM tblCommon_tblSkills comski
left JOIN tblskills ski ON comski.skill_id=ski.id WHERE comski.common_id=com.id AND ski.id=3) THEN 'Yes' ELSE 'No' END AS 'ASP.Net',
CASE WHEN EXISTS (SELECT '1' FROM tblCommon_tblSkills comski
left JOIN tblskills ski ON comski.skill_id=ski.id WHERE comski.common_id=com.id AND ski.id=4) THEN 'Yes' ELSE 'No' END AS 'C#',
CASE WHEN EXISTS (SELECT '1' FROM tblCommon_tblSkills comski
left JOIN tblskills ski ON comski.skill_id=ski.id WHERE comski.common_id=com.id AND ski.id=5) THEN 'Yes' ELSE 'No' END AS 'J2EE',
CASE WHEN EXISTS (SELECT '1' FROM tblCommon_tblSkills comski
left JOIN tblskills ski ON comski.skill_id=ski.id WHERE comski.common_id=com.id AND ski.id=6) THEN 'Yes' ELSE 'No' END AS SQLServer,
CASE WHEN EXISTS (SELECT '1' FROM tblCommon_tblSkills comski
left JOIN tblskills ski ON comski.skill_id=ski.id WHERE comski.common_id=com.id AND ski.id=7) THEN 'Yes' ELSE 'No' END AS Oracle
FROM
tblcommon com

The results are the following:

ID Fname Lname Age Sex Location MSOffice SharePoint ASP.Net C# J2EE SQLServer Oracle
1 Kishore P 37 m hyd Yes Yes Yes Yes No Yes No
2 Koti R 28 m hyd Yes Yes Yes Yes Yes Yes Yes
3 Ramesh B 30 m hyd Yes No Yes Yes No Yes No


Wish you good ideas!
Andreea
Post #889673
Posted Thursday, March 25, 2010 6:25 AM
SSC Eights!

SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!SSC Eights!

Group: General Forum Members
Last Login: Yesterday @ 6:37 AM
Points: 850, Visits: 5,582
It will probably be more efficient to PIVOT tblCommon_tblSkills.
Something like:
;WITH Skills
AS
(
SELECT Common_ID, [1],[2],[3],[4],[5],[6],[7]
FROM
(
SELECT Common_ID, Skill_ID
FROM tblCommon_tblSkills
) P
PIVOT
(
COUNT(Skill_ID)
FOR Skill_ID IN ([1],[2],[3],[4],[5],[6],[7])
) A
)
SELECT C.*
,CASE WHEN S.[1] = 1 THEN 'Yes' ELSE 'No' END AS MSOffice
,CASE WHEN S.[2] = 1 THEN 'Yes' ELSE 'No' END AS ScarePoint
,CASE WHEN S.[3] = 1 THEN 'Yes' ELSE 'No' END AS [ASP.Net]
,CASE WHEN S.[4] = 1 THEN 'Yes' ELSE 'No' END AS [C#]
,CASE WHEN S.[5] = 1 THEN 'Yes' ELSE 'No' END AS J2EE
,CASE WHEN S.[6] = 1 THEN 'Yes' ELSE 'No' END AS SQLServer
,CASE WHEN S.[7] = 1 THEN 'Yes' ELSE 'No' END AS Oracle
FROM tblCommon C
JOIN Skills S
ON C.[ID] = S.Common_ID

Post #889717
Posted Thursday, March 25, 2010 6:30 AM


Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Sunday, November 23, 2014 8:16 AM
Points: 60, Visits: 376
Yes, you're right, and it works if the database compatibility level is 90.
Even if I work with SQL Server 2005, because of the application, my dbs compatiliblty levels are set to 80

So, that's another better solution.


Wish you good ideas!
Andreea
Post #889723
Posted Thursday, March 25, 2010 11:10 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, March 30, 2010 12:34 AM
Points: 2, Visits: 16
Thanks Andreea and Ken McKelvey for your quick response. The queries are awesome.

But if a new row added to tblSkills table, then how to get those columns dynamically?

Can you please help me in this regard.

Thanks and Regards
Kishore
Post #890041
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse