From c2d0ebce755157ce525d9b08c96dfa88b4da1eab Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Tue, 30 Jul 2002 05:24:56 +0000 Subject: [PATCH] Rewrite xindex.sgml for CREATE OPERATOR CLASS. catalogs.sgml finally contains descriptions of every single system table. Update 'complex' tutorial example too. --- doc/src/sgml/catalogs.sgml | 394 +++++++++++++++++++- doc/src/sgml/xindex.sgml | 719 ++++++++++++++++++++---------------- src/tutorial/complex.source | 143 ++----- 3 files changed, 805 insertions(+), 451 deletions(-) diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index 5ef29364533..13f883a65de 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -1,6 +1,6 @@ @@ -21,7 +21,7 @@ DATABASE inserts a row into the pg_database catalog -- and actually creates the database on disk.) There are some exceptions for - esoteric operations, such as adding index access methods. + especially esoteric operations, such as adding index access methods. @@ -180,9 +180,7 @@
- More detailed documentation of most catalogs follow below. The - catalogs that relate to index access methods are explained in the - Programmer's Guide. + More detailed documentation of each catalog follows below. @@ -267,6 +265,294 @@ + + pg_am + + + pg_am stores information about index access + methods. There is one row for each index access method supported by + the system. + + + + pg_am Columns + + + + + Name + Type + References + Description + + + + + + amname + name + + name of the access method + + + + amowner + int4 + pg_shadow.usesysid + user ID of the owner (currently not used) + + + + amstrategies + int2 + + number of operator strategies for this access method + + + + amsupport + int2 + + number of support routines for this access method + + + + amorderstrategy + int2 + + zero if the index offers no sort order, otherwise the strategy + number of the strategy operator that describes the sort order + + + + amcanunique + bool + + does AM support unique indexes? + + + + amcanmulticol + bool + + does AM support multicolumn indexes? + + + + amindexnulls + bool + + does AM support NULL index entries? + + + + amconcurrent + bool + + does AM support concurrent updates? + + + + amgettuple + regproc + pg_proc.oid + next valid tuple function + + + + aminsert + regproc + pg_proc.oid + insert this tuple function + + + + ambeginscan + regproc + pg_proc.oid + start new scan function + + + + amrescan + regproc + pg_proc.oid + restart this scan function + + + + amendscan + regproc + pg_proc.oid + end this scan function + + + + ammarkpos + regproc + pg_proc.oid + mark current scan position function + + + + amrestrpos + regproc + pg_proc.oid + restore marked scan position function + + + + ambuild + regproc + pg_proc.oid + build new index function + + + + ambulkdelete + regproc + pg_proc.oid + bulk-delete function + + + + amcostestimate + regproc + pg_proc.oid + estimate cost of an indexscan + + + + +
+ + + An index AM that supports multiple columns (has + amcanmulticol true) must + support indexing nulls in columns after the first, because the planner + will assume the index can be used for queries on just the first + column(s). For example, consider an index on (a,b) and a query + WHERE a = 4. The system will assume the index can be used to scan for + rows with a = 4, which is wrong if the index omits rows where b is null. + However it is okay to omit rows where the first indexed column is null. + (GiST currently does so.) + amindexnulls should be set true only if the + index AM indexes all rows, including arbitrary combinations of nulls. + + +
+ + + + pg_amop + + + pg_amop stores information about operators + associated with index access method operator classes. There is one + row for each operator that is a member of an operator class. + + + + pg_amop Columns + + + + + Name + Type + References + Description + + + + + + amopclaid + oid + pg_opclass.oid + the index opclass this entry is for + + + + amopstrategy + int2 + + operator strategy number + + + + amopreqcheck + bool + + index hit must be rechecked + + + + amopopr + oid + pg_operator.oid + the operator's pg_operator OID + + + + +
+ +
+ + + + pg_amproc + + + pg_amproc stores information about support + procedures + associated with index access method operator classes. There is one + row for each support procedure belonging to an operator class. + + + + pg_amproc Columns + + + + + Name + Type + References + Description + + + + + + amopclaid + oid + pg_opclass.oid + the index opclass this entry is for + + + + amprocnum + int2 + + support procedure index + + + + amproc + regproc + pg_proc.oid + OID of the proc + + + + +
+ +
+ + pg_attrdef @@ -1923,6 +2209,104 @@ + + pg_opclass + + + pg_opclass defines + index access method operator classes. Each operator class defines + semantics for index columns of a particular datatype and a particular + index access method. Note that there can be multiple operator classes + for a given datatype/access method combination, thus supporting multiple + behaviors. + + + + Operator classes are described at length in the + Programmer's Guide. + + + + pg_opclass Columns + + + + + Name + Type + References + Description + + + + + + opcamid + oid + pg_am.oid + index access method opclass is for + + + + opcname + name + + name of this opclass + + + + opcnamespace + oid + pg_namespace.oid + namespace of this opclass + + + + opcowner + int4 + pg_shadow.usesysid + opclass owner + + + + opcintype + oid + pg_type.oid + type of input data for opclass + + + + opcdefault + bool + + true if opclass is default for opcintype + + + + opckeytype + oid + pg_type.oid + type of index data, or zero if same as opcintype + + + + +
+ + + The majority of the information defining an operator class is actually + not in its pg_opclass row, but in the associated + rows in pg_amop and + pg_amproc. Those rows are considered to be + part of the operator class definition --- this is not unlike the way + that a relation is defined by a single pg_class + row, plus associated rows in pg_attribute and + other tables. + + +
+ + pg_operator diff --git a/doc/src/sgml/xindex.sgml b/doc/src/sgml/xindex.sgml index 99f069a6748..062307e09ff 100644 --- a/doc/src/sgml/xindex.sgml +++ b/doc/src/sgml/xindex.sgml @@ -1,5 +1,5 @@ @@ -13,132 +13,74 @@ PostgreSQL documentation The procedures described thus far let you define new types, new functions, and new operators. However, we cannot yet define a secondary index (such as a B-tree, R-tree, or hash access method) - over a new type or its operators. - - - - Look back at - . - The right half shows the catalogs that we must modify in order to tell - PostgreSQL how to use a user-defined type and/or - user-defined operators with an index (i.e., pg_am, pg_amop, - pg_amproc, pg_operator and pg_opclass). - Unfortunately, there is no simple command to do this. We will demonstrate - how to modify these catalogs through a running example: a new operator + over a new type, nor associate operators of a new type with secondary + indexes. + To do these things, we must define an operator class + for the new datatype. We will describe operator classes in the + context of a running example: a new operator class for the B-tree access method that stores and sorts complex numbers in ascending absolute value order. - - - - Access Methods - - - The pg_am table contains one row for every - index access method. Support for the heap access method is built - into PostgreSQL, but all other access - methods are described in pg_am. The schema is - shown in . - - - Index Access Method Schema - - - - - Column - Description - - - - - amname - name of the access method - - - amowner - user ID of the owner (currently not used) - - - amstrategies - number of strategies for this access method (see below) - - - amsupport - number of support routines for this access method (see below) - - - amorderstrategy - zero if the index offers no sort order, otherwise the strategy - number of the strategy operator that describes the sort order - - - amcanunique - does AM support unique indexes? - - - amcanmulticol - does AM support multicolumn indexes? - - - amindexnulls - does AM support NULL index entries? - - - amconcurrent - does AM support concurrent updates? - - - amgettuple - - - aminsert - - - ... - procedure identifiers for interface routines to the access - method. For example, regproc IDs for opening, closing, and - getting rows from the access method appear here. - - - -
-
- An index AM that supports multiple columns (has - amcanmulticol true) must - support indexing nulls in columns after the first, because the planner - will assume the index can be used for queries on just the first - column(s). For example, consider an index on (a,b) and a query - WHERE a = 4. The system will assume the index can be used to scan for - rows with a = 4, which is wrong if the index omits rows where b is null. - However it is okay to omit rows where the first indexed column is null. - (GiST currently does so.) - amindexnulls should be set true only if the - index AM indexes all rows, including arbitrary combinations of nulls. + Prior to PostgreSQL release 7.3, it was + necesssary to make manual additions to + pg_amop, pg_amproc, and + pg_opclass in order to create a user-defined + operator class. That approach is now deprecated in favor of + using CREATE OPERATOR CLASS, which is a much simpler + and less error-prone way of creating the necessary catalog entries. +
+ + + Access Methods and Operator Classes - The OID of the row in - pg_am is used as a foreign key in a lot of other - tables. You do not need to add a new row to this table; all that - you are interested in is the OID of the access - method you want to extend: + The pg_am table contains one row for every + index access method. Support for access to regular tables is + built into PostgreSQL, but all index access + methods are described in pg_am. It is possible + to add a new index access method by defining the required interface + routines and then creating a row in pg_am --- + but that is far beyond the scope of this chapter. + - -SELECT oid FROM pg_am WHERE amname = 'btree'; + + The routines for an index access method do not directly know anything + about the data types the access method will operate on. Instead, an + operator class identifies the set of operations that the + access method needs to be able to use to work with a particular data type. + Operator classes are so called because one thing they specify is the set + of WHERE-clause operators that can be used with an index (ie, can be + converted into an indexscan qualification). An operator class may also + specify some support procedures that are needed by the + internal operations of the index access method, but do not directly + correspond to any WHERE-clause operator that can be used with the index. + - oid ------ - 403 -(1 row) - + + It is possible to define multiple operator classes for the same + input datatype and index access method. By doing this, multiple + sets of indexing semantics can be defined for a single datatype. + For example, a B-tree index requires a sort ordering to be defined + for each datatype it works on. + It might be useful for a complex-number datatype + to have one B-tree operator class that sorts the data by complex + absolute value, another that sorts by real part, and so on. + Typically one of the operator classes will be deemed most commonly + useful and will be marked as the default operator class for that + datatype and index access method. + - We will use that query in a WHERE - clause later. + + The same operator class name + can be used for several different access methods (for example, both B-tree + and hash access methods have operator classes named + oid_ops), but each such class is an independent + entity and must be defined separately. @@ -146,44 +88,36 @@ SELECT oid FROM pg_am WHERE amname = 'btree'; Access Method Strategies - The amstrategies column exists to standardize - comparisons across data types. For example, B-trees - impose a strict ordering on keys, lesser to greater. Since + The operators associated with an operator class are identified by + strategy numbers, which serve to identify the semantics of + each operator within the context of its operator class. + For example, B-trees impose a strict ordering on keys, lesser to greater, + and so operators like less than and greater than or equal + to are interesting with respect to a B-tree. + Because PostgreSQL allows the user to define operators, PostgreSQL cannot look at the name of an operator - (e.g., > or <) and tell what kind of comparison it is. In fact, - some access methods don't impose any ordering at all. For example, - R-trees express a rectangle-containment relationship, - whereas a hashed data structure expresses only bitwise similarity based - on the value of a hash function. PostgreSQL - needs some consistent way of taking a qualification in your query, - looking at the operator, and then deciding if a usable index exists. This - implies that PostgreSQL needs to know, for - example, that the <= and > operators partition a - B-tree. PostgreSQL - uses strategies to express these relationships between - operators and the way they can be used to scan indexes. + (e.g., > or <) and tell what kind of + comparison it is. Instead, the index access method defines a set of + strategies, which can be thought of as generalized operators. + Each operator class shows which actual operator corresponds to each + strategy for a particular datatype and interpretation of the index + semantics. - Defining a new set of strategies is beyond the scope of this - discussion, but we'll explain how B-tree strategies work because - you'll need to know that to add a new B-tree operator class. In the - pg_am table, the - amstrategies column sets the number of - strategies defined for this access method. For B-trees, this number - is 5. The meanings of these strategies are shown in . + B-tree indexes define 5 strategies, as shown in . - +
B-tree StrategiesB-tree Operation - Index + Strategy Number @@ -212,14 +146,101 @@ SELECT oid FROM pg_am WHERE amname = 'btree';
- The idea is that you'll need to add operators corresponding to these strategies - to the pg_amop relation (see below). - The access method code can use these strategy numbers, regardless of data - type, to figure out how to partition the B-tree, - compute selectivity, and so on. Don't worry about the details of adding - operators yet; just understand that there must be a set of these - operators for int2, int4, oid, and all other - data types on which a B-tree can operate. + Hash indexes express only bitwise similarity, and so they define only 1 + strategy, as shown in . + + + + Hash Strategies + Hash + + + + Operation + Strategy Number + + + + + equal + 1 + + + +
+ + + R-tree indexes express rectangle-containment relationships. + They define 8 strategies, as shown in . + + + + R-tree Strategies + R-tree + + + + Operation + Strategy Number + + + + + left of + 1 + + + left of or overlapping + 2 + + + overlapping + 3 + + + right of or overlapping + 4 + + + right of + 5 + + + same + 6 + + + contains + 7 + + + contained by + 8 + + + +
+ + + GiST indexes are even more flexible: they do not have a fixed set of + strategies at all. Instead, the consistency support routine + of a particular GiST operator class interprets the strategy numbers + however it likes. + + + + By the way, the amorderstrategy column + in pg_am tells whether + the access method supports ordered scan. Zero means it doesn't; if it + does, amorderstrategy is the strategy + number that corresponds to the ordering operator. For example, B-tree + has amorderstrategy = 1, which is its + less than strategy number. + + + + In short, an operator class must specify a set of operators that express + each of these semantic ideas for the operator class's datatype. @@ -227,9 +248,9 @@ SELECT oid FROM pg_am WHERE amname = 'btree'; Access Method Support Routines - Sometimes, strategies aren't enough information for the system to figure - out how to use an index. Some access methods require additional support - routines in order to work. For example, the B-tree + Strategies aren't usually enough information for the system to figure + out how to use an index. In practice, the access methods require + additional support routines in order to work. For example, the B-tree access method must be able to compare two keys and determine whether one is greater than, equal to, or less than the other. Similarly, the R-tree access method must be able to compute @@ -240,102 +261,156 @@ SELECT oid FROM pg_am WHERE amname = 'btree'; - In order to manage diverse support routines consistently across all - PostgreSQL access methods, - pg_am includes a column called - amsupport. This column records the - number of support routines used by an access method. For B-trees, - this number is one: the routine to take two keys and return -1, 0, + Just as with operators, the operator class identifies which specific + functions should play each of these roles for a given datatype and + semantic interpretation. The index access method specifies the set + of functions it needs, and the operator class identifies the correct + functions to use by assigning support function numbers to them. + + + + B-trees require a single support function, as shown in . + + + + B-tree Support Functions + B-tree + + + + Operation + Support Number + + + + + + Compare two keys and return -1, 0, or +1, depending on whether the first key is less than, equal to, - or greater than the second. (Strictly speaking, this routine can - return a negative number (< 0), zero, or a non-zero positive - number (> 0).) - + or greater than the second. (Actually, this routine can + return any negative int32 value (< 0), zero, or any non-zero positive + int32 value (> 0).) + + 1 + + + +
- The amstrategies entry in - pg_am is just the number of strategies - defined for the access method in question. The operators for less - than, less equal, and so on don't appear in - pg_am. Similarly, - amsupport is just the number of support - routines required by the access method. The actual routines are - listed elsewhere. + Hash indexes likewise require one support function, as shown in . + + Hash Support Functions + Hash + + + + Operation + Support Number + + + + + compute the hash value for a key + 1 + + + +
+ - By the way, the amorderstrategy column tells whether - the access method supports ordered scan. Zero means it doesn't; if it - does, amorderstrategy is the number of the strategy - routine that corresponds to the ordering operator. For example, B-tree - has amorderstrategy = 1, which is its - less than strategy number. + R-tree indexes require three support functions, + as shown in . - - - Operator Classes + + R-tree Support Functions + R-tree + + + + Operation + Support Number + + + + + union + 1 + + + intersection + 2 + + + size + 3 + + + +
- The next table of interest is pg_opclass. This table - defines operator class names and input data types for each of the operator - classes supported by a given index access method. The same class name - can be used for several different access methods (for example, both B-tree - and hash access methods have operator classes named - oid_ops), but a separate - pg_opclass row must appear for each access method. - The OID of the pg_opclass row is - used as a foreign - key in other tables to associate specific operators and support routines - with the operator class. + GiST indexes require seven support functions, + as shown in . - - You need to add a row with your operator class name (for example, - complex_abs_ops) to - pg_opclass: + + GiST Support Functions + GiST + + + + Operation + Support Number + + + + + consistent + 1 + + + union + 2 + + + compress + 3 + + + decompress + 4 + + + penalty + 5 + + + picksplit + 6 + + + equal + 7 + + + +
- -INSERT INTO pg_opclass (opcamid, opcname, opcnamespace, opcowner, opcintype, opcdefault, opckeytype) - VALUES ( - (SELECT oid FROM pg_am WHERE amname = 'btree'), - 'complex_abs_ops', - (SELECT oid FROM pg_namespace WHERE nspname = 'pg_catalog'), - 1, -- UID of superuser is hardwired to 1 as of PG 7.3 - (SELECT oid FROM pg_type WHERE typname = 'complex'), - true, - 0); - -SELECT oid, * - FROM pg_opclass - WHERE opcname = 'complex_abs_ops'; - - oid | opcamid | opcname | opcnamespace | opcowner | opcintype | opcdefault | opckeytype ---------+---------+-----------------+--------------+----------+-----------+------------+------------ - 277975 | 403 | complex_abs_ops | 11 | 1 | 277946 | t | 0 -(1 row) - - - Note that the OID for your pg_opclass row will - be different! Don't worry about this though. We'll get this number - from the system later just like we got the OID of the type here. -
- - - The above example assumes that you want to make this new operator class the - default B-tree operator class for the complex data type. - If you don't, just set opcdefault to false instead. - opckeytype is not described here; it should always - be zero for B-tree operator classes. -
Creating the Operators and Support Routines - So now we have an access method and an operator class. - We still need a set of operators. The procedure for + Now that we have seen the ideas, here is the promised example + of creating a new operator class. First, we need a set of operators. + The procedure for defining operators was discussed in . For the complex_abs_ops operator class on B-trees, the operators we require are: @@ -426,21 +501,14 @@ CREATE FUNCTION complex_abs_eq(complex, complex) RETURNS boolean In practice, all operators defined as index access method strategies must return type boolean, since they must appear at the top level of a WHERE clause to be used with an index. - (On the other hand, the support function returns whatever the - particular access method expects -- in this case, a signed - integer.) + (On the other hand, support functions return whatever the + particular access method expects -- in the case of the comparison + function for B-trees, a signed integer.) - - The final routine in the file is the support routine - mentioned when we discussed the amsupport column of the - pg_am table. We will use this later on. For - now, ignore it. - - Now we are ready to define the operators: @@ -464,108 +532,35 @@ CREATE OPERATOR = ( - The next step is to add entries for these operators to - the pg_amop relation. To do this, - we'll need the OIDs of the operators we just - defined. We'll look up the names of all the operators that take - two operands of type complex, and pick ours out: - - -SELECT o.oid AS opoid, o.oprname - INTO TEMP TABLE complex_ops_tmp - FROM pg_operator o, pg_type t - WHERE o.oprleft = t.oid and o.oprright = t.oid - and t.typname = 'complex'; - - opoid | oprname ---------+--------- - 277963 | + - 277970 | < - 277971 | <= - 277972 | = - 277973 | >= - 277974 | > -(6 rows) - - - (Again, some of your OID numbers will almost - certainly be different.) The operators we are interested in are those - with OIDs 277970 through 277974. The values you - get will probably be different, and you should substitute them for the - values below. We will do this with a select statement. - - - - Now we are ready to insert entries into pg_amop for - our new operator class. These entries must associate the correct - B-tree strategy numbers with each of the operators we need. - The command to insert the less-than operator looks like: - - -INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr) - SELECT opcl.oid, 1, false, c.opoid - FROM pg_opclass opcl, complex_ops_tmp c - WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') AND - opcname = 'complex_abs_ops' AND - c.oprname = '<'; - - - Now do this for the other operators substituting for the 1 in the - second line above and the < in the last line. Note the order: - less than is 1, less than or equal is 2, - equal is 3, greater than or equal is 4, and - greater than is 5. - - - - The field amopreqcheck is not discussed here; it - should always be false for B-tree operators. - - - - The final step is the registration of the support routine previously - described in our discussion of pg_am. The - OID of this support routine is stored in the - pg_amproc table, keyed by the operator class - OID and the support routine number. - - - - First, we need to register the function in - PostgreSQL (recall that we put the - C code that implements this routine in the bottom of - the file in which we implemented the operator routines): + The next step is the registration of the comparison support + routine required by B-trees. The C code that implements this + is in the same file that contains the operator procedures: CREATE FUNCTION complex_abs_cmp(complex, complex) RETURNS integer AS 'PGROOT/src/tutorial/complex' LANGUAGE C; - -SELECT oid, proname FROM pg_proc - WHERE proname = 'complex_abs_cmp'; - - oid | proname ---------+----------------- - 277997 | complex_abs_cmp -(1 row) - - (Again, your OID number will probably be different.) + + + + Creating the Operator Class - We can add the new row as follows: + Now that we have the required operators and support routine, + we can finally create the operator class: -INSERT INTO pg_amproc (amopclaid, amprocnum, amproc) - SELECT opcl.oid, 1, p.oid - FROM pg_opclass opcl, pg_proc p - WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') AND - opcname = 'complex_abs_ops' AND - p.proname = 'complex_abs_cmp'; +CREATE OPERATOR CLASS complex_abs_ops + DEFAULT FOR TYPE complex USING btree AS + OPERATOR 1 < , + OPERATOR 2 <= , + OPERATOR 3 = , + OPERATOR 4 >= , + OPERATOR 5 > , + FUNCTION 1 complex_abs_cmp(complex, complex); @@ -573,6 +568,76 @@ INSERT INTO pg_amproc (amopclaid, amprocnum, amproc) And we're done! (Whew.) It should now be possible to create and use B-tree indexes on complex columns. + + + We could have written the operator entries more verbosely, as in + + OPERATOR 1 < (complex, complex) , + + but there is no need to do so when the operators take the same datatype + we are defining the operator class for. + + + + The above example assumes that you want to make this new operator class the + default B-tree operator class for the complex data type. + If you don't, just leave out the word DEFAULT. + + + + + Special Features of Operator Classes + + + There are two special features of operator classes that we have + not discussed yet, mainly because they are not very useful + with the default B-tree index access method. + + + + Normally, declaring an operator as a member of an operator class means + that the index access method can retrieve exactly the set of rows + that satisfy a WHERE condition using the operator. For example, + +SELECT * FROM table WHERE integer_column < 4; + + can be satisfied exactly by a B-tree index on the integer column. + But there are cases where an index is useful as an inexact guide to + the matching rows. For example, if an R-tree index stores only + bounding boxes for objects, then it cannot exactly satisfy a WHERE + condition that tests overlap between nonrectangular objects such as + polygons. Yet we could use the index to find objects whose bounding + box overlaps the bounding box of the target object, and then do the + exact overlap test only on the objects found by the index. If this + scenario applies, the index is said to be lossy for the + operator, and we mark the OPERATOR clause in the + CREATE OPERATOR CLASS command with RECHECK. + RECHECK is valid if the index is guaranteed to return + all the required tuples, plus perhaps some additional tuples, which + can be eliminated by performing the original operator comparison. + + + + Consider again the situation where we are storing in the index only + the bounding box of a complex object such as a polygon. In this + case there's not much value in storing the whole polygon in the index + entry --- we may as well store just a simpler object of type + box. This situation is expressed by the STORAGE + option in CREATE OPERATOR CLASS: we'd write something like + + +CREATE OPERATOR CLASS polygon_ops + DEFAULT FOR TYPE polygon USING gist AS + ... + STORAGE box; + + + At present, only the GiST access method supports a + STORAGE type that's different from the column datatype. + The GiST compress and decompress support + routines must deal with datatype conversion when STORAGE + is used. +
diff --git a/src/tutorial/complex.source b/src/tutorial/complex.source index 6fbaaf89dbd..5df3c5d6779 100644 --- a/src/tutorial/complex.source +++ b/src/tutorial/complex.source @@ -5,9 +5,10 @@ -- use this new type. -- -- --- Copyright (c) 1994, Regents of the University of California +-- Portions Copyright (c) 1996-2002, PostgreSQL Global Development Group +-- Portions Copyright (c) 1994, Regents of the University of California -- --- $Id: complex.source,v 1.12 2002/04/17 20:57:57 tgl Exp $ +-- $Header: /cvsroot/pgsql/src/tutorial/complex.source,v 1.13 2002/07/30 05:24:56 tgl Exp $ -- --------------------------------------------------------------------------- @@ -46,13 +47,14 @@ CREATE FUNCTION complex_out(opaque) CREATE TYPE complex ( internallength = 16, input = complex_in, - output = complex_out + output = complex_out, + alignment = double ); ----------------------------- -- Using the new type: --- user-defined types can be use like ordinary built-in types. +-- user-defined types can be used like ordinary built-in types. ----------------------------- -- eg. we can use it in a schema @@ -62,7 +64,7 @@ CREATE TABLE test_complex ( b complex ); --- data for user-defined type are just strings in the proper textual +-- data for user-defined types are just strings in the proper textual -- representation. INSERT INTO test_complex VALUES ('(1.0, 2.5)', '(4.2, 3.55 )'); @@ -74,7 +76,7 @@ SELECT * FROM test_complex; -- Creating an operator for the new type: -- Let's define an add operator for complex types. Since POSTGRES -- supports function overloading, we'll use + as the add operator. --- (Operators can be reused with different number and types of +-- (Operator names can be reused with different numbers and types of -- arguments.) ----------------------------- @@ -121,20 +123,11 @@ CREATE AGGREGATE complex_sum ( SELECT complex_sum(a) FROM test_complex; -------------------------------------------------------------------------------- --- ATTENTION! ATTENTION! ATTENTION! -- --- YOU MAY SKIP THE SECTION BELOW ON INTERFACING WITH INDICES. YOU DON'T -- --- NEED THE FOLLOWING IF YOU DON'T USE INDICES WITH NEW DATA TYPES. -- -------------------------------------------------------------------------------- - -SELECT 'READ ABOVE!' AS STOP; - ----------------------------- --- Interfacing New Types with Indices: +-- Interfacing New Types with Indexes: -- We cannot define a secondary index (eg. a B-tree) over the new type --- yet. We need to modify a few system catalogs to show POSTGRES how --- to use the new type. Unfortunately, there is no simple command to --- do this. Please bear with me. +-- yet. We need to create all the required operators and support +-- functions, then we can make the operator class. ----------------------------- -- first, define the required operators @@ -170,81 +163,20 @@ CREATE OPERATOR > ( restrict = scalargtsel, join = scalargtjoinsel ); -INSERT INTO pg_opclass (opcamid, opcname, opcnamespace, opcowner, opcintype, opcdefault, opckeytype) - VALUES ( - (SELECT oid FROM pg_am WHERE amname = 'btree'), - 'complex_abs_ops', - (SELECT oid FROM pg_namespace WHERE nspname = 'pg_catalog'), - 1, -- UID of superuser is hardwired to 1 as of PG 7.3 - (SELECT oid FROM pg_type WHERE typname = 'complex'), - true, - 0); - -SELECT oid, * - FROM pg_opclass WHERE opcname = 'complex_abs_ops'; - -SELECT o.oid AS opoid, o.oprname -INTO TEMP TABLE complex_ops_tmp -FROM pg_operator o, pg_type t -WHERE o.oprleft = t.oid and o.oprright = t.oid - and t.typname = 'complex'; - --- make sure we have the right operators -SELECT * from complex_ops_tmp; - -INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr) - SELECT opcl.oid, 1, false, c.opoid - FROM pg_opclass opcl, complex_ops_tmp c - WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops' - and c.oprname = '<'; - -INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr) - SELECT opcl.oid, 2, false, c.opoid - FROM pg_opclass opcl, complex_ops_tmp c - WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops' - and c.oprname = '<='; - -INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr) - SELECT opcl.oid, 3, false, c.opoid - FROM pg_opclass opcl, complex_ops_tmp c - WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops' - and c.oprname = '='; - -INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr) - SELECT opcl.oid, 4, false, c.opoid - FROM pg_opclass opcl, complex_ops_tmp c - WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops' - and c.oprname = '>='; - -INSERT INTO pg_amop (amopclaid, amopstrategy, amopreqcheck, amopopr) - SELECT opcl.oid, 5, false, c.opoid - FROM pg_opclass opcl, complex_ops_tmp c - WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops' - and c.oprname = '>'; - --- +-- create the support function too CREATE FUNCTION complex_abs_cmp(complex, complex) RETURNS int4 AS '_OBJWD_/complex' LANGUAGE 'c'; -SELECT oid, proname FROM pg_proc WHERE proname = 'complex_abs_cmp'; +-- now we can make the operator class +CREATE OPERATOR CLASS complex_abs_ops + DEFAULT FOR TYPE complex USING btree AS + OPERATOR 1 < , + OPERATOR 2 <= , + OPERATOR 3 = , + OPERATOR 4 >= , + OPERATOR 5 > , + FUNCTION 1 complex_abs_cmp(complex, complex); -INSERT INTO pg_amproc (amopclaid, amprocnum, amproc) - SELECT opcl.oid, 1, pro.oid - FROM pg_opclass opcl, pg_proc pro - WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops' - and proname = 'complex_abs_cmp'; -- now, we can define a btree index on complex types. First, let's populate -- the table. Note that postgres needs many more tuples to start using the @@ -259,35 +191,8 @@ SELECT * from test_complex where a = '(56.0,-22.5)'; SELECT * from test_complex where a < '(56.0,-22.5)'; SELECT * from test_complex where a > '(56.0,-22.5)'; -DELETE FROM pg_amop WHERE - amopclaid = (SELECT oid FROM pg_opclass WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops'); -DELETE FROM pg_amproc WHERE - amopclaid = (SELECT oid FROM pg_opclass WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops'); - -DELETE FROM pg_opclass WHERE - opcamid = (SELECT oid FROM pg_am WHERE amname = 'btree') - and opcname = 'complex_abs_ops'; - -DROP FUNCTION complex_in(opaque); +-- clean up the example +DROP TABLE test_complex; +DROP TYPE complex CASCADE; DROP FUNCTION complex_out(opaque); -DROP FUNCTION complex_add(complex, complex); -DROP FUNCTION complex_abs_lt(complex, complex); -DROP FUNCTION complex_abs_le(complex, complex); -DROP FUNCTION complex_abs_eq(complex, complex); -DROP FUNCTION complex_abs_ge(complex, complex); -DROP FUNCTION complex_abs_gt(complex, complex); -DROP FUNCTION complex_abs_cmp(complex, complex); -DROP OPERATOR + (complex, complex); -DROP OPERATOR < (complex, complex); -DROP OPERATOR <= (complex, complex); -DROP OPERATOR = (complex, complex); -DROP OPERATOR >= (complex, complex); -DROP OPERATOR > (complex, complex); -DROP AGGREGATE complex_sum (complex); -DROP TYPE complex; -DROP TABLE test_complex, complex_ops_tmp;