1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-28 23:42:10 +03:00

Support enum data types. Along the way, use macros for the values of

pg_type.typtype whereever practical.  Tom Dunstan, with some kibitzing
from Tom Lane.
This commit is contained in:
Tom Lane
2007-04-02 03:49:42 +00:00
parent a482a3e58b
commit 57690c6803
74 changed files with 2398 additions and 332 deletions

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.148 2007/03/26 16:58:37 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.149 2007/04/02 03:49:36 tgl Exp $ -->
<!--
Documentation of the system catalogs, directed toward PostgreSQL developers
-->
@ -128,6 +128,11 @@
<entry>descriptions or comments on database objects</entry>
</row>
<row>
<entry><link linkend="catalog-pg-enum"><structname>pg_enum</structname></link></entry>
<entry>enum label and value definitions</entry>
</row>
<row>
<entry><link linkend="catalog-pg-index"><structname>pg_index</structname></link></entry>
<entry>additional index information</entry>
@ -1425,11 +1430,7 @@
in which the source and target types are the same, if the associated
function takes more than one argument. Such entries represent
<quote>length coercion functions</> that coerce values of the type
to be legal for a particular type modifier value. Note however that
at present there is no support for associating non-default type
modifiers with user-created data types, and so this facility is only
of use for the small number of built-in types that have type modifier
syntax built into the grammar.
to be legal for a particular type modifier value.
</para>
<para>
@ -2413,6 +2414,55 @@
</sect1>
<sect1 id="catalog-pg-enum">
<title><structname>pg_enum</structname></title>
<indexterm zone="catalog-pg-enum">
<primary>pg_enum</primary>
</indexterm>
<para>
The <structname>pg_enum</structname> catalog contains entries
matching enum types to their associated values and labels. The
internal representation of a given enum value is actually the OID
of its associated row in <structname>pg_enum</structname>. The
OIDs for a particular enum type are guaranteed to be ordered in
the way the type should sort, but there is no guarantee about the
ordering of OIDs of unrelated enum types.
</para>
<table>
<title><structname>pg_enum</> Columns</title>
<tgroup cols=4>
<thead>
<row>
<entry>Name</entry>
<entry>Type</entry>
<entry>References</entry>
<entry>Description</entry>
</row>
</thead>
<tbody>
<row>
<entry><structfield>enumtypid</structfield></entry>
<entry><type>oid</type></entry>
<entry><literal><link linkend="catalog-pg-type"><structname>pg_type</structname></link>.oid</literal></entry>
<entry>The OID of the <structname>pg_type</> entry owning this enum value</entry>
</row>
<row>
<entry><structfield>enumlabel</structfield></entry>
<entry><type>name</type></entry>
<entry></entry>
<entry>The textual label for this enum value</entry>
</row>
</tbody>
</tgroup>
</table>
</sect1>
<sect1 id="catalog-pg-index">
<title><structname>pg_index</structname></title>
@ -4395,11 +4445,13 @@
<entry><type>char</type></entry>
<entry></entry>
<entry>
<structfield>typtype</structfield> is <literal>b</literal> for
a base type, <literal>c</literal> for a composite type (e.g., a
table's row type), <literal>d</literal> for a domain, or
<literal>p</literal> for a pseudo-type. See also
<structfield>typrelid</structfield> and
<structfield>typtype</structfield> is
<literal>b</literal> for a base type,
<literal>c</literal> for a composite type (e.g., a table's row type),
<literal>d</literal> for a domain,
<literal>e</literal> for an enum type,
or <literal>p</literal> for a pseudo-type.
See also <structfield>typrelid</structfield> and
<structfield>typbasetype</structfield>
</entry>
</row>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/datatype.sgml,v 1.191 2007/03/14 17:38:05 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/datatype.sgml,v 1.192 2007/04/02 03:49:36 tgl Exp $ -->
<chapter id="datatype">
<title id="datatype-title">Data Types</title>
@ -2424,6 +2424,161 @@ SELECT * FROM test1 WHERE a;
</para>
</sect1>
<sect1 id="datatype-enum">
<title>Enumerated Types</title>
<indexterm zone="datatype-enum">
<primary>data type</primary>
<secondary>enumerated (enum)</secondary>
</indexterm>
<para>
Enumerated (enum) types are data types that
are comprised of a static, predefined set of values with a
specific order. They are equivalent to the <type>enum</type>
types in a number of programming languages. An example of an enum
type might be the days of the week, or a set of status values for
a piece of data.
</para>
<sect2>
<title>Declaration of Enumerated Types</title>
<para>
Enum types are created using the <xref
linkend="sql-createtype" endterm="sql-createtype-title"> command,
for example:
<programlisting>
CREATE TYPE mood AS ENUM ('sad', 'ok', 'happy');
</programlisting>
Once created, the enum type can be used in table and function
definitions much like any other type:
</para>
<example>
<title>Basic Enum Usage</title>
<programlisting>
CREATE TYPE mood AS ENUM ('sad', 'ok', 'happy');
CREATE TABLE person (
name text,
current_mood mood
);
INSERT INTO person VALUES ('Moe', 'happy');
SELECT * FROM person WHERE current_mood = 'happy';
name | current_mood
------+--------------
Moe | happy
(1 row)
</programlisting>
</example>
</sect2>
<sect2>
<title>Ordering</title>
<para>
The ordering of the values in an enum type is the
order in which the values were listed when the type was declared.
All standard comparison operators and related
aggregate functions are supported for enums. For example:
</para>
<example>
<title>Enum Ordering</title>
<programlisting>
INSERT INTO person VALUES ('Larry', 'sad');
INSERT INTO person VALUES ('Curly', 'ok');
SELECT * FROM person WHERE current_mood > 'sad';
name | current_mood
-------+--------------
Moe | happy
Curly | ok
(2 rows)
SELECT * FROM person WHERE current_mood > 'sad' ORDER BY current_mood;
name | current_mood
-------+--------------
Curly | ok
Moe | happy
(2 rows)
SELECT name FROM person
WHERE current_mood = (SELECT MIN(current_mood) FROM person);
name
-------
Larry
(1 row)
</programlisting>
</example>
</sect2>
<sect2>
<title>Type Safety</title>
<para>
Enumerated types are completely separate data types and may not
be compared with each other.
</para>
<example>
<title>Lack of Casting</title>
<programlisting>
CREATE TYPE happiness AS ENUM ('happy', 'very happy', 'ecstatic');
CREATE TABLE holidays (
num_weeks int,
happiness happiness
);
INSERT INTO holidays(num_weeks,happiness) VALUES (4, 'happy');
INSERT INTO holidays(num_weeks,happiness) VALUES (6, 'very happy');
INSERT INTO holidays(num_weeks,happiness) VALUES (8, 'ecstatic');
INSERT INTO holidays(num_weeks,happiness) VALUES (2, 'sad');
ERROR: invalid input value for enum happiness: "sad"
SELECT person.name, holidays.num_weeks FROM person, holidays
WHERE person.current_mood = holidays.happiness;
ERROR: operator does not exist: mood = happiness
</programlisting>
</example>
<para>
If you really need to do something like that, you can either
write a custom operator or add explicit casts to your query:
</para>
<example>
<title>Comparing Different Enums by Casting to Text</title>
<programlisting>
SELECT person.name, holidays.num_weeks FROM person, holidays
WHERE person.current_mood::text = holidays.happiness::text;
name | num_weeks
------+-----------
Moe | 4
(1 row)
</programlisting>
</example>
</sect2>
<sect2>
<title>Implementation Details</title>
<para>
An enum value occupies four bytes on disk. The length of an enum
value's textual label is limited by the <symbol>NAMEDATALEN</symbol>
setting compiled into <productname>PostgreSQL</productname>; in standard
builds this means at most 63 bytes.
</para>
<para>
Enum labels are case sensitive, so
<type>'happy'</type> is not the same as <type>'HAPPY'</type>.
Spaces in the labels are significant, too.
</para>
</sect2>
</sect1>
<sect1 id="datatype-geometric">
<title>Geometric Types</title>
@ -3278,6 +3433,10 @@ SELECT * FROM pg_attribute
<primary>anyelement</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>anyenum</primary>
</indexterm>
<indexterm zone="datatype-pseudo">
<primary>void</primary>
</indexterm>
@ -3343,6 +3502,13 @@ SELECT * FROM pg_attribute
(see <xref linkend="extend-types-polymorphic">).</entry>
</row>
<row>
<entry><type>anyenum</></entry>
<entry>Indicates that a function accepts any enum data type
(see <xref linkend="extend-types-polymorphic"> and
<xref linkend="datatype-enum">).</entry>
</row>
<row>
<entry><type>cstring</></entry>
<entry>Indicates that a function accepts or returns a null-terminated C string.</entry>
@ -3395,8 +3561,8 @@ SELECT * FROM pg_attribute
languages all forbid use of a pseudo-type as argument type, and allow
only <type>void</> and <type>record</> as a result type (plus
<type>trigger</> when the function is used as a trigger). Some also
support polymorphic functions using the types <type>anyarray</> and
<type>anyelement</>.
support polymorphic functions using the types <type>anyarray</>,
<type>anyelement</> and <type>anyenum</>.
</para>
<para>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/extend.sgml,v 1.33 2007/01/31 20:56:17 momjian Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/extend.sgml,v 1.34 2007/04/02 03:49:36 tgl Exp $ -->
<chapter id="extend">
<title>Extending <acronym>SQL</acronym></title>
@ -193,9 +193,10 @@
</indexterm>
<para>
Two pseudo-types of special interest are <type>anyelement</> and
<type>anyarray</>, which are collectively called <firstterm>polymorphic
types</>. Any function declared using these types is said to be
Three pseudo-types of special interest are <type>anyelement</>,
<type>anyarray</>, and <type>anyenum</>,
which are collectively called <firstterm>polymorphic types</>.
Any function declared using these types is said to be
a <firstterm>polymorphic function</>. A polymorphic function can
operate on many different data types, with the specific data type(s)
being determined by the data types actually passed to it in a particular
@ -215,6 +216,9 @@
<type>anyelement</type>, the actual array type in the
<type>anyarray</type> positions must be an array whose elements are
the same type appearing in the <type>anyelement</type> positions.
<type>anyenum</> is treated exactly the same as <type>anyelement</>,
but adds the additional constraint that the actual type must
be an enum type.
</para>
<para>
@ -234,7 +238,9 @@
implements subscripting as <literal>subscript(anyarray, integer)
returns anyelement</>. This declaration constrains the actual first
argument to be an array type, and allows the parser to infer the correct
result type from the actual first argument's type.
result type from the actual first argument's type. Another example
is that a function declared as <literal>f(anyarray) returns anyenum</>
will only accept arrays of enum types.
</para>
</sect2>
</sect1>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.372 2007/04/01 09:00:24 petere Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.373 2007/04/02 03:49:36 tgl Exp $ -->
<chapter id="functions">
<title>Functions and Operators</title>
@ -6646,6 +6646,87 @@ SELECT pg_sleep(1.5);
</sect1>
<sect1 id="functions-enum">
<title>Enum Support Functions</title>
<para>
For enum types (described in <xref linkend="datatype-enum">),
there are several functions that allow cleaner programming without
hard-coding particular values of an enum type.
These are listed in <xref linkend="functions-enum-table">. The examples
assume an enum type created as:
<programlisting>
CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
</programlisting>
</para>
<table id="functions-enum-table">
<title>Enum Support Functions</title>
<tgroup cols="4">
<thead>
<row>
<entry>Function</entry>
<entry>Description</entry>
<entry>Example</entry>
<entry>Example Result</entry>
</row>
</thead>
<tbody>
<row>
<entry><literal>enum_first(anyenum)</literal></entry>
<entry>Returns the first value of the input enum type</entry>
<entry><literal>enum_first(null::rainbow)</literal></entry>
<entry><literal>red</literal></entry>
</row>
<row>
<entry><literal>enum_last(anyenum)</literal></entry>
<entry>Returns the last value of the input enum type</entry>
<entry><literal>enum_last(null::rainbow)</literal></entry>
<entry><literal>purple</literal></entry>
</row>
<row>
<entry><literal>enum_range(anyenum)</literal></entry>
<entry>Returns all values of the input enum type in an ordered array</entry>
<entry><literal>enum_range(null::rainbow)</literal></entry>
<entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
</row>
<row>
<entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
<entry morerows="2">
Returns the range between the two given enum values, as an ordered
array. The values must be from the same enum type. If the first
parameter is null, the result will start with the first value of
the enum type.
If the second parameter is null, the result will end with the last
value of the enum type.
</entry>
<entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
<entry><literal>{orange,yellow,green}</literal></entry>
</row>
<row>
<entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
<entry><literal>{red,orange,yellow,green}</literal></entry>
</row>
<row>
<entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
<entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
</row>
</tbody>
</tgroup>
</table>
<para>
Notice that except for the two-argument form of <function>enum_range</>,
these functions disregard the specific value passed to them; they care
only about its declared datatype. Either NULL or a specific value of
the type can be passed, with the same result. It is more common to
apply these functions to a table column or function argument than to
a hardwired type name as suggested by the examples.
</para>
</sect1>
<sect1 id="functions-geometry">
<title>Geometric Functions and Operators</title>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.105 2007/02/01 00:28:17 momjian Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.106 2007/04/02 03:49:37 tgl Exp $ -->
<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
@ -210,7 +210,8 @@ $$ LANGUAGE plpgsql;
<para>
<application>PL/pgSQL</> functions can also be declared to accept
and return the polymorphic types
<type>anyelement</type> and <type>anyarray</type>. The actual
<type>anyelement</type>, <type>anyarray</type>, and <type>anyenum</>.
The actual
data types handled by a polymorphic function can vary from call to
call, as discussed in <xref linkend="extend-types-polymorphic">.
An example is shown in <xref linkend="plpgsql-declaration-aliases">.
@ -698,8 +699,9 @@ $$ LANGUAGE plpgsql;
<para>
When the return type of a <application>PL/pgSQL</application>
function is declared as a polymorphic type (<type>anyelement</type>
or <type>anyarray</type>), a special parameter <literal>$0</literal>
function is declared as a polymorphic type (<type>anyelement</type>,
<type>anyarray</type>, or <type>anyenum</>),
a special parameter <literal>$0</literal>
is created. Its data type is the actual return type of the function,
as deduced from the actual input types (see <xref
linkend="extend-types-polymorphic">).
@ -726,7 +728,7 @@ $$ LANGUAGE plpgsql;
<para>
The same effect can be had by declaring one or more output parameters as
<type>anyelement</type> or <type>anyarray</type>. In this case the
polymorphic types. In this case the
special <literal>$0</literal> parameter is not used; the output
parameters themselves serve the same purpose. For example:

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/create_type.sgml,v 1.68 2007/02/01 00:28:18 momjian Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/create_type.sgml,v 1.69 2007/04/02 03:49:37 tgl Exp $
PostgreSQL documentation
-->
@ -23,6 +23,9 @@ PostgreSQL documentation
CREATE TYPE <replaceable class="parameter">name</replaceable> AS
( <replaceable class="PARAMETER">attribute_name</replaceable> <replaceable class="PARAMETER">data_type</replaceable> [, ... ] )
CREATE TYPE <replaceable class="parameter">name</replaceable> AS ENUM
( '<replaceable class="parameter">label</replaceable>' [, ... ] )
CREATE TYPE <replaceable class="parameter">name</replaceable> (
INPUT = <replaceable class="parameter">input_function</replaceable>,
OUTPUT = <replaceable class="parameter">output_function</replaceable>
@ -77,11 +80,23 @@ CREATE TYPE <replaceable class="parameter">name</replaceable>
</para>
</refsect2>
<refsect2>
<title>Enumerated Types</title>
<para>
The second form of <command>CREATE TYPE</command> creates an enumerated
(enum) type, as described in <xref linkend="datatype-enum">.
Enum types take a list of one or more quoted labels, each of which
must be less than <symbol>NAMEDATALEN</symbol> bytes long (64 in a standard
<productname>PostgreSQL</productname> build).
</para>
</refsect2>
<refsect2>
<title>Base Types</title>
<para>
The second form of <command>CREATE TYPE</command> creates a new base type
The third form of <command>CREATE TYPE</command> creates a new base type
(scalar type). The parameters can appear in any order, not only that
illustrated above, and most are optional. You must register
two or more functions (using <command>CREATE FUNCTION</command>) before
@ -297,7 +312,7 @@ CREATE TYPE <replaceable class="parameter">name</replaceable>
<title>Array Types</title>
<para>
Whenever a user-defined base data type is created,
Whenever a user-defined base or enum data type is created,
<productname>PostgreSQL</productname> automatically creates an
associated array type, whose name consists of the base type's
name prepended with an underscore. The parser understands this
@ -363,6 +378,16 @@ CREATE TYPE <replaceable class="parameter">name</replaceable>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">label</replaceable></term>
<listitem>
<para>
A string literal representing the textual label associated with
one value of an enum type.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">input_function</replaceable></term>
<listitem>
@ -567,6 +592,20 @@ $$ LANGUAGE SQL;
</programlisting>
</para>
<para>
This example creates an enumerated type and uses it in
a table definition:
<programlisting>
CREATE TYPE bug_status AS ENUM ('new', 'open', 'closed');
CREATE TABLE bug (
serial id,
description text,
status bug_status
);
</programlisting>
</para>
<para>
This example creates the base data type <type>box</type> and then uses the
type in a table definition:

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.126 2007/02/27 23:48:06 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/xfunc.sgml,v 1.127 2007/04/02 03:49:37 tgl Exp $ -->
<sect1 id="xfunc">
<title>User-Defined Functions</title>
@ -717,8 +717,8 @@ SELECT name, listchildren(name) FROM nodes;
<para>
<acronym>SQL</acronym> functions can be declared to accept and
return the polymorphic types <type>anyelement</type> and
<type>anyarray</type>. See <xref
return the polymorphic types <type>anyelement</type>,
<type>anyarray</type>, and <type>anyenum</type>. See <xref
linkend="extend-types-polymorphic"> for a more detailed
explanation of polymorphic functions. Here is a polymorphic
function <function>make_array</function> that builds up an array
@ -746,7 +746,7 @@ SELECT make_array(1, 2) AS intarray, make_array('a'::text, 'b') AS textarray;
Without the typecast, you will get errors like this:
<screen>
<computeroutput>
ERROR: could not determine "anyarray"/"anyelement" type because input has type "unknown"
ERROR: could not determine polymorphic type because input has type "unknown"
</computeroutput>
</screen>
</para>
@ -769,7 +769,7 @@ CREATE FUNCTION invalid_func() RETURNS anyelement AS $$
SELECT 1;
$$ LANGUAGE SQL;
ERROR: cannot determine result data type
DETAIL: A function returning "anyarray" or "anyelement" must have at least one argument of either type.
DETAIL: A function returning a polymorphic type must have at least one polymorphic argument.
</screen>
</para>
@ -2831,7 +2831,7 @@ CREATE OR REPLACE FUNCTION retcomposite(IN integer, IN integer,
<para>
C-language functions can be declared to accept and
return the polymorphic types
<type>anyelement</type> and <type>anyarray</type>.
<type>anyelement</type>, <type>anyarray</type>, and <type>anyenum</type>.
See <xref linkend="extend-types-polymorphic"> for a more detailed explanation
of polymorphic functions. When function arguments or return types
are defined as polymorphic types, the function author cannot know