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

Require help to retrieve data from a table Expand / Collapse
Author
Message
Posted Friday, July 5, 2013 7:06 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, March 27, 2014 12:42 AM
Points: 24, Visits: 116
Hi All,

I have two tables as described below:

CREATE TABLE [dbo].[Batch](
[BatchID] [int] IDENTITY(1,1) NOT NULL,
[BatchName] [nvarchar](50) NULL,
[CourseID] [int] NULL,
[DateFrom] [datetime] NULL,
[DateTo] [datetime] NULL,
CONSTRAINT [PK_Batch] PRIMARY KEY CLUSTERED
(
[BatchID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET IDENTITY_INSERT [dbo].[Batch] ON
INSERT [dbo].[Batch] ([BatchID], [BatchName], [CourseID], [DateFrom], [DateTo]) VALUES (1, N'B1', 1, CAST(0x0000A1F200000000 AS DateTime), CAST(0x0000A1FC00000000 AS DateTime))
INSERT [dbo].[Batch] ([BatchID], [BatchName], [CourseID], [DateFrom], [DateTo]) VALUES (2, N'B2', 2, CAST(0x0000A1F300000000 AS DateTime), CAST(0x0000A1FD00000000 AS DateTime))
INSERT [dbo].[Batch] ([BatchID], [BatchName], [CourseID], [DateFrom], [DateTo]) VALUES (3, N'B3', 3, CAST(0x0000A1F400000000 AS DateTime), CAST(0x0000A1FE00000000 AS DateTime))
INSERT [dbo].[Batch] ([BatchID], [BatchName], [CourseID], [DateFrom], [DateTo]) VALUES (4, N'B4', 4, CAST(0x0000A1F500000000 AS DateTime), CAST(0x0000A1FF00000000 AS DateTime))
INSERT [dbo].[Batch] ([BatchID], [BatchName], [CourseID], [DateFrom], [DateTo]) VALUES (5, N'B5', 5, CAST(0x0000A1F600000000 AS DateTime), CAST(0x0000A20000000000 AS DateTime))
SET IDENTITY_INSERT [dbo].[Batch] OFF
------------

CREATE TABLE [dbo].[Course_Module](
[CourseModuleID] [int] IDENTITY(1,1) NOT NULL,
[CourseID] [int] NOT NULL,
[ModuleID] [int] NOT NULL,
CONSTRAINT [PK_Course_Module] PRIMARY KEY CLUSTERED
(
[CourseModuleID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO
SET IDENTITY_INSERT [dbo].[Course_Module] ON
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (1, 1, 1)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (2, 1, 2)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (3, 1, 3)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (4, 1, 4)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (5, 2, 2)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (6, 2, 5)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (7, 2, 6)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (8, 2, 7)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (9, 3, 1)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (10, 3, 4)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (11, 3, 5)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (12, 4, 2)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (13, 4, 3)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (14, 5, 6)
INSERT [dbo].[Course_Module] ([CourseModuleID], [CourseID], [ModuleID]) VALUES (15, 5, 7)
SET IDENTITY_INSERT [dbo].[Course_Module] OFF

Here I want a TSQL query which return those batches
When I provide a CourseID then I should get all those batches which explicitly contains all the MODULEID attached with the provided CourseID.

For Example:
I have provided the CourseID = 4, then it should return CourseID 1 and 4 as both of them contains the ModuleID 2,3 but it should not return 1,2,3,4 as CourseID = 2 do not contain the ModuleID = 3 and CourseID = 3 do not contain the ModuleID = 2

I have written the Code :

Select distinct B.* from Batch B
inner join course_Module CM on B.CourseID = CM.CourseID
inner join Course_Module CMM on CM.ModuleID = CMM.ModuleID
where CMM.CourseID = 4

The Answer I am getting is :
BatchName CourseID
B1 1
B2 2
B4 4

Answer should be :
BatchName CourseID
B1 1
B4 4
Post #1470721
Posted Friday, July 5, 2013 7:58 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Today @ 2:38 AM
Points: 5,438, Visits: 10,141
I haven't got anywhere to test this at the moment, but I think you need to join Course_Module twice to Batch instead of once to Batch and once to itself.

John
Post #1470742
Posted Friday, July 5, 2013 8:21 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 7:33 AM
Points: 2,873, Visits: 5,190
try this:



;WITH cteModules
AS
(
SELECT ModuleId
FROM Course_Module
WHERE CourseID = 4
)
, cteQualifyingCources
AS
(
SELECT cmc.CourseID
FROM Course_Module AS cmc
JOIN cteModules AS cm ON cm.ModuleID = cmc.ModuleID
GROUP BY cmc.CourseID
HAVING COUNT(*) = (SELECT COUNT(*) FROM cteModules)
)
SELECT *
FROM Batch
WHERE CourseID IN (SELECT CourseID FROM cteQualifyingCources)



_____________________________________________
"The only true wisdom is in knowing you know nothing"
"O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1470756
Posted Friday, July 5, 2013 9:33 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, March 27, 2014 12:42 AM
Points: 24, Visits: 116
Thanks SSCrazy, it helps me alot.

Sumit
Post #1470896
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse