diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index 2063812942..f1dcf8ab1a 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -4607,7 +4607,9 @@ - The catalog pg_range stores information about range types. + The catalog pg_range stores information about + range types. This is in addition to the types' entries in + pg_type. @@ -4628,47 +4630,57 @@ rngtypidoidpg_type.oid - The type that is a range type + OID of the range type rngsubtype oid pg_type.oid - Subtype of this range type, e.g. integer is the subtype of int4range + OID of the element type (subtype) of this range type rngcollation oid pg_collation.oid - The collation used when comparing range boundaries + OID of the collation used for range comparisons, or 0 if none rngsubopc oid pg_opclass.oid - The operator class used when comparing range boundaries + OID of the subtype's operator class used for range comparisons rngcanonical regproc pg_proc.oid - A function to convert a range into its canonical form + OID of the function to convert a range value into canonical form, + or 0 if none rngsubdiff regproc pg_proc.oid - A function to return the distance between two lower and upper bound, as a double precision. Used for GiST support + OID of the function to return the difference between two element + values as double precision, or 0 if none
+ + rngsubopc (plus rngcollation, if the + element type is collatable) determines the sort ordering used by the range + type. rngcanonical is used when the element type is + discrete. rngsubdiff is optional but should be supplied to + improve performance of GiST indexes on the range type. + + @@ -6059,7 +6071,8 @@ c for a composite type (e.g., a table's row type), d for a domain, e for an enum type, - or p for a pseudo-type. + p for a pseudo-type, or + r for a range type. See also typrelid and typbasetype. @@ -6429,6 +6442,10 @@ P Pseudo-types + + R + Range types + S String types diff --git a/doc/src/sgml/extend.sgml b/doc/src/sgml/extend.sgml index f3850b391e..8d5b9d0c83 100644 --- a/doc/src/sgml/extend.sgml +++ b/doc/src/sgml/extend.sgml @@ -200,13 +200,13 @@ Five pseudo-types of special interest are anyelement, anyarray, anynonarray, anyenum, - and anyrange, which are collectively - called polymorphic types. Any function declared - using these types is said to be a 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 call. + and anyrange, + which are collectively called polymorphic types. + Any function declared using these types is said to be + a 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 + call. @@ -217,15 +217,16 @@ data type, but in any given call they must all be the same actual type. Each position declared as anyarray can have any array data type, - but similarly they must all be the same type. If there are + but similarly they must all be the same type. And similarly, + positions declared as anyrange must all be the same range + type. Furthermore, if there are positions declared anyarray and others declared anyelement, the actual array type in the anyarray positions must be an array whose elements are the same type appearing in the anyelement positions. Similarly, if there are positions declared anyrange - and others declared - anyelement, the actual range type in the - anyrange positions must be a range whose subtype is + and others declared anyelement, the actual range type in + the anyrange positions must be a range whose subtype is the same type appearing in the anyelement positions. anynonarray is treated exactly the same as anyelement, but adds the additional constraint that the actual type must not be diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index a7dc05bf38..be92e6acb3 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -10525,18 +10525,32 @@ SELECT NULLIF(value, '(none)') ... @> - contains + contains range + int4range(2,4) @> int4range(2,3) + t + + + + @> + contains element '[2011-01-01,2011-03-01)'::tsrange @> '2011-01-10'::timestamp t <@ - is contained by + range is contained by int4range(2,4) <@ int4range(1,7) t + + <@ + element is contained by + 42 <@ int4range(1,7) + f + + && overlap (have points in common) diff --git a/doc/src/sgml/rangetypes.sgml b/doc/src/sgml/rangetypes.sgml index cf16f25de9..4a888a021d 100644 --- a/doc/src/sgml/rangetypes.sgml +++ b/doc/src/sgml/rangetypes.sgml @@ -8,137 +8,166 @@ - Range types are data types representing a range of values over some - sub-type with a total order. For instance, ranges + Range types are data types representing a range of values of some + element type (called the range's subtype). + For instance, ranges of timestamp might be used to represent the ranges of time that a meeting room is reserved. In this case the data type - is tsrange (short for "timestamp range"), - and timestamp is the sub-type with a total order. + is tsrange (short for timestamp range), + and timestamp is the subtype. The subtype must have + a total order so that it is well-defined whether element values are + within, before, or after a range of values. - Range types are useful because they represent many points in a - single value. The use of time and date ranges for scheduling + Range types are useful because they represent many element values in a + single range value, and because concepts such as overlapping ranges can + be expressed clearly. The use of time and date ranges for scheduling purposes is the clearest example; but price ranges, measurement - ranges from an instrument, etc., are also useful. + ranges from an instrument, and so forth can also be useful. Built-in Range Types + PostgreSQL comes with the following built-in range types: - INT4RANGE -- Range of INTEGER. This is a discrete range type, see . + INT4RANGE — Range of INTEGER - INT8RANGE -- Range of BIGINT. This is a discrete range type, see . + INT8RANGE — Range of BIGINT - NUMRANGE -- Range of NUMERIC. + NUMRANGE — Range of NUMERIC - TSRANGE -- Range of TIMESTAMP WITHOUT TIME ZONE. + TSRANGE — Range of TIMESTAMP WITHOUT TIME ZONE - TSTZRANGE -- Range of TIMESTAMP WITH TIME ZONE. + TSTZRANGE — Range of TIMESTAMP WITH TIME ZONE - DATERANGE -- Range of DATE. This is a discrete range type, see . + DATERANGE — Range of DATE - In addition, you can define your own; see for more information. + In addition, you can define your own range types; + see for more information. Examples + -CREATE TABLE reservation ( during TSRANGE ); -INSERT INTO reservation VALUES - ( '[2010-01-01 14:30, 2010-01-01 15:30)' ); +CREATE TABLE reservation ( room int, during TSRANGE ); +INSERT INTO reservation VALUES + ( 1108, '[2010-01-01 14:30, 2010-01-01 15:30)' ); -- Containment SELECT int4range(10, 20) @> 3; -- Overlaps -SELECT numrange(11.1, 22.2) && numrange(20.0, 30.0); +SELECT numrange(11.1, 22.2) && numrange(20.0, 30.0); --- Find the upper bound: +-- Extract the upper bound SELECT upper(int8range(15, 25)); --- Compute the intersection: +-- Compute the intersection SELECT int4range(10, 20) * int4range(15, 25); -- Is the range non-empty? SELECT isempty(numrange(1, 5)); - - See - and for complete lists of - functions and operators on range types. + See + and for complete lists of + functions and operators on range types. Inclusive and Exclusive Bounds + - Every range has two bounds, the lower bound and the upper bound. All - points in between those values are included in the range. An - inclusive bound means that the boundary point itself is included in - the range as well, while an exclusive bound means that the boundary - point is not included in the range. + Every non-empty range has two bounds, the lower bound and the upper + bound. All points between these values are included in the range. An + inclusive bound means that the boundary point itself is included in + the range as well, while an exclusive bound means that the boundary + point is not included in the range. + - An inclusive lower bound is represented by [ - while an exclusive lower bound is represented - by ( (see - and below). Likewise, an inclusive - upper bound is represented by ], while an - exclusive upper bound is represented by ). + In the text form of a range, an inclusive lower bound is represented by + [ while an exclusive lower bound is + represented by (. Likewise, an inclusive upper bound is represented by + ], while an exclusive upper bound is + represented by ). + (See for more details.) + - Functions lower_inc - and upper_inc test the inclusivity of the lower - and upper bounds of a range, respectively. + The functions lower_inc + and upper_inc test the inclusivity of the lower + and upper bounds of a range value, respectively. - Infinite (unbounded) Ranges + Infinite (Unbounded) Ranges + - The lower bound of a range can be omitted, meaning that all points - less (or equal to, if inclusive) than the upper bound are included - in the range. Likewise, if the upper bound of the range is omitted, - then all points greater than (or equal to, if omitted) the lower - bound are included in the range. If both lower and upper bounds are - omitted, all points are considered to be in the range. + The lower bound of a range can be omitted, meaning that all points less + than the upper bound are included in the range. Likewise, if the upper + bound of the range is omitted, then all points greater than the lower bound + are included in the range. If both lower and upper bounds are omitted, all + values of the element type are considered to be in the range. + - Functions lower_inf - and upper_inf test the range for infinite lower - and upper bounds of a range, respectively. + This is equivalent to considering that the lower bound is minus + infinity, or the upper bound is plus infinity, + respectively. But note that these infinite values are never values of + the range's element type, and can never be part of the range. (So there + is no such thing as an inclusive infinite bound — if you try to + write one, it will automatically be converted to an exclusive bound.) + + + + Also, some element types have a notion of infinity, but that + is just another value so far as the range type mechanisms are concerned. + For example, in timestamp ranges, [today,] means the same + thing as [today,). But [today,infinity] means + something different from [today,infinity) — the latter + excludes the special timestamp value infinity. + + + + The functions lower_inf + and upper_inf test for infinite lower + and upper bounds of a range, respectively. - Input/Output + Range Input/Output + - The input follows one of the following patterns: + The input for a range value must follow one of the following patterns: (lower-bound,upper-bound) (lower-bound,upper-bound] @@ -146,127 +175,173 @@ SELECT isempty(numrange(1, 5)); [lower-bound,upper-bound] empty - Notice that the final pattern is empty, which - represents an empty range (a range that contains no points). + The parentheses or brackets indicate whether the lower and upper bounds + are exclusive or inclusive, as described previously. + Notice that the final pattern is empty, which + represents an empty range (a range that contains no points). + - The lower-bound may be either a string - that is valid input for the sub-type, or omitted (to indicate no - lower bound); and upper-bound may be - either a string that is valid input for the sub-type, or omitted (to - indicate no upper bound). + The lower-bound may be either a string + that is valid input for the subtype, or empty to indicate no + lower bound. Likewise, upper-bound may be + either a string that is valid input for the subtype, or empty to + indicate no upper bound. + - Either the lower-bound or - the upper-bound may be quoted - using "" (double quotation marks), which will allow - special characters such as ",". Within quotation - marks, "\" (backslash) serves as an escape - character. + Each bound value can be quoted using " (double quote) + characters. This is necessary if the bound value contains parentheses, + brackets, commas, double quotes, or backslashes, since these characters + would otherwise be taken as part of the range syntax. To put a double + quote or backslash in a quoted bound value, precede it with a + backslash. (Also, a pair of double quotes within a double-quoted bound + value is taken to represent a double quote character, analogously to the + rules for single quotes in SQL literal strings.) Alternatively, you can + avoid quoting and use backslash-escaping to protect all data characters + that would otherwise be taken as range syntax. Also, to write a bound + value that is an empty string, write "", since writing + nothing means an infinite bound. + - The choice between the other input formats affects the inclusivity - of the bounds. See . + Whitespace is allowed before and after the range value, but any whitespace + between the parentheses or brackets is taken as part of the lower or upper + bound value. (Depending on the element type, it might or might not be + significant.) + + + + These rules are very similar to those for writing field values in + composite-type literals. See for + additional commentary. + + + Examples: --- includes point 3, does not include point 7, and does include all points in between -select '[3,7)' +-- includes 3, does not include 7, and does include all points in between +select '[3,7)'::int4range; -- does not include either 3 or 7, but includes all points in between -select '(3,7)' +select '(3,7)'::int4range; -- includes only the single point 4 -select '[4,4]' +select '[4,4]'::int4range; Constructing Ranges + - Each range type has a constructor by the same name. The constructor + Each range type has a constructor function with the same name as the range + type. Using the constructor function is frequently more convenient than + writing a range literal constant, since it avoids the need for extra + quoting of the bound values. The constructor function accepts from zero to three arguments. The zero-argument form constructs an empty range; the one-argument form constructs a - singleton range; the two-argument form constructs a range - in [ ) form; and the three-argument form - constructs a range in a form specified by the third argument. For - example: + singleton range; the two-argument form constructs a range in + standard form (lower bound inclusive, upper bound exclusive); + and the three-argument form constructs a range in a form specified by the + third argument. The third argument must be one of the strings + (), + (], + [), or + []. + For example: + -- Three-argument form: lower bound, upper bound, and third argument indicating --- inclusivity/exclusivity of bounds (if omitted, defaults to '[)'). +-- inclusivity/exclusivity of bounds. SELECT numrange(1.0, 14.0, '(]'); --- The int4range input will exclude the lower bound and include the upper bound; but the --- resulting output will appear in the canonical form; see . +-- If the third argument is omitted, '[)' is assumed. +SELECT numrange(1.0, 14.0); + +-- Although '(]' is specified here, on display the value will be converted to +-- canonical form, since int8range is a discrete range type (see below). SELECT int8range(1, 14, '(]'); --- Single argument form constructs a singleton range; that is a range consisting of just --- one point. +-- Using NULL for either bound causes the range to be unbounded on that side. +SELECT numrange(NULL, 2.2); + +-- Single argument constructs a singleton range; that is a range consisting of +-- just one point. SELECT numrange(11.1); --- Zero-argument form constructs and empty range. +-- Zero-argument form constructs an empty range. SELECT numrange(); - --- Using NULL for a bound causes the range to be unbounded on that side; that is, negative --- infinity for the lower bound or positive infinity for the upper bound. -SELECT numrange(NULL,2.2); Discrete Range Types + - Discrete ranges are those that have a - defined canonical function. Loosely speaking, a - discrete range has a sub-type with a well-defined "step"; - e.g. INTEGER or DATE. + A discrete range is one whose element type has a well-defined + step, such as INTEGER or DATE. + In these types two elements can be said to be adjacent, since there are + no valid values between them. This contrasts with continuous ranges, + where it's always (or almost always) possible to identify other element + values between two given values. For example, a range over the + NUMERIC type is continuous, as is a range over TIMESTAMP. + (Even though TIMESTAMP has limited precision, and so could + theoretically be treated as discrete, it's better to consider it continuous + since the step size is normally not of interest.) + - The canonical function should take an input range - value, and return an equal range value that may have a different - formatting. For instance, the integer range [1, - 7] could be represented by the equal integer - range [1, 8). The two values are equal because - there are no points within the integer domain - between 7 and 8, so not - including the end point 8 is the same as - including the end point 7. The canonical output - for two values that are equal, like [1, 7] - and [1, 8), must be equal. It doesn't matter - which representation you choose to be the canonical one, as long as - two equal values with different formattings are always mapped to the - same value with the same formatting. If the canonical function is - not specified, then ranges with different formatting - (e.g. [1, 7] and [1, 8)) will - always be treated as unequal. + Another way to think about a discrete range type is that there is a clear + idea of a next or previous value for each element value. + Knowing that, it is possible to convert between inclusive and exclusive + representations of a range's bounds, by choosing the next or previous + element value instead of the one originally given. + For example, in an integer range type [4,8] and + (3,9) denote the same set of values; but this would not be so + for a range over numeric. + - For types such as NUMRANGE, this is not possible, - because there are always points in between two - distinct NUMERIC values. + A discrete range type should have a canonicalization + function that is aware of the desired step size for the element type. + The canonicalization function is charged with converting values of the + range type to have consistently inclusive or exclusive bounds. + The canonicalization function takes an input range value, and + must return an equivalent range value that may have a different + formatting. The canonical output for two values that are equivalent, like + [1, 7] and [1, 8), must be identical. + It doesn't matter which representation you choose to be the canonical one, + so long as two equivalent values with different formattings are always + mapped to the same value with the same formatting. If a canonicalization + function is not specified, then ranges with different formatting + will always be treated as unequal, even though they might represent the + same set of values. + - The built-in range - types INT4RANGE, INT8RANGE, - and DATERNAGE all use a canonical form that includes - the lower bound and excludes the upper bound; that is, [ - ). User-defined ranges can use other conventions, however. + The built-in range types INT4RANGE, INT8RANGE, + and DATERANGE all use a canonical form that includes + the lower bound and excludes the upper bound; that is, + [). User-defined range types can use other conventions, + however. Defining New Range Types + - Users can define their own range types. The most common reason to do - this is to use ranges where the subtype is not among the built-in - range types, e.g. a range of type FLOAT (or, if the - subtype itself is a user-defined type). - - - For example: to define a new range type of sub-type DOUBLE PRECISION: + Users can define their own range types. The most common reason to do + this is to use ranges over subtypes not provided among the built-in + range types. + For example, to define a new range type of subtype DOUBLE + PRECISION: + CREATE TYPE FLOATRANGE AS RANGE ( SUBTYPE = DOUBLE PRECISION @@ -274,99 +349,113 @@ CREATE TYPE FLOATRANGE AS RANGE ( SELECT '[1.234, 5.678]'::floatrange; - Because DOUBLE PRECISION has no meaningful "step", we - do not define a canonical - function. See for more - information. + + Because DOUBLE PRECISION has no meaningful + step, we do not define a canonicalization + function. + - Defining your own range type also allows you to specify a different - operator class or collation to use (which affects the points that - fall between the range boundaries), or a different canonicalization - function. + Defining your own range type also allows you to specify a different + operator class or collation to use, so as to change the sort ordering + that determines which values fall into a given range. You might also + choose to use a different canonicalization function, either to change + the displayed format or to modify the effective step size. + + + + See for more information about creating + range types. + Indexing + range type - gist + GiST index - Indexing + - GiST indexes can be applied to a table containing a range type. For instance: + GiST indexes can be applied to columns of range types. For instance: CREATE INDEX reservation_idx ON reservation USING gist (during); - This index may speed up queries - involving && - (overlaps), @> (contains), and all the boolean - operators found in this - table: . + This index may speed up queries + involving && + (overlaps), @> (contains), and other boolean + operators listed in . + Constraints on Ranges + range type exclude - Constraints on Ranges + While UNIQUE is a natural constraint for scalar values, it is usually unsuitable for range types. Instead, an exclusion constraint is often more appropriate (see CREATE TABLE ... CONSTRAINT ... EXCLUDE). Exclusion constraints allow the - specification of constraints such as "non-overlapping" on a range - type. For example: + specification of constraints such as non-overlapping on a + range type. For example: + ALTER TABLE reservation - ADD EXCLUDE USING gist (during WITH &&); + ADD EXCLUDE USING gist (during WITH &&); + That constraint will prevent any overlapping values from existing in the table at the same time: + -INSERT INTO reservation VALUES - ( '[2010-01-01 11:30, 2010-01-01 13:00)' ); --- Result: INSERT 0 1 -INSERT INTO reservation VALUES - ( '[2010-01-01 14:45, 2010-01-01 15:45)' ); --- Result: --- ERROR: conflicting key value violates exclusion constraint "reservation_during_excl" --- DETAIL: Key (during)=([ 2010-01-01 14:45:00, 2010-01-01 15:45:00 )) conflicts with --- existing key (during)=([ 2010-01-01 14:30:00, 2010-01-01 15:30:00 )). +INSERT INTO reservation VALUES + ( 1108, '[2010-01-01 11:30, 2010-01-01 13:00)' ); +INSERT 0 1 + +INSERT INTO reservation VALUES + ( 1108, '[2010-01-01 14:45, 2010-01-01 15:45)' ); +ERROR: conflicting key value violates exclusion constraint "reservation_during_excl" +DETAIL: Key (during)=([ 2010-01-01 14:45:00, 2010-01-01 15:45:00 )) conflicts +with existing key (during)=([ 2010-01-01 14:30:00, 2010-01-01 15:30:00 )). - - Combine range types and exclusion constraints - with btree_gist for maximum - flexibility defining - constraints. After btree_gist is installed, the - following constraint will prevent overlapping ranges only if the - meeting room numbers are equal: - + + You can use the btree_gist + extension to define exclusion constraints on plain scalar datatypes, which + can then be combined with range exclusions for maximum flexibility. For + example, after btree_gist is installed, the following + constraint will reject overlapping ranges only if the meeting room numbers + are equal: + + CREATE TABLE room_reservation ( room TEXT, during TSRANGE, - EXCLUDE USING gist (room WITH =, during WITH &&) + EXCLUDE USING gist (room WITH =, during WITH &&) ); INSERT INTO room_reservation VALUES ( '123A', '[2010-01-01 14:00, 2010-01-01 15:00)' ); --- Result: INSERT 0 1 +INSERT 0 1 + INSERT INTO room_reservation VALUES ( '123A', '[2010-01-01 14:30, 2010-01-01 15:30)' ); --- Result: --- ERROR: conflicting key value violates exclusion constraint "room_reservation_room_during_excl" --- DETAIL: Key (room, during)=(123A, [ 2010-01-01 14:30:00, 2010-01-01 15:30:00 )) conflicts with --- existing key (room, during)=(123A, [ 2010-01-01 14:00:00, 2010-01-01 15:00:00 )). +ERROR: conflicting key value violates exclusion constraint "room_reservation_room_during_excl" +DETAIL: Key (room, during)=(123A, [ 2010-01-01 14:30:00, 2010-01-01 15:30:00 )) conflicts with +existing key (room, during)=(123A, [ 2010-01-01 14:00:00, 2010-01-01 15:00:00 )). + INSERT INTO room_reservation VALUES ( '123B', '[2010-01-01 14:30, 2010-01-01 15:30)' ); --- Result: INSERT 0 1 - +INSERT 0 1 diff --git a/doc/src/sgml/ref/create_type.sgml b/doc/src/sgml/ref/create_type.sgml index ebcd461bd9..808990feb7 100644 --- a/doc/src/sgml/ref/create_type.sgml +++ b/doc/src/sgml/ref/create_type.sgml @@ -28,12 +28,12 @@ CREATE TYPE name AS ENUM ( [ 'label' [, ... ] ] ) CREATE TYPE name AS RANGE ( - SUBTYPE = subtype, + SUBTYPE = subtype [ , SUBTYPE_OPCLASS = subtype_operator_class ] - [ , SUBTYPE_DIFF = subtype_diff_function ] - [ , CANONICAL = canonical_function ] - [ , ANALYZE = analyze_function ] [ , COLLATION = collation ] + [ , CANONICAL = canonical_function ] + [ , SUBTYPE_DIFF = subtype_diff_function ] + [ , ANALYZE = analyze_function ] ) CREATE TYPE name ( @@ -79,6 +79,18 @@ CREATE TYPE name table in the same schema.) + + There are five forms of CREATE TYPE, as shown in the + syntax synopsis above. They respectively create a composite + type, an enum type, a range type, a + base type, or a shell type. The first four + of these are discussed in turn below. A shell type is simply a placeholder + for a type to be defined later; it is created by issuing CREATE + TYPE with no parameters except for the type name. Shell types + are needed as forward references when creating range types and base types, + as discussed in those sections. + + Composite Types @@ -102,59 +114,65 @@ CREATE TYPE name The second form of CREATE TYPE creates an enumerated (enum) type, as described in . Enum types take a list of one or more quoted labels, each of which - must be less than NAMEDATALEN bytes long (64 in a standard - PostgreSQL build). + must be less than NAMEDATALEN bytes long (64 bytes in a + standard PostgreSQL build). Range Types - + The third form of CREATE TYPE creates a new range type, as described in . - + - - The subtype parameter - can be any type with an associated btree opclass (uses the type's - default btree operator class unless specified with - subtype_operator_class). - + + The range type's subtype can + be any type with an associated btree operator class (to determine the + ordering of values for the range type). Normally the subtype's default + btree operator class is used to determine ordering; to use a non-default + opclass, specify its name with subtype_opclass. If the subtype is + collatable, and you want to use a non-default collation in the range's + ordering, specify the desired collation with the collation option. + - - The subtype_diff - function takes two values of type - subtype as argument, and - returns the distance between the two values as - double precision. This function is used for GiST indexing - (see for more information), and should be provided - for efficiency. - - - - The canonical - function takes an argument and returns a value, both of the same - type being defined. This is used to convert the range value to a - canonical form, when applicable. See + + The optional canonical + function must take one argument of the range type being defined, and + return a value of the same type. This is used to convert the range value + to a canonical form, when applicable. See for more information. To define - a canonical function, - you must first create a shell type, which is a + the canonical function, + you must first create a shell type, which is a placeholder type that has no properties except a name and an owner. This is done by issuing the command CREATE TYPE - name, with no additional parameters. - + name, with no additional parameters. Then + the function can be declared, and finally the range type can be declared, + replacing the shell type entry with a valid range type. + - - The analyze - function is the same as for creating a base type. - + + The optional subtype_diff + function must take two values of the + subtype type as argument, + and return a double precision value representing the + difference between the two given values. While this is optional, + providing it allows much greater efficiency of GiST indexes on columns of + the range type. Note that the subtype_diff function should agree with + the sort ordering implied by the selected operator class and collation; + that is, its result should be positive whenever its first argument is + greater than its second according to the sort ordering. + - - The collation option - specifies the collation used when determining the total order for - the range. - + + The optional analyze + function performs type-specific statistics collection for columns of the + range type. This is defined the same as for base types; see below. + @@ -431,7 +449,7 @@ CREATE TYPE name Whenever a user-defined type is created, PostgreSQL automatically creates an - associated array type, whose name consists of the base type's + associated array type, whose name consists of the element type's name prepended with an underscore, and truncated if necessary to keep it less than NAMEDATALEN bytes long. (If the name so generated collides with an existing type name, the process is @@ -496,6 +514,16 @@ CREATE TYPE name + + collation + + + The name of an existing collation to be associated with a column of + a composite type, or with a range type. + + + + label @@ -506,6 +534,43 @@ CREATE TYPE name + + subtype + + + The name of the element type that the range type will represent ranges + of. + + + + + + subtype_operator_class + + + The name of a btree operator class for the subtype. + + + + + + canonical_function + + + The name of the canonicalization function for the range type. + + + + + + subtype_diff_function + + + The name of a difference function for the subtype. + + + + input_function @@ -699,8 +764,8 @@ CREATE TYPE name Because there are no restrictions on use of a data type once it's been - created, creating a base type is tantamount to granting public execute - permission on the functions mentioned in the type definition. + created, creating a base type or range type is tantamount to granting + public execute permission on the functions mentioned in the type definition. This is usually not an issue for the sorts of functions that are useful in a type definition. But you might want to think twice before designing a type @@ -730,7 +795,8 @@ CREATE TYPE name - Before PostgreSQL version 8.2, the syntax + Before PostgreSQL version 8.2, the shell-type + creation syntax CREATE TYPE name did not exist. The way to create a new base type was to create its input function first. In this approach, PostgreSQL will first see @@ -787,6 +853,13 @@ CREATE TABLE bug ( + + This example creates a range type: + +CREATE TYPE float8_range AS RANGE (subtype = float8, subtype_diff = float8mi); + + + This example creates the base data type box and then uses the type in a table definition: @@ -860,7 +933,7 @@ CREATE TABLE big_objs ( The ability to create a composite type with zero attributes is a PostgreSQL-specific deviation from the - standard (analogous to CREATE TABLE). + standard (analogous to the same case in CREATE TABLE). diff --git a/doc/src/sgml/rowtypes.sgml b/doc/src/sgml/rowtypes.sgml index 4f8e559f6c..605dc71dab 100644 --- a/doc/src/sgml/rowtypes.sgml +++ b/doc/src/sgml/rowtypes.sgml @@ -243,7 +243,7 @@ INSERT INTO mytab (complex_col.r, complex_col.i) VALUES(1.1, 2.2); - + Composite Type Input and Output Syntax diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c index 973f0b335d..d2005c1e80 100644 --- a/src/bin/pg_dump/pg_dump.c +++ b/src/bin/pg_dump/pg_dump.c @@ -2986,7 +2986,8 @@ getTypes(int *numTypes) /* * If it's a base type, make a DumpableObject representing a shell * definition of the type. We will need to dump that ahead of the I/O - * functions for the type. + * functions for the type. Similarly, range types need a shell + * definition in case they have a canonicalize function. * * Note: the shell type doesn't have a catId. You might think it * should copy the base type's catId, but then it might capture the @@ -3006,8 +3007,8 @@ getTypes(int *numTypes) /* * Initially mark the shell type as not to be dumped. We'll only - * dump it if the I/O functions need to be dumped; this is taken - * care of while sorting dependencies. + * dump it if the I/O or canonicalize functions need to be dumped; + * this is taken care of while sorting dependencies. */ stinfo->dobj.dump = false; @@ -7340,6 +7341,9 @@ dumpType(Archive *fout, TypeInfo *tyinfo) dumpEnumType(fout, tyinfo); else if (tyinfo->typtype == TYPTYPE_RANGE) dumpRangeType(fout, tyinfo); + else + write_msg(NULL, "WARNING: typtype of data type \"%s\" appears to be invalid\n", + tyinfo->dobj.name); } /* diff --git a/src/bin/pg_dump/pg_dump_sort.c b/src/bin/pg_dump/pg_dump_sort.c index efde0d0026..6b6c073eb6 100644 --- a/src/bin/pg_dump/pg_dump_sort.c +++ b/src/bin/pg_dump/pg_dump_sort.c @@ -636,7 +636,8 @@ findLoop(DumpableObject *obj, /* * A user-defined datatype will have a dependency loop with each of its * I/O functions (since those have the datatype as input or output). - * Break the loop and make the I/O function depend on the associated + * Similarly, a range type will have a loop with its canonicalize function, + * if any. Break the loop by making the function depend on the associated * shell type, instead. */ static void @@ -651,7 +652,7 @@ repairTypeFuncLoop(DumpableObject *typeobj, DumpableObject *funcobj) if (typeInfo->shellType) { addObjectDependency(funcobj, typeInfo->shellType->dobj.dumpId); - /* Mark shell type as to be dumped if any I/O function is */ + /* Mark shell type as to be dumped if any such function is */ if (funcobj->dump) typeInfo->shellType->dobj.dump = true; } @@ -789,7 +790,7 @@ repairDependencyLoop(DumpableObject **loop, int i, j; - /* Datatype and one of its I/O functions */ + /* Datatype and one of its I/O or canonicalize functions */ if (nLoop == 2 && loop[0]->objType == DO_TYPE && loop[1]->objType == DO_FUNC) diff --git a/src/include/catalog/pg_range.h b/src/include/catalog/pg_range.h index cc9ba293c1..4fbde166b3 100644 --- a/src/include/catalog/pg_range.h +++ b/src/include/catalog/pg_range.h @@ -34,7 +34,7 @@ CATALOG(pg_range,3541) BKI_WITHOUT_OIDS { Oid rngtypid; /* OID of owning range type */ - Oid rngsubtype; /* OID of range's subtype */ + Oid rngsubtype; /* OID of range's element type (subtype) */ Oid rngcollation; /* collation for this range type, or 0 */ Oid rngsubopc; /* subtype's btree opclass */ regproc rngcanonical; /* canonicalize range, or 0 */ diff --git a/src/include/catalog/pg_type.h b/src/include/catalog/pg_type.h index 1806985b69..f2a3250790 100644 --- a/src/include/catalog/pg_type.h +++ b/src/include/catalog/pg_type.h @@ -61,8 +61,9 @@ CATALOG(pg_type,1247) BKI_BOOTSTRAP BKI_ROWTYPE_OID(71) BKI_SCHEMA_MACRO /* * typtype is 'b' for a base type, 'c' for a composite type (e.g., a - * table's rowtype), 'd' for a domain type, 'e' for an enum type, or 'p' - * for a pseudo-type. (Use the TYPTYPE macros below.) + * table's rowtype), 'd' for a domain, 'e' for an enum type, + * 'p' for a pseudo-type, or 'r' for a range type. + * (Use the TYPTYPE macros below.) * * If typtype is 'c', typrelid is the OID of the class' entry in pg_class. */ diff --git a/src/test/regress/expected/type_sanity.out b/src/test/regress/expected/type_sanity.out index 19d437ade5..0e1dfd8486 100644 --- a/src/test/regress/expected/type_sanity.out +++ b/src/test/regress/expected/type_sanity.out @@ -56,11 +56,14 @@ WHERE (p1.typtype = 'c' AND p1.typrelid = 0) OR -----+--------- (0 rows) --- Look for basic or enum types that don't have an array type. +-- Look for types that should have an array type according to their typtype, +-- but don't. We exclude composites here because we have not bothered to +-- make array types corresponding to the system catalogs' rowtypes. -- NOTE: as of 9.1, this check finds pg_node_tree, smgr, and unknown. SELECT p1.oid, p1.typname FROM pg_type as p1 -WHERE p1.typtype in ('b','e') AND p1.typname NOT LIKE E'\\_%' AND NOT EXISTS +WHERE p1.typtype not in ('c','d','p') AND p1.typname NOT LIKE E'\\_%' + AND NOT EXISTS (SELECT 1 FROM pg_type as p2 WHERE p2.typname = ('_' || p1.typname)::name AND p2.typelem = p1.oid and p1.typarray = p2.oid); @@ -150,6 +153,19 @@ ORDER BY 1; 30 | oidvector | 54 | oidvectorin (2 rows) +-- Composites, domains, enums, ranges should all use the same input routines +SELECT DISTINCT typtype, typinput +FROM pg_type AS p1 +WHERE p1.typtype not in ('b', 'p') +ORDER BY 1; + typtype | typinput +---------+----------- + c | record_in + d | domain_in + e | enum_in + r | range_in +(4 rows) + -- Check for bogus typoutput routines -- As of 8.0, this check finds refcursor, which is borrowing -- other types' I/O routines @@ -174,6 +190,26 @@ WHERE p1.typoutput = p2.oid AND p1.typtype in ('b', 'p') AND NOT -----+---------+-----+--------- (0 rows) +-- Composites, enums, ranges should all use the same output routines +SELECT DISTINCT typtype, typoutput +FROM pg_type AS p1 +WHERE p1.typtype not in ('b', 'd', 'p') +ORDER BY 1; + typtype | typoutput +---------+------------ + c | record_out + e | enum_out + r | range_out +(3 rows) + +-- Domains should have same typoutput as their base types +SELECT p1.oid, p1.typname, p2.oid, p2.typname +FROM pg_type AS p1 LEFT JOIN pg_type AS p2 ON p1.typbasetype = p2.oid +WHERE p1.typtype = 'd' AND p1.typoutput IS DISTINCT FROM p2.typoutput; + oid | typname | oid | typname +-----+---------+-----+--------- +(0 rows) + -- Check for bogus typreceive routines SELECT p1.oid, p1.typname, p2.oid, p2.proname FROM pg_type AS p1, pg_proc AS p2 @@ -222,6 +258,19 @@ WHERE p1.typinput = p2.oid AND p1.typreceive = p3.oid AND -----+---------+-----+---------+-----+--------- (0 rows) +-- Composites, domains, enums, ranges should all use the same receive routines +SELECT DISTINCT typtype, typreceive +FROM pg_type AS p1 +WHERE p1.typtype not in ('b', 'p') +ORDER BY 1; + typtype | typreceive +---------+------------- + c | record_recv + d | domain_recv + e | enum_recv + r | range_recv +(4 rows) + -- Check for bogus typsend routines -- As of 7.4, this check finds refcursor, which is borrowing -- other types' I/O routines @@ -246,10 +295,30 @@ WHERE p1.typsend = p2.oid AND p1.typtype in ('b', 'p') AND NOT -----+---------+-----+--------- (0 rows) +-- Composites, enums, ranges should all use the same send routines +SELECT DISTINCT typtype, typsend +FROM pg_type AS p1 +WHERE p1.typtype not in ('b', 'd', 'p') +ORDER BY 1; + typtype | typsend +---------+------------- + c | record_send + e | enum_send + r | range_send +(3 rows) + +-- Domains should have same typsend as their base types +SELECT p1.oid, p1.typname, p2.oid, p2.typname +FROM pg_type AS p1 LEFT JOIN pg_type AS p2 ON p1.typbasetype = p2.oid +WHERE p1.typtype = 'd' AND p1.typsend IS DISTINCT FROM p2.typsend; + oid | typname | oid | typname +-----+---------+-----+--------- +(0 rows) + -- Check for bogus typmodin routines SELECT p1.oid, p1.typname, p2.oid, p2.proname FROM pg_type AS p1, pg_proc AS p2 -WHERE p1.typmodin = p2.oid AND p1.typtype in ('b', 'p') AND NOT +WHERE p1.typmodin = p2.oid AND NOT (p2.pronargs = 1 AND p2.proargtypes[0] = 'cstring[]'::regtype AND p2.prorettype = 'int4'::regtype AND NOT p2.proretset); @@ -260,7 +329,7 @@ WHERE p1.typmodin = p2.oid AND p1.typtype in ('b', 'p') AND NOT -- Check for bogus typmodout routines SELECT p1.oid, p1.typname, p2.oid, p2.proname FROM pg_type AS p1, pg_proc AS p2 -WHERE p1.typmodout = p2.oid AND p1.typtype in ('b', 'p') AND NOT +WHERE p1.typmodout = p2.oid AND NOT (p2.pronargs = 1 AND p2.proargtypes[0] = 'int4'::regtype AND p2.prorettype = 'cstring'::regtype AND NOT p2.proretset); @@ -298,7 +367,7 @@ WHERE p1.typarray = p2.oid AND -- Check for bogus typanalyze routines SELECT p1.oid, p1.typname, p2.oid, p2.proname FROM pg_type AS p1, pg_proc AS p2 -WHERE p1.typanalyze = p2.oid AND p1.typtype in ('b', 'p') AND NOT +WHERE p1.typanalyze = p2.oid AND NOT (p2.pronargs = 1 AND p2.proargtypes[0] = 'internal'::regtype AND p2.prorettype = 'bool'::regtype AND NOT p2.proretset); diff --git a/src/test/regress/sql/type_sanity.sql b/src/test/regress/sql/type_sanity.sql index d7d9cea5dc..c6a70ad14c 100644 --- a/src/test/regress/sql/type_sanity.sql +++ b/src/test/regress/sql/type_sanity.sql @@ -50,12 +50,15 @@ FROM pg_type as p1 WHERE (p1.typtype = 'c' AND p1.typrelid = 0) OR (p1.typtype != 'c' AND p1.typrelid != 0); --- Look for basic or enum types that don't have an array type. +-- Look for types that should have an array type according to their typtype, +-- but don't. We exclude composites here because we have not bothered to +-- make array types corresponding to the system catalogs' rowtypes. -- NOTE: as of 9.1, this check finds pg_node_tree, smgr, and unknown. SELECT p1.oid, p1.typname FROM pg_type as p1 -WHERE p1.typtype in ('b','e') AND p1.typname NOT LIKE E'\\_%' AND NOT EXISTS +WHERE p1.typtype not in ('c','d','p') AND p1.typname NOT LIKE E'\\_%' + AND NOT EXISTS (SELECT 1 FROM pg_type as p2 WHERE p2.typname = ('_' || p1.typname)::name AND p2.typelem = p1.oid and p1.typarray = p2.oid); @@ -117,6 +120,12 @@ WHERE p1.typinput = p2.oid AND p1.typtype in ('b', 'p') AND (p2.oid = 'array_in'::regproc) ORDER BY 1; +-- Composites, domains, enums, ranges should all use the same input routines +SELECT DISTINCT typtype, typinput +FROM pg_type AS p1 +WHERE p1.typtype not in ('b', 'p') +ORDER BY 1; + -- Check for bogus typoutput routines -- As of 8.0, this check finds refcursor, which is borrowing @@ -135,6 +144,17 @@ FROM pg_type AS p1, pg_proc AS p2 WHERE p1.typoutput = p2.oid AND p1.typtype in ('b', 'p') AND NOT (p2.prorettype = 'cstring'::regtype AND NOT p2.proretset); +-- Composites, enums, ranges should all use the same output routines +SELECT DISTINCT typtype, typoutput +FROM pg_type AS p1 +WHERE p1.typtype not in ('b', 'd', 'p') +ORDER BY 1; + +-- Domains should have same typoutput as their base types +SELECT p1.oid, p1.typname, p2.oid, p2.typname +FROM pg_type AS p1 LEFT JOIN pg_type AS p2 ON p1.typbasetype = p2.oid +WHERE p1.typtype = 'd' AND p1.typoutput IS DISTINCT FROM p2.typoutput; + -- Check for bogus typreceive routines SELECT p1.oid, p1.typname, p2.oid, p2.proname @@ -169,6 +189,12 @@ FROM pg_type AS p1, pg_proc AS p2, pg_proc AS p3 WHERE p1.typinput = p2.oid AND p1.typreceive = p3.oid AND p2.pronargs != p3.pronargs; +-- Composites, domains, enums, ranges should all use the same receive routines +SELECT DISTINCT typtype, typreceive +FROM pg_type AS p1 +WHERE p1.typtype not in ('b', 'p') +ORDER BY 1; + -- Check for bogus typsend routines -- As of 7.4, this check finds refcursor, which is borrowing @@ -187,11 +213,22 @@ FROM pg_type AS p1, pg_proc AS p2 WHERE p1.typsend = p2.oid AND p1.typtype in ('b', 'p') AND NOT (p2.prorettype = 'bytea'::regtype AND NOT p2.proretset); +-- Composites, enums, ranges should all use the same send routines +SELECT DISTINCT typtype, typsend +FROM pg_type AS p1 +WHERE p1.typtype not in ('b', 'd', 'p') +ORDER BY 1; + +-- Domains should have same typsend as their base types +SELECT p1.oid, p1.typname, p2.oid, p2.typname +FROM pg_type AS p1 LEFT JOIN pg_type AS p2 ON p1.typbasetype = p2.oid +WHERE p1.typtype = 'd' AND p1.typsend IS DISTINCT FROM p2.typsend; + -- Check for bogus typmodin routines SELECT p1.oid, p1.typname, p2.oid, p2.proname FROM pg_type AS p1, pg_proc AS p2 -WHERE p1.typmodin = p2.oid AND p1.typtype in ('b', 'p') AND NOT +WHERE p1.typmodin = p2.oid AND NOT (p2.pronargs = 1 AND p2.proargtypes[0] = 'cstring[]'::regtype AND p2.prorettype = 'int4'::regtype AND NOT p2.proretset); @@ -200,7 +237,7 @@ WHERE p1.typmodin = p2.oid AND p1.typtype in ('b', 'p') AND NOT SELECT p1.oid, p1.typname, p2.oid, p2.proname FROM pg_type AS p1, pg_proc AS p2 -WHERE p1.typmodout = p2.oid AND p1.typtype in ('b', 'p') AND NOT +WHERE p1.typmodout = p2.oid AND NOT (p2.pronargs = 1 AND p2.proargtypes[0] = 'int4'::regtype AND p2.prorettype = 'cstring'::regtype AND NOT p2.proretset); @@ -230,7 +267,7 @@ WHERE p1.typarray = p2.oid AND SELECT p1.oid, p1.typname, p2.oid, p2.proname FROM pg_type AS p1, pg_proc AS p2 -WHERE p1.typanalyze = p2.oid AND p1.typtype in ('b', 'p') AND NOT +WHERE p1.typanalyze = p2.oid AND NOT (p2.pronargs = 1 AND p2.proargtypes[0] = 'internal'::regtype AND p2.prorettype = 'bool'::regtype AND NOT p2.proretset);