Re: Tropashko nested sets and materialized path - great idea but how do I insert?
Date: Thu, 11 Sep 2003 13:56:40 -0700
Message-ID: <Fs58b.22$927.175_at_news.oracle.com>
The article mentioned that every subtree is a scaled up (or down) replica of
the other subtree. That's the idea.
Suppose you want to move the node 27/16 positioned in a subtree originated
in 3/2 into a subtree originated in 7/8. (Actually you want to move the
whole subtree originated in 27/16 into the new position 3/2).
Let's intoduce some notation:
new_x - new_origin_x = k * (old_x - old_origin_x)
new_y - new_origin_y = k * (old_y - old_origin_y)
That's again nothin more than linear transformation, where k is zooming
factor. Zooming factor is just the ratio of the origin's denominators -- the
main picture of the article can convince you if you have any doubt about it.
"old"=27/16
"old_origin"=3/2
"new_origin"=27/16
so that we want to know what "new" position is. We'll write scaling&shifting
transformation component-wise as follows:
CREATE or replace
function new_denom
( old_numer integer, old_denom integer,
old_origin_numer integer, old_origin_denom integer,
new_origin_numer integer, new_origin_denom integer )
RETURN integer IS
ret_num integer; ret_den integer; zoom_factor integer; is_magnified boolean;
BEGIN
...
RETURN new_origin_denom; -- special case ...
RETURN ret_den; -- main logic
END;
/
Warmup testing:
select new_numer(27,16, 3,2, 3,4)||'/'||new_denom(27,16, 3,2, 3,4) from dual
27/32
select new_numer(27,16, 7,4, 3,4)||'/'||new_denom(27,16, 7,4, 3,4) from dual
11/16
Main test, given
SQL> select substr(lpad(' ',3*depth)||name, 1, 15), substr(path,1,15),
numer, denom
SUBSTR(LPAD('', SUBSTR(PATH,1,1 NUMER DENOM
--------------- --------------- ---------- ----------
we move all hierarchy under "BLAKE" into "MILLER" as follows:
SQL> update emps
5 rows updated.
The idea is to find the first child of MILLER -- child_...(39,32,1) -- and
move all the nodes reachable from BLAKE (11/8) into the new place
The resulting hierarchy:
SQL> select substr(lpad(' ',3*depth)||name, 1, 15), substr(path,1,15),
numer, denom
SUBSTR(LPAD('', SUBSTR(PATH,1,1 NUMER DENOM
--------------- --------------- ---------- ----------
2 from hierarchy order by numer_left/denom_left;
KING .1 3 2
CLARK .1.3 19 16
MILLER .1.3.1 39 32
BLAKE .1.2 11 8
TURNER .1.2.4 163 128
MARTIN .1.2.3 83 64
WARD .1.2.2 43 32
ALLEN .1.2.1 23 16
JONES .1.1 7 4
FORD .1.1.2 27 16
SMITH .1.1.2.1 55 32
SCOTT .1.1.1 15 8
ADAMS .1.1.1.1 31 16
2 set numer = new_numer(numer,denom, 11,8, child_numer(39,32,1),
child_denom(39,32,1))
3 , denom = new_denom(numer,denom, 11,8, child_numer(39,32,1),
child_denom(39,32,1))
4 where distance(numer,denom, 11,8)>=0
5 ;
2 from hierarchy order by numer_left/denom_left;
KING .1 3 2
CLARK .1.3 19 16
MILLER .1.3.1 39 32
BLAKE .1.3.1.1 79 64
TUR .1.3.1.1.4 1251 1024
MAR .1.3.1.1.3 627 512
WAR .1.3.1.1.2 315 256
ALL .1.3.1.1.1 159 128
JONES .1.1 7 4
FORD .1.1.2 27 16
SMITH .1.1.2.1 55 32
SCOTT .1.1.1 15 8
ADAMS .1.1.1.1 31 16
Received on Thu Sep 11 2003 - 22:56:40 CEST
