Re: [SQL] rule's behavior with join interesting

2004-04-22 Thread Richard Huxton
On Wednesday 21 April 2004 21:07, Kemin Zhou wrote:
 Here I have a very simple case

 table1
 table1_removed

 anotherTable

 create or replace RULE rec_remove as ON DELETE TO table1
 do insert into table1_remove
 select old.*, a.acc from old g join anotherTable a on g.acc=a.other_acc;
 ===
 the parser complained   ERROR:  relation *OLD* does not exist
 So I used
 select old.*, a.acc from table1 g join anotherTable a on g.acc=a.other_acc;

 This worked find.

 When I run delete on table1, 213 rows.

 tmp table received 213X213 = 45369 rows.  each row is duplicated 213 times.

The issue here is that although you can refer to values such as OLD.acc, OLD 
is not a table but more like single row. So, you probably want
...DO INSERT INSTO table1_remove
SELECT old.*, a.acc FROM anotherTable a WHERE a.other_acc = OLD.acc;

Your second example just ignored the OLD.acc altogether in the join, so of 
course you got an unconstraind join of 213 x 213.
-- 
  Richard Huxton
  Archonet Ltd

---(end of broadcast)---
TIP 1: subscribe and unsubscribe commands go to [EMAIL PROTECTED]


Re: [SQL] rule's behavior with join interesting

2004-04-22 Thread Jan Wieck
Richard Huxton wrote:
On Wednesday 21 April 2004 21:07, Kemin Zhou wrote:
Here I have a very simple case

table1
table1_removed
anotherTable

create or replace RULE rec_remove as ON DELETE TO table1
do insert into table1_remove
select old.*, a.acc from old g join anotherTable a on g.acc=a.other_acc;
===
the parser complained   ERROR:  relation *OLD* does not exist
So I used
select old.*, a.acc from table1 g join anotherTable a on g.acc=a.other_acc;
This worked find.

When I run delete on table1, 213 rows.

tmp table received 213X213 = 45369 rows.  each row is duplicated 213 times.
The issue here is that although you can refer to values such as OLD.acc, OLD 
is not a table but more like single row. So, you probably want
...DO INSERT INSTO table1_remove
SELECT old.*, a.acc FROM anotherTable a WHERE a.other_acc = OLD.acc;
Old is not a single row at all, it is a placeholder for the result set 
that is deleted in this case. The rule you probably want is:

create rule rec_remove as on delete to table1
do insert into table1_remove select old.*, a.acc
from anotherTable a where old.acc = a.other_acc;
This unfortunately does NOT support all the other join types, since the 
parser does not let you use JOIN before any FROM and you have old 
already in your rangetable, even if you don't see it.

Jan

Your second example just ignored the OLD.acc altogether in the join, so of 
course you got an unconstraind join of 213 x 213.


--
#==#
# It's easier to get forgiveness for being wrong than for being right. #
# Let's break this rule - forgive me.  #
#== [EMAIL PROTECTED] #
---(end of broadcast)---
TIP 9: the planner will ignore your desire to choose an index scan if your
 joining column's datatypes do not match


[SQL] rule's behavior with join interesting

2004-04-21 Thread Kemin Zhou
Here I have a very simple case

table1
table1_removed
anotherTable

create or replace RULE rec_remove as ON DELETE TO table1
do insert into table1_remove
select old.*, a.acc from old g join anotherTable a on g.acc=a.other_acc;
===
the parser complained   ERROR:  relation *OLD* does not exist
So I used
select old.*, a.acc from table1 g join anotherTable a on g.acc=a.other_acc;
This worked find.

When I run delete on table1, 213 rows.

tmp table received 213X213 = 45369 rows.  each row is duplicated 213 times.

My question: Is it possible to bring in another table in a rule?
Where am I wrong in this case.  Certainly I don't want that duplications.
My table1_removed contain a primary key for the id.  The speed of doing 
the delete is also very slow
apparently it has to do N-square inserts.
I have very limited information to read on the manual of postgres.
Any solution?

Kemin





**
Proprietary or confidential information belonging to Ferring Holding SA or to one of 
its affiliated companies may be contained in the message. If you are not the addressee 
indicated in this message (or responsible for the delivery of the message to such 
person), please do not copy or deliver this message to anyone. In such case, please 
destroy this message and notify the sender by reply e-mail. Please advise the sender 
immediately if you or your employer do not consent to e-mail for messages of this 
kind. Opinions, conclusions and other information in this message represent the 
opinion of the sender and do not necessarily represent or reflect the views and 
opinions of Ferring.
**
---(end of broadcast)---
TIP 8: explain analyze is your friend