mirror of https://github.com/postgres/postgres
Selectivity estimation functions are missing for some range type operators, which is a TODO. Jeff Davispull/1/head
parent
4334289186
commit
4429f6a9e3
@ -0,0 +1,373 @@ |
|||||||
|
<!-- doc/src/sgml/rangetypes.sgml --> |
||||||
|
|
||||||
|
<sect1 id="rangetypes"> |
||||||
|
<title>Range Types</title> |
||||||
|
|
||||||
|
<indexterm> |
||||||
|
<primary>range type</primary> |
||||||
|
</indexterm> |
||||||
|
|
||||||
|
<para> |
||||||
|
Range types are data types representing a range of values over some |
||||||
|
sub-type with a total order. For instance, ranges |
||||||
|
of <type>timestamp</type> might be used to represent the ranges of |
||||||
|
time that a meeting room is reserved. In this case the data type |
||||||
|
is <type>tsrange</type> (short for "timestamp range"), |
||||||
|
and <type>timestamp</type> is the sub-type with a total order. |
||||||
|
</para> |
||||||
|
|
||||||
|
<para> |
||||||
|
Range types are useful because they represent many points in a |
||||||
|
single value. 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. |
||||||
|
</para> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-builtin"> |
||||||
|
<title>Built-in Range Types</title> |
||||||
|
<para> |
||||||
|
PostgreSQL comes with the following built-in range types: |
||||||
|
<itemizedlist> |
||||||
|
<listitem> |
||||||
|
<para> |
||||||
|
<type>INT4RANGE</type> -- Range of <type>INTEGER</type>. This is a discrete range type, see <xref linkend="rangetypes-discrete">. |
||||||
|
</para> |
||||||
|
</listitem> |
||||||
|
<listitem> |
||||||
|
<para> |
||||||
|
<type>INT8RANGE</type> -- Range of <type>BIGINT</type>. This is a discrete range type, see <xref linkend="rangetypes-discrete">. |
||||||
|
</para> |
||||||
|
</listitem> |
||||||
|
<listitem> |
||||||
|
<para> |
||||||
|
<type>NUMRANGE</type> -- Range of <type>NUMERIC</type>. |
||||||
|
</para> |
||||||
|
</listitem> |
||||||
|
<listitem> |
||||||
|
<para> |
||||||
|
<type>TSRANGE</type> -- Range of <type>TIMESTAMP WITHOUT TIME ZONE</type>. |
||||||
|
</para> |
||||||
|
</listitem> |
||||||
|
<listitem> |
||||||
|
<para> |
||||||
|
<type>TSTZRANGE</type> -- Range of <type>TIMESTAMP WITH TIME ZONE</type>. |
||||||
|
</para> |
||||||
|
</listitem> |
||||||
|
<listitem> |
||||||
|
<para> |
||||||
|
<type>DATERANGE</type> -- Range of <type>DATE</type>. This is a discrete range type, see <xref linkend="rangetypes-discrete">. |
||||||
|
</para> |
||||||
|
</listitem> |
||||||
|
</itemizedlist> |
||||||
|
In addition, you can define your own; see <xref linkend="SQL-CREATETYPE"> for more information. |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-examples"> |
||||||
|
<title>Examples</title> |
||||||
|
<para> |
||||||
|
<programlisting> |
||||||
|
CREATE TABLE reservation ( during TSRANGE ); |
||||||
|
INSERT INTO reservation VALUES |
||||||
|
( '[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); |
||||||
|
|
||||||
|
-- Find the upper bound: |
||||||
|
SELECT upper(int8range(15, 25)); |
||||||
|
|
||||||
|
-- Compute the intersection: |
||||||
|
SELECT int4range(10, 20) * int4range(15, 25); |
||||||
|
|
||||||
|
-- Is the range non-empty? |
||||||
|
SELECT numrange(1, 5)? ; |
||||||
|
|
||||||
|
</programlisting> |
||||||
|
|
||||||
|
See <xref linkend="range-functions-table"> |
||||||
|
and <xref linkend="range-operators-table"> for complete lists of |
||||||
|
functions and operators on range types. |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-inclusivity"> |
||||||
|
<title>Inclusive and Exclusive Bounds</title> |
||||||
|
<para> |
||||||
|
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. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
An inclusive lower bound is represented by <literal>[</literal> |
||||||
|
while an exclusive lower bound is represented |
||||||
|
by <literal>(</literal> (see <xref linkend="rangetypes-construct"> |
||||||
|
and <xref linkend="rangetypes-io"> below). Likewise, an inclusive |
||||||
|
upper bound is represented by <literal>]</literal>, while an |
||||||
|
exclusive upper bound is represented by <literal>)</literal>. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
Functions <literal>lower_inc</literal> |
||||||
|
and <literal>upper_inc</literal> test the inclusivity of the lower |
||||||
|
and upper bounds of a range, respectively. |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-infinite"> |
||||||
|
<title>Infinite (unbounded) Ranges</title> |
||||||
|
<para> |
||||||
|
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. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
Functions <literal>lower_inf</literal> |
||||||
|
and <literal>upper_inf</literal> test the range for infinite lower |
||||||
|
and upper bounds of a range, respectively. |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-io"> |
||||||
|
<title>Input/Output</title> |
||||||
|
<para> |
||||||
|
The input follows one of the following patterns: |
||||||
|
<synopsis> |
||||||
|
(<replaceable>lower-bound</replaceable>,<replaceable>upper-bound</replaceable>) |
||||||
|
(<replaceable>lower-bound</replaceable>,<replaceable>upper-bound</replaceable>] |
||||||
|
[<replaceable>lower-bound</replaceable>,<replaceable>upper-bound</replaceable>) |
||||||
|
[<replaceable>lower-bound</replaceable>,<replaceable>upper-bound</replaceable>] |
||||||
|
empty |
||||||
|
</synopsis> |
||||||
|
Notice that the final pattern is <literal>empty</literal>, which |
||||||
|
represents an empty range (a range that contains no points). |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
The <replaceable>lower-bound</replaceable> may be either a string |
||||||
|
that is valid input for the sub-type, or omitted (to indicate no |
||||||
|
lower bound); and <replaceable>upper-bound</replaceable> may be |
||||||
|
either a string that is valid input for the sub-type, or omitted (to |
||||||
|
indicate no upper bound). |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
Either the <replaceable>lower-bound</replaceable> or |
||||||
|
the <replaceable>upper-bound</replaceable> may be quoted |
||||||
|
using <literal>""</literal> (double quotation marks), which will allow |
||||||
|
special characters such as "<literal>,</literal>". Within quotation |
||||||
|
marks, "<literal>\</literal>" (backslash) serves as an escape |
||||||
|
character. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
The choice between the other input formats affects the inclusivity |
||||||
|
of the bounds. See <xref linkend="rangetypes-inclusivity">. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
Examples: |
||||||
|
<programlisting> |
||||||
|
-- includes point 3, does not include point 7, and does include all points in between |
||||||
|
select '[3,7)' |
||||||
|
|
||||||
|
-- does not include either 3 or 7, but includes all points in between |
||||||
|
select '(3,7)' |
||||||
|
|
||||||
|
-- includes only the single point 4 |
||||||
|
select '[4,4]' |
||||||
|
</programlisting> |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-construct"> |
||||||
|
<title>Constructing Ranges</title> |
||||||
|
<para> |
||||||
|
Each range type has a constructor by the same name. The constructor |
||||||
|
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 <literal>[ )</literal> form; and the three-argument form |
||||||
|
constructs a range in a form specified by the third argument. For |
||||||
|
example: |
||||||
|
<programlisting> |
||||||
|
-- Three-argument form: lower bound, upper bound, and third argument indicating |
||||||
|
-- inclusivity/exclusivity of bounds (if omitted, defaults to <literal>'[)'</literal>). |
||||||
|
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 <xref linkend="rangetypes-discrete">. |
||||||
|
SELECT int8range(1, 14, '(]'); |
||||||
|
|
||||||
|
-- Single argument form constructs a singleton range; that is a range consisting of just |
||||||
|
-- one point. |
||||||
|
SELECT numrange(11.1); |
||||||
|
|
||||||
|
-- Zero-argument form constructs and 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); |
||||||
|
</programlisting> |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-discrete"> |
||||||
|
<title>Discrete Range Types</title> |
||||||
|
<para> |
||||||
|
Discrete ranges are those that have a |
||||||
|
defined <literal>canonical</literal> function. Loosely speaking, a |
||||||
|
discrete range has a sub-type with a well-defined "step"; |
||||||
|
e.g. <type>INTEGER</type> or <type>DATE</type>. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
The <literal>canonical</literal> function should take an input range |
||||||
|
value, and return an equal range value that may have a different |
||||||
|
formatting. For instance, the integer range <literal>[1, |
||||||
|
7]</literal> could be represented by the equal integer |
||||||
|
range <literal>[1, 8)</literal>. The two values are equal because |
||||||
|
there are no points within the integer domain |
||||||
|
between <literal>7</literal> and <literal>8</literal>, so not |
||||||
|
including the end point <literal>8</literal> is the same as |
||||||
|
including the end point <literal>7</literal>. The canonical output |
||||||
|
for two values that are equal, like <literal>[1, 7]</literal> |
||||||
|
and <literal>[1, 8)</literal>, 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. <literal>[1, 7]</literal> and <literal>[1, 8)</literal>) will |
||||||
|
always be treated as unequal. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
For types such as <type>NUMRANGE</type>, this is not possible, |
||||||
|
because there are always points in between two |
||||||
|
distinct <type>NUMERIC</type> values. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
The built-in range |
||||||
|
types <type>INT4RANGE</type>, <type>INT8RANGE</type>, |
||||||
|
and <type>DATERNAGE</type> all use a canonical form that includes |
||||||
|
the lower bound and excludes the upper bound; that is, <literal>[ |
||||||
|
)</literal>. User-defined ranges can use other conventions, however. |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-defining"> |
||||||
|
<title>Defining New Range Types</title> |
||||||
|
<para> |
||||||
|
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 <type>FLOAT</type> (or, if the |
||||||
|
subtype itself is a user-defined type). |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
For example: to define a new range type of sub-type <type>DOUBLE PRECISION</type>: |
||||||
|
<programlisting> |
||||||
|
CREATE TYPE FLOATRANGE AS RANGE ( |
||||||
|
SUBTYPE = DOUBLE PRECISION |
||||||
|
); |
||||||
|
|
||||||
|
SELECT '[1.234, 5.678]'::floatrange; |
||||||
|
</programlisting> |
||||||
|
Because <type>DOUBLE PRECISION</type> has no meaningful "step", we |
||||||
|
do not define a <literal>canonical</literal> |
||||||
|
function. See <xref linkend="SQL-CREATETYPE"> for more |
||||||
|
information. |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
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. |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-gist"> |
||||||
|
<indexterm> |
||||||
|
<primary>range type</primary> |
||||||
|
<secondary>gist</secondary> |
||||||
|
</indexterm> |
||||||
|
<title>Indexing</title> |
||||||
|
<para> |
||||||
|
GiST indexes can be applied to a table containing a range type. For instance: |
||||||
|
<programlisting> |
||||||
|
CREATE INDEX reservation_idx ON reservation USING gist (during); |
||||||
|
</programlisting> |
||||||
|
This index may speed up queries |
||||||
|
involving <literal>&&</literal> |
||||||
|
(overlaps), <literal>@></literal> (contains), and all the boolean |
||||||
|
operators found in this |
||||||
|
table: <xref linkend="range-operators-table">. |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
|
||||||
|
<sect2 id="rangetypes-constraint"> |
||||||
|
<indexterm> |
||||||
|
<primary>range type</primary> |
||||||
|
<secondary>exclude</secondary> |
||||||
|
</indexterm> |
||||||
|
<title>Constraints on Ranges</title> |
||||||
|
<para> |
||||||
|
While <literal>UNIQUE</literal> is a natural constraint for scalar |
||||||
|
values, it is usually unsuitable for range types. Instead, an |
||||||
|
exclusion constraint is often more appropriate |
||||||
|
(see <link linkend="SQL-CREATETABLE-EXCLUDE">CREATE TABLE |
||||||
|
... CONSTRAINT ... EXCLUDE</link>). Exclusion constraints allow the |
||||||
|
specification of constraints such as "non-overlapping" on a range |
||||||
|
type. For example: |
||||||
|
<programlisting> |
||||||
|
ALTER TABLE reservation |
||||||
|
ADD EXCLUDE USING gist (during WITH &&); |
||||||
|
</programlisting> |
||||||
|
That constraint will prevent any overlapping values from existing |
||||||
|
in the table at the same time: |
||||||
|
<programlisting> |
||||||
|
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 )). |
||||||
|
</programlisting> |
||||||
|
</para> |
||||||
|
<para> |
||||||
|
Combine range types and exclusion constraints |
||||||
|
with <link linkend="btree-gist">btree_gist</link> for maximum |
||||||
|
flexibility defining |
||||||
|
constraints. After <literal>btree_gist</literal> is installed, the |
||||||
|
following constraint will prevent overlapping ranges only if the |
||||||
|
meeting room numbers are equal: |
||||||
|
<programlisting> |
||||||
|
|
||||||
|
CREATE TABLE room_reservation |
||||||
|
( |
||||||
|
room TEXT, |
||||||
|
during TSRANGE, |
||||||
|
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 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 )). |
||||||
|
INSERT INTO room_reservation VALUES |
||||||
|
( '123B', '[2010-01-01 14:30, 2010-01-01 15:30)' ); |
||||||
|
-- Result: INSERT 0 1 |
||||||
|
|
||||||
|
</programlisting> |
||||||
|
</para> |
||||||
|
</sect2> |
||||||
|
</sect1> |
||||||
@ -0,0 +1,136 @@ |
|||||||
|
/*-------------------------------------------------------------------------
|
||||||
|
* |
||||||
|
* pg_range.c |
||||||
|
* routines to support manipulation of the pg_range relation |
||||||
|
* |
||||||
|
* Copyright (c) 2006-2010, PostgreSQL Global Development Group |
||||||
|
* |
||||||
|
* |
||||||
|
* IDENTIFICATION |
||||||
|
* src/backend/catalog/pg_range.c |
||||||
|
* |
||||||
|
*------------------------------------------------------------------------- |
||||||
|
*/ |
||||||
|
#include "postgres.h" |
||||||
|
|
||||||
|
#include "access/genam.h" |
||||||
|
#include "access/heapam.h" |
||||||
|
#include "catalog/dependency.h" |
||||||
|
#include "catalog/indexing.h" |
||||||
|
#include "catalog/pg_collation.h" |
||||||
|
#include "catalog/pg_opclass.h" |
||||||
|
#include "catalog/pg_proc.h" |
||||||
|
#include "catalog/pg_range.h" |
||||||
|
#include "catalog/pg_type.h" |
||||||
|
#include "utils/builtins.h" |
||||||
|
#include "utils/fmgroids.h" |
||||||
|
#include "utils/tqual.h" |
||||||
|
#include "utils/rel.h" |
||||||
|
|
||||||
|
/*
|
||||||
|
* RangeCreate |
||||||
|
* Create an entry in pg_range. |
||||||
|
*/ |
||||||
|
void |
||||||
|
RangeCreate(Oid rangeTypeOid, Oid rangeSubType, Oid rangeCollation, |
||||||
|
Oid rangeSubOpclass, RegProcedure rangeCanonical, |
||||||
|
RegProcedure rangeSubDiff) |
||||||
|
{ |
||||||
|
Relation pg_range; |
||||||
|
Datum values[Natts_pg_range]; |
||||||
|
bool nulls[Natts_pg_range]; |
||||||
|
HeapTuple tup; |
||||||
|
ObjectAddress myself; |
||||||
|
ObjectAddress referenced; |
||||||
|
|
||||||
|
pg_range = heap_open(RangeRelationId, RowExclusiveLock); |
||||||
|
|
||||||
|
memset(nulls, 0, Natts_pg_range * sizeof(bool)); |
||||||
|
|
||||||
|
values[Anum_pg_range_rngtypid - 1] = ObjectIdGetDatum(rangeTypeOid); |
||||||
|
values[Anum_pg_range_rngsubtype - 1] = ObjectIdGetDatum(rangeSubType); |
||||||
|
values[Anum_pg_range_rngcollation - 1] = ObjectIdGetDatum(rangeCollation); |
||||||
|
values[Anum_pg_range_rngsubopc - 1] = ObjectIdGetDatum(rangeSubOpclass); |
||||||
|
values[Anum_pg_range_rngcanonical - 1] = ObjectIdGetDatum(rangeCanonical); |
||||||
|
values[Anum_pg_range_rngsubdiff - 1] = ObjectIdGetDatum(rangeSubDiff); |
||||||
|
|
||||||
|
tup = heap_form_tuple(RelationGetDescr(pg_range), values, nulls); |
||||||
|
simple_heap_insert(pg_range, tup); |
||||||
|
CatalogUpdateIndexes(pg_range, tup); |
||||||
|
heap_freetuple(tup); |
||||||
|
|
||||||
|
/* record dependencies */ |
||||||
|
|
||||||
|
myself.classId = TypeRelationId; |
||||||
|
myself.objectId = rangeTypeOid; |
||||||
|
myself.objectSubId = 0; |
||||||
|
|
||||||
|
referenced.classId = TypeRelationId; |
||||||
|
referenced.objectId = rangeSubType; |
||||||
|
referenced.objectSubId = 0; |
||||||
|
recordDependencyOn(&myself, &referenced, DEPENDENCY_NORMAL); |
||||||
|
|
||||||
|
referenced.classId = OperatorClassRelationId; |
||||||
|
referenced.objectId = rangeSubOpclass; |
||||||
|
referenced.objectSubId = 0; |
||||||
|
recordDependencyOn(&myself, &referenced, DEPENDENCY_NORMAL); |
||||||
|
|
||||||
|
if (OidIsValid(rangeCollation)) |
||||||
|
{ |
||||||
|
referenced.classId = CollationRelationId; |
||||||
|
referenced.objectId = rangeCollation; |
||||||
|
referenced.objectSubId = 0; |
||||||
|
recordDependencyOn(&myself, &referenced, DEPENDENCY_NORMAL); |
||||||
|
} |
||||||
|
|
||||||
|
if (OidIsValid(rangeCanonical)) |
||||||
|
{ |
||||||
|
referenced.classId = ProcedureRelationId; |
||||||
|
referenced.objectId = rangeCanonical; |
||||||
|
referenced.objectSubId = 0; |
||||||
|
recordDependencyOn(&myself, &referenced, DEPENDENCY_NORMAL); |
||||||
|
} |
||||||
|
|
||||||
|
if (OidIsValid(rangeSubDiff)) |
||||||
|
{ |
||||||
|
referenced.classId = ProcedureRelationId; |
||||||
|
referenced.objectId = rangeSubDiff; |
||||||
|
referenced.objectSubId = 0; |
||||||
|
recordDependencyOn(&myself, &referenced, DEPENDENCY_NORMAL); |
||||||
|
} |
||||||
|
|
||||||
|
heap_close(pg_range, RowExclusiveLock); |
||||||
|
} |
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* RangeDelete |
||||||
|
* Remove the pg_range entry. |
||||||
|
*/ |
||||||
|
void |
||||||
|
RangeDelete(Oid rangeTypeOid) |
||||||
|
{ |
||||||
|
Relation pg_range; |
||||||
|
ScanKeyData key[1]; |
||||||
|
SysScanDesc scan; |
||||||
|
HeapTuple tup; |
||||||
|
|
||||||
|
pg_range = heap_open(RangeRelationId, RowExclusiveLock); |
||||||
|
|
||||||
|
ScanKeyInit(&key[0], |
||||||
|
Anum_pg_range_rngtypid, |
||||||
|
BTEqualStrategyNumber, F_OIDEQ, |
||||||
|
ObjectIdGetDatum(rangeTypeOid)); |
||||||
|
|
||||||
|
scan = systable_beginscan(pg_range, RangeTypidIndexId, true, |
||||||
|
SnapshotNow, 1, key); |
||||||
|
|
||||||
|
while (HeapTupleIsValid(tup = systable_getnext(scan))) |
||||||
|
{ |
||||||
|
simple_heap_delete(pg_range, &tup->t_self); |
||||||
|
} |
||||||
|
|
||||||
|
systable_endscan(scan); |
||||||
|
|
||||||
|
heap_close(pg_range, RowExclusiveLock); |
||||||
|
} |
||||||
File diff suppressed because it is too large
Load Diff
@ -0,0 +1,587 @@ |
|||||||
|
/*-------------------------------------------------------------------------
|
||||||
|
* |
||||||
|
* rangetypes_gist.c |
||||||
|
* GiST support for range types. |
||||||
|
* |
||||||
|
* Copyright (c) 2006-2011, PostgreSQL Global Development Group |
||||||
|
* |
||||||
|
* |
||||||
|
* IDENTIFICATION |
||||||
|
* src/backend/utils/adt/rangetypes_gist.c |
||||||
|
* |
||||||
|
*------------------------------------------------------------------------- |
||||||
|
*/ |
||||||
|
#include "postgres.h" |
||||||
|
|
||||||
|
#include "access/gist.h" |
||||||
|
#include "access/skey.h" |
||||||
|
#include "utils/builtins.h" |
||||||
|
#include "utils/fmgroids.h" |
||||||
|
#include "utils/lsyscache.h" |
||||||
|
#include "utils/rangetypes.h" |
||||||
|
|
||||||
|
#define RANGESTRAT_EQ 1 |
||||||
|
#define RANGESTRAT_NE 2 |
||||||
|
#define RANGESTRAT_OVERLAPS 3 |
||||||
|
#define RANGESTRAT_CONTAINS_ELEM 4 |
||||||
|
#define RANGESTRAT_ELEM_CONTAINED_BY 5 |
||||||
|
#define RANGESTRAT_CONTAINS 6 |
||||||
|
#define RANGESTRAT_CONTAINED_BY 7 |
||||||
|
#define RANGESTRAT_BEFORE 8 |
||||||
|
#define RANGESTRAT_AFTER 9 |
||||||
|
#define RANGESTRAT_OVERLEFT 10 |
||||||
|
#define RANGESTRAT_OVERRIGHT 11 |
||||||
|
#define RANGESTRAT_ADJACENT 12 |
||||||
|
|
||||||
|
static RangeType *range_super_union(FunctionCallInfo fcinfo, RangeType *r1, |
||||||
|
RangeType *r2); |
||||||
|
static bool range_gist_consistent_int(FunctionCallInfo fcinfo, |
||||||
|
StrategyNumber strategy, RangeType *key, |
||||||
|
RangeType *query); |
||||||
|
static bool range_gist_consistent_leaf(FunctionCallInfo fcinfo, |
||||||
|
StrategyNumber strategy, RangeType *key, |
||||||
|
RangeType *query); |
||||||
|
static int sort_item_cmp(const void *a, const void *b); |
||||||
|
|
||||||
|
/*
|
||||||
|
* Auxiliary structure for picksplit method. |
||||||
|
*/ |
||||||
|
typedef struct |
||||||
|
{ |
||||||
|
int index; |
||||||
|
RangeType *data; |
||||||
|
FunctionCallInfo fcinfo; |
||||||
|
} PickSplitSortItem; |
||||||
|
|
||||||
|
|
||||||
|
Datum |
||||||
|
range_gist_consistent(PG_FUNCTION_ARGS) |
||||||
|
{ |
||||||
|
GISTENTRY *entry = (GISTENTRY *) PG_GETARG_POINTER(0); |
||||||
|
Datum dquery = PG_GETARG_DATUM(1); |
||||||
|
StrategyNumber strategy = (StrategyNumber) PG_GETARG_UINT16(2); |
||||||
|
/* Oid subtype = PG_GETARG_OID(3); */ |
||||||
|
bool *recheck = (bool *) PG_GETARG_POINTER(4); |
||||||
|
RangeType *key = DatumGetRangeType(entry->key); |
||||||
|
RangeType *query; |
||||||
|
|
||||||
|
RangeBound lower; |
||||||
|
RangeBound upper; |
||||||
|
bool empty; |
||||||
|
Oid rngtypid; |
||||||
|
|
||||||
|
*recheck = false; |
||||||
|
range_deserialize(fcinfo, key, &lower, &upper, &empty); |
||||||
|
rngtypid = lower.rngtypid; |
||||||
|
|
||||||
|
switch (strategy) |
||||||
|
{ |
||||||
|
RangeBound lower; |
||||||
|
RangeBound upper; |
||||||
|
|
||||||
|
/*
|
||||||
|
* For contains and contained by operators, the other operand is a |
||||||
|
* "point" of the subtype. Construct a singleton range containing just |
||||||
|
* that value. |
||||||
|
*/ |
||||||
|
case RANGESTRAT_CONTAINS_ELEM: |
||||||
|
case RANGESTRAT_ELEM_CONTAINED_BY: |
||||||
|
lower.rngtypid = rngtypid; |
||||||
|
lower.inclusive = true; |
||||||
|
lower.val = dquery; |
||||||
|
lower.lower = true; |
||||||
|
lower.infinite = false; |
||||||
|
upper.rngtypid = rngtypid; |
||||||
|
upper.inclusive = true; |
||||||
|
upper.val = dquery; |
||||||
|
upper.lower = false; |
||||||
|
upper.infinite = false; |
||||||
|
query = DatumGetRangeType( |
||||||
|
make_range(fcinfo, &lower, &upper, false)); |
||||||
|
break; |
||||||
|
|
||||||
|
default: |
||||||
|
query = DatumGetRangeType(dquery); |
||||||
|
break; |
||||||
|
} |
||||||
|
|
||||||
|
if (GIST_LEAF(entry)) |
||||||
|
PG_RETURN_BOOL(range_gist_consistent_leaf( |
||||||
|
fcinfo, strategy, key, query)); |
||||||
|
else |
||||||
|
PG_RETURN_BOOL(range_gist_consistent_int( |
||||||
|
fcinfo, strategy, key, query)); |
||||||
|
} |
||||||
|
|
||||||
|
Datum |
||||||
|
range_gist_union(PG_FUNCTION_ARGS) |
||||||
|
{ |
||||||
|
GistEntryVector *entryvec = (GistEntryVector *) PG_GETARG_POINTER(0); |
||||||
|
GISTENTRY *ent = entryvec->vector; |
||||||
|
RangeType *result_range; |
||||||
|
int i; |
||||||
|
|
||||||
|
result_range = DatumGetRangeType(ent[0].key); |
||||||
|
|
||||||
|
for (i = 1; i < entryvec->n; i++) |
||||||
|
{ |
||||||
|
result_range = range_super_union(fcinfo, result_range, |
||||||
|
DatumGetRangeType(ent[i].key)); |
||||||
|
} |
||||||
|
|
||||||
|
PG_RETURN_RANGE(result_range); |
||||||
|
} |
||||||
|
|
||||||
|
Datum |
||||||
|
range_gist_compress(PG_FUNCTION_ARGS) |
||||||
|
{ |
||||||
|
GISTENTRY *entry = (GISTENTRY *) PG_GETARG_POINTER(0); |
||||||
|
PG_RETURN_POINTER(entry); |
||||||
|
} |
||||||
|
|
||||||
|
Datum |
||||||
|
range_gist_decompress(PG_FUNCTION_ARGS) |
||||||
|
{ |
||||||
|
GISTENTRY *entry = (GISTENTRY *) PG_GETARG_POINTER(0); |
||||||
|
PG_RETURN_POINTER(entry); |
||||||
|
} |
||||||
|
|
||||||
|
Datum |
||||||
|
range_gist_penalty(PG_FUNCTION_ARGS) |
||||||
|
{ |
||||||
|
GISTENTRY *origentry = (GISTENTRY *) PG_GETARG_POINTER(0); |
||||||
|
GISTENTRY *newentry = (GISTENTRY *) PG_GETARG_POINTER(1); |
||||||
|
float *penalty = (float *) PG_GETARG_POINTER(2); |
||||||
|
RangeType *orig = DatumGetRangeType(origentry->key); |
||||||
|
RangeType *new = DatumGetRangeType(newentry->key); |
||||||
|
RangeType *s_union = range_super_union(fcinfo, orig, new); |
||||||
|
|
||||||
|
FmgrInfo *subtype_diff; |
||||||
|
|
||||||
|
RangeBound lower1, lower2; |
||||||
|
RangeBound upper1, upper2; |
||||||
|
bool empty1, empty2; |
||||||
|
|
||||||
|
float lower_diff, upper_diff; |
||||||
|
|
||||||
|
RangeTypeInfo rngtypinfo; |
||||||
|
|
||||||
|
range_deserialize(fcinfo, orig, &lower1, &upper1, &empty1); |
||||||
|
range_deserialize(fcinfo, s_union, &lower2, &upper2, &empty2); |
||||||
|
|
||||||
|
range_gettypinfo(fcinfo, lower1.rngtypid, &rngtypinfo); |
||||||
|
subtype_diff = &rngtypinfo.subdiffFn; |
||||||
|
|
||||||
|
Assert(empty1 || !empty2); |
||||||
|
|
||||||
|
if (empty1 && empty2) |
||||||
|
return 0; |
||||||
|
else if (empty1 && !empty2) |
||||||
|
{ |
||||||
|
if (lower2.infinite || upper2.infinite) |
||||||
|
/* from empty to infinite */ |
||||||
|
return get_float8_infinity(); |
||||||
|
else if (subtype_diff->fn_addr != NULL) |
||||||
|
/* from empty to upper2-lower2 */ |
||||||
|
return DatumGetFloat8(FunctionCall2(subtype_diff, |
||||||
|
upper2.val, lower2.val)); |
||||||
|
else |
||||||
|
/* wild guess */ |
||||||
|
return 1.0; |
||||||
|
} |
||||||
|
|
||||||
|
Assert(lower2.infinite || !lower1.infinite); |
||||||
|
|
||||||
|
if (lower2.infinite && !lower1.infinite) |
||||||
|
lower_diff = get_float8_infinity(); |
||||||
|
else if (lower2.infinite && lower1.infinite) |
||||||
|
lower_diff = 0; |
||||||
|
else if (subtype_diff->fn_addr != NULL) |
||||||
|
{ |
||||||
|
lower_diff = DatumGetFloat8(FunctionCall2(subtype_diff, |
||||||
|
lower1.val, lower2.val)); |
||||||
|
if (lower_diff < 0) |
||||||
|
lower_diff = 0; /* subtype_diff is broken */ |
||||||
|
} |
||||||
|
else /* only know whether there is a difference or not */ |
||||||
|
lower_diff = (float) range_cmp_bounds(fcinfo, &lower1, &lower2); |
||||||
|
|
||||||
|
Assert(upper2.infinite || !upper1.infinite); |
||||||
|
|
||||||
|
if (upper2.infinite && !upper1.infinite) |
||||||
|
upper_diff = get_float8_infinity(); |
||||||
|
else if (upper2.infinite && upper1.infinite) |
||||||
|
upper_diff = 0; |
||||||
|
else if (subtype_diff->fn_addr != NULL) |
||||||
|
{ |
||||||
|
upper_diff = DatumGetFloat8(FunctionCall2(subtype_diff, |
||||||
|
upper2.val, upper1.val)); |
||||||
|
if (upper_diff < 0) |
||||||
|
upper_diff = 0; /* subtype_diff is broken */ |
||||||
|
} |
||||||
|
else /* only know whether there is a difference or not */ |
||||||
|
upper_diff = (float) range_cmp_bounds(fcinfo, &upper2, &upper1); |
||||||
|
|
||||||
|
Assert(lower_diff >= 0 && upper_diff >= 0); |
||||||
|
|
||||||
|
*penalty = (float) (lower_diff + upper_diff); |
||||||
|
PG_RETURN_POINTER(penalty); |
||||||
|
} |
||||||
|
|
||||||
|
/*
|
||||||
|
* The GiST PickSplit method for ranges |
||||||
|
* |
||||||
|
* Algorithm based on sorting. Incoming array of periods is sorted using |
||||||
|
* sort_item_cmp function. After that first half of periods goes to the left |
||||||
|
* datum, and the second half of periods goes to the right datum. |
||||||
|
*/ |
||||||
|
Datum |
||||||
|
range_gist_picksplit(PG_FUNCTION_ARGS) |
||||||
|
{ |
||||||
|
GistEntryVector *entryvec = (GistEntryVector *) PG_GETARG_POINTER(0); |
||||||
|
GIST_SPLITVEC *v = (GIST_SPLITVEC *) PG_GETARG_POINTER(1); |
||||||
|
OffsetNumber i; |
||||||
|
RangeType *pred_left; |
||||||
|
RangeType *pred_right; |
||||||
|
PickSplitSortItem *sortItems; |
||||||
|
int nbytes; |
||||||
|
OffsetNumber split_idx; |
||||||
|
OffsetNumber *left; |
||||||
|
OffsetNumber *right; |
||||||
|
OffsetNumber maxoff; |
||||||
|
|
||||||
|
maxoff = entryvec->n - 1; |
||||||
|
nbytes = (maxoff + 1) * sizeof(OffsetNumber); |
||||||
|
sortItems = (PickSplitSortItem *) palloc( |
||||||
|
maxoff * sizeof(PickSplitSortItem)); |
||||||
|
v->spl_left = (OffsetNumber *) palloc(nbytes); |
||||||
|
v->spl_right = (OffsetNumber *) palloc(nbytes); |
||||||
|
|
||||||
|
/*
|
||||||
|
* Preparing auxiliary array and sorting. |
||||||
|
*/ |
||||||
|
for (i = FirstOffsetNumber; i <= maxoff; i = OffsetNumberNext(i)) |
||||||
|
{ |
||||||
|
sortItems[i - 1].index = i; |
||||||
|
sortItems[i - 1].data = DatumGetRangeType(entryvec->vector[i].key); |
||||||
|
sortItems[i - 1].fcinfo = fcinfo; |
||||||
|
} |
||||||
|
qsort(sortItems, maxoff, sizeof(PickSplitSortItem), sort_item_cmp); |
||||||
|
split_idx = maxoff / 2; |
||||||
|
|
||||||
|
left = v->spl_left; |
||||||
|
v->spl_nleft = 0; |
||||||
|
right = v->spl_right; |
||||||
|
v->spl_nright = 0; |
||||||
|
|
||||||
|
/*
|
||||||
|
* First half of segs goes to the left datum. |
||||||
|
*/ |
||||||
|
pred_left = DatumGetRangeType(sortItems[0].data); |
||||||
|
*left++ = sortItems[0].index; |
||||||
|
v->spl_nleft++; |
||||||
|
for (i = 1; i < split_idx; i++) |
||||||
|
{ |
||||||
|
pred_left = range_super_union(fcinfo, pred_left, |
||||||
|
DatumGetRangeType(sortItems[i].data)); |
||||||
|
*left++ = sortItems[i].index; |
||||||
|
v->spl_nleft++; |
||||||
|
} |
||||||
|
|
||||||
|
/*
|
||||||
|
* Second half of segs goes to the right datum. |
||||||
|
*/ |
||||||
|
pred_right = DatumGetRangeType(sortItems[split_idx].data); |
||||||
|
*right++ = sortItems[split_idx].index; |
||||||
|
v->spl_nright++; |
||||||
|
for (i = split_idx + 1; i < maxoff; i++) |
||||||
|
{ |
||||||
|
pred_right = range_super_union(fcinfo, pred_right, |
||||||
|
DatumGetRangeType(sortItems[i].data)); |
||||||
|
*right++ = sortItems[i].index; |
||||||
|
v->spl_nright++; |
||||||
|
} |
||||||
|
|
||||||
|
*left = *right = FirstOffsetNumber; /* sentinel value, see dosplit() */ |
||||||
|
|
||||||
|
v->spl_ldatum = RangeTypeGetDatum(pred_left); |
||||||
|
v->spl_rdatum = RangeTypeGetDatum(pred_right); |
||||||
|
|
||||||
|
PG_RETURN_POINTER(v); |
||||||
|
} |
||||||
|
|
||||||
|
Datum |
||||||
|
range_gist_same(PG_FUNCTION_ARGS) |
||||||
|
{ |
||||||
|
Datum r1 = PG_GETARG_DATUM(0); |
||||||
|
Datum r2 = PG_GETARG_DATUM(1); |
||||||
|
bool *result = (bool *) PG_GETARG_POINTER(2); |
||||||
|
|
||||||
|
*result = DatumGetBool(OidFunctionCall2(F_RANGE_EQ, r1, r2)); |
||||||
|
PG_RETURN_POINTER(result); |
||||||
|
} |
||||||
|
|
||||||
|
/*
|
||||||
|
*---------------------------------------------------------- |
||||||
|
* STATIC FUNCTIONS |
||||||
|
*---------------------------------------------------------- |
||||||
|
*/ |
||||||
|
|
||||||
|
/* return the smallest range that contains r1 and r2 */ |
||||||
|
static RangeType * |
||||||
|
range_super_union(FunctionCallInfo fcinfo, RangeType *r1, RangeType *r2) |
||||||
|
{ |
||||||
|
RangeBound lower1, lower2; |
||||||
|
RangeBound upper1, upper2; |
||||||
|
bool empty1, empty2; |
||||||
|
RangeBound *result_lower; |
||||||
|
RangeBound *result_upper; |
||||||
|
|
||||||
|
range_deserialize(fcinfo, r1, &lower1, &upper1, &empty1); |
||||||
|
range_deserialize(fcinfo, r2, &lower2, &upper2, &empty2); |
||||||
|
|
||||||
|
if (empty1) |
||||||
|
return r2; |
||||||
|
if (empty2) |
||||||
|
return r1; |
||||||
|
|
||||||
|
if (range_cmp_bounds(fcinfo, &lower1, &lower2) <= 0) |
||||||
|
result_lower = &lower1; |
||||||
|
else |
||||||
|
result_lower = &lower2; |
||||||
|
|
||||||
|
if (range_cmp_bounds(fcinfo, &upper1, &upper2) >= 0) |
||||||
|
result_upper = &upper1; |
||||||
|
else |
||||||
|
result_upper = &upper2; |
||||||
|
|
||||||
|
/* optimization to avoid constructing a new range */ |
||||||
|
if (result_lower == &lower1 && result_upper == &upper1) |
||||||
|
return r1; |
||||||
|
if (result_lower == &lower2 && result_upper == &upper2) |
||||||
|
return r2; |
||||||
|
|
||||||
|
return DatumGetRangeType( |
||||||
|
make_range(fcinfo, result_lower, result_upper, false)); |
||||||
|
} |
||||||
|
|
||||||
|
static bool |
||||||
|
range_gist_consistent_int(FunctionCallInfo fcinfo, StrategyNumber strategy, |
||||||
|
RangeType *key, RangeType *query) |
||||||
|
{ |
||||||
|
Oid proc = InvalidOid; |
||||||
|
|
||||||
|
RangeBound lower1, lower2; |
||||||
|
RangeBound upper1, upper2; |
||||||
|
bool empty1, empty2; |
||||||
|
|
||||||
|
bool retval; |
||||||
|
bool negate = false; |
||||||
|
|
||||||
|
range_deserialize(fcinfo, key, &lower1, &upper1, &empty1); |
||||||
|
range_deserialize(fcinfo, query, &lower2, &upper2, &empty2); |
||||||
|
|
||||||
|
switch (strategy) |
||||||
|
{ |
||||||
|
case RANGESTRAT_EQ: |
||||||
|
proc = F_RANGE_CONTAINS; |
||||||
|
break; |
||||||
|
case RANGESTRAT_NE: |
||||||
|
return true; |
||||||
|
break; |
||||||
|
case RANGESTRAT_OVERLAPS: |
||||||
|
proc = F_RANGE_OVERLAPS; |
||||||
|
break; |
||||||
|
case RANGESTRAT_CONTAINS_ELEM: |
||||||
|
case RANGESTRAT_CONTAINS: |
||||||
|
proc = F_RANGE_CONTAINS; |
||||||
|
break; |
||||||
|
case RANGESTRAT_ELEM_CONTAINED_BY: |
||||||
|
case RANGESTRAT_CONTAINED_BY: |
||||||
|
return true; |
||||||
|
break; |
||||||
|
case RANGESTRAT_BEFORE: |
||||||
|
if (empty1) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_OVERRIGHT; |
||||||
|
negate = true; |
||||||
|
break; |
||||||
|
case RANGESTRAT_AFTER: |
||||||
|
if (empty1) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_OVERLEFT; |
||||||
|
negate = true; |
||||||
|
break; |
||||||
|
case RANGESTRAT_OVERLEFT: |
||||||
|
if (empty1) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_AFTER; |
||||||
|
negate = true; |
||||||
|
break; |
||||||
|
case RANGESTRAT_OVERRIGHT: |
||||||
|
if (empty1) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_BEFORE; |
||||||
|
negate = true; |
||||||
|
break; |
||||||
|
case RANGESTRAT_ADJACENT: |
||||||
|
if (empty1 || empty2) |
||||||
|
return false; |
||||||
|
if (DatumGetBool( |
||||||
|
OidFunctionCall2(F_RANGE_ADJACENT, |
||||||
|
RangeTypeGetDatum(key), |
||||||
|
RangeTypeGetDatum(query)))) |
||||||
|
return true; |
||||||
|
proc = F_RANGE_OVERLAPS; |
||||||
|
break; |
||||||
|
} |
||||||
|
|
||||||
|
retval = DatumGetBool(OidFunctionCall2(proc, RangeTypeGetDatum(key), |
||||||
|
RangeTypeGetDatum(query))); |
||||||
|
|
||||||
|
if (negate) |
||||||
|
retval = !retval; |
||||||
|
|
||||||
|
PG_RETURN_BOOL(retval); |
||||||
|
} |
||||||
|
|
||||||
|
static bool |
||||||
|
range_gist_consistent_leaf(FunctionCallInfo fcinfo, StrategyNumber strategy, |
||||||
|
RangeType *key, RangeType *query) |
||||||
|
{ |
||||||
|
Oid proc = InvalidOid; |
||||||
|
|
||||||
|
RangeBound lower1, lower2; |
||||||
|
RangeBound upper1, upper2; |
||||||
|
bool empty1, empty2; |
||||||
|
|
||||||
|
range_deserialize(fcinfo, key, &lower1, &upper1, &empty1); |
||||||
|
range_deserialize(fcinfo, query, &lower2, &upper2, &empty2); |
||||||
|
|
||||||
|
switch (strategy) |
||||||
|
{ |
||||||
|
case RANGESTRAT_EQ: |
||||||
|
proc = F_RANGE_EQ; |
||||||
|
break; |
||||||
|
case RANGESTRAT_NE: |
||||||
|
proc = F_RANGE_NE; |
||||||
|
break; |
||||||
|
case RANGESTRAT_OVERLAPS: |
||||||
|
proc = F_RANGE_OVERLAPS; |
||||||
|
break; |
||||||
|
case RANGESTRAT_CONTAINS_ELEM: |
||||||
|
case RANGESTRAT_CONTAINS: |
||||||
|
proc = F_RANGE_CONTAINS; |
||||||
|
break; |
||||||
|
case RANGESTRAT_ELEM_CONTAINED_BY: |
||||||
|
case RANGESTRAT_CONTAINED_BY: |
||||||
|
proc = F_RANGE_CONTAINED_BY; |
||||||
|
break; |
||||||
|
case RANGESTRAT_BEFORE: |
||||||
|
if (empty1 || empty2) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_BEFORE; |
||||||
|
break; |
||||||
|
case RANGESTRAT_AFTER: |
||||||
|
if (empty1 || empty2) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_AFTER; |
||||||
|
break; |
||||||
|
case RANGESTRAT_OVERLEFT: |
||||||
|
if (empty1 || empty2) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_OVERLEFT; |
||||||
|
break; |
||||||
|
case RANGESTRAT_OVERRIGHT: |
||||||
|
if (empty1 || empty2) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_OVERRIGHT; |
||||||
|
break; |
||||||
|
case RANGESTRAT_ADJACENT: |
||||||
|
if (empty1 || empty2) |
||||||
|
return false; |
||||||
|
proc = F_RANGE_ADJACENT; |
||||||
|
break; |
||||||
|
} |
||||||
|
|
||||||
|
return DatumGetBool(OidFunctionCall2(proc, RangeTypeGetDatum(key), |
||||||
|
RangeTypeGetDatum(query))); |
||||||
|
} |
||||||
|
|
||||||
|
/*
|
||||||
|
* Compare function for PickSplitSortItem. This is actually the |
||||||
|
* interesting part of the picksplit algorithm. |
||||||
|
* |
||||||
|
* We want to separate out empty ranges, bounded ranges, and unbounded |
||||||
|
* ranges. We assume that "contains" and "overlaps" are the most |
||||||
|
* important queries, so empty ranges will rarely match and unbounded |
||||||
|
* ranges frequently will. Bounded ranges should be in the middle. |
||||||
|
* |
||||||
|
* Empty ranges we push all the way to the left, then bounded ranges |
||||||
|
* (sorted on lower bound, then upper), then ranges with no lower |
||||||
|
* bound, then ranges with no upper bound; and finally, ranges with no |
||||||
|
* upper or lower bound all the way to the right. |
||||||
|
*/ |
||||||
|
static int |
||||||
|
sort_item_cmp(const void *a, const void *b) |
||||||
|
{ |
||||||
|
PickSplitSortItem *i1 = (PickSplitSortItem *)a; |
||||||
|
PickSplitSortItem *i2 = (PickSplitSortItem *)b; |
||||||
|
RangeType *r1 = i1->data; |
||||||
|
RangeType *r2 = i2->data; |
||||||
|
|
||||||
|
RangeBound lower1, lower2; |
||||||
|
RangeBound upper1, upper2; |
||||||
|
bool empty1, empty2; |
||||||
|
|
||||||
|
FunctionCallInfo fcinfo = i1->fcinfo; |
||||||
|
|
||||||
|
int cmp; |
||||||
|
|
||||||
|
range_deserialize(fcinfo, r1, &lower1, &upper1, &empty1); |
||||||
|
range_deserialize(fcinfo, r2, &lower2, &upper2, &empty2); |
||||||
|
|
||||||
|
if (empty1 || empty2) |
||||||
|
{ |
||||||
|
if (empty1 && empty2) |
||||||
|
return 0; |
||||||
|
else if (empty1) |
||||||
|
return -1; |
||||||
|
else if (empty2) |
||||||
|
return 1; |
||||||
|
else |
||||||
|
Assert(false); |
||||||
|
} |
||||||
|
|
||||||
|
/*
|
||||||
|
* If both lower or both upper bounds are infinite, we sort by |
||||||
|
* ascending range size. That means that if both upper bounds are |
||||||
|
* infinite, we sort by the lower bound _descending_. That creates |
||||||
|
* a slightly odd total order, but keeps the pages with very |
||||||
|
* unselective predicates grouped more closely together on the |
||||||
|
* right. |
||||||
|
*/ |
||||||
|
if (lower1.infinite || upper1.infinite || |
||||||
|
lower2.infinite || upper2.infinite) |
||||||
|
{ |
||||||
|
if (lower1.infinite && lower2.infinite) |
||||||
|
return range_cmp_bounds(fcinfo, &upper1, &upper2); |
||||||
|
else if (lower1.infinite) |
||||||
|
return -1; |
||||||
|
else if (lower2.infinite) |
||||||
|
return 1; |
||||||
|
else if (upper1.infinite && upper2.infinite) |
||||||
|
return -1 * range_cmp_bounds(fcinfo, &lower1, &lower2); |
||||||
|
else if (upper1.infinite) |
||||||
|
return 1; |
||||||
|
else if (upper2.infinite) |
||||||
|
return -1; |
||||||
|
else |
||||||
|
Assert(false); |
||||||
|
} |
||||||
|
|
||||||
|
if ((cmp = range_cmp_bounds(fcinfo, &lower1, &lower2)) != 0) |
||||||
|
return cmp; |
||||||
|
|
||||||
|
return range_cmp_bounds(fcinfo, &upper1, &upper2); |
||||||
|
} |
||||||
@ -0,0 +1,84 @@ |
|||||||
|
/*-------------------------------------------------------------------------
|
||||||
|
* |
||||||
|
* pg_range.h |
||||||
|
* definition of the system "range" relation (pg_range) |
||||||
|
* along with the relation's initial contents. |
||||||
|
* |
||||||
|
* |
||||||
|
* Copyright (c) 2006-2010, PostgreSQL Global Development Group |
||||||
|
* |
||||||
|
* src/include/catalog/pg_range.h |
||||||
|
* |
||||||
|
* NOTES |
||||||
|
* the genbki.pl script reads this file and generates .bki |
||||||
|
* information from the DATA() statements. |
||||||
|
* |
||||||
|
* XXX do NOT break up DATA() statements into multiple lines! |
||||||
|
* the scripts are not as smart as you might think... |
||||||
|
* |
||||||
|
*------------------------------------------------------------------------- |
||||||
|
*/ |
||||||
|
#ifndef PG_RANGE_H |
||||||
|
#define PG_RANGE_H |
||||||
|
|
||||||
|
#include "catalog/genbki.h" |
||||||
|
|
||||||
|
/* ----------------
|
||||||
|
* pg_range definition. cpp turns this into |
||||||
|
* typedef struct FormData_pg_range |
||||||
|
* ---------------- |
||||||
|
*/ |
||||||
|
#define RangeRelationId 3541 |
||||||
|
|
||||||
|
CATALOG(pg_range,3541) BKI_WITHOUT_OIDS |
||||||
|
{ |
||||||
|
Oid rngtypid; /* OID of owning range type */ |
||||||
|
Oid rngsubtype; /* OID of range's subtype */ |
||||||
|
Oid rngcollation; /* collation for this range type, or 0 */ |
||||||
|
Oid rngsubopc; /* subtype's btree opclass */ |
||||||
|
regproc rngcanonical; /* canonicalize range, or 0 */ |
||||||
|
regproc rngsubdiff; /* subtype difference as a float8 (for GiST) */ |
||||||
|
} FormData_pg_range; |
||||||
|
|
||||||
|
/* ----------------
|
||||||
|
* Form_pg_range corresponds to a pointer to a tuple with |
||||||
|
* the format of pg_range relation. |
||||||
|
* ---------------- |
||||||
|
*/ |
||||||
|
typedef FormData_pg_range *Form_pg_range; |
||||||
|
|
||||||
|
/* ----------------
|
||||||
|
* compiler constants for pg_range |
||||||
|
* ---------------- |
||||||
|
*/ |
||||||
|
#define Natts_pg_range 6 |
||||||
|
#define Anum_pg_range_rngtypid 1 |
||||||
|
#define Anum_pg_range_rngsubtype 2 |
||||||
|
#define Anum_pg_range_rngcollation 3 |
||||||
|
#define Anum_pg_range_rngsubopc 4 |
||||||
|
#define Anum_pg_range_rngcanonical 5 |
||||||
|
#define Anum_pg_range_rngsubdiff 6 |
||||||
|
|
||||||
|
#define RANGE_DEFAULT_FLAGS "[)" |
||||||
|
|
||||||
|
/*
|
||||||
|
* prototypes for functions in pg_range.c |
||||||
|
*/ |
||||||
|
|
||||||
|
extern void RangeCreate(Oid rangeTypeOid, Oid rangeSubType, Oid rangeCollation, |
||||||
|
Oid rangeSubOpclass, RegProcedure rangeCanonical, |
||||||
|
RegProcedure rangeSubDiff); |
||||||
|
extern void RangeDelete(Oid rangeTypeOid); |
||||||
|
|
||||||
|
/* ----------------
|
||||||
|
* initial contents of pg_range |
||||||
|
* ---------------- |
||||||
|
*/ |
||||||
|
DATA(insert ( 3904 23 0 1978 int4range_canonical int4range_subdiff)); |
||||||
|
DATA(insert ( 3906 1700 0 10037 - numrange_subdiff)); |
||||||
|
DATA(insert ( 3908 1114 0 10054 - tsrange_subdiff)); |
||||||
|
DATA(insert ( 3910 1184 0 10047 - tstzrange_subdiff)); |
||||||
|
DATA(insert ( 3912 1082 0 10019 daterange_canonical daterange_subdiff)); |
||||||
|
DATA(insert ( 3926 20 0 10029 int8range_canonical int8range_subdiff)); |
||||||
|
|
||||||
|
#endif /* PG_RANGE_H */ |
||||||
@ -0,0 +1,159 @@ |
|||||||
|
/*-------------------------------------------------------------------------
|
||||||
|
* |
||||||
|
* rangetypes.h |
||||||
|
* Declarations for Postgres range types. |
||||||
|
* |
||||||
|
*/ |
||||||
|
|
||||||
|
#ifndef RANGETYPES_H |
||||||
|
#define RANGETYPES_H |
||||||
|
|
||||||
|
#include "fmgr.h" |
||||||
|
|
||||||
|
typedef struct varlena RangeType; |
||||||
|
|
||||||
|
typedef struct |
||||||
|
{ |
||||||
|
Datum val; |
||||||
|
Oid rngtypid; |
||||||
|
bool infinite; |
||||||
|
bool lower; |
||||||
|
bool inclusive; |
||||||
|
} RangeBound; |
||||||
|
|
||||||
|
typedef struct |
||||||
|
{ |
||||||
|
FmgrInfo canonicalFn; |
||||||
|
FmgrInfo cmpFn; |
||||||
|
FmgrInfo subdiffFn; |
||||||
|
Oid rngtypid; |
||||||
|
Oid subtype; |
||||||
|
Oid collation; |
||||||
|
int16 subtyplen; |
||||||
|
char subtypalign; |
||||||
|
char subtypstorage; |
||||||
|
bool subtypbyval; |
||||||
|
} RangeTypeInfo; |
||||||
|
|
||||||
|
/*
|
||||||
|
* fmgr macros for range type objects |
||||||
|
*/ |
||||||
|
#define DatumGetRangeType(X) ((RangeType *) PG_DETOAST_DATUM(X)) |
||||||
|
#define DatumGetRangeTypeCopy(X) ((RangeType *) PG_DETOAST_DATUM_COPY(X)) |
||||||
|
#define RangeTypeGetDatum(X) PointerGetDatum(X) |
||||||
|
#define PG_GETARG_RANGE(n) DatumGetRangeType(PG_GETARG_DATUM(n)) |
||||||
|
#define PG_GETARG_RANGE_COPY(n) DatumGetRangeTypeCopy(PG_GETARG_DATUM(n)) |
||||||
|
#define PG_RETURN_RANGE(x) return RangeTypeGetDatum(x) |
||||||
|
|
||||||
|
/*
|
||||||
|
* prototypes for functions defined in rangetypes.c |
||||||
|
*/ |
||||||
|
|
||||||
|
/* IO */ |
||||||
|
extern Datum anyrange_in(PG_FUNCTION_ARGS); |
||||||
|
extern Datum anyrange_out(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_in(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_out(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_recv(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_send(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* constructors */ |
||||||
|
extern Datum range_constructor0(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_constructor1(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_constructor2(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_constructor3(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_make1(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_linf_(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_uinf_(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_linfi(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_uinfi(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range__(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_i(PG_FUNCTION_ARGS); |
||||||
|
extern Datum rangei_(PG_FUNCTION_ARGS); |
||||||
|
extern Datum rangeii(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* range -> subtype */ |
||||||
|
extern Datum range_lower(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_upper(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* range -> bool */ |
||||||
|
extern Datum range_empty(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_lower_inc(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_upper_inc(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_lower_inf(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_upper_inf(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* range, point -> bool */ |
||||||
|
extern Datum range_contains_elem(PG_FUNCTION_ARGS); |
||||||
|
extern Datum elem_contained_by_range(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* range, range -> bool */ |
||||||
|
extern Datum range_eq(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_ne(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_contains(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_contained_by(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_before(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_after(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_adjacent(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_overlaps(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_overleft(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_overright(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* range, range -> range */ |
||||||
|
extern Datum range_minus(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_union(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_intersect(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* BTree support */ |
||||||
|
extern Datum range_cmp(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_lt(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_le(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_ge(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_gt(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* Hash support */ |
||||||
|
extern Datum hash_range(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* GiST support (rangetypes_gist.c) */ |
||||||
|
extern Datum range_gist_consistent(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_gist_compress(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_gist_decompress(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_gist_union(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_gist_penalty(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_gist_picksplit(PG_FUNCTION_ARGS); |
||||||
|
extern Datum range_gist_same(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* Canonical functions */ |
||||||
|
Datum int4range_canonical(PG_FUNCTION_ARGS); |
||||||
|
Datum int8range_canonical(PG_FUNCTION_ARGS); |
||||||
|
Datum daterange_canonical(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* Subtype Difference functions */ |
||||||
|
Datum int4range_subdiff(PG_FUNCTION_ARGS); |
||||||
|
Datum int8range_subdiff(PG_FUNCTION_ARGS); |
||||||
|
Datum numrange_subdiff(PG_FUNCTION_ARGS); |
||||||
|
Datum daterange_subdiff(PG_FUNCTION_ARGS); |
||||||
|
Datum tsrange_subdiff(PG_FUNCTION_ARGS); |
||||||
|
Datum tstzrange_subdiff(PG_FUNCTION_ARGS); |
||||||
|
|
||||||
|
/* for defining more generic functions */ |
||||||
|
extern Datum make_range(FunctionCallInfo fcinfo, RangeBound *lower, |
||||||
|
RangeBound *upper, bool empty); |
||||||
|
extern void range_deserialize(FunctionCallInfo fcinfo, RangeType *range, |
||||||
|
RangeBound *lower, RangeBound *upper, |
||||||
|
bool *empty); |
||||||
|
extern int range_cmp_bounds(FunctionCallInfo fcinfo, RangeBound *b1, |
||||||
|
RangeBound *b2); |
||||||
|
extern RangeType *make_empty_range(FunctionCallInfo fcinfo, Oid rngtypid); |
||||||
|
extern void range_gettypinfo(FunctionCallInfo fcinfo, Oid rngtypid, |
||||||
|
RangeTypeInfo *rngtypinfo); |
||||||
|
|
||||||
|
/* for defining a range "canonicalize" function */ |
||||||
|
extern Datum range_serialize(FunctionCallInfo fcinfo, RangeBound *lower, |
||||||
|
RangeBound *upper, bool empty); |
||||||
|
|
||||||
|
/* for use in DefineRange */ |
||||||
|
extern char range_parse_flags(char *flags_str); |
||||||
|
|
||||||
|
#endif /* RANGETYPES_H */ |
||||||
@ -0,0 +1,951 @@ |
|||||||
|
-- |
||||||
|
-- test parser |
||||||
|
-- |
||||||
|
create type textrange as range (subtype=text, collation="C"); |
||||||
|
-- negative tests; should fail |
||||||
|
select ''::textrange; |
||||||
|
ERROR: malformed range literal: "" |
||||||
|
LINE 1: select ''::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Missing left parenthesis or bracket. |
||||||
|
select '-[a,z)'::textrange; |
||||||
|
ERROR: malformed range literal: "-[a,z)" |
||||||
|
LINE 1: select '-[a,z)'::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Missing left parenthesis or bracket. |
||||||
|
select '[a,z) - '::textrange; |
||||||
|
ERROR: malformed range literal: "[a,z) - " |
||||||
|
LINE 1: select '[a,z) - '::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Junk after right parenthesis or bracket. |
||||||
|
select '(",a)'::textrange; |
||||||
|
ERROR: malformed range literal: "(",a)" |
||||||
|
LINE 1: select '(",a)'::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Unexpected end of input. |
||||||
|
select '(,,a)'::textrange; |
||||||
|
ERROR: malformed range literal: "(,,a)" |
||||||
|
LINE 1: select '(,,a)'::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Too many boundaries. |
||||||
|
select '(),a)'::textrange; |
||||||
|
ERROR: malformed range literal: "(),a)" |
||||||
|
LINE 1: select '(),a)'::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Missing upper bound. |
||||||
|
select '(a,))'::textrange; |
||||||
|
ERROR: malformed range literal: "(a,))" |
||||||
|
LINE 1: select '(a,))'::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Junk after right parenthesis or bracket. |
||||||
|
select '(],a)'::textrange; |
||||||
|
ERROR: malformed range literal: "(],a)" |
||||||
|
LINE 1: select '(],a)'::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Missing upper bound. |
||||||
|
select '(a,])'::textrange; |
||||||
|
ERROR: malformed range literal: "(a,])" |
||||||
|
LINE 1: select '(a,])'::textrange; |
||||||
|
^ |
||||||
|
DETAIL: Junk after right parenthesis or bracket. |
||||||
|
-- should succeed |
||||||
|
select ' empty '::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
empty |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select ' ( empty, empty ) '::textrange; |
||||||
|
textrange |
||||||
|
---------------------- |
||||||
|
(" empty"," empty ") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select ' ( " a " " a ", " z " " z " ) '::textrange; |
||||||
|
textrange |
||||||
|
-------------------------- |
||||||
|
(" a a "," z z ") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '(,z)'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
(,z) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '(a,)'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
(a,) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '[,z]'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
(,z] |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '[a,]'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
[a,) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '( , )'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
(" "," ") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '("","")'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
("","") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '["",""]'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
["",""] |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '(",",",")'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
(",",",") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '("\\","\\")'::textrange |
||||||
|
select '(\\,a)'::textrange; |
||||||
|
ERROR: syntax error at or near "select" |
||||||
|
LINE 2: select '(\\,a)'::textrange; |
||||||
|
^ |
||||||
|
select '((,z)'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
("(",z) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '([,z)'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
("[",z) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '(!,()'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
(!,"(") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '(!,[)'::textrange; |
||||||
|
textrange |
||||||
|
----------- |
||||||
|
(!,"[") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
drop type textrange; |
||||||
|
-- |
||||||
|
-- create some test data and test the operators |
||||||
|
-- |
||||||
|
CREATE TABLE numrange_test (nr NUMRANGE); |
||||||
|
create index numrange_test_btree on numrange_test(nr); |
||||||
|
SET enable_seqscan = f; |
||||||
|
INSERT INTO numrange_test VALUES('[,)'); |
||||||
|
INSERT INTO numrange_test VALUES('[3,]'); |
||||||
|
INSERT INTO numrange_test VALUES('[, 5)'); |
||||||
|
INSERT INTO numrange_test VALUES(numrange(1.1, 2.2)); |
||||||
|
INSERT INTO numrange_test VALUES('empty'); |
||||||
|
INSERT INTO numrange_test VALUES(numrange(1.7)); |
||||||
|
SELECT isempty(nr) FROM numrange_test; |
||||||
|
isempty |
||||||
|
--------- |
||||||
|
f |
||||||
|
f |
||||||
|
f |
||||||
|
f |
||||||
|
t |
||||||
|
f |
||||||
|
(6 rows) |
||||||
|
|
||||||
|
SELECT lower_inc(nr), lower(nr), upper(nr), upper_inc(nr) FROM numrange_test |
||||||
|
WHERE NOT isempty(nr) AND NOT lower_inf(nr) AND NOT upper_inf(nr); |
||||||
|
lower_inc | lower | upper | upper_inc |
||||||
|
-----------+-------+-------+----------- |
||||||
|
t | 1.1 | 2.2 | f |
||||||
|
t | 1.7 | 1.7 | t |
||||||
|
(2 rows) |
||||||
|
|
||||||
|
SELECT * FROM numrange_test WHERE contains(nr, numrange(1.9,1.91)); |
||||||
|
nr |
||||||
|
----------- |
||||||
|
(,) |
||||||
|
(,5) |
||||||
|
[1.1,2.2) |
||||||
|
(3 rows) |
||||||
|
|
||||||
|
SELECT * FROM numrange_test WHERE nr @> numrange(1.0,10000.1); |
||||||
|
nr |
||||||
|
----- |
||||||
|
(,) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
SELECT * FROM numrange_test WHERE contained_by(numrange(-1e7,-10000.1), nr); |
||||||
|
nr |
||||||
|
------ |
||||||
|
(,) |
||||||
|
(,5) |
||||||
|
(2 rows) |
||||||
|
|
||||||
|
SELECT * FROM numrange_test WHERE 1.9 <@ nr; |
||||||
|
nr |
||||||
|
----------- |
||||||
|
(,) |
||||||
|
(,5) |
||||||
|
[1.1,2.2) |
||||||
|
(3 rows) |
||||||
|
|
||||||
|
SELECT * FROM numrange_test WHERE nr = 'empty'; |
||||||
|
nr |
||||||
|
------- |
||||||
|
empty |
||||||
|
(1 row) |
||||||
|
|
||||||
|
SELECT * FROM numrange_test WHERE range_eq(nr, '(1.1, 2.2)'); |
||||||
|
nr |
||||||
|
---- |
||||||
|
(0 rows) |
||||||
|
|
||||||
|
SELECT * FROM numrange_test WHERE nr = '[1.1, 2.2)'; |
||||||
|
nr |
||||||
|
----------- |
||||||
|
[1.1,2.2) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(2.0, 1.0); |
||||||
|
ERROR: range lower bound must be less than or equal to range upper bound |
||||||
|
select numrange(2.0, 3.0) -|- numrange(3.0, 4.0); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select adjacent(numrange(2.0, 3.0), numrange(3.1, 4.0)); |
||||||
|
adjacent |
||||||
|
---------- |
||||||
|
f |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(2.0, 3.0, '[]') -|- numrange(3.0, 4.0, '()'); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) -|- numrange(2.0, 3.0,'[]'); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select adjacent(numrange(2.0, 3.0, '(]'), numrange(1.0, 2.0, '(]')); |
||||||
|
adjacent |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.1, 3.3) <@ numrange(0.1,10.1); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(0.1, 10.1) <@ numrange(1.1,3.3); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
f |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.1, 2.2) - numrange(2.0, 3.0); |
||||||
|
?column? |
||||||
|
----------- |
||||||
|
[1.1,2.0) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.1, 2.2) - numrange(2.2, 3.0); |
||||||
|
?column? |
||||||
|
----------- |
||||||
|
[1.1,2.2) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.1, 2.2,'[]') - numrange(2.0, 3.0); |
||||||
|
?column? |
||||||
|
----------- |
||||||
|
[1.1,2.0) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select minus(numrange(10.1,12.2,'[]'), numrange(110.0,120.2,'(]')); |
||||||
|
minus |
||||||
|
------------- |
||||||
|
[10.1,12.2] |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select minus(numrange(10.1,12.2,'[]'), numrange(0.0,120.2,'(]')); |
||||||
|
minus |
||||||
|
------- |
||||||
|
empty |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(4.5, 5.5, '[]') && numrange(5.5, 6.5); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) << numrange(3.0, 4.0); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) >> numrange(3.0, 4.0); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
f |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(3.0, 70.0) &< numrange(6.6, 100.0); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.1, 2.2) < numrange(1.0, 200.2); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
f |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.1, 2.2) < numrange(1.1, 1.2); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
f |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) + numrange(2.0, 3.0); |
||||||
|
?column? |
||||||
|
----------- |
||||||
|
[1.0,3.0) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) + numrange(1.5, 3.0); |
||||||
|
?column? |
||||||
|
----------- |
||||||
|
[1.0,3.0) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) + numrange(2.5, 3.0); |
||||||
|
ERROR: result range is not contiguous |
||||||
|
select numrange(1.0, 2.0) * numrange(2.0, 3.0); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
empty |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) * numrange(1.5, 3.0); |
||||||
|
?column? |
||||||
|
----------- |
||||||
|
[1.5,2.0) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) * numrange(2.5, 3.0); |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
empty |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from numrange_test where nr < numrange(-1000.0, -1000.0,'[]'); |
||||||
|
nr |
||||||
|
------- |
||||||
|
(,) |
||||||
|
(,5) |
||||||
|
empty |
||||||
|
(3 rows) |
||||||
|
|
||||||
|
select * from numrange_test where nr < numrange(0.0, 1.0,'[]'); |
||||||
|
nr |
||||||
|
------- |
||||||
|
(,) |
||||||
|
(,5) |
||||||
|
empty |
||||||
|
(3 rows) |
||||||
|
|
||||||
|
select * from numrange_test where nr < numrange(1000.0, 1001.0,'[]'); |
||||||
|
nr |
||||||
|
----------- |
||||||
|
(,) |
||||||
|
[3,) |
||||||
|
(,5) |
||||||
|
[1.1,2.2) |
||||||
|
empty |
||||||
|
[1.7,1.7] |
||||||
|
(6 rows) |
||||||
|
|
||||||
|
select * from numrange_test where nr > numrange(-1001.0, -1000.0,'[]'); |
||||||
|
nr |
||||||
|
----------- |
||||||
|
[3,) |
||||||
|
[1.1,2.2) |
||||||
|
[1.7,1.7] |
||||||
|
(3 rows) |
||||||
|
|
||||||
|
select * from numrange_test where nr > numrange(0.0, 1.0,'[]'); |
||||||
|
nr |
||||||
|
----------- |
||||||
|
[3,) |
||||||
|
[1.1,2.2) |
||||||
|
[1.7,1.7] |
||||||
|
(3 rows) |
||||||
|
|
||||||
|
select * from numrange_test where nr > numrange(1000.0, 1000.0,'[]'); |
||||||
|
nr |
||||||
|
---- |
||||||
|
(0 rows) |
||||||
|
|
||||||
|
create table numrange_test2(nr numrange); |
||||||
|
create index numrange_test2_hash_idx on numrange_test2 (nr); |
||||||
|
INSERT INTO numrange_test2 VALUES('[, 5)'); |
||||||
|
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2)); |
||||||
|
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2)); |
||||||
|
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2,'()')); |
||||||
|
INSERT INTO numrange_test2 VALUES('empty'); |
||||||
|
select * from numrange_test2 where nr = 'empty'::numrange; |
||||||
|
nr |
||||||
|
------- |
||||||
|
empty |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select * from numrange_test2 where nr = numrange(1.1, 2.2); |
||||||
|
nr |
||||||
|
----------- |
||||||
|
[1.1,2.2) |
||||||
|
[1.1,2.2) |
||||||
|
(2 rows) |
||||||
|
|
||||||
|
select * from numrange_test2 where nr = numrange(1.1, 2.3); |
||||||
|
nr |
||||||
|
---- |
||||||
|
(0 rows) |
||||||
|
|
||||||
|
set enable_nestloop=t; |
||||||
|
set enable_hashjoin=f; |
||||||
|
set enable_mergejoin=f; |
||||||
|
select * from numrange_test natural join numrange_test2 order by nr; |
||||||
|
nr |
||||||
|
----------- |
||||||
|
empty |
||||||
|
(,5) |
||||||
|
[1.1,2.2) |
||||||
|
[1.1,2.2) |
||||||
|
(4 rows) |
||||||
|
|
||||||
|
set enable_nestloop=f; |
||||||
|
set enable_hashjoin=t; |
||||||
|
set enable_mergejoin=f; |
||||||
|
select * from numrange_test natural join numrange_test2 order by nr; |
||||||
|
nr |
||||||
|
----------- |
||||||
|
empty |
||||||
|
(,5) |
||||||
|
[1.1,2.2) |
||||||
|
[1.1,2.2) |
||||||
|
(4 rows) |
||||||
|
|
||||||
|
set enable_nestloop=f; |
||||||
|
set enable_hashjoin=f; |
||||||
|
set enable_mergejoin=t; |
||||||
|
select * from numrange_test natural join numrange_test2 order by nr; |
||||||
|
nr |
||||||
|
----------- |
||||||
|
empty |
||||||
|
(,5) |
||||||
|
[1.1,2.2) |
||||||
|
[1.1,2.2) |
||||||
|
(4 rows) |
||||||
|
|
||||||
|
set enable_nestloop to default; |
||||||
|
set enable_hashjoin to default; |
||||||
|
set enable_mergejoin to default; |
||||||
|
SET enable_seqscan TO DEFAULT; |
||||||
|
DROP TABLE numrange_test; |
||||||
|
DROP TABLE numrange_test2; |
||||||
|
-- test canonical form for int4range |
||||||
|
select int4range(1,10,'[]'); |
||||||
|
int4range |
||||||
|
----------- |
||||||
|
[1,11) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select int4range(1,10,'[)'); |
||||||
|
int4range |
||||||
|
----------- |
||||||
|
[1,10) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select int4range(1,10,'(]'); |
||||||
|
int4range |
||||||
|
----------- |
||||||
|
[2,11) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select int4range(1,10,'[]'); |
||||||
|
int4range |
||||||
|
----------- |
||||||
|
[1,11) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- test canonical form for daterange |
||||||
|
select daterange('2000-01-10'::date, '2000-01-20'::date,'[]'); |
||||||
|
daterange |
||||||
|
------------------------- |
||||||
|
[01-10-2000,01-21-2000) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select daterange('2000-01-10'::date, '2000-01-20'::date,'[)'); |
||||||
|
daterange |
||||||
|
------------------------- |
||||||
|
[01-10-2000,01-20-2000) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select daterange('2000-01-10'::date, '2000-01-20'::date,'(]'); |
||||||
|
daterange |
||||||
|
------------------------- |
||||||
|
[01-11-2000,01-21-2000) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select daterange('2000-01-10'::date, '2000-01-20'::date,'[]'); |
||||||
|
daterange |
||||||
|
------------------------- |
||||||
|
[01-10-2000,01-21-2000) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
create table test_range_gist(ir int4range); |
||||||
|
create index test_range_gist_idx on test_range_gist using gist (ir); |
||||||
|
insert into test_range_gist select int4range(g, g+10) from generate_series(1,2000) g; |
||||||
|
insert into test_range_gist select 'empty'::int4range from generate_series(1,500) g; |
||||||
|
insert into test_range_gist select int4range(g, g+10000) from generate_series(1,1000) g; |
||||||
|
insert into test_range_gist select 'empty'::int4range from generate_series(1,500) g; |
||||||
|
insert into test_range_gist select int4range(NULL,g*10,'(]') from generate_series(1,100) g; |
||||||
|
insert into test_range_gist select int4range(g*10,NULL,'(]') from generate_series(1,100) g; |
||||||
|
insert into test_range_gist select int4range(g, g+10) from generate_series(1,2000) g; |
||||||
|
BEGIN; |
||||||
|
SET LOCAL enable_seqscan = t; |
||||||
|
SET LOCAL enable_bitmapscan = f; |
||||||
|
SET LOCAL enable_indexscan = f; |
||||||
|
select count(*) from test_range_gist where ir @> 'empty'::int4range; |
||||||
|
count |
||||||
|
------- |
||||||
|
6200 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir = int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
2 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> 10; |
||||||
|
count |
||||||
|
------- |
||||||
|
130 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
111 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir && int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
158 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir <@ int4range(10,50); |
||||||
|
count |
||||||
|
------- |
||||||
|
1062 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir << int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
189 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir >> int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
3554 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir &< int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
1029 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir &> int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
4794 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir -|- int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
5 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
COMMIT; |
||||||
|
BEGIN; |
||||||
|
SET LOCAL enable_seqscan = f; |
||||||
|
SET LOCAL enable_bitmapscan = f; |
||||||
|
SET LOCAL enable_indexscan = t; |
||||||
|
select count(*) from test_range_gist where ir @> 'empty'::int4range; |
||||||
|
count |
||||||
|
------- |
||||||
|
6200 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir = int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
2 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> 10; |
||||||
|
count |
||||||
|
------- |
||||||
|
130 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
111 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir && int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
158 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir <@ int4range(10,50); |
||||||
|
count |
||||||
|
------- |
||||||
|
1062 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir << int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
189 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir >> int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
3554 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir &< int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
1029 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir &> int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
4794 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir -|- int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
5 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
COMMIT; |
||||||
|
drop index test_range_gist_idx; |
||||||
|
create index test_range_gist_idx on test_range_gist using gist (ir); |
||||||
|
BEGIN; |
||||||
|
SET LOCAL enable_seqscan = f; |
||||||
|
SET LOCAL enable_bitmapscan = f; |
||||||
|
SET LOCAL enable_indexscan = t; |
||||||
|
select count(*) from test_range_gist where ir @> 'empty'::int4range; |
||||||
|
count |
||||||
|
------- |
||||||
|
6200 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir = int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
2 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> 10; |
||||||
|
count |
||||||
|
------- |
||||||
|
130 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
111 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir && int4range(10,20); |
||||||
|
count |
||||||
|
------- |
||||||
|
158 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir <@ int4range(10,50); |
||||||
|
count |
||||||
|
------- |
||||||
|
1062 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir << int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
189 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir >> int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
3554 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir &< int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
1029 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir &> int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
4794 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir -|- int4range(100,500); |
||||||
|
count |
||||||
|
------- |
||||||
|
5 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
COMMIT; |
||||||
|
drop table test_range_gist; |
||||||
|
-- |
||||||
|
-- Btree_gist is not included by default, so to test exclusion |
||||||
|
-- constraints with range types, use singleton int ranges for the "=" |
||||||
|
-- portion of the constraint. |
||||||
|
-- |
||||||
|
create table test_range_excl( |
||||||
|
room int4range, |
||||||
|
speaker int4range, |
||||||
|
during tsrange, |
||||||
|
exclude using gist (room with =, during with &&), |
||||||
|
exclude using gist (speaker with =, during with &&) |
||||||
|
); |
||||||
|
NOTICE: CREATE TABLE / EXCLUDE will create implicit index "test_range_excl_room_during_excl" for table "test_range_excl" |
||||||
|
NOTICE: CREATE TABLE / EXCLUDE will create implicit index "test_range_excl_speaker_during_excl" for table "test_range_excl" |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(123), int4range(1), '[2010-01-02 10:00, 2010-01-02 11:00)'); |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(123), int4range(2), '[2010-01-02 11:00, 2010-01-02 12:00)'); |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(123), int4range(3), '[2010-01-02 10:10, 2010-01-02 11:10)'); |
||||||
|
ERROR: conflicting key value violates exclusion constraint "test_range_excl_room_during_excl" |
||||||
|
DETAIL: Key (room, during)=([123,124), ["Sat Jan 02 10:10:00 2010","Sat Jan 02 11:10:00 2010")) conflicts with existing key (room, during)=([123,124), ["Sat Jan 02 10:00:00 2010","Sat Jan 02 11:00:00 2010")). |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(124), int4range(3), '[2010-01-02 10:10, 2010-01-02 11:10)'); |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(125), int4range(1), '[2010-01-02 10:10, 2010-01-02 11:10)'); |
||||||
|
ERROR: conflicting key value violates exclusion constraint "test_range_excl_speaker_during_excl" |
||||||
|
DETAIL: Key (speaker, during)=([1,2), ["Sat Jan 02 10:10:00 2010","Sat Jan 02 11:10:00 2010")) conflicts with existing key (speaker, during)=([1,2), ["Sat Jan 02 10:00:00 2010","Sat Jan 02 11:00:00 2010")). |
||||||
|
drop table test_range_excl; |
||||||
|
-- test bigint ranges |
||||||
|
select int8range(10000000000::int8, 20000000000::int8,'(]'); |
||||||
|
int8range |
||||||
|
--------------------------- |
||||||
|
[10000000001,20000000001) |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- test tstz ranges |
||||||
|
set timezone to '-08'; |
||||||
|
select '[2010-01-01 01:00:00 -05, 2010-01-01 02:00:00 -08)'::tstzrange; |
||||||
|
tstzrange |
||||||
|
----------------------------------------------------------------- |
||||||
|
["Thu Dec 31 22:00:00 2009 -08","Fri Jan 01 02:00:00 2010 -08") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- should fail |
||||||
|
select '[2010-01-01 01:00:00 -08, 2010-01-01 02:00:00 -05)'::tstzrange; |
||||||
|
ERROR: range lower bound must be less than or equal to range upper bound |
||||||
|
LINE 1: select '[2010-01-01 01:00:00 -08, 2010-01-01 02:00:00 -05)':... |
||||||
|
^ |
||||||
|
set timezone to default; |
||||||
|
-- |
||||||
|
-- Test user-defined range of floats |
||||||
|
-- |
||||||
|
--should fail |
||||||
|
create type float8range as range (subtype=float8, subtype_diff=float4mi); |
||||||
|
ERROR: function float4mi(double precision, double precision) does not exist |
||||||
|
--should succeed |
||||||
|
create type float8range as range (subtype=float8, subtype_diff=float8mi); |
||||||
|
select '[123.001, 5.e9)'::float8range @> 888.882::float8; |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
create table float8range_test(f8r float8range, i int); |
||||||
|
insert into float8range_test values(float8range(-100.00007, '1.111113e9')); |
||||||
|
select * from float8range_test; |
||||||
|
f8r | i |
||||||
|
-------------------------+--- |
||||||
|
[-100.00007,1111113000) | |
||||||
|
(1 row) |
||||||
|
|
||||||
|
drop table float8range_test; |
||||||
|
drop type float8range; |
||||||
|
-- |
||||||
|
-- Test range types over domains |
||||||
|
-- |
||||||
|
create domain mydomain as int4; |
||||||
|
create type mydomainrange as range(subtype=mydomain); |
||||||
|
select '[4,50)'::mydomainrange @> 7::mydomain; |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
drop type mydomainrange; |
||||||
|
drop domain mydomain; |
||||||
|
-- |
||||||
|
-- Test domains over range types |
||||||
|
-- |
||||||
|
create domain restrictedrange as int4range check (upper(value) < 10); |
||||||
|
select '[4,5)'::restrictedrange @> 7; |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
f |
||||||
|
(1 row) |
||||||
|
|
||||||
|
select '[4,50)'::restrictedrange @> 7; -- should fail |
||||||
|
ERROR: value for domain restrictedrange violates check constraint "restrictedrange_check" |
||||||
|
drop domain restrictedrange; |
||||||
|
-- |
||||||
|
-- Test multiple range types over the same subtype |
||||||
|
-- |
||||||
|
create type textrange1 as range(subtype=text, collation="C"); |
||||||
|
create type textrange2 as range(subtype=text, collation="C"); |
||||||
|
select textrange1('a','Z') @> 'b'::text; |
||||||
|
ERROR: range lower bound must be less than or equal to range upper bound |
||||||
|
select textrange2('a','z') @> 'b'::text; |
||||||
|
?column? |
||||||
|
---------- |
||||||
|
t |
||||||
|
(1 row) |
||||||
|
|
||||||
|
drop type textrange1; |
||||||
|
drop type textrange2; |
||||||
|
-- |
||||||
|
-- Test out polymorphic type system |
||||||
|
-- |
||||||
|
create function anyarray_anyrange_func(a anyarray, r anyrange) |
||||||
|
returns anyelement as 'select $1[1] + lower($2);' language sql; |
||||||
|
select anyarray_anyrange_func(ARRAY[1,2], int4range(10,20)); |
||||||
|
anyarray_anyrange_func |
||||||
|
------------------------ |
||||||
|
11 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- should fail |
||||||
|
select anyarray_anyrange_func(ARRAY[1,2], numrange(10,20)); |
||||||
|
ERROR: function anyarray_anyrange_func(integer[], numrange) does not exist |
||||||
|
LINE 1: select anyarray_anyrange_func(ARRAY[1,2], numrange(10,20)); |
||||||
|
^ |
||||||
|
HINT: No function matches the given name and argument types. You might need to add explicit type casts. |
||||||
|
drop function anyarray_anyrange_func(anyarray, anyrange); |
||||||
|
-- should fail |
||||||
|
create function bogus_func(anyelement) |
||||||
|
returns anyrange as 'select int4range(1,10)' language sql; |
||||||
|
ERROR: cannot determine result data type |
||||||
|
DETAIL: A function returning ANYRANGE must have at least one ANYRANGE argument. |
||||||
|
-- should fail |
||||||
|
create function bogus_func(int) |
||||||
|
returns anyrange as 'select int4range(1,10)' language sql; |
||||||
|
ERROR: cannot determine result data type |
||||||
|
DETAIL: A function returning a polymorphic type must have at least one polymorphic argument. |
||||||
|
create function range_add_bounds(anyrange) |
||||||
|
returns anyelement as 'select lower($1) + upper($1)' language sql; |
||||||
|
select range_add_bounds(numrange(1.0001, 123.123)); |
||||||
|
range_add_bounds |
||||||
|
------------------ |
||||||
|
124.1231 |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- |
||||||
|
-- Arrays of ranges |
||||||
|
-- |
||||||
|
select ARRAY[numrange(1.1), numrange(12.3,155.5)]; |
||||||
|
array |
||||||
|
------------------------------ |
||||||
|
{"[1.1,1.1]","[12.3,155.5)"} |
||||||
|
(1 row) |
||||||
|
|
||||||
|
-- |
||||||
|
-- Ranges of arrays |
||||||
|
-- |
||||||
|
create type arrayrange as range (subtype=int4[]); |
||||||
|
select arrayrange(ARRAY[1,2], ARRAY[2,1]); |
||||||
|
arrayrange |
||||||
|
------------------- |
||||||
|
["{1,2}","{2,1}") |
||||||
|
(1 row) |
||||||
|
|
||||||
|
drop type arrayrange; |
||||||
|
-- |
||||||
|
-- OUT/INOUT/TABLE functions |
||||||
|
-- |
||||||
|
create function outparam_succeed(i anyrange, out r anyrange, out t text) |
||||||
|
as $$ select $1, 'foo' $$ language sql; |
||||||
|
create function inoutparam_succeed(out i anyelement, inout r anyrange) |
||||||
|
as $$ select $1, $2 $$ language sql; |
||||||
|
create function table_succeed(i anyelement, r anyrange) returns table(i anyelement, r anyrange) |
||||||
|
as $$ select $1, $2 $$ language sql; |
||||||
|
-- should fail |
||||||
|
create function outparam_fail(i anyelement, out r anyrange, out t text) |
||||||
|
as $$ select '[1,10]', 'foo' $$ language sql; |
||||||
|
ERROR: cannot determine result data type |
||||||
|
DETAIL: A function returning ANYRANGE must have at least one ANYRANGE argument. |
||||||
|
--should fail |
||||||
|
create function inoutparam_fail(inout i anyelement, out r anyrange) |
||||||
|
as $$ select $1, '[1,10]' $$ language sql; |
||||||
|
ERROR: cannot determine result data type |
||||||
|
DETAIL: A function returning ANYRANGE must have at least one ANYRANGE argument. |
||||||
|
--should fail |
||||||
|
create function table_succeed(i anyelement) returns table(i anyelement, r anyrange) |
||||||
|
as $$ select $1, '[1,10]' $$ language sql; |
||||||
|
ERROR: cannot determine result data type |
||||||
|
DETAIL: A function returning ANYRANGE must have at least one ANYRANGE argument. |
||||||
@ -0,0 +1,371 @@ |
|||||||
|
|
||||||
|
-- |
||||||
|
-- test parser |
||||||
|
-- |
||||||
|
|
||||||
|
create type textrange as range (subtype=text, collation="C"); |
||||||
|
|
||||||
|
-- negative tests; should fail |
||||||
|
select ''::textrange; |
||||||
|
select '-[a,z)'::textrange; |
||||||
|
select '[a,z) - '::textrange; |
||||||
|
select '(",a)'::textrange; |
||||||
|
select '(,,a)'::textrange; |
||||||
|
select '(),a)'::textrange; |
||||||
|
select '(a,))'::textrange; |
||||||
|
select '(],a)'::textrange; |
||||||
|
select '(a,])'::textrange; |
||||||
|
|
||||||
|
-- should succeed |
||||||
|
select ' empty '::textrange; |
||||||
|
select ' ( empty, empty ) '::textrange; |
||||||
|
select ' ( " a " " a ", " z " " z " ) '::textrange; |
||||||
|
select '(,z)'::textrange; |
||||||
|
select '(a,)'::textrange; |
||||||
|
select '[,z]'::textrange; |
||||||
|
select '[a,]'::textrange; |
||||||
|
select '( , )'::textrange; |
||||||
|
select '("","")'::textrange; |
||||||
|
select '["",""]'::textrange; |
||||||
|
select '(",",",")'::textrange; |
||||||
|
select '("\\","\\")'::textrange |
||||||
|
select '(\\,a)'::textrange; |
||||||
|
select '((,z)'::textrange; |
||||||
|
select '([,z)'::textrange; |
||||||
|
select '(!,()'::textrange; |
||||||
|
select '(!,[)'::textrange; |
||||||
|
|
||||||
|
drop type textrange; |
||||||
|
|
||||||
|
-- |
||||||
|
-- create some test data and test the operators |
||||||
|
-- |
||||||
|
|
||||||
|
CREATE TABLE numrange_test (nr NUMRANGE); |
||||||
|
create index numrange_test_btree on numrange_test(nr); |
||||||
|
SET enable_seqscan = f; |
||||||
|
|
||||||
|
INSERT INTO numrange_test VALUES('[,)'); |
||||||
|
INSERT INTO numrange_test VALUES('[3,]'); |
||||||
|
INSERT INTO numrange_test VALUES('[, 5)'); |
||||||
|
INSERT INTO numrange_test VALUES(numrange(1.1, 2.2)); |
||||||
|
INSERT INTO numrange_test VALUES('empty'); |
||||||
|
INSERT INTO numrange_test VALUES(numrange(1.7)); |
||||||
|
|
||||||
|
SELECT isempty(nr) FROM numrange_test; |
||||||
|
SELECT lower_inc(nr), lower(nr), upper(nr), upper_inc(nr) FROM numrange_test |
||||||
|
WHERE NOT isempty(nr) AND NOT lower_inf(nr) AND NOT upper_inf(nr); |
||||||
|
|
||||||
|
SELECT * FROM numrange_test WHERE contains(nr, numrange(1.9,1.91)); |
||||||
|
SELECT * FROM numrange_test WHERE nr @> numrange(1.0,10000.1); |
||||||
|
SELECT * FROM numrange_test WHERE contained_by(numrange(-1e7,-10000.1), nr); |
||||||
|
SELECT * FROM numrange_test WHERE 1.9 <@ nr; |
||||||
|
SELECT * FROM numrange_test WHERE nr = 'empty'; |
||||||
|
SELECT * FROM numrange_test WHERE range_eq(nr, '(1.1, 2.2)'); |
||||||
|
SELECT * FROM numrange_test WHERE nr = '[1.1, 2.2)'; |
||||||
|
|
||||||
|
select numrange(2.0, 1.0); |
||||||
|
|
||||||
|
select numrange(2.0, 3.0) -|- numrange(3.0, 4.0); |
||||||
|
select adjacent(numrange(2.0, 3.0), numrange(3.1, 4.0)); |
||||||
|
select numrange(2.0, 3.0, '[]') -|- numrange(3.0, 4.0, '()'); |
||||||
|
select numrange(1.0, 2.0) -|- numrange(2.0, 3.0,'[]'); |
||||||
|
select adjacent(numrange(2.0, 3.0, '(]'), numrange(1.0, 2.0, '(]')); |
||||||
|
|
||||||
|
select numrange(1.1, 3.3) <@ numrange(0.1,10.1); |
||||||
|
select numrange(0.1, 10.1) <@ numrange(1.1,3.3); |
||||||
|
|
||||||
|
select numrange(1.1, 2.2) - numrange(2.0, 3.0); |
||||||
|
select numrange(1.1, 2.2) - numrange(2.2, 3.0); |
||||||
|
select numrange(1.1, 2.2,'[]') - numrange(2.0, 3.0); |
||||||
|
select minus(numrange(10.1,12.2,'[]'), numrange(110.0,120.2,'(]')); |
||||||
|
select minus(numrange(10.1,12.2,'[]'), numrange(0.0,120.2,'(]')); |
||||||
|
|
||||||
|
select numrange(4.5, 5.5, '[]') && numrange(5.5, 6.5); |
||||||
|
select numrange(1.0, 2.0) << numrange(3.0, 4.0); |
||||||
|
select numrange(1.0, 2.0) >> numrange(3.0, 4.0); |
||||||
|
select numrange(3.0, 70.0) &< numrange(6.6, 100.0); |
||||||
|
|
||||||
|
select numrange(1.1, 2.2) < numrange(1.0, 200.2); |
||||||
|
select numrange(1.1, 2.2) < numrange(1.1, 1.2); |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) + numrange(2.0, 3.0); |
||||||
|
select numrange(1.0, 2.0) + numrange(1.5, 3.0); |
||||||
|
select numrange(1.0, 2.0) + numrange(2.5, 3.0); |
||||||
|
|
||||||
|
select numrange(1.0, 2.0) * numrange(2.0, 3.0); |
||||||
|
select numrange(1.0, 2.0) * numrange(1.5, 3.0); |
||||||
|
select numrange(1.0, 2.0) * numrange(2.5, 3.0); |
||||||
|
|
||||||
|
select * from numrange_test where nr < numrange(-1000.0, -1000.0,'[]'); |
||||||
|
select * from numrange_test where nr < numrange(0.0, 1.0,'[]'); |
||||||
|
select * from numrange_test where nr < numrange(1000.0, 1001.0,'[]'); |
||||||
|
select * from numrange_test where nr > numrange(-1001.0, -1000.0,'[]'); |
||||||
|
select * from numrange_test where nr > numrange(0.0, 1.0,'[]'); |
||||||
|
select * from numrange_test where nr > numrange(1000.0, 1000.0,'[]'); |
||||||
|
|
||||||
|
create table numrange_test2(nr numrange); |
||||||
|
create index numrange_test2_hash_idx on numrange_test2 (nr); |
||||||
|
INSERT INTO numrange_test2 VALUES('[, 5)'); |
||||||
|
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2)); |
||||||
|
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2)); |
||||||
|
INSERT INTO numrange_test2 VALUES(numrange(1.1, 2.2,'()')); |
||||||
|
INSERT INTO numrange_test2 VALUES('empty'); |
||||||
|
|
||||||
|
select * from numrange_test2 where nr = 'empty'::numrange; |
||||||
|
select * from numrange_test2 where nr = numrange(1.1, 2.2); |
||||||
|
select * from numrange_test2 where nr = numrange(1.1, 2.3); |
||||||
|
|
||||||
|
set enable_nestloop=t; |
||||||
|
set enable_hashjoin=f; |
||||||
|
set enable_mergejoin=f; |
||||||
|
select * from numrange_test natural join numrange_test2 order by nr; |
||||||
|
set enable_nestloop=f; |
||||||
|
set enable_hashjoin=t; |
||||||
|
set enable_mergejoin=f; |
||||||
|
select * from numrange_test natural join numrange_test2 order by nr; |
||||||
|
set enable_nestloop=f; |
||||||
|
set enable_hashjoin=f; |
||||||
|
set enable_mergejoin=t; |
||||||
|
select * from numrange_test natural join numrange_test2 order by nr; |
||||||
|
|
||||||
|
set enable_nestloop to default; |
||||||
|
set enable_hashjoin to default; |
||||||
|
set enable_mergejoin to default; |
||||||
|
SET enable_seqscan TO DEFAULT; |
||||||
|
DROP TABLE numrange_test; |
||||||
|
DROP TABLE numrange_test2; |
||||||
|
|
||||||
|
-- test canonical form for int4range |
||||||
|
select int4range(1,10,'[]'); |
||||||
|
select int4range(1,10,'[)'); |
||||||
|
select int4range(1,10,'(]'); |
||||||
|
select int4range(1,10,'[]'); |
||||||
|
|
||||||
|
-- test canonical form for daterange |
||||||
|
select daterange('2000-01-10'::date, '2000-01-20'::date,'[]'); |
||||||
|
select daterange('2000-01-10'::date, '2000-01-20'::date,'[)'); |
||||||
|
select daterange('2000-01-10'::date, '2000-01-20'::date,'(]'); |
||||||
|
select daterange('2000-01-10'::date, '2000-01-20'::date,'[]'); |
||||||
|
|
||||||
|
create table test_range_gist(ir int4range); |
||||||
|
create index test_range_gist_idx on test_range_gist using gist (ir); |
||||||
|
|
||||||
|
insert into test_range_gist select int4range(g, g+10) from generate_series(1,2000) g; |
||||||
|
insert into test_range_gist select 'empty'::int4range from generate_series(1,500) g; |
||||||
|
insert into test_range_gist select int4range(g, g+10000) from generate_series(1,1000) g; |
||||||
|
insert into test_range_gist select 'empty'::int4range from generate_series(1,500) g; |
||||||
|
insert into test_range_gist select int4range(NULL,g*10,'(]') from generate_series(1,100) g; |
||||||
|
insert into test_range_gist select int4range(g*10,NULL,'(]') from generate_series(1,100) g; |
||||||
|
insert into test_range_gist select int4range(g, g+10) from generate_series(1,2000) g; |
||||||
|
|
||||||
|
BEGIN; |
||||||
|
SET LOCAL enable_seqscan = t; |
||||||
|
SET LOCAL enable_bitmapscan = f; |
||||||
|
SET LOCAL enable_indexscan = f; |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> 'empty'::int4range; |
||||||
|
select count(*) from test_range_gist where ir = int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir @> 10; |
||||||
|
select count(*) from test_range_gist where ir @> int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir && int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir <@ int4range(10,50); |
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir << int4range(100,500); |
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir >> int4range(100,500); |
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir &< int4range(100,500); |
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir &> int4range(100,500); |
||||||
|
select count(*) from (select * from test_range_gist where not isempty(ir)) s where ir -|- int4range(100,500); |
||||||
|
COMMIT; |
||||||
|
|
||||||
|
BEGIN; |
||||||
|
SET LOCAL enable_seqscan = f; |
||||||
|
SET LOCAL enable_bitmapscan = f; |
||||||
|
SET LOCAL enable_indexscan = t; |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> 'empty'::int4range; |
||||||
|
select count(*) from test_range_gist where ir = int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir @> 10; |
||||||
|
select count(*) from test_range_gist where ir @> int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir && int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir <@ int4range(10,50); |
||||||
|
select count(*) from test_range_gist where ir << int4range(100,500); |
||||||
|
select count(*) from test_range_gist where ir >> int4range(100,500); |
||||||
|
select count(*) from test_range_gist where ir &< int4range(100,500); |
||||||
|
select count(*) from test_range_gist where ir &> int4range(100,500); |
||||||
|
select count(*) from test_range_gist where ir -|- int4range(100,500); |
||||||
|
COMMIT; |
||||||
|
|
||||||
|
drop index test_range_gist_idx; |
||||||
|
create index test_range_gist_idx on test_range_gist using gist (ir); |
||||||
|
|
||||||
|
BEGIN; |
||||||
|
SET LOCAL enable_seqscan = f; |
||||||
|
SET LOCAL enable_bitmapscan = f; |
||||||
|
SET LOCAL enable_indexscan = t; |
||||||
|
|
||||||
|
select count(*) from test_range_gist where ir @> 'empty'::int4range; |
||||||
|
select count(*) from test_range_gist where ir = int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir @> 10; |
||||||
|
select count(*) from test_range_gist where ir @> int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir && int4range(10,20); |
||||||
|
select count(*) from test_range_gist where ir <@ int4range(10,50); |
||||||
|
select count(*) from test_range_gist where ir << int4range(100,500); |
||||||
|
select count(*) from test_range_gist where ir >> int4range(100,500); |
||||||
|
select count(*) from test_range_gist where ir &< int4range(100,500); |
||||||
|
select count(*) from test_range_gist where ir &> int4range(100,500); |
||||||
|
select count(*) from test_range_gist where ir -|- int4range(100,500); |
||||||
|
COMMIT; |
||||||
|
|
||||||
|
drop table test_range_gist; |
||||||
|
|
||||||
|
-- |
||||||
|
-- Btree_gist is not included by default, so to test exclusion |
||||||
|
-- constraints with range types, use singleton int ranges for the "=" |
||||||
|
-- portion of the constraint. |
||||||
|
-- |
||||||
|
|
||||||
|
create table test_range_excl( |
||||||
|
room int4range, |
||||||
|
speaker int4range, |
||||||
|
during tsrange, |
||||||
|
exclude using gist (room with =, during with &&), |
||||||
|
exclude using gist (speaker with =, during with &&) |
||||||
|
); |
||||||
|
|
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(123), int4range(1), '[2010-01-02 10:00, 2010-01-02 11:00)'); |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(123), int4range(2), '[2010-01-02 11:00, 2010-01-02 12:00)'); |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(123), int4range(3), '[2010-01-02 10:10, 2010-01-02 11:10)'); |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(124), int4range(3), '[2010-01-02 10:10, 2010-01-02 11:10)'); |
||||||
|
insert into test_range_excl |
||||||
|
values(int4range(125), int4range(1), '[2010-01-02 10:10, 2010-01-02 11:10)'); |
||||||
|
|
||||||
|
drop table test_range_excl; |
||||||
|
|
||||||
|
-- test bigint ranges |
||||||
|
select int8range(10000000000::int8, 20000000000::int8,'(]'); |
||||||
|
-- test tstz ranges |
||||||
|
set timezone to '-08'; |
||||||
|
select '[2010-01-01 01:00:00 -05, 2010-01-01 02:00:00 -08)'::tstzrange; |
||||||
|
-- should fail |
||||||
|
select '[2010-01-01 01:00:00 -08, 2010-01-01 02:00:00 -05)'::tstzrange; |
||||||
|
set timezone to default; |
||||||
|
|
||||||
|
-- |
||||||
|
-- Test user-defined range of floats |
||||||
|
-- |
||||||
|
|
||||||
|
--should fail |
||||||
|
create type float8range as range (subtype=float8, subtype_diff=float4mi); |
||||||
|
|
||||||
|
--should succeed |
||||||
|
create type float8range as range (subtype=float8, subtype_diff=float8mi); |
||||||
|
select '[123.001, 5.e9)'::float8range @> 888.882::float8; |
||||||
|
create table float8range_test(f8r float8range, i int); |
||||||
|
insert into float8range_test values(float8range(-100.00007, '1.111113e9')); |
||||||
|
select * from float8range_test; |
||||||
|
drop table float8range_test; |
||||||
|
drop type float8range; |
||||||
|
|
||||||
|
-- |
||||||
|
-- Test range types over domains |
||||||
|
-- |
||||||
|
|
||||||
|
create domain mydomain as int4; |
||||||
|
create type mydomainrange as range(subtype=mydomain); |
||||||
|
select '[4,50)'::mydomainrange @> 7::mydomain; |
||||||
|
drop type mydomainrange; |
||||||
|
drop domain mydomain; |
||||||
|
|
||||||
|
-- |
||||||
|
-- Test domains over range types |
||||||
|
-- |
||||||
|
|
||||||
|
create domain restrictedrange as int4range check (upper(value) < 10); |
||||||
|
select '[4,5)'::restrictedrange @> 7; |
||||||
|
select '[4,50)'::restrictedrange @> 7; -- should fail |
||||||
|
drop domain restrictedrange; |
||||||
|
|
||||||
|
-- |
||||||
|
-- Test multiple range types over the same subtype |
||||||
|
-- |
||||||
|
|
||||||
|
create type textrange1 as range(subtype=text, collation="C"); |
||||||
|
create type textrange2 as range(subtype=text, collation="C"); |
||||||
|
|
||||||
|
select textrange1('a','Z') @> 'b'::text; |
||||||
|
select textrange2('a','z') @> 'b'::text; |
||||||
|
|
||||||
|
drop type textrange1; |
||||||
|
drop type textrange2; |
||||||
|
|
||||||
|
-- |
||||||
|
-- Test out polymorphic type system |
||||||
|
-- |
||||||
|
|
||||||
|
create function anyarray_anyrange_func(a anyarray, r anyrange) |
||||||
|
returns anyelement as 'select $1[1] + lower($2);' language sql; |
||||||
|
|
||||||
|
select anyarray_anyrange_func(ARRAY[1,2], int4range(10,20)); |
||||||
|
|
||||||
|
-- should fail |
||||||
|
select anyarray_anyrange_func(ARRAY[1,2], numrange(10,20)); |
||||||
|
|
||||||
|
drop function anyarray_anyrange_func(anyarray, anyrange); |
||||||
|
|
||||||
|
-- should fail |
||||||
|
create function bogus_func(anyelement) |
||||||
|
returns anyrange as 'select int4range(1,10)' language sql; |
||||||
|
|
||||||
|
-- should fail |
||||||
|
create function bogus_func(int) |
||||||
|
returns anyrange as 'select int4range(1,10)' language sql; |
||||||
|
|
||||||
|
create function range_add_bounds(anyrange) |
||||||
|
returns anyelement as 'select lower($1) + upper($1)' language sql; |
||||||
|
|
||||||
|
select range_add_bounds(numrange(1.0001, 123.123)); |
||||||
|
|
||||||
|
-- |
||||||
|
-- Arrays of ranges |
||||||
|
-- |
||||||
|
|
||||||
|
select ARRAY[numrange(1.1), numrange(12.3,155.5)]; |
||||||
|
|
||||||
|
-- |
||||||
|
-- Ranges of arrays |
||||||
|
-- |
||||||
|
|
||||||
|
create type arrayrange as range (subtype=int4[]); |
||||||
|
|
||||||
|
select arrayrange(ARRAY[1,2], ARRAY[2,1]); |
||||||
|
|
||||||
|
drop type arrayrange; |
||||||
|
|
||||||
|
-- |
||||||
|
-- OUT/INOUT/TABLE functions |
||||||
|
-- |
||||||
|
|
||||||
|
create function outparam_succeed(i anyrange, out r anyrange, out t text) |
||||||
|
as $$ select $1, 'foo' $$ language sql; |
||||||
|
|
||||||
|
create function inoutparam_succeed(out i anyelement, inout r anyrange) |
||||||
|
as $$ select $1, $2 $$ language sql; |
||||||
|
|
||||||
|
create function table_succeed(i anyelement, r anyrange) returns table(i anyelement, r anyrange) |
||||||
|
as $$ select $1, $2 $$ language sql; |
||||||
|
|
||||||
|
-- should fail |
||||||
|
create function outparam_fail(i anyelement, out r anyrange, out t text) |
||||||
|
as $$ select '[1,10]', 'foo' $$ language sql; |
||||||
|
|
||||||
|
--should fail |
||||||
|
create function inoutparam_fail(inout i anyelement, out r anyrange) |
||||||
|
as $$ select $1, '[1,10]' $$ language sql; |
||||||
|
|
||||||
|
--should fail |
||||||
|
create function table_succeed(i anyelement) returns table(i anyelement, r anyrange) |
||||||
|
as $$ select $1, '[1,10]' $$ language sql; |
||||||
Loading…
Reference in new issue