Обсуждение: CHECK() Constraint on Column Using Lookup Table

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

CHECK() Constraint on Column Using Lookup Table

От
Rich Shepard
Дата:
   I've seen the syntax for using a lookup table in a CHECK() constraint, but
I cannot find a reference to it. It's not in Section 5.3.1 of the 8.2 docs.

   Specifically, I want to reference a table of ISO 2-letter codes for US
states and Canadian provinces/territories in a table with name and address
columns.

   Please point me to a reference.

Rich

--
Richard B. Shepard, Ph.D.               |    The Environmental Permitting
Applied Ecosystem Services, Inc.        |          Accelerator(TM)
<http://www.appl-ecosys.com>     Voice: 503-667-4517      Fax: 503-667-8863

Re: CHECK() Constraint on Column Using Lookup Table

От
"Joshua D. Drake"
Дата:
Rich Shepard wrote:
>   I've seen the syntax for using a lookup table in a CHECK() constraint,
> but
> I cannot find a reference to it. It's not in Section 5.3.1 of the 8.2 docs.
>
>   Specifically, I want to reference a table of ISO 2-letter codes for US
> states and Canadian provinces/territories in a table with name and address
> columns.
>
>   Please point me to a reference.

You could use a function, or a foreign key.


Joshua D. Drake

>
> Rich
>


--

       === The PostgreSQL Company: Command Prompt, Inc. ===
Sales/Support: +1.503.667.4564 || 24x7/Emergency: +1.800.492.2240
Providing the most comprehensive  PostgreSQL solutions since 1997
              http://www.commandprompt.com/

Donate to the PostgreSQL Project: http://www.postgresql.org/about/donate
PostgreSQL Replication: http://www.commandprompt.com/products/


Re: CHECK() Constraint on Column Using Lookup Table

От
Richard Broersma Jr
Дата:
--- Rich Shepard <rshepard@appl-ecosys.com> wrote:

>    I've seen the syntax for using a lookup table in a CHECK() constraint, but
> I cannot find a reference to it. It's not in Section 5.3.1 of the 8.2 docs.
>
>    Specifically, I want to reference a table of ISO 2-letter codes for US
> states and Canadian provinces/territories in a table with name and address
> columns.

Using sub-queries in a table DDL is legal per SQL92, but Postgresql doesn't support this syntax.
However, I don't see what you would need it since the "REFERENCES" predicate should work just fine
for you.

You can scroll down to the passages that discuss the check constraint from the following page:
http://www.postgresql.org/docs/8.2/interactive/sql-createtable.html

Regards,
Richard Broersma Jr.

Re: CHECK() Constraint on Column Using Lookup Table

От
"A. Kretschmer"
Дата:
am  Tue, dem 01.05.2007, um 10:41:44 -0700 mailte Rich Shepard folgendes:
>   I've seen the syntax for using a lookup table in a CHECK() constraint, but
> I cannot find a reference to it. It's not in Section 5.3.1 of the 8.2 docs.
>
>   Specifically, I want to reference a table of ISO 2-letter codes for US
> states and Canadian provinces/territories in a table with name and address
> columns.
>
>   Please point me to a reference.

How about with a simple foreign key? (Section 5.3.5 of the 8.2 docs)


Andreas
--
Andreas Kretschmer
Kontakt:  Heynitz: 035242/47150,   D1: 0160/7141639 (mehr: -> Header)
GnuPG-ID:   0x3FFF606C, privat 0x7F4584DA   http://wwwkeys.de.pgp.net

Re: CHECK() Constraint on Column Using Lookup Table

От
Rich Shepard
Дата:
On Tue, 1 May 2007, Joshua D. Drake wrote:

> You could use a function, or a foreign key.

Josh,

   The foreign key approach will do nicely.

Thanks,

Rich

--
Richard B. Shepard, Ph.D.               |    The Environmental Permitting
Applied Ecosystem Services, Inc.        |          Accelerator(TM)
<http://www.appl-ecosys.com>     Voice: 503-667-4517      Fax: 503-667-8863

Re: CHECK() Constraint on Column Using Lookup Table

От
Michael Glaesemann
Дата:
On May 1, 2007, at 12:41 , Rich Shepard wrote:

>   I've seen the syntax for using a lookup table in a CHECK()
> constraint, but
> I cannot find a reference to it. It's not in Section 5.3.1 of the
> 8.2 docs.

I'm not sure I follow. Generally if one has a column the value of
which belongs to a limited set, one uses a lookup table (via a
foreign key) *or* a check constraint, but not both, as it'd be
redundant.

For example, using a lookup table:

CREATE TABLE states
(
    state_code TEXT PRIMARY KEY
);

CREATE TABLE addresses
(
    address TEXT NOT NULL
    , state_code TEXT NOT NULL
        REFERENCES states (state_code)
    , PRIMARY KEY (address, state_code)
);

or, using a CHECK constraint:

CREATE TABLE addresses
(
    address TEXT NOT NULL
    , state_code TEXT NOT NULL
        CHECK (value in ('state_1', 'state_2', ...))
);

In this case, I would definitely use a lookup table rather than a
CHECK constraint as it's much easier to maintain.

I feel I probably didn't answer your question, but this is what I
understood from your description. I guess you might be referring to
using a subquery or lookup function in the check constraint to make
sure the values of state_code are valid values (in the states table),
but that's what a foreign key is doing anyway, and much more
efficiently. Further, subqueries in check constraints aren't
supported in PostgreSQL. You can fake it by wrapping the subquery in
a function, but again, you're just manually doing what foreign keys
are designed to do for you automatically.

Hope this helps.

Michael Glaesemann
grzm seespotcode net



Re: CHECK() Constraint on Column Using Lookup Table

От
"Dann Corbit"
Дата:
> -----Original Message-----
> From: pgsql-general-owner@postgresql.org [mailto:pgsql-general-
> owner@postgresql.org] On Behalf Of Rich Shepard
> Sent: Tuesday, May 01, 2007 10:42 AM
> To: pgsql-general@postgresql.org
> Subject: [GENERAL] CHECK() Constraint on Column Using Lookup Table
>
>    I've seen the syntax for using a lookup table in a CHECK()
constraint,
> but
> I cannot find a reference to it. It's not in Section 5.3.1 of the 8.2
> docs.
>
>    Specifically, I want to reference a table of ISO 2-letter codes for
US
> states and Canadian provinces/territories in a table with name and
address
> columns.

It sounds like a foreign key to me, and not a check constraint.  If the
state/province/territory data is in a table, then use a foreign key.

It is likely that you will need to add things in the future (e.g. places
like Virgin Islands, international expansion into Mexico, Europe, etc.)
It is better to be data driven than to use a hardwired list in the SQL
definition.

You will need some way to handle APO and FPO addresses (which are a bit
different).

Maybe something along the lines of this:
CREATE TABLE localhost.dbo.state_prov_terr (abbr CHAR(4) PRIMARY KEY,
name VARCHAR(255));
INSERT INTO state_prov_terr (abbr, name) values ('AB', 'Alberta');
INSERT INTO state_prov_terr (abbr, name) values ('AK', 'Alaska');
INSERT INTO state_prov_terr (abbr, name) values ('AL', 'Alabama');
INSERT INTO state_prov_terr (abbr, name) values ('APO', '(Army or Air
Force Post Office)');
INSERT INTO state_prov_terr (abbr, name) values ('AR', 'Arkansas');
INSERT INTO state_prov_terr (abbr, name) values ('AS', 'American
Samoa');
INSERT INTO state_prov_terr (abbr, name) values ('AZ', 'Arizona');
INSERT INTO state_prov_terr (abbr, name) values ('BC', 'British
Columbia');
INSERT INTO state_prov_terr (abbr, name) values ('CA', 'California');
INSERT INTO state_prov_terr (abbr, name) values ('CO', 'Colorado');
INSERT INTO state_prov_terr (abbr, name) values ('CT', 'Connecticut');
INSERT INTO state_prov_terr (abbr, name) values ('DC', 'District of
Columbia');
INSERT INTO state_prov_terr (abbr, name) values ('DE', 'Delaware');
INSERT INTO state_prov_terr (abbr, name) values ('FL', 'Florida');
INSERT INTO state_prov_terr (abbr, name) values ('FM', 'Federated States
of Micronesia');
INSERT INTO state_prov_terr (abbr, name) values ('FPO', '(Fleet Post
Office for the Navy, Marine Corps, or Coast Guard)');
INSERT INTO state_prov_terr (abbr, name) values ('GA', 'Georgia');
INSERT INTO state_prov_terr (abbr, name) values ('GU', 'Guam');
INSERT INTO state_prov_terr (abbr, name) values ('HI', 'Hawaii');
INSERT INTO state_prov_terr (abbr, name) values ('IA', 'Iowa');
INSERT INTO state_prov_terr (abbr, name) values ('ID', 'Idaho');
INSERT INTO state_prov_terr (abbr, name) values ('IL', 'Illinois');
INSERT INTO state_prov_terr (abbr, name) values ('IN', 'Indiana');
INSERT INTO state_prov_terr (abbr, name) values ('KS', 'Kansas');
INSERT INTO state_prov_terr (abbr, name) values ('KY', 'Kentucky');
INSERT INTO state_prov_terr (abbr, name) values ('LA', 'Louisiana');
INSERT INTO state_prov_terr (abbr, name) values ('MA', 'Massachusetts');
INSERT INTO state_prov_terr (abbr, name) values ('MB', 'Manitoba');
INSERT INTO state_prov_terr (abbr, name) values ('MD', 'Maryland');
INSERT INTO state_prov_terr (abbr, name) values ('ME', 'Maine');
INSERT INTO state_prov_terr (abbr, name) values ('MH', 'Marshall
Islands');
INSERT INTO state_prov_terr (abbr, name) values ('MI', 'Michigan');
INSERT INTO state_prov_terr (abbr, name) values ('MN', 'Minnesota');
INSERT INTO state_prov_terr (abbr, name) values ('MO', 'Missouri');
INSERT INTO state_prov_terr (abbr, name) values ('MP', 'Northern Mariana
Islands');
INSERT INTO state_prov_terr (abbr, name) values ('MS', 'Mississippi');
INSERT INTO state_prov_terr (abbr, name) values ('MT', 'Montana');
INSERT INTO state_prov_terr (abbr, name) values ('NB', 'New Brunswick');
INSERT INTO state_prov_terr (abbr, name) values ('NC', 'North
Carolina');
INSERT INTO state_prov_terr (abbr, name) values ('ND', 'North Dakota');
INSERT INTO state_prov_terr (abbr, name) values ('NE', 'Nebraska');
INSERT INTO state_prov_terr (abbr, name) values ('NH', 'New Hampshire');
INSERT INTO state_prov_terr (abbr, name) values ('NJ', 'New Jersey');
INSERT INTO state_prov_terr (abbr, name) values ('NL', 'Newfoundland and
Labrador');
INSERT INTO state_prov_terr (abbr, name) values ('NM', 'New Mexico');
INSERT INTO state_prov_terr (abbr, name) values ('NS', 'Nova Scotia');
INSERT INTO state_prov_terr (abbr, name) values ('NT', 'Northwest
Territories');
INSERT INTO state_prov_terr (abbr, name) values ('NU', 'Nunavut');
INSERT INTO state_prov_terr (abbr, name) values ('NV', 'Nevada');
INSERT INTO state_prov_terr (abbr, name) values ('NY', 'New York');
INSERT INTO state_prov_terr (abbr, name) values ('OH', 'Ohio');
INSERT INTO state_prov_terr (abbr, name) values ('OK', 'Oklahoma');
INSERT INTO state_prov_terr (abbr, name) values ('ON', 'Ontario');
INSERT INTO state_prov_terr (abbr, name) values ('OR', 'Oregon');
INSERT INTO state_prov_terr (abbr, name) values ('PA', 'Pennsylvania');
INSERT INTO state_prov_terr (abbr, name) values ('PE', 'Prince Edward
Island');
INSERT INTO state_prov_terr (abbr, name) values ('PR', 'Puerto Rico');
INSERT INTO state_prov_terr (abbr, name) values ('PW', 'Palau');
INSERT INTO state_prov_terr (abbr, name) values ('QC', 'Quebec');
INSERT INTO state_prov_terr (abbr, name) values ('RI', 'Rhode Island');
INSERT INTO state_prov_terr (abbr, name) values ('SC', 'South
Carolina');
INSERT INTO state_prov_terr (abbr, name) values ('SD', 'South Dakota');
INSERT INTO state_prov_terr (abbr, name) values ('SK', 'Saskatchewan');
INSERT INTO state_prov_terr (abbr, name) values ('TN', 'Tennessee');
INSERT INTO state_prov_terr (abbr, name) values ('TX', 'Texas');
INSERT INTO state_prov_terr (abbr, name) values ('UT', 'Utah');
INSERT INTO state_prov_terr (abbr, name) values ('VA', 'Virginia');
INSERT INTO state_prov_terr (abbr, name) values ('VI', 'Virgin
Islands');
INSERT INTO state_prov_terr (abbr, name) values ('VT', 'Vermont');
INSERT INTO state_prov_terr (abbr, name) values ('WA', 'Washington');
INSERT INTO state_prov_terr (abbr, name) values ('WI', 'Wisconsin');
INSERT INTO state_prov_terr (abbr, name) values ('WV', 'West Virginia');
INSERT INTO state_prov_terr (abbr, name) values ('WY', 'Wyoming');
INSERT INTO state_prov_terr (abbr, name) values ('YT', 'Yukon');

And then add a foreign key.

Re: CHECK() Constraint on Column Using Lookup Table

От
"Dann Corbit"
Дата:
For postal addressing, this is a really good reference site:
http://www.columbia.edu/kermit/postal.html

Re: CHECK() Constraint on Column Using Lookup Table

От
Rich Shepard
Дата:
On Tue, 1 May 2007, Dann Corbit wrote:

> For postal addressing, this is a really good reference site:
> http://www.columbia.edu/kermit/postal.html

   Thank you. Frank did/does an outstanding job with Kermit, and that's a
very useful language for serial communications among data collecting devices
and the computer.

Rich

--
Richard B. Shepard, Ph.D.               |    The Environmental Permitting
Applied Ecosystem Services, Inc.        |          Accelerator(TM)
<http://www.appl-ecosys.com>     Voice: 503-667-4517      Fax: 503-667-8863