SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Counting all childs and sub-childs of a node in tree


Counting all childs and sub-childs of a node in tree

Author
Message
girish.envision
girish.envision
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 Visits: 20
Hi friends,
I have one problem.
I have one tree which I have saved in sql server table like

ID               Node                  ParentID
1 A 0
2 B 1
3 C 1
4 D 2
5 E 2
6 F 3
7 G 3
8 H 3
9 I 4
10 J 4
11 K 10
12 L 11




ParentID stores ID of the parent of the node.


Now suppose I have only one node given from the table, say "A", I have to count all its child nodes up to the leafs. In above table under node "A", there are in-total 11 child and sub-child nodes , if I have node "B" then there are total 6 child and sub-child nodes under it.

How to achieve this in sql server (withought using loops) if we are provided with only one node from the tree and we have to count all the child and sub-child up to leafs? Please remember tree may have N number of nodes, I have just used 12 here. We don't know total number nodes in the tree.

[Sorry for the language-related mistakes].
Attachments
Hierarchy.JPG (27 views, 12.00 KB)
Dave Ballantyne
Dave Ballantyne
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2962 Visits: 8370
Recursive CTE's are the way to go....

Try this link http://www.sqlservercentral.com/articles/Development/recursivequeriesinsqlserver2005/1760/



Clear Sky SQL
My Blog
girish.envision
girish.envision
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 Visits: 20
thanks for replying dave.....

Actually I have used recursive queries with some different scenarios in hierarchies. But here the case is little different i have to count all nodes, for this i will have traverse from top to bottom.
In case of the example i have given in my question,

from A i will have to search child nodes, which are B and C.
then from B i will have to get D and E and from C have to find F, G and H. then again i will have to look for the child nodes of these nodes also.
I tried the recursive query, but I didn't find any fruitful result.
But ok, I will try it again. Thanks once again for reply.
Dave Ballantyne
Dave Ballantyne
SSCrazy
SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)SSCrazy (3K reputation)

Group: General Forum Members
Points: 2962 Visits: 8370
Try this, possibly not the most efficient, i suspect that a hierarchyId-esque based query may be faster over a large dataset , but should do

Create table #RecursTest
(
ID integer,
Node varchar(10),
ParentId integer
)

insert into #RecursTest(Id,Node,ParentID) values(1, 'A', 0)
insert into #RecursTest(Id,Node,ParentID) values(2, 'B', 1)
insert into #RecursTest(Id,Node,ParentID) values(3, 'C', 1)
insert into #RecursTest(Id,Node,ParentID) values(4, 'D', 2)
insert into #RecursTest(Id,Node,ParentID) values(5, 'E', 2)
insert into #RecursTest(Id,Node,ParentID) values(6, 'F', 3)
insert into #RecursTest(Id,Node,ParentID) values(7, 'G', 3)
insert into #RecursTest(Id,Node,ParentID) values(8, 'H', 3)
insert into #RecursTest(Id,Node,ParentID) values(9, 'I', 4)
insert into #RecursTest(Id,Node,ParentID) values(10, 'J', 4)
insert into #RecursTest(Id,Node,ParentID) values(11, 'K', 10)
insert into #RecursTest(Id,Node,ParentID) values(12, 'L', 11)



go
with cteRecurs(AncestorId,Id,Node,ParentId)
as
(
Select Id,Id,Node,ParentId
from #RecursTest
union all
Select cteRecurs.AncestorId,#RecursTest.Id,#RecursTest.Node,#RecursTest.ParentId
from cteRecurs,
#RecursTest
where #RecursTest.ParentId = cteRecurs.Id
)

select AncestorId,count(*)-1 From cteRecurs
group by AncestorId





Clear Sky SQL
My Blog
girish.envision
girish.envision
Forum Newbie
Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)Forum Newbie (5 reputation)

Group: General Forum Members
Points: 5 Visits: 20
hey dave, sorry for replying late.
i tested it with the same logic but in a different way. it worked. also i tried it using cursors too. that also worked. but as cursors are not that efficient, i kept this CTE logic.

thanks for the help.:-)
anilkumar04_b
anilkumar04_b
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 9
Hi All,

I need an urgent help to build some logic in Oracle DB.

I have a table called TREE and in that we have data based on hierarchies.
We have columns like DataID and ParentID and DataID column is unique one.

And the data for DataID and ParentID will be this is like parent and child relation ship.
I need to get the count of all DataID's and Sub-dataID's of ParentID.

I need to get the count of this without using Start With connect by option.

Is there a way to get this done...

Thanks
Anilkumar B
kunalchatterjeeit
kunalchatterjeeit
Forum Newbie
Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)Forum Newbie (1 reputation)

Group: General Forum Members
Points: 1 Visits: 0
Thank u for the post. It helps me lot.
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