IDENTITY columns as foreign keys

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • Frank Swarbrick

    IDENTITY columns as foreign keys

    So we're trying to decide if it's better to use IDENTITY columns or
    sequences to create a surrogate key as the primary key for our tables. I
    kind of like the identity column, because it's more 'tightly integrated' in
    to the table. With a sequence you have to make sure that each application
    that inserts records uses the same sequence. (Probably not likely that it
    wouldn't, but...)

    One thing where it seems like a SEQUENCE would be better is when you insert
    a row in to a table, and then insert more than one row in to another table,
    where the PK from the first table is an FK in to the second.

    For example:

    INSERT INTO test.accounts (account_id, appl_code, appl_id, branch_number)
    VALUES (NEXT VALUE FOR test.accounts_s eq, 'DDA', 1239876543, 543);

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    PREVIOUS VALUE FOR test.accounts_s eq
    , 123456789
    , 'EN'
    );

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    PREVIOUS VALUE FOR test.accounts_s eq
    , 987654321
    , 'JP'
    );

    There seem to be various ways to handle this for an identity column. You
    can use IDENTITY_VAL_LO CAL():

    INSERT INTO test.accounts (appl_code, appl_id, branch_number)
    VALUES ('DDA', 1239876543, 543);

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    IDENTITY_VAL_LO CAL()
    , 123456789
    , 'EN'
    );

    But that will not work, in this case, for the second insert in to
    account_relatio nships, because IDENTITY_VAL_LO CAL() would return the
    identity of the previous insert into account_relatio nships, rather than the
    one in to accounts.

    Of course you could retrieve IDENTITY_VAL_LO CAL() in to a host variable
    after the insert in to accounts, but that's an extra trip to the database.

    There's also this:
    SELECT account_id
    INTO :account-id
    FROM FINAL TABLE (
    INSERT INTO test.accounts (appl_code, appl_id, branch_number)
    VALUES ('DDA', 1239876543, 543)
    );

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    :account-id
    , 123456789
    , 'EN'
    );

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    :account-id
    , 987654321
    , 'JP'
    );

    I'm not sure if this actually creates an extra trip to the database. In any
    case, my client (DB2 for VSE) does not appear to be able to handle this type
    of statement, so I can't use it.

    Another thing that does work for my particular example is using a select
    inside the values clause, ie:

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    (SELECT account_id
    FROM test.accounts
    WHERE appl_code = 'DDA'
    AND appl_id = 1239876543)
    , 123456789
    , 'EN'
    );

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    (SELECT account_id
    FROM test.accounts
    WHERE appl_code = 'DDA'
    AND appl_id = 1239876543)
    , 987654321
    , 'JP'
    );

    This works in my case because of a UNIQUE (appl_code, appl_id) constraint.
    I don't like the fact that it does the SELECT for each insert in to
    account_relatio nships, but that does not appear to add too much overhead
    since the predicate uses the index for the UNIQUE constraint.

    Have I missed any options for how to do this when using an IDENTITY column?

    Seems to me it would be nice to extend the IDENTITY_VAL_LO CAL() function to
    allow an input parameter naming the table that you want to retrieve it from.
    For instance:

    INSERT INTO test.accounts (appl_code, appl_id, branch_number)
    VALUES ('DDA', 1239876543, 543);

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    IDENTITY_VAL_LO CAL(test.accoun ts)
    , 123456789
    , 'EN'
    );

    INSERT INTO test.account_re lationships (account_id, cif_number,
    relationship_in d)
    VALUES (
    IDENTITY_VAL_LO CAL(test.accoun ts)
    , 987654321
    , 'JP'
    );

    But since that does not appear to be available...

    Here's all of the relevant DDL for all of the above examples:

    CREATE TABLE test.accounts (
    account_id INTEGER NOT NULL GENERATED BY DEFAULT AS IDENTITY (START WITH
    +1)
    , CONSTRAINT accounts_pk PRIMARY KEY (account_id)
    , appl_code CHAR(3) NOT NULL
    , appl_id DEC(16) NOT NULL
    , branch_number DEC(3) NOT NULL
    , address_key DEC(3) NOT NULL DEFAULT 1
    , category_code CHAR(1) NOT NULL DEFAULT 'N'
    , open_date DATE NOT NULL DEFAULT
    , closed_date DATE
    , pmt_appl_code CHAR(3)
    , pmt_appl_id DEC(16)
    , last_mtce_date DATE
    , last_update TIMESTAMP NOT NULL
    GENERATED ALWAYS FOR EACH ROW ON UPDATE AS ROW
    CHANGE TIMESTAMP
    , CONSTRAINT account_unique UNIQUE (appl_code, appl_id)

    )
    @

    CREATE TABLE test.account_re lationships (
    account_rel_id INTEGER NOT NULL GENERATED ALWAYS AS IDENTITY (START WITH
    +1)
    , CONSTRAINT account_rel_pk PRIMARY KEY (account_rel_id )
    , account_id INTEGER NOT NULL
    , CONSTRAINT account_rel_fk1 FOREIGN KEY (account_id) REFERENCES
    test.accounts (account_id)
    ON DELETE CASCADE ON UPDATE NO ACTION
    ENFORCED
    ENABLE QUERY OPTIMIZATION
    , cif_number DECIMAL(9) NOT NULL --need to add foreign key...
    , relationship_in d CHAR(4) NOT NULL
    , added_date DATE NOT NULL DEFAULT
    , last_update TIMESTAMP NOT NULL
    GENERATED ALWAYS FOR EACH ROW ON UPDATE AS ROW
    CHANGE TIMESTAMP
    , CONSTRAINT account_rel_uni que UNIQUE (cif_number, relationship_in d)
    )
    @

    CREATE SEQUENCE test.accounts_s eq AS INTEGER
    START WITH +9999
    @

    Thanks,
    Frank

Working...