Re: [HACKERS] [PATCHES] Foreign key type checking patch

2004-03-02 Thread Fabien COELHO

Hello again,

I turn the discussion to the dev list as it seems more appropriate.

So about the proposed patch to warn if foreign key type do not match the
target key:

 Stephan Szabo [EMAIL PROTECTED] writes:
  I'm really not sure that it makes sense to warn for the fk cases where the
  semantics should be correct (if they're not we need to fix it or make it
  an error) but in which an error might have been made by the user because
  the types are different given that it at least seems reasonable to me that
  the fk type is allowable to be a subset of the referenced type.  I don't
  think simply different types is sufficient to be warning material.

 I can think of several cases where it might be reasonable for the types
 to be different.  One case in particular that needs some thought is
 where the FK and referenced PK are domains on a common base type.


I'm looking forward to see an example where:

  1) the difference in type is actually needed by the application.

  2) a simple warning about the issue would be considered harmful.


Let me describe some examples where IMVVHO a simple warning make sense,
although they are silently accepted by postgres at the moment:

1/ integers

CREATE TABLE foo(fid INT4 NOT NULL PRIMARY KEY, ...);
CREATE TABLE bla(fid INT2 REFERENCES foo, ...);

The application will be fine till you enter fid=32767, and
it inserts will fail in bla with fid=32768. Much later on.

2/ chars

CREATE TABLE foo(fid VARCHAR(4) NOT NULL PRIMARY KEY, ...);
CREATE TABLE bla(fid VARCHAR(2) REFERENCES foo, ...);

bla will be able to reference all 2-letters keys of foo, but no more.
If you have some counter in foo, it will fail when it turns 3 letters.

3/ chars

CREATE TABLE foo(fid VARCHAR(4) NOT NULL PRIMARY KEY, ...);
CREATE TABLE bla(fid VARCHAR(8) REFERENCES foo, ...);

declaring a larger size is not a problem here, however you will
never be able to but any reference in bla larger than 4 as it must
match its counter part in foo. So it is just a little bit stupid.

4/ time

CREATE TABLE day(quand DATE NOT NULL PRIMARY KEY, ...);
CREATE TABLE event(quand TIMESTAMP REFERENCES day, ...);

The intent could be that events should refer to some day already
registered in the base. Obviously it does work, because the = will cast to
timestamp, to only the 00:00:00 timestamp will match a day.

etc.

-- 
Fabien Coelho - [EMAIL PROTECTED]

---(end of broadcast)---
TIP 7: don't forget to increase your free space map settings


Re: [HACKERS] [PATCHES] Foreign key type checking patch

2004-03-02 Thread Stephan Szabo
On Tue, 2 Mar 2004, Fabien COELHO wrote:


 Hello again,

 I turn the discussion to the dev list as it seems more appropriate.

 So about the proposed patch to warn if foreign key type do not match the
 target key:

  Stephan Szabo [EMAIL PROTECTED] writes:
   I'm really not sure that it makes sense to warn for the fk cases where the
   semantics should be correct (if they're not we need to fix it or make it
   an error) but in which an error might have been made by the user because
   the types are different given that it at least seems reasonable to me that
   the fk type is allowable to be a subset of the referenced type.  I don't
   think simply different types is sufficient to be warning material.
 
  I can think of several cases where it might be reasonable for the types
  to be different.  One case in particular that needs some thought is
  where the FK and referenced PK are domains on a common base type.


 I'm looking forward to see an example where:

   1) the difference in type is actually needed by the application.

   2) a simple warning about the issue would be considered harmful.


 Let me describe some examples where IMVVHO a simple warning make sense,
 although they are silently accepted by postgres at the moment:

 1/ integers

 CREATE TABLE foo(fid INT4 NOT NULL PRIMARY KEY, ...);
 CREATE TABLE bla(fid INT2 REFERENCES foo, ...);

 The application will be fine till you enter fid=32767, and
 it inserts will fail in bla with fid=32768. Much later on.

Which is fine if bla is meant to store a subset of the allowable foo
values.  It'd be really hard to say at bla creation time that there isn't
going to be a bla2 which say takes an int4 check (fid=32768) which might
be being used for dividing up the foo space between multiple tables.

 2/ chars

 CREATE TABLE foo(fid VARCHAR(4) NOT NULL PRIMARY KEY, ...);
 CREATE TABLE bla(fid VARCHAR(2) REFERENCES foo, ...);

 bla will be able to reference all 2-letters keys of foo, but no more.
 If you have some counter in foo, it will fail when it turns 3 letters.

Same as above.

 3/ chars

 CREATE TABLE foo(fid VARCHAR(4) NOT NULL PRIMARY KEY, ...);
 CREATE TABLE bla(fid VARCHAR(8) REFERENCES foo, ...);

 declaring a larger size is not a problem here, however you will
 never be able to but any reference in bla larger than 4 as it must
 match its counter part in foo. So it is just a little bit stupid.

This one is fairly pointless for the single column case but a multiple
column match unspecified constraint could allow the full 8 characters if
there's a second column which is null.

 4/ time

 CREATE TABLE day(quand DATE NOT NULL PRIMARY KEY, ...);
 CREATE TABLE event(quand TIMESTAMP REFERENCES day, ...);

 The intent could be that events should refer to some day already
 registered in the base. Obviously it does work, because the = will cast to
 timestamp, to only the 00:00:00 timestamp will match a day.

This one does seem fairly broken.

5/ domains

CREATE DOMAIN posint AS int4 check(value0);
CREATE TABLE foo(fid int4 primary key);
CREATE TABLE bla(fid posint references foo);

The intent here is that foo may contain negative numbers but that those
rows won't be referenced by bla.  This is similar to 1 and 2.

---(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


Re: [HACKERS] [PATCHES] Foreign key type checking patch

2004-03-02 Thread Fabien COELHO

Hello Stephan,

  CREATE TABLE foo(fid INT4 NOT NULL PRIMARY KEY, ...);
  CREATE TABLE bla(fid INT2 REFERENCES foo, ...);
 
  The application will be fine till you enter fid=32767, and
  it inserts will fail in bla with fid=32768. Much later on.

 Which is fine if bla is meant to store a subset of the allowable foo
 values.
 [...]

Sure. This is NOT my point. I totally agree with you that the above
example MAY BE what the user intends, and that it must be allowed.
However it may ALSO be a bug that will pop up later on.

Although it is POSSIBLE that this is fine, it is much more PROBABLE that
it is a bug, hence I just suggest to issue a mere simple basic plain
user-friendly little warning, what is quite different from issuing an
error.

Thus, the user has the information. He may chose to go on as that is what
was meant, or maybe check the stuff and correct it.

In postgres compilation, gcc uses the -Wall option to issue warnings about
correct C constructs that may hide application bugs. This is the
philosophy I'm suggesting here for this very small feature.
Dear user, what you ask is right, however it looks a little bit strange,
so I tell you just in case. I'm sure you're pretty happy that the gcc
developers put such features for basic programmers, and that you use
them;-) Why not allowing that kind of approach in postgres?

  CREATE TABLE foo(fid VARCHAR(4) NOT NULL PRIMARY KEY, ...);
  CREATE TABLE bla(fid VARCHAR(8) REFERENCES foo, ...);
 
  declaring a larger size is not a problem here, however you will
  never be able to but any reference in bla larger than 4 as it must
  match its counter part in foo. So it is just a little bit stupid.

 This one is fairly pointless

Isn't it what I'm saying?

 for the single column case but a multiple column match unspecified
 constraint could allow the full 8 characters if there's a second column
 which is null.

I do not understand. I can't see how you can put 8 characters in a
reference which must match a 4 characters string.

  CREATE TABLE day(quand DATE NOT NULL PRIMARY KEY, ...);
  CREATE TABLE event(quand TIMESTAMP REFERENCES day, ...);
 
  The intent could be that events should refer to some day already
  registered in the base. Obviously it does work, because the = will cast to
  timestamp, to only the 00:00:00 timestamp will match a day.

 This one does seem fairly broken.

Yes, my comment is broken, as I wrote it does work, meaning, it does
not work:-(

Anyway postgres accepts the two tables and the foreign key references from
a timestamp to a date without a warning, and although I can imagine an
application that would really mean that, I'm pretty sure most users would
like this reported as a warning, as it is more likely to be a bug.

 CREATE DOMAIN posint AS int4 check(value0);
 CREATE TABLE foo(fid int4 primary key);
 CREATE TABLE bla(fid posint references foo);

 The intent here is that foo may contain negative numbers but that those
 rows won't be referenced by bla. This is similar to 1 and 2.

Sure, I agree with you there are example where you may mean that.
My point is about a ***warning***, because I think that most of the time
this hides a future bug, even if some time it may be the intent.

Have a nice day,

-- 
Fabien Coelho - [EMAIL PROTECTED]

---(end of broadcast)---
TIP 5: Have you checked our extensive FAQ?

   http://www.postgresql.org/docs/faqs/FAQ.html


Re: [HACKERS] [PATCHES] Foreign key type checking patch

2004-03-02 Thread Stephan Szabo
On Tue, 2 Mar 2004, Fabien COELHO wrote:


 Hello Stephan,

   CREATE TABLE foo(fid INT4 NOT NULL PRIMARY KEY, ...);
   CREATE TABLE bla(fid INT2 REFERENCES foo, ...);
  
   The application will be fine till you enter fid=32767, and
   it inserts will fail in bla with fid=32768. Much later on.
 
  Which is fine if bla is meant to store a subset of the allowable foo
  values.
  [...]

 Sure. This is NOT my point. I totally agree with you that the above
 example MAY BE what the user intends, and that it must be allowed.
 However it may ALSO be a bug that will pop up later on.

 Although it is POSSIBLE that this is fine, it is much more PROBABLE that
 it is a bug, hence I just suggest to issue a mere simple basic plain
 user-friendly little warning, what is quite different from issuing an
 error.

 Thus, the user has the information. He may chose to go on as that is what
 was meant, or maybe check the stuff and correct it.

 In postgres compilation, gcc uses the -Wall option to issue warnings about
 correct C constructs that may hide application bugs. This is the
 philosophy I'm suggesting here for this very small feature.
 Dear user, what you ask is right, however it looks a little bit strange,
 so I tell you just in case. I'm sure you're pretty happy that the gcc
 developers put such features for basic programmers, and that you use
 them;-) Why not allowing that kind of approach in postgres?

Because producing noise warnings often *lower* the amount of use you get
from real warnings.  If one has to wade through useless messages to divine
the ones that are meaningful, overall many people just start ignoring all
warnings.  I could be convinced that it is notice material, since people
who don't want to see it probably don't want to see the other notices
either, but warning seems way to strong to me.

Fundamentally, I don't see a huge difference between this and
 select * from foo,bla where foo.fid=bla.fid;
where the same general constraints on meaningful values apply.

   CREATE TABLE foo(fid VARCHAR(4) NOT NULL PRIMARY KEY, ...);
   CREATE TABLE bla(fid VARCHAR(8) REFERENCES foo, ...);
  
   declaring a larger size is not a problem here, however you will
   never be able to but any reference in bla larger than 4 as it must
   match its counter part in foo. So it is just a little bit stupid.
 
  This one is fairly pointless

 Isn't it what I'm saying?

  for the single column case but a multiple column match unspecified
  constraint could allow the full 8 characters if there's a second column
  which is null.

 I do not understand. I can't see how you can put 8 characters in a
 reference which must match a 4 characters string.

Because in match unspecified, any column being null means the remainder of
the columns are not checked against the other table.  IE given a key of
(fid, other), ('abcdefg', null) is valid in match unspecified even if the
other key can only have 4 characters.

---(end of broadcast)---
TIP 6: Have you searched our list archives?

   http://archives.postgresql.org


Re: [HACKERS] [PATCHES] Foreign key type checking patch

2004-03-02 Thread Fabien COELHO

Dear Stephan,

  Although it is POSSIBLE that this is fine, it is much more PROBABLE that
  it is a bug, hence I just suggest to issue a mere simple basic plain
  user-friendly little warning, what is quite different from issuing an
  error. [...] Why not allowing that kind of approach in postgres?

 Because producing noise warnings often *lower* the amount of use you get
 from real warnings.

Ok, I understand this argument. I agree with the general idea...
However I think that this case is special enough in the sense that:

  (1) it should occur rarely, and when it occurs

  (2) it should be most of the time appropriate.

 If one has to wade through useless messages to divine the ones that are
 meaningful, overall many people just start ignoring all warnings.  I
 could be convinced that it is notice material, since people who don't
 want to see it probably don't want to see the other notices either, but
 warning seems way to strong to me.

Well, I used NOTICE in my suggested implementation, so it is fine;-)

 Fundamentally, I don't see a huge difference between this and
  select * from foo,bla where foo.fid=bla.fid;
 where the same general constraints on meaningful values apply.

1/ The warning I'm suggesting is ONCE in the life-time of the table,
   when it is declared. Your above case would be EVERY TIME a join
   is issued on the tables, which is likely to be quite often!

2/ If you use a select with a join, and if your modelisation is
   correct, then you must have declared a foreign key on your table,
   so you already get the warning at that time. If you chose to
   ignore it, you must be right!

3/ If you bother to declare foreign keys, you want them to be sound,
   so if postgres can help a little bit, that should not harm.

-- 
Fabien Coelho - [EMAIL PROTECTED]

---(end of broadcast)---
TIP 6: Have you searched our list archives?

   http://archives.postgresql.org