Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Show only Parent and 1st Child

Author  Topic 

shanmugaraj
Posting Yak Master

219 Posts

Posted - 2014-01-10 : 05:32:23
I have data where i need to Show only Parent and 1st Child
====================
CREATE TABLES
====================
CREATE TABLE [dbo].[Travel_Master](
[Load_Id] [int] NULL,
[Mode_Id] [nchar](2) NULL,
[Mode_Info] [nchar](10) NULL,
[Has_Nodes] [nchar](3) NULL
) ON [PRIMARY]

CREATE TABLE [dbo].[Travel_Quantity](
[Load_Id] [int] NULL,
[Mode_Sno] [int] NULL,
[Mode_Id] [nchar](2) NULL,
[Mode_Parent_Sno] [int] NULL,
[QA] [numeric](18, 0) NULL
) ON [PRIMARY]


====================
INSERT DATA TABLE 1
====================
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'AP' ,'AIR' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'SE' ,'SEA' ,'Yes')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'SP' ,'SHIP' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'BT' ,'BOAT' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'RD' ,'ROAD' ,'Yes')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'BU' ,'BUS' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'CA' ,'CAR' ,'Yes')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'BI' ,'BIKE' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'CY' ,'CYCLE' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'TR' ,'TRAM' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'BM' ,'BMW' ,'Yes')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'AI' ,'AUDI' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'BMC' ,'BMW-C' ,'No')
INSERT INTO [dbo].[Travel_Master] ([Load_Id] ,[Mode_Id] ,[Mode_Info] ,[Has_Nodes]) VALUES ( 1,'BMS' ,'BMW-S' ,'No')

====================
INSERT DATA TABLE 2
====================

INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'1' ,'AP' ,'-1','4' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'2' ,'SE' ,'-1','2' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'3' ,'SP' ,'2','3' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'4' ,'BT' ,'2','4' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'5' ,'RD' ,'-1','2' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'6' ,'BU' ,'5','7' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'7' ,'CA' ,'5','3' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'8' ,'BI' ,'5','15' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'9' ,'CY' ,'5','2' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'10' ,'TR' ,'5','5' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'11' ,'BM' ,'7','6' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'12' ,'AI' ,'7','14' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'13' ,'BM' ,'11','6' )
INSERT INTO [Travel_Quantity]([Load_Id],[Mode_Sno],[Mode_Id],[Mode_Parent_Sno],[QA]) VALUES ( 1,'14' ,'AI' ,'12','14' )


====================
EXPECTED RESULT
====================

Mode_Info |Mode_Detail |QA
Air | |4
Sea | |2
SEA |SHIP |3
SEA |BOAT |4
ROAD| | 2
ROAD |BUS |7
ROAD |CAR |3
ROAD |BIKE |15
ROAD |CYCLE |2
ROAD |TRAM |5

THANKS
SHANMUGARAJ
nshanmugaraj@gmail.com

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2014-01-10 : 06:35:35
[code]

SELECT COALESCE(m1.Mode_Info,m.Mode_Info) ,CASE WHEN m1.Mode_Info IS NULL THEN '' ELSE m.Mode_Info END AS ModeDetails,
q.QA
FROM [Travel_Master] m
INNER JOIN [Travel_Quantity] q
ON q.Load_Id = m.Load_Id
AND q.Mode_Id = m.Mode_Id
LEFT JOIN [Travel_Quantity] q1
ON q1.Mode_Sno = q.Mode_Parent_Sno
LEFT JOIN [Travel_Master] m1
ON q1.Load_Id = m1.Load_Id
AND q1.Mode_Id = m1.Mode_Id
[/code]

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

shanmugaraj
Posting Yak Master

219 Posts

Posted - 2014-01-10 : 06:56:10
quote:
Originally posted by visakh16



SELECT COALESCE(m1.Mode_Info,m.Mode_Info) ,CASE WHEN m1.Mode_Info IS NULL THEN '' ELSE m.Mode_Info END AS ModeDetails,
q.QA
FROM [Travel_Master] m
INNER JOIN [Travel_Quantity] q
ON q.Load_Id = m.Load_Id
AND q.Mode_Id = m.Mode_Id
LEFT JOIN [Travel_Quantity] q1
ON q1.Mode_Sno = q.Mode_Parent_Sno
LEFT JOIN [Travel_Master] m1
ON q1.Load_Id = m1.Load_Id
AND q1.Mode_Id = m1.Mode_Id


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs




Hivisakhm,
I am still getting the childrens.
Data displayed is 14 rows.
Expected 10 Rows.


THANKS
SHANMUGARAJ
nshanmugaraj@gmail.com
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2014-01-10 : 07:09:37
quote:
Originally posted by shanmugaraj

quote:
Originally posted by visakh16



SELECT COALESCE(m1.Mode_Info,m.Mode_Info) ,CASE WHEN m1.Mode_Info IS NULL THEN '' ELSE m.Mode_Info END AS ModeDetails,
q.QA
FROM [Travel_Master] m
INNER JOIN [Travel_Quantity] q
ON q.Load_Id = m.Load_Id
AND q.Mode_Id = m.Mode_Id
LEFT JOIN [Travel_Quantity] q1
ON q1.Mode_Sno = q.Mode_Parent_Sno
LEFT JOIN [Travel_Master] m1
ON q1.Load_Id = m1.Load_Id
AND q1.Mode_Id = m1.Mode_Id


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs




Hivisakhm,
I am still getting the childrens.
Data displayed is 14 rows.
Expected 10 Rows.


THANKS
SHANMUGARAJ
nshanmugaraj@gmail.com


ok..so want to ignore child ones without parent
then here you go

SELECT ModeInfo,ModeDetails,QA
FROM
(
SELECT COALESCE(m1.Mode_Info,m.Mode_Info) AS ModeInfo,CASE WHEN m1.Mode_Info IS NULL THEN '' ELSE m.Mode_Info END AS ModeDetails,
q.QA,SUM(CASE WHEN m1.Mode_Info IS NULL THEN 1 ELSE 0 END) OVER (PARTITION BY COALESCE(m1.Mode_Info,m.Mode_Info)) AS Cnt
FROM [#Travel_Master] m
INNER JOIN [#Travel_Quantity] q
ON q.Load_Id = m.Load_Id
AND q.Mode_Id = m.Mode_Id
LEFT JOIN [#Travel_Quantity] q1
ON q1.Mode_Sno = q.Mode_Parent_Sno
LEFT JOIN [#Travel_Master] m1
ON q1.Load_Id = m1.Load_Id
AND q1.Mode_Id = m1.Mode_Id
)t
WHERE Cnt > 0


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page

shanmugaraj
Posting Yak Master

219 Posts

Posted - 2014-01-10 : 07:34:45
Hi visakhm
Thanks. It works

THANKS
SHANMUGARAJ
nshanmugaraj@gmail.com
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2014-01-10 : 07:42:16
welcome

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/
https://www.facebook.com/VmBlogs
Go to Top of Page
   

- Advertisement -