Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


SQL Query help required


SQL Query help required

Author
Message
kishorepvk
kishorepvk
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
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
Attachments
Requirement.xls (12 views, 15.00 KB)
blue_inelush
blue_inelush
SSC Journeyman
SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)

Group: General Forum Members
Points: 76 Visits: 427
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
Ken McKelvey
Ken McKelvey
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1121 Visits: 7531
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


blue_inelush
blue_inelush
SSC Journeyman
SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)SSC Journeyman (76 reputation)

Group: General Forum Members
Points: 76 Visits: 427
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
kishorepvk
kishorepvk
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
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
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