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 ««12

Two Useful Hierarchy Functions Expand / Collapse
Author
Message
Posted Thursday, May 22, 2008 12:16 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, February 20, 2014 10:17 AM
Points: 2, 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
Post #505393
Posted Friday, May 30, 2008 5:54 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Friday, June 5, 2009 12:09 PM
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
Post #509428
Posted Thursday, October 2, 2008 6:22 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Thursday, October 2, 2008 8:46 AM
Points: 1, Visits: 6
EXCELENTE TU SUGERENCIA, TOD!!! REALMENTE EXCELENTE!!!

Enhorabuena Tod!
Post #579598
Posted Tuesday, August 3, 2010 2:15 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, August 3, 2010 2:05 AM
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?
Post #962638
Posted Tuesday, August 3, 2010 7:03 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 11:18 PM
Points: 35,267, Visits: 31,759
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #962761
Posted Tuesday, August 3, 2010 7:09 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 11:18 PM
Points: 35,267, Visits: 31,759
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #962766
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse