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
 SQL Server 2008 Forums
 Transact-SQL (2008)
 Hierarchical data

Author  Topic 

imrul
Starting Member

36 Posts

Posted - 2012-05-13 : 06:26:53
Hi All,
I have a table with following sample data

AccountCode ParentAccCode AccountName
---------------------------------------------------
1 null Asset
101 1 Non current asset
10101 101 Land Development
1010101 10101 Land

I need output like bellow

AccountCode Level
-----------------------------------------------------
10101 3
1010101 4

Please help

vijays3
Constraint Violating Yak Guru

354 Posts

Posted - 2012-05-13 : 07:21:59
[code]
Solution:1
;with cte as
(

select AccountCode,ParentAccCode,1 as [level] from level where ParentAccCode is null
union all
select L.AccountCode,L.ParentAccCode,[level]+1 from level L inner join cte C on L.ParentAccCode
= C.AccountCode

)
select * from ( select top 2 * from cte order by level desc) A order by level

Solution2 :


;with cte as
(
select top 1 AccountCode,ParentAccCode,4 as [Level] from level order by AccountCode desc
union all
select L.AccountCode,L.ParentAccCode,[Level]-1 as [Level] from level L inner join cte C on
L.AccountCode= C. ParentAccCode )

select * from (select top 2 * from cte order by level desc) A order by level

[/code]



Vijay is here to learn something from you guys.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-05-13 : 14:53:07
it should be


;with cte as
(
select AccountCode,ParentAccCode,1 as [Level] ,CAST(AccountCode as varchar(max)) AS [Path]
from level

union all

select L.AccountCode,L.ParentAccCode,[Level]+1 as [Level] ,cast([Path] + '/' + cast(L.AccountCode AS varchar(100)) as varchar(max))
from level L
inner join cte C
on L.AccountCode= C. ParentAccCode
)

select val,Level
from
(
select dense_rank() over (partition by left([Path],charindex('/',[Path] + '/')-1) order by Level desc) AS Rnk,
left([Path],charindex('/',[Path] + '/')-1) as val,Level
from cte
)t
Where Rnk <= 2


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

imrul
Starting Member

36 Posts

Posted - 2012-05-17 : 06:22:05
Thanks a lot
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-05-19 : 15:08:03
wc

------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page
   

- Advertisement -