Обсуждение: foreign key problems

Поиск
Список
Период
Сортировка

foreign key problems

От
"BARTKO, Zoltán"
Дата:
Dear all,

I have a problem:

if I create the tables that are in the attached file, I can't insert
rows into the AAttachment table, even though the rows in DObject with
the given primary key exist (PgSQL 8.0 rc1 complains about
(ownerid)=(insert the number here) not available in DObject. The same
happens with attribute bodyid).

I have noticed that this behavior is different, if I do not use
inherited tables, e.g. if I use

create table A (
a integer references B(b),
b integer references B(b));

create table B
(b serial primary key);

insert into B values (1);
insert into B values (2);
insert into A (a,b) values (1,2);

works flawlessly.

Is this a feature or a bug or is the problem in front of the computer?

thanks

Zoltan



____________________________________
RAMMSTEIN, 22.02.2005 o 20,00, Bratislava Incheba,
Info: 0904 666 363, http://www.xl.sk

create table AAssociation (createdBy    integer,                    --* the creator of the associationcreation
timestampwith time zone default 'now'        --* creation timestamp with time zone 
);

create table AObjAssociation (privilege    integer not null references SysPrivilege(privilege),        --* the
privilegeused to create the associationinsteadOf    integer references DPerson(person)        --* instead of whom is
theaction taken 
) inherits (AAssociation);

create table AAttachment (ownerID    bigint references DObject(object),    --* owner objectbodyID    bigint references
DObject(object)   --* attached object 
) inherits (AObjAssociation);

create table DPerson (person        serial primary key,    --* person row id#login        varchar(16) not null unique,
 --* login namepasswd        varchar(16) not null,    --* passwordaname        varchar not null,    --* name surname
   varchar not null,    --* surnameisAdmin        boolean default false,    --* is the person an admin?unique (aname,
surname)
) inherits (DOrgEntity);

create table DOrgEntity (who        integer not null,            --* record authorcreatedAt    timestamp with time zone
default'now',    --* creation timestamp with time zoneisActive    boolean default true            --* is the entity
active?
);

create table SysObjTypes (objectType    integer unique not null primary key,    --* object typeaname        text,
            --* nameisAttachment    boolean,                --* is attachment of other objectshasAttachment    boolean
                 --* has attachments 
);

create table SysStatus (status        integer unique not null primary key,    --* id#addAttachment    boolean,
     --* allow adding new attachmentsdropAttachment    boolean,                --* allow dropping existing
attachmentsaname       text not null,                --* status namedescription    text                    --* status
description
);

create table DObject (object        bigserial primary key,        --* id#revision    integer not null default 0,    --*
ordinalnumber of the commited changeaname        text not null,            --* object namedescription    text default
'',       --* object descriptionobjectType    integer not null references SysObjTypes(objectType),
 --* the object typestatus        integer not null references SysStatus(status),                        --* the object
statusunique(aname, description, objectType) 
) inherits (DRecord);

create table SysPrivilege (privilege    integer unique not null primary key,    --* id#aname        text not null,
         --* privilege namedescription    text                     --* privilege description 
);

Re: foreign key problems

От
Stephan Szabo
Дата:
On Tue, 4 Jan 2005, [iso-8859-2] BARTKO, Zolt�n wrote:

> if I create the tables that are in the attached file, I can't insert
> rows into the AAttachment table, even though the rows in DObject with
> the given primary key exist (PgSQL 8.0 rc1 complains about
> (ownerid)=(insert the number here) not available in DObject. The same
> happens with attribute bodyid).

It looks like the set of table definitions you gave in the attached file
do not actually work as given, and there's no example data. Running on
8.0 beta3 I was able to insert data that allowed me to place a row into
AAttachment (and in fact I actually can insert some data that probably
should not be allowed). I'm not sure if that's based on my basically null
definition of DRecord or not however.

In general, however, foreign keys and inheritance don't mix (neither do
primary keys or unique constraints). In general, they'll only currently
work for the table they're in specifically and only for the table
mentioned specifically. So, for example, the references constraints in
AObjAssociation are not inherited by AAttachment. Inheritance really needs
someone to champion getting all of these deficiencies fixed.


Re: foreign key problems

От
"BARTKO, Zoltán"
Дата:
Ok, so I made some changes (manual "inheritance" of PK and FK
constraints), but nevertheless I get still the same dumb error. I made
a dump of the DB via pg_dump, it is available at

http://de.geocities.com/bartkozo/dump.tgz

DRecord was dropped, the columns moved into DObject. I still have no
idea why foreign keys work on other tables and do not on this one.

I have three users, superaspiramus, aspiramus and aspiramusadmin. The
first is the owner of the db.

After loading, the contents of the DObject table are:

aspiramus=> select * from DObject;who | insteadof | privilege |         createdat          | objectid |
revision
| aname | description | objecttype | status
-----+-----------+-----------+----------------------------+----------+----------
+-------+-------------+------------+-------- -2 |           |        -1 | 2005-01-05 09:38:11.906+01 |       34 |
1
| a     | a           |          1 |     67 -2 |           |        -1 | 2005-01-05 09:37:27.625+01 |       35 |      0
| b     | b           |          1 |     61 -2 |           |        -2 | 2005-01-05 09:37:27.625+01 |       33 |      0
| name  | description |         13 |    301
(3 riadkov)

when trying this:

aspiramus=> insert into AAttachment (createdby, privilege, insteadof,
objectid, bodyid) values (-2,-2,null,33,33);

I get:

ERROR:  insert or update on table "aattachment" violates foreign key
constraint "aattachment_objectid_fkey"
DETAIL:  Key (objectid)=(33) is not present in table "dobject".

I think the problem is not in front of the computer, but maybe I am
wrong. If so, I would appreciate some help as to where I am wrong.

I can bypass this problem by dropping the FK constraints from objectID
and bodyID in AAttachment, but it is not too kosher.

Thanks for your assistance

Zoltan

>
> On Tue, 4 Jan 2005, [iso-8859-2] BARTKO, Zoltán wrote:
>
> > if I create the tables that are in the attached file, I can't insert
> > rows into the AAttachment table, even though the rows in DObject with
> > the given primary key exist (PgSQL 8.0 rc1 complains about
> > (ownerid)=(insert the number here) not available in DObject. The same
> > happens with attribute bodyid).
>
> It looks like the set of table definitions you gave in the attached file
> do not actually work as given, and there's no example data. Running on
> 8.0 beta3 I was able to insert data that allowed me to place a row into
> AAttachment (and in fact I actually can insert some data that probably
> should not be allowed). I'm not sure if that's based on my basically
null
> definition of DRecord or not however.
>
> In general, however, foreign keys and inheritance don't mix (neither do
> primary keys or unique constraints). In general, they'll only currently
> work for the table they're in specifically and only for the table
> mentioned specifically. So, for example, the references constraints in
> AObjAssociation are not inherited by AAttachment. Inheritance really
needs
> someone to champion getting all of these deficiencies fixed.
>
> ---------------------------(end of broadcast)---------------------------
> TIP 5: Have you checked our extensive FAQ?
>
>                http://www.postgresql.org/docs/faqs/FAQ.html
>

____________________________________
RAMMSTEIN, 22.02.2005 o 20,00, Bratislava Incheba,
Info: 0904 666 363, http://www.xl.sk



Re: foreign key problems

От
Stephan Szabo
Дата:
On Wed, 5 Jan 2005, [iso-8859-2] BARTKO, Zoltán wrote:

> Ok, so I made some changes (manual "inheritance" of PK and FK
> constraints), but nevertheless I get still the same dumb error. I made
> a dump of the DB via pg_dump, it is available at
>
> http://de.geocities.com/bartkozo/dump.tgz
>
> DRecord was dropped, the columns moved into DObject. I still have no
> idea why foreign keys work on other tables and do not on this one.
>
> I have three users, superaspiramus, aspiramus and aspiramusadmin. The
> first is the owner of the db.
>
> After loading, the contents of the DObject table are:
>
> aspiramus=> select * from DObject;

Do select * from ONLY DObject.

The constraint currently only goes to DObject, records that are actually
in DObject and not any tables derived from it. This is one of the
deficiencies I was trying to refer to in the previous message. As a note,
your primary keys will also not work to prevent duplicates of objectid
between subclasses of DObject currently, and I'm not sure whether that
matters to you:

insert into dmessage (who, privilege, objectid, objecttype, status,
aname,sender,receiver) values (-2,-2,33,13,301,'name',-2,-2);

select objectid from dobject;objectid
----------      34      35      33      33
(4 rows)

Inheritance needs alot of work. :(



Re: foreign key problems

От
Stephan Szabo
Дата:
On Wed, 5 Jan 2005, Stephan Szabo wrote:

>
> On Wed, 5 Jan 2005, [iso-8859-2] BARTKO, Zoltán wrote:
>
> > Ok, so I made some changes (manual "inheritance" of PK and FK
> > constraints), but nevertheless I get still the same dumb error. I made
> > a dump of the DB via pg_dump, it is available at
> >
> > http://de.geocities.com/bartkozo/dump.tgz
> >
> > DRecord was dropped, the columns moved into DObject. I still have no
> > idea why foreign keys work on other tables and do not on this one.
> >
> > I have three users, superaspiramus, aspiramus and aspiramusadmin. The
> > first is the owner of the db.
> >
> > After loading, the contents of the DObject table are:
> >
> > aspiramus=> select * from DObject;
>
> Do select * from ONLY DObject.
>
> The constraint currently only goes to DObject, records that are actually
> in DObject and not any tables derived from it. This is one of the
> deficiencies I was trying to refer to in the previous message. As a note,
> your primary keys will also not work to prevent duplicates of objectid
> between subclasses of DObject currently, and I'm not sure whether that
> matters to you:
>
> insert into dmessage (who, privilege, objectid, objecttype, status,
> aname,sender,receiver) values (-2,-2,33,13,301,'name',-2,-2);
>
> select objectid from dobject;
>  objectid
> ----------
>        34
>        35
>        33
>        33
> (4 rows)
>
> Inheritance needs alot of work. :(

I forgot to mention that this has come up in the past, and some people
have sent messages about workarounds. I believe one involved pulling the
canonical key values out into a separate table that is managed by triggers
with foreign keys between each of the tables in the hierarchy to the key
table. Thus, a unique constraint on that key table would effectively span
all tables with such triggers and foreign keys to that table might work.
However, that doesn't work if you also have foreign keys to a derived
table from which other tables might be inherited.