By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
438,756 Members | 1,745 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 438,756 IT Pros & Developers. It's quick & easy.

Probably dumb question

P: n/a
I have a (somewhat complicated) query that returns the rows from a table
and its self join in the correct order. I want to call a procedure on
each of the returned rows, in the order returned. Is there any to do
this in straight sql or must I write an sql procedure with a cursor on
the select and issue the call while accessing rows through the cursor?

What I'm trying to do (as those of you that follow comp.databases.theory
will remember) is to create (and maintain) a sorted tree from an
unsorted one.

What I'd like (I'm making this syntax up from wishful thinking) is
something like:

for each row in (select ...) call add_location2(subx.entity_id,
subx.loc_id, subx.namex, supx.loc_id)

query follows (after Joe Celko in _Trees and Hierarchies in SQL for
Smarties_, p51):

select subx.entity_id, subx.loc_id, subx.namex, supx.loc_id
from is3.locations as supx,
is3.locations as subx
where subx.leftx between supx.leftx and supx.rightx
and supx.loc_id<>subx.loc_id
and not exists
(select *
from is3.locations as midx
where midx.leftx between supx.leftx and supx.rightx
and subx.leftx between midx.leftx and midx.rightx
and midx.loc_id not in (supx.loc_id, subx.loc_id))
order by subx.leftx

The procedure (ibid, pp 78-79) modified to create a sorted (by namex) tree:

create procedure add_location2(in ent integer,
in new_id integer,
in new_name varchar(50),
in under integer)
language sql
modifies sql data

begin
declare under_lft integer;
declare under_rgt integer;
declare parent_level smallint;
declare sib_lft integer;
declare sib_rgt integer;
declare my_lft integer;
declare my_rgt integer;

set schema nullid;

select leftx, rightx, levelx into under_lft, under_rgt,
parent_level
from locations2
where loc_id = under;
and leftx between under_lft and under_rgt
and namex<new_name
order by namex desc
fetch first 1 row only;

if(sib_rgt is null) then begin
set my_lft = under_lft+1;
set my_rgt = under_lft+2;
end;
else begin
set my_lft = sib_rgt+1;
set my_rgt = sib_rgt+2;
end;
end if;

update locations2
set leftx = case
when leftx >= my_rgt-1 then leftx+2
else leftx
end,
rightx = case
when rightx >= my_rgt-1 then rightx+2
else rightx
end;

insert into locations2 values(new_id,new_name,my_lft,my_rgt,ent,
null, parent_level+1);

end
Nov 12 '05 #1
Share this Question
Share on Google+
9 Replies


P: n/a
Bob Stearns wrote:
I have a (somewhat complicated) query that returns the rows from a table
and its self join in the correct order. I want to call a procedure on
each of the returned rows, in the order returned. Is there any to do
this in straight sql or must I write an sql procedure with a cursor on
the select and issue the call while accessing rows through the cursor?

What I'm trying to do (as those of you that follow comp.databases.theory
will remember) is to create (and maintain) a sorted tree from an
unsorted one.

What I'd like (I'm making this syntax up from wishful thinking) is
something like:

for each row in (select ...) call add_location2(subx.entity_id,
subx.loc_id, subx.namex, supx.loc_id)

query follows (after Joe Celko in _Trees and Hierarchies in SQL for
Smarties_, p51):

select subx.entity_id, subx.loc_id, subx.namex, supx.loc_id
from is3.locations as supx,
is3.locations as subx
where subx.leftx between supx.leftx and supx.rightx
and supx.loc_id<>subx.loc_id
and not exists
(select *
from is3.locations as midx
where midx.leftx between supx.leftx and supx.rightx
and subx.leftx between midx.leftx and midx.rightx
and midx.loc_id not in (supx.loc_id, subx.loc_id))
order by subx.leftx

The procedure (ibid, pp 78-79) modified to create a sorted (by namex) tree:

create procedure add_location2(in ent integer,
in new_id integer,
in new_name varchar(50),
in under integer)
language sql
modifies sql data

begin
declare under_lft integer;
declare under_rgt integer;
declare parent_level smallint;
declare sib_lft integer;
declare sib_rgt integer;
declare my_lft integer;
declare my_rgt integer;

set schema nullid;

select leftx, rightx, levelx into under_lft,
under_rgt, parent_level
from locations2
where loc_id = under;
and leftx between under_lft and under_rgt
and namex<new_name
order by namex desc
fetch first 1 row only;

if(sib_rgt is null) then begin
set my_lft = under_lft+1;
set my_rgt = under_lft+2;
end;
else begin
set my_lft = sib_rgt+1;
set my_rgt = sib_rgt+2;
end;
end if;

update locations2
set leftx = case
when leftx >= my_rgt-1 then leftx+2
else leftx
end,
rightx = case
when rightx >= my_rgt-1 then rightx+2
else rightx
end;

insert into locations2 values(new_id,new_name,my_lft,my_rgt,ent,
null, parent_level+1);

end

You could use an dynmaoci compound statement (BEGIN ATOMIC ... END) with
a FOR and a CALL in DB2 for LUW V8.2.
In DB2 V8.1.4 and higher you could also use a correlated TABLE function
if you want inlining.
Heck you could even make that a correlated table function feeding the
FOR loop as the outer of the join. But that would be mean since you have
to rely on DB2's optimizer not kicking out the nested ORDER BY.

Cheres
Serge
--
Serge Rielau
DB2 SQL Compiler Development
IBM Toronto Lab
Nov 12 '05 #2

P: n/a
Serge Rielau wrote:
Bob Stearns wrote:
I have a (somewhat complicated) query that returns the rows from a
table and its self join in the correct order. I want to call a
procedure on each of the returned rows, in the order returned. Is
there any to do this in straight sql or must I write an sql procedure
with a cursor on the select and issue the call while accessing rows
through the cursor?

What I'm trying to do (as those of you that follow
comp.databases.theory will remember) is to create (and maintain) a
sorted tree from an unsorted one.

What I'd like (I'm making this syntax up from wishful thinking) is
something like:

for each row in (select ...) call add_location2(subx.entity_id,
subx.loc_id, subx.namex, supx.loc_id)

query follows (after Joe Celko in _Trees and Hierarchies in SQL for
Smarties_, p51):

select subx.entity_id, subx.loc_id, subx.namex, supx.loc_id
from is3.locations as supx,
is3.locations as subx
where subx.leftx between supx.leftx and supx.rightx
and supx.loc_id<>subx.loc_id
and not exists
(select *
from is3.locations as midx
where midx.leftx between supx.leftx and supx.rightx
and subx.leftx between midx.leftx and midx.rightx
and midx.loc_id not in (supx.loc_id, subx.loc_id))
order by subx.leftx

The procedure (ibid, pp 78-79) modified to create a sorted (by namex)
tree:

create procedure add_location2(in ent integer,
in new_id integer,
in new_name varchar(50),
in under integer)
language sql
modifies sql data

begin
declare under_lft integer;
declare under_rgt integer;
declare parent_level smallint;
declare sib_lft integer;
declare sib_rgt integer;
declare my_lft integer;
declare my_rgt integer;

set schema nullid;

select leftx, rightx, levelx into under_lft,
under_rgt, parent_level
from locations2
where loc_id = under;
and leftx between under_lft and under_rgt
and namex<new_name
order by namex desc
fetch first 1 row only;

if(sib_rgt is null) then begin
set my_lft = under_lft+1;
set my_rgt = under_lft+2;
end;
else begin
set my_lft = sib_rgt+1;
set my_rgt = sib_rgt+2;
end;
end if;

update locations2
set leftx = case
when leftx >= my_rgt-1 then leftx+2
else leftx
end,
rightx = case
when rightx >= my_rgt-1 then rightx+2
else rightx
end;

insert into locations2 values(new_id,new_name,my_lft,my_rgt,ent,
null, parent_level+1);

end


You could use an dynmaoci compound statement (BEGIN ATOMIC ... END) with
a FOR and a CALL in DB2 for LUW V8.2.
In DB2 V8.1.4 and higher you could also use a correlated TABLE function
if you want inlining.
Heck you could even make that a correlated table function feeding the
FOR loop as the outer of the join. But that would be mean since you have
to rely on DB2's optimizer not kicking out the nested ORDER BY.

Cheres
Serge

I need a little better pointer to "correlated TABLE function" (I'm
currently running 8.1.5). I couldn't find a useful reference at the
Information center using these keywords an I am sufficiently ignorant of
the subject that no further keywords occurred to me. Or a sample
skeleton example of the statement you are thing of would do. I can (I
think) fill in the blanks.
Nov 12 '05 #3

P: n/a
Bob Stearns wrote:
I need a little better pointer to "correlated TABLE function" (I'm
currently running 8.1.5). I couldn't find a useful reference at the
Information center using these keywords an I am sufficiently ignorant of
the subject that no further keywords occurred to me. Or a sample
skeleton example of the statement you are thing of would do. I can (I
think) fill in the blanks.

Here you go. Check e.g. listing 4 and 5:
http://www-128.ibm.com/developerwork...dm-0411rielau/
FP5 will do the job.

Cheers
Serge
--
Serge Rielau
DB2 SQL Compiler Development
IBM Toronto Lab
Nov 12 '05 #4

P: n/a
Serge Rielau wrote:
Bob Stearns wrote:
I need a little better pointer to "correlated TABLE function" (I'm
currently running 8.1.5). I couldn't find a useful reference at the
Information center using these keywords an I am sufficiently ignorant
of the subject that no further keywords occurred to me. Or a sample
skeleton example of the statement you are thing of would do. I can (I
think) fill in the blanks.


Here you go. Check e.g. listing 4 and 5:
http://www-128.ibm.com/developerwork...dm-0411rielau/

FP5 will do the job.

Cheers
Serge

Thank you. I have my homework for the {day, week, month, year}. That is
some powerful sql code. Out of curiosity, how long did you work on these
codes to get the elegant results you did? In other words, is there any
hope for a beginner to learn to do this level of work in 5 years?
Nov 12 '05 #5

P: n/a
Bob Stearns wrote:
Serge Rielau wrote:
Bob Stearns wrote:
I need a little better pointer to "correlated TABLE function" (I'm
currently running 8.1.5). I couldn't find a useful reference at the
Information center using these keywords an I am sufficiently ignorant
of the subject that no further keywords occurred to me. Or a sample
skeleton example of the statement you are thing of would do. I can (I
think) fill in the blanks.

Here you go. Check e.g. listing 4 and 5:
http://www-128.ibm.com/developerwork...dm-0411rielau/

FP5 will do the job.

Cheers
Serge


Thank you. I have my homework for the {day, week, month, year}. That is
some powerful sql code. Out of curiosity, how long did you work on these
codes to get the elegant results you did? In other words, is there any
hope for a beginner to learn to do this level of work in 5 years?

Sure it can be doen in 5 years, but keep in mind that I did "nothing
but". The majority of my job has been to undertand SQL, implement it
into DB2 and devise new language. I'd guess it took 3-4 years to become
proficient. The rest is begging for resources. There are always more
ideas than there are developers to execute ;-)
By comparison I'm clueless about administrating DB2 or Java.

Cheers
Serge
--
Serge Rielau
DB2 SQL Compiler Development
IBM Toronto Lab
Nov 12 '05 #6

P: n/a
Serge Rielau wrote:
Bob Stearns wrote:
I need a little better pointer to "correlated TABLE function" (I'm
currently running 8.1.5). I couldn't find a useful reference at the
Information center using these keywords an I am sufficiently ignorant
of the subject that no further keywords occurred to me. Or a sample
skeleton example of the statement you are thing of would do. I can (I
think) fill in the blanks.


Here you go. Check e.g. listing 4 and 5:
http://www-128.ibm.com/developerwork...dm-0411rielau/

FP5 will do the job.

Cheers
Serge

If I've understood the example (only possible, not probable, given that
I've only studied it and the relevant parts of the SQL Reference for 4
hours), I would have to change the function add_location2 to a table
function in order to use it in a construct similar to your listing 4. Is
that correct?

Another question: your sql statement apparently depends on the select
for itemlist being done "before" the new_ol_local function being called.
Is forced by the order of the phrases or is the optimizer smart enough
to see the dependency?
Nov 12 '05 #7

P: n/a
Bob Stearns wrote:
Another question: your sql statement apparently depends on the select
for itemlist being done "before" the new_ol_local function being called.
Is forced by the order of the phrases or is the optimizer smart enough
to see the dependency?

A table function which MODFIES SQL DATA must be correlated to all the
join parters. This forces it to be the last (inner most) to start executing.
IFF there is a read/wrote conflict the optimizer will detect it and
ensure that the outer of the join have complete before the table
function is allowed to start.
To get good performance any sort of conflicts should be avoided.

Cheers
Serge

--
Serge Rielau
DB2 SQL Compiler Development
IBM Toronto Lab
Nov 12 '05 #8

P: n/a
>> I want to call a procedure on each of the returned rows, in the order returned. <<

SQL is a set-oriented language!!! Let's get back to the basics of an
RDBMS. Rows are not records; fields are not columns; tables are not
files; there is no sequential access or ordering in an RDBMS, so
"first", "next" and "last" are totally meaningless.

We need more info ..

Nov 12 '05 #9

P: n/a
--CELKO-- wrote:
I want to call a procedure on each of the returned rows, in the order returned. <<

SQL is a set-oriented language!!! Let's get back to the basics of an
RDBMS. Rows are not records; fields are not columns; tables are not
files; there is no sequential access or ordering in an RDBMS, so
"first", "next" and "last" are totally meaningless.

We need more info ..

Look back at my message of 10/05/2005, 11:41PM, which started this
thread. It gives the complete sql, function, and reasoning of why I
think I have to process the given rows in a given order.
Nov 12 '05 #10

This discussion thread is closed

Replies have been disabled for this discussion.