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


Two Useful Hierarchy Functions


Two Useful Hierarchy Functions

Author
Message
John Cawley III
John Cawley III
Forum Newbie
Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)Forum Newbie (8 reputation)

Group: General Forum Members
Points: 8 Visits: 29
I apologize, Omama -- I was just using that as an example if you had a Salaries table to subtotal against. Though not included in the article, we can create a quick simple table that will work:


create table salaries(
emp_id int not null,
salary money,
fica money
)
GO
insert into salaries values( 1, 110000, 11000 )
insert into salaries values( 2, 100000, 10000 )
insert into salaries values( 3, 70000, 7000 )
insert into salaries values( 4, 90000, 9000 )
insert into salaries values( 5, 95000, 9500 )
insert into salaries values( 6, 60000, 6000 )
insert into salaries values( 7, 75000, 75000 )
insert into salaries values( 8, 50000, 50000 )
insert into salaries values( 9, 55000, 55000 )
insert into salaries values( 10, 60000, 6000 )
GO

select
sum( s.salary ) departmental_salary_total,
sum( s.fica ) as departmental_fica_total
from subordinates( 2007, 2 ) base
left join salaries s
on s.emp_id = node_id
Tod Conover
Tod Conover
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: 19
For reporting purposes we would generally want to sort all the nodes within one parent by node name. Below is an extension to the subordinates function that returns a field suitable for this purpose. The added field is called "node_sort" so your query might look like this...

select * from subordinates(2007,1) order by node_sort, node_name

----- create Subordinates function using CTE with added sort field

if object_id( 'subordinates', 'IF' ) is not null drop function subordinates
GO
create function subordinates( @year int, @node_id int ) returns table as return
with subnodes( distance, year, node_id, parent_node, node_name, node_seq, node_sort) as
(
select 0, @year, h.node_id, h.parent_node, h.node_name,
convert( varchar(99), ltrim(str(h.node_id))) as node_seq,
convert( varchar(99), '')
from hierarchy h where h.node_id = @node_id and h.year = @year
union all
select distance+1, @year, h.node_id, h.parent_node, h.node_name,
convert( varchar(99), sn.node_seq + '.' + ltrim(str(h.node_id))),
convert( varchar(99), sn.node_sort + '.' + right('00000' + cast(isnull(h.parent_node,'0') as varchar(5)), 5) )
from hierarchy h inner join subnodes sn on h.year = @year and h.parent_node = sn.node_id
)
select distance, year, node_id, parent_node, node_name, node_seq, node_sort from subnodes
GO
José Luis R.
José Luis R.
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: 6
EXCELENTE TU SUGERENCIA, TOD!!! REALMENTE EXCELENTE!!!

Enhorabuena Tod!
Jack-408956
Jack-408956
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 3
None of this "with" stuff is working for us on MSSQL 2000...
Server: Msg 156, Level 15, State 1, Procedure subordinates, Line 2
Incorrect syntax near the keyword 'with'.

Is it a feature of MSSQL 2005 only?
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)

Group: General Forum Members
Points: 114931 Visits: 41398
Jack-408956 (8/3/2010)
None of this "with" stuff is working for us on MSSQL 2000...
Server: Msg 156, Level 15, State 1, Procedure subordinates, Line 2
Incorrect syntax near the keyword 'with'.

Is it a feature of MSSQL 2005 only?


Yes... "WITH" is a precursor to CTE's.

If you want to do this "stuff" in 2k, do an initial insert similar to the first part (above the UNION) of the CTE. Then, do a loop that does very similar to the second part of the CTE which will have nearly the same speed as the CTE and (haven't tried it with this particular table) will likely use about 1/3rd the number of reads. The second part of the CTE (or the loop) is NOT RBAR, in this case. Each iteration of the loop loads an entire level of the hierarchy no matter how wide a given level becomes.

That's all a recursive CTE does, by the way... it does an "initial load" and then loops the same way (and with the same impact on performance) as a While Loop.

In 2k, this method will give much better utility and performance than using the classic "Expanding Hierarchies" example given in 2k Books Online.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)SSC Guru (114K reputation)

Group: General Forum Members
Points: 114931 Visits: 41398
Jack-408956 (8/3/2010)
None of this "with" stuff is working for us on MSSQL 2000...
Server: Msg 156, Level 15, State 1, Procedure subordinates, Line 2
Incorrect syntax near the keyword 'with'.

Is it a feature of MSSQL 2005 only?


As a side bar, I'm writing an article/presentation on how to deal with Million Row Hierarchies... you just reminded me that there are still people out there that may need to do such a thing in MSSQL 2000 or earlier and that I need to include code for that in the presentation materials.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
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