diff --git a/doc/manual/admin.html b/doc/manual/admin.html new file mode 100644 index 00000000000..be24aca1e60 --- /dev/null +++ b/doc/manual/admin.html @@ -0,0 +1,539 @@ + +
++
+
/usr/local/postgres95/bin
is in your
+ shell command path, because the postmaster will use
+ your PATH to locate POSTGRES commands.+
+
+
SELECT * from EMP where salary < 5000 ++ then a B-tree index on the salary attribute will + probably be useful. If scans involving equality + are more common, as in + +
SELECT * from EMP where salary = 5000 ++ then you should consider defining a hash index + on salary. You can define both, though it will + use more disk space and may slow down updates a + bit. Scans using indices are much faster than + sequential scans of the entire class.
+
+
EMP.salary = 5000 ++ The POSTGRES query optimizer will only use an + index with a constant qualification of this + form. It doesn't hurt to write the clause as + +
5000 = EMP.salary ++ if the operator (in this case, =) has a commutator + operator defined so that POSTGRES can + rewrite the query into the desired form. However, + if such an operator does not exist, POSTGRES + will never consider the use of an index.
+
where A.a = B.b and B.b = C.c and ... ++ Notice that relatively few clauses refer to a + given class and attribute; the clauses form a + linear sequence connecting the attributes, like + links in a chain. This is preferable to a query + written in a "star" form, such as + +
where A.a = B.b and A.a = C.c and ... ++ Here, many clauses refer to the same class and + attribute (in this case, A.a). When presented + with a query of this form, the POSTGRES query + optimizer will tend to consider far more choices + than it should and may run out of memory.
+
FATAL: no response from backend: detected in ... ++ This generally means one of two things: there is a bug + in the POSTGRES server, or there is a bug in some user + code that has been dynamically loaded into POSTGRES. + You should be able to restart your application and + resume processing, but there are some considerations: +
/usr/local/postgres95/data/base/<database>/core ++ on the server machine. If you don't want to try + to debug the problem or produce a stack trace to + report the bug to someone else, you can delete + this file (which is probably around 10MB).
+
I have been signalled by the postmaster. + Some backend process has died unexpectedly and possibly + corrupted shared memory. The current transaction was + aborted, and I am going to exit. Please resend the + last query. -- The postgres backend +
WARN: cannot write block 34 of myclass [mydb] blind ++ In this case, you should kill the postmaster and + restart it.
+
+
/usr/local/postgres95/data/base
.[10] At some point, you
+ may find that you wish to move one or more databases to
+ another location (e.g., to a filesystem with more free
+ space).
+ If you wish to move all of your databases to the new
+ location, you can simply:
+ +
% cp -rp /usr/local/postgres95/data /new/place/data +
+
# using csh or tcsh... + % setenv PGDATA /new/place/data + + # using sh, ksh or bash... + % PGDATA=/new/place/data; export PGDATA + +
+
% postmaster & +
+
% rm -rf /usr/local/postgres95/data +
+
+
+
/usr/local/postgres95/data/base/foo
and its contents
+ to its ultimate destination. It should still be
+ owned by the "postgres" user.
+
+% cp -rp /usr/local/postgres95/data/base/foo /new/place/foo ++
/usr/local/postgres95/data/base/foo
:
+
+% rm -rf /usr/local/postgres95/data/base/foo ++
/usr/local/postgres95/data/base
to the new directory:
+
+% ln -s /new/place/foo /usr/local/postgres95/data/base/foo ++
+
+
/usr/local/postgres95/tutorial/syscat.sql ++ so use cut-and-paste (or the \i command) instead of + doing a lot of typing. + This query prints the names of all database adminstrators + and the name of their database(s). +
SELECT usename, datname + FROM pg_user, pg_database + WHERE usesysid = int2in(int4out(datdba)) + ORDER BY usename, datname; ++ This query lists all user-defined classes in the + database. +
SELECT relname + FROM pg_class + WHERE relkind = 'r' -- not indices + and relname !~ '^pg_' -- not catalogs + and relname !~ '^Inv' -- not large objects + ORDER BY relname; ++ This query lists all simple indices (i.e., those that + are not defined over a function of several attributes). +
SELECT bc.relname AS class_name, + ic.relname AS index_name, + a.attname + FROM pg_class bc, -- base class + pg_class ic, -- index class + pg_index i, + pg_attribute a -- att in base + WHERE i.indrelid = bc.oid + and i.indexrelid = ic.oid + and i.indkey[0] = a.attnum + and a.attrelid = bc.oid + and i.indproc = '0'::oid -- no functional indices + ORDER BY class_name, index_name, attname; ++ This query prints a report of the user-defined + attributes and their types for all user-defined classes + in the database. +
SELECT c.relname, a.attname, t.typname + FROM pg_class c, pg_attribute a, pg_type t + WHERE c.relkind = 'r' -- no indices + and c.relname !~ '^pg_' -- no catalogs + and c.relname !~ '^Inv' -- no large objects + and a.attnum > 0 -- no system att's + and a.attrelid = c.oid + and a.atttypid = t.oid + ORDER BY relname, attname; ++ This query lists all user-defined base types (not + including array types). +
SELECT u.usename, t.typname + FROM pg_type t, pg_user u + WHERE u.usesysid = int2in(int4out(t.typowner)) + and t.typrelid = '0'::oid -- no complex types + and t.typelem = '0'::oid -- no arrays + and u.usename <> 'postgres' + ORDER BY usename, typname; ++ This query lists all left-unary (post-fix) operators. +
SELECT o.oprname AS left_unary, + right.typname AS operand, + result.typname AS return_type + FROM pg_operator o, pg_type right, pg_type result + WHERE o.oprkind = 'l' -- left unary + and o.oprright = right.oid + and o.oprresult = result.oid + ORDER BY operand; ++ This query lists all right-unary (pre-fix) operators. +
SELECT o.oprname AS right_unary, + left.typname AS operand, + result.typname AS return_type + FROM pg_operator o, pg_type left, pg_type result + WHERE o.oprkind = 'r' -- right unary + and o.oprleft = left.oid + and o.oprresult = result.oid + ORDER BY operand; ++ This query lists all binary operators. +
SELECT o.oprname AS binary_op, + left.typname AS left_opr, + right.typname AS right_opr, + result.typname AS return_type + FROM pg_operator o, pg_type left, pg_type right, pg_type result + WHERE o.oprkind = 'b' -- binary + and o.oprleft = left.oid + and o.oprright = right.oid + and o.oprresult = result.oid + ORDER BY left_opr, right_opr; ++ This query returns the name, number of arguments + (parameters) and return type of all user-defined C + functions. The same query can be used to find all + built-in C functions if you change the "C" to "internal", + or all SQL functions if you change the "C" to + "sql". +
SELECT p.proname, p.pronargs, t.typname + FROM pg_proc p, pg_language l, pg_type t + WHERE p.prolang = l.oid + and p.prorettype = t.oid + and l.lanname = 'c' + ORDER BY proname; ++ This query lists all of the aggregate functions that + have been installed and the types to which they can be + applied. count is not included because it can take any + type as its argument. +
SELECT a.aggname, t.typname + FROM pg_aggregate a, pg_type t + WHERE a.aggbasetype = t.oid + ORDER BY aggname, typname; ++ This query lists all of the operator classes that can + be used with each access method as well as the operators + that can be used with the respective operator + classes. +
SELECT am.amname, opc.opcname, opr.oprname + FROM pg_am am, pg_amop amop, pg_opclass opc, pg_operator opr + WHERE amop.amopid = am.oid + and amop.amopclaid = opc.oid + and amop.amopopr = opr.oid + ORDER BY amname, opcname, oprname; ++
+ +
advance.sql
in the tutorial directory. (Refer to the
+ introduction of the previous chapter for how to use
+ it.)
+
+CREATE TABLE cities ( + name text, + population float, + altitude int -- (in ft) + ); + + CREATE TABLE capitals ( + state char2 + ) INHERITS (cities); ++ In this case, an instance of capitals inherits all + attributes (name, population, and altitude) from its + parent, cities. The type of the attribute name is + text, a built-in POSTGRES type for variable length + ASCII strings. The type of the attribute population is + float4, a built-in POSTGRES type for double precision + floating point numbres. State capitals have an extra + attribute, state, that shows their state. In POSTGRES, + a class can inherit from zero or more other classes,[4] + and a query can reference either all instances of a + class or all instances of a class plus all of its + descendants. For example, the following query finds + all the cities that are situated at an attitude of 500 + 'ft or higher: + +
SELECT name, altitude + FROM cities + WHERE altitude > 500; + + + +----------+----------+ + |name | altitude | + +----------+----------+ + |Las Vegas | 2174 | + +----------+----------+ + |Mariposa | 1953 | + +----------+----------+ ++ On the other hand, to find the names of all cities, + including state capitals, that are located at an altitude + over 500 'ft, the query is: + +
SELECT c.name, c.altitude + FROM cities* c + WHERE c.altitude > 500; ++ which returns: + +
+----------+----------+ + |name | altitude | + +----------+----------+ + |Las Vegas | 2174 | + +----------+----------+ + |Mariposa | 1953 | + +----------+----------+ + |Madison | 845 | + +----------+----------+ ++ Here the * after cities indicates that the query should + be run over cities and all classes below cities in the + inheritance hierarchy. Many of the commands that we + have already discussed -- select, update and delete -- + support this * notation, as do others, like alter command. + +
SELECT * FROM cities WHERE name = 'Mariposa'; + + +---------+------------+----------+ + |name | population | altitude | + +---------+------------+----------+ + |Mariposa | 1320 | 1953 | + +---------+------------+----------+ ++ POSTGRES will automatically find the version of Mariposa's + record valid at the current time. + One can also give a time range. For example to see the + past and present populations of Mariposa, one would + query: + +
SELECT name, population + FROM cities['epoch', 'now'] + WHERE name = 'Mariposa'; ++ where "epoch" indicates the beginning of the system + clock.[5] If you have executed all of the examples so + far, then the above query returns: + +
+---------+------------+ + |name | population | + +---------+------------+ + |Mariposa | 1200 | + +---------+------------+ + |Mariposa | 1320 | + +---------+------------+ ++ The default beginning of a time range is the earliest + time representable by the system and the default end is + the current time; thus, the above time range can be + abbreviated as ``[,].'' + +
* CREATE TABLE SAL_EMP ( + name text, + pay_by_quarter int4[], + schedule char16[][] + ); ++ The above query will create a class named SAL_EMP with + a text string (name), a one-dimensional array of int4 + (pay_by_quarter), which represents the employee's + salary by quarter and a two-dimensional array of char16 + (schedule), which represents the employee's weekly + schedule. Now we do some INSERTSs; note that when + appending to an array, we enclose the values within + braces and separate them by commas. If you know C, + this is not unlike the syntax for initializing structures. + +
INSERT INTO SAL_EMP + VALUES ('Bill', + '{10000, 10000, 10000, 10000}', + '{{"meeting", "lunch"}, {}}'); + + INSERT INTO SAL_EMP + VALUES ('Carol', + '{20000, 25000, 25000, 25000}', + '{{"talk", "consult"}, {"meeting"}}'); ++ By default, POSTGRES uses the "one-based" numbering + convention for arrays -- that is, an array of n elements starts with array[1] and ends with array[n]. + Now, we can run some queries on SAL_EMP. First, we + show how to access a single element of an array at a + time. This query retrieves the names of the employees + whose pay changed in the second quarter: + +
* SELECT name + FROM SAL_EMP + WHERE SAL_EMP.pay_by_quarter[1] <> + SAL_EMP.pay_by_quarter[2]; + + +------+ + |name | + +------+ + |Carol | + +------+ ++ This query retrieves the third quarter pay of all + employees: + +
* SELECT SAL_EMP.pay_by_quarter[3] FROM SAL_EMP; + + + +---------------+ + |pay_by_quarter | + +---------------+ + |10000 | + +---------------+ + |25000 | + +---------------+ ++ We can also access arbitrary slices of an array, or + subarrays. This query retrieves the first item on + Bill's schedule for the first two days of the week. + +
* SELECT SAL_EMP.schedule[1:2][1:1] + FROM SAL_EMP + WHERE SAL_EMP.name = 'Bill'; + + +-------------------+ + |schedule | + +-------------------+ + |{{"meeting"},{""}} | + +-------------------+ + ++
+
+ The following general restrictions and notes also apply + to the discussion below. +
+ULTRIX
+ It is very easy to build dynamically-loaded object
+ files under ULTRIX. ULTRIX does not have any sharedlibrary
+ mechanism and hence does not place any restrictions on
+ the dynamic loader interface. On the other
+ hand, we had to (re)write a non-portable dynamic loader
+ ourselves and could not use true shared libraries.
+ Under ULTRIX, the only restriction is that you must
+ produce each object file with the option -G 0. (Notice
+ that that's the numeral ``0'' and not the letter
+ ``O''). For example,
+
+
# simple ULTRIX example + % cc -G 0 -c foo.c ++ produces an object file called foo.o that can then be + dynamically loaded into POSTGRES. No additional loading or link-editing must be performed. +
+DEC OSF/1
+ Under DEC OSF/1, you can take any simple object file
+ and produce a shared object file by running the ld command over it with the correct options. The commands to
+ do this look like:
+
+
# simple DEC OSF/1 example + % cc -c foo.c + % ld -shared -expect_unresolved '*' -o foo.so foo.o ++ The resulting shared object file can then be loaded + into POSTGRES. When specifying the object file name to + the create function command, one must give it the name + of the shared object file (ending in .so) rather than + the simple object file.13 If the file you specify is + not a shared object, the backend will hang! +
+SunOS 4.x, Solaris 2.x and HP-UX
+ Under both SunOS 4.x, Solaris 2.x and HP-UX, the simple
+ object file must be created by compiling the source
+ file with special compiler flags and a shared library
+ must be produced.
+ The necessary steps with HP-UX are as follows. The +z
+ flag to the HP-UX C compiler produces so-called
+ "Position Independent Code" (PIC) and the +u flag
+ removes
+ some alignment restrictions that the PA-RISC architecture
+ normally enforces. The object file must be turned
+ into a shared library using the HP-UX link editor with
+ the -b option. This sounds complicated but is actually
+ very simple, since the commands to do it are just:
+
# simple HP-UX example + % cc +z +u -c foo.c + % ld -b -o foo.sl foo.o ++ + As with the .so files mentioned in the last subsection, + the create function command must be told which file is + the correct file to load (i.e., you must give it the + location of the shared library, or .sl file). + Under SunOS 4.x, the commands look like: + +
# simple SunOS 4.x example + % cc -PIC -c foo.c + % ld -dc -dp -Bdynamic -o foo.so foo.o ++ and the equivalent lines under Solaris 2.x are: +
# simple Solaris 2.x example + % cc -K PIC -c foo.c + or + % gcc -fPIC -c foo.c + % ld -G -Bdynamic -o foo.so foo.o ++ When linking shared libraries, you may have to specify + some additional shared libraries (typically system + libraries, such as the C and math libraries) on your ld + command line. +
+ IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE + LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, + INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST + PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND + ITS DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA + HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. + THE UNIVERSITY OF CALIFORNIA SPECIFICALLY + DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, + THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS + FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED + HEREUNDER IS ON AN "AS IS" BASIS, AND THE UNIVERSITY OF + CALIFORNIA HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, + SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. + + + + diff --git a/doc/manual/extend.html b/doc/manual/extend.html new file mode 100644 index 00000000000..a3cdfc06211 --- /dev/null +++ b/doc/manual/extend.html @@ -0,0 +1,199 @@ + +
++
int4
, that are implemented
+ in a language such as C. They generally correspond to
+ what are often known as "abstract data types"; POSTGRES
+ can only operate on such types through methods provided
+ by the user and only understands the behavior of such
+ types to the extent that the user describes them.
+ Composite types are created whenever the user creates a
+ class. EMP is an example of a composite type.
+ POSTGRES stores these types in only one way (within the
+ file that stores all instances of the class) but the
+ user can "look inside" at the attributes of these types
+ from the query language and optimize their retrieval by
+ (for example) defining indices on the attributes.
+ POSTGRES base types are further divided into built-in
+ types and user-defined types. Built-in types (like
+ int4
) are those that are compiled into the system.
+ User-defined types are those created by the user in the
+ manner to be described below.
+
+pg_
.
+ The following classes contain information that may be
+ useful to the end user. (There are many other system
+ catalogs, but there should rarely be a reason to query
+ them directly.)
+ +
catalog name | description | +
---|---|
pg_database | databases | +
pg_class | classes | +
pg_attribute | class attributes | +
pg_index | secondary indices | +
pg_proc | procedures (both C and SQL) | +
pg_type | types (both base and complex) | +
pg_operator | operators | +
pg_aggregate | aggregates and aggregate functions | +
pg_am | access methods | +
pg_amop | access method operators | +
pg_amproc | access method support functions | +
pg_opclass | access method operator classes | +
+
+ The Reference Manual gives a more detailed explanation
+ of these catalogs and their attributes. However, Figure 3
+ shows the major entities and their relationships
+ in the system catalogs. (Attributes that do not refer
+ to other entities are not shown unless they are part of
+ a primary key.)
+ This diagram is more or less incomprehensible until you
+ actually start looking at the contents of the catalogs
+ and see how they relate to each other. For now, the
+ main things to take away from this diagram are as follows:
+
+
pg_am, pg_amop, pg_amproc, pg_operator
and
+ pg_opclass
are particularly hard to understand
+ and will be described in depth (in the section
+ on interfacing types and operators to indices)
+ after we have discussed basic extensions.
++
+
classes + inheritance + types + functions +
+ In addition, POSTGRES supports a powerful production + rule system. + +
+
+
Architecture | +Processor | +Operating System | +
---|---|---|
DECstation 3000 | +Alpha AXP | +OSF/1 2.1, 3.0, 3.2 | +
DECstation 5000 | +MIPS | +ULTRIX 4.4 | +
Sun4 | +SPARC | +SunOS 4.1.3, 4.1.3_U1; Solaris 2.4 | +
H-P 9000/700 and 800 | +PA-RISC | +HP-UX 9.00, 9.01, 9.03 | +
Intel | +X86 | +Linux 1.2.8, ELF | +
+
+ + We assume proficiency with UNIX and C programming. + +
../src/test/regress + ../src/test/examples + ../src/bin/psql ++ Frontend programs which use LIBPQ must include the + header file
libpq-fe.h
and must link with the libpq
+ library.
+
+PGconn *PQsetdb(char *pghost, + char *pgport, + char *pgoptions, + char *pgtty, + char *dbName); ++
char *PQdb(PGconn *conn) +
char *PQhost(PGconn *conn) +
char *PQoptions(PGconn *conn) +
char *PQport(PGconn *conn) +
char *PQtty(PGconn *conn) +
ConnStatusType *PQstatus(PGconn *conn) +
char *PQerrorMessage(PGconn* conn); +
void PQfinish(PGconn *conn) +
void PQreset(PGconn *conn) +
void PQtrace(PGconn *conn, + FILE* debug_port); +
void PQuntrace(PGconn *conn); +
PGresult *PQexec(PGconn *conn, + char *query); ++
PGRES_EMPTY_QUERY, + PGRES_COMMAND_OK, /* the query was a command */ + PGRES_TUPLES_OK, /* the query successfully returned tuples */ + PGRES_COPY_OUT, + PGRES_COPY_IN, + PGRES_BAD_RESPONSE, /* an unexpected response was received */ + PGRES_NONFATAL_ERROR, + PGRES_FATAL_ERROR ++
int PQntuples(PGresult *res); +
int PQnfields(PGresult *res); +
char *PQfname(PGresult *res, + int field_index); +
int PQfnumber(PGresult *res, + char* field_name); +
Oid PQftype(PGresult *res, + int field_num); +
int2 PQfsize(PGresult *res, + int field_index); +
char* PQgetvalue(PGresult *res, + int tup_num, + int field_num); +
int PQgetlength(PGresult *res, + int tup_num, + int field_num); +
+ char *PQcmdStatus(PGresult *res); +
char* PQoidStatus(PGresult *res); +
void PQprintTuples( + PGresult* res, + FILE* fout, /* output stream */ + int printAttName,/* print attribute names or not*/ + int terseOutput, /* delimiter bars or not?*/ + int width /* width of column, variable width if 0*/ + ); +
void PQclear(PQresult *res); +
PGresult* PQfn(PGconn* conn, + int fnid, + int *result_buf, + int *result_len, + int result_is_int, + PQArgBlock *args, + int nargs); +
typedef struct { + int len; + int isint; + union { + int *ptr; + int integer; + } u; + } PQArgBlock; ++ PQfn always returns a valid PGresult*. The resultStatus should be checked before the result is used. The + caller is responsible for freeing the PGresult with + PQclear when it is not longer needed. +
PGnotify* PQNotifies(PGconn *conn); +
../src/bin/psql/psql.c ++ contains routines that correctly handle the copy + protocol. +
int PQgetline(PGconn *conn, + char *string, + int length) +
void PQputline(PGconn *conn, + char *string); +
int PQendcopy(PGconn *conn); +
PQexec(conn, "create table foo (a int4, b char16, d float8)"); + PQexec(conn, "copy foo from stdin"); + PQputline(conn, "3<TAB>hello world<TAB>4.5\n"); + PQputline(conn,"4<TAB>goodbye world<TAB>7.11\n"); + ... + PQputline(conn,".\n"); + PQendcopy(conn); +
void PQtrace(PGconn *conn + FILE *debug_port) +
void PQuntrace(PGconn *conn) +
/etc/passwd
.
+
+char *fe_getauthname(char* errorMessage) +
void fe_setauthsvc(char *name, + char* errorMessage) ++
+
+ /* + * testlibpq.c + * Test the C version of LIBPQ, the POSTGRES frontend library. + * + * + */ + #include <stdio.h> + #include "libpq-fe.h" +++ void + exit_nicely(PGconn* conn) + { + PQfinish(conn); + exit(1); + } +
+ main() + { + char *pghost, *pgport, *pgoptions, *pgtty; + char* dbName; + int nFields; + int i,j; +
+ /* FILE *debug; */ +
+ PGconn* conn; + PGresult* res; +
+ /* begin, by setting the parameters for a backend connection + if the parameters are null, then the system will try to use + reasonable defaults by looking up environment variables + or, failing that, using hardwired constants */ + pghost = NULL; /* host name of the backend server */ + pgport = NULL; /* port of the backend server */ + pgoptions = NULL; /* special options to start up the backend server */ + pgtty = NULL; /* debugging tty for the backend server */ + dbName = "template1"; +
+ /* make a connection to the database */ + conn = PQsetdb(pghost, pgport, pgoptions, pgtty, dbName); +
+ /* check to see that the backend connection was successfully made */ + if (PQstatus(conn) == CONNECTION_BAD) { + fprintf(stderr,"Connection to database '%s' failed.0, dbName); + fprintf(stderr,"%s",PQerrorMessage(conn)); + exit_nicely(conn); + } +
+ /* debug = fopen("/tmp/trace.out","w"); */ + /* PQtrace(conn, debug); */ +
+ /* start a transaction block */ + + res = PQexec(conn,"BEGIN"); + if (PQresultStatus(res) != PGRES_COMMAND_OK) { + fprintf(stderr,"BEGIN command failed0); + PQclear(res); + exit_nicely(conn); + } + /* should PQclear PGresult whenever it is no longer needed to avoid + memory leaks */ + PQclear(res); +
+ /* fetch instances from the pg_database, the system catalog of databases*/ + res = PQexec(conn,"DECLARE myportal CURSOR FOR select * from pg_database"); + if (PQresultStatus(res) != PGRES_COMMAND_OK) { + fprintf(stderr,"DECLARE CURSOR command failed0); + PQclear(res); + exit_nicely(conn); + } + PQclear(res); +
+ res = PQexec(conn,"FETCH ALL in myportal"); + if (PQresultStatus(res) != PGRES_TUPLES_OK) { + fprintf(stderr,"FETCH ALL command didn't return tuples properly0); + PQclear(res); + exit_nicely(conn); + } +
+ /* first, print out the attribute names */ + nFields = PQnfields(res); + for (i=0; i < nFields; i++) { + printf("%-15s",PQfname(res,i)); + } + printf("0); +
+ /* next, print out the instances */ + for (i=0; i < PQntuples(res); i++) { + for (j=0 ; j < nFields; j++) { + printf("%-15s", PQgetvalue(res,i,j)); + } + printf("0); + } +
+ PQclear(res); +
+ /* close the portal */ + res = PQexec(conn, "CLOSE myportal"); + PQclear(res); +
+ /* end the transaction */ + res = PQexec(conn, "END"); + PQclear(res); +
+ /* close the connection to the database and cleanup */ + PQfinish(conn); + + /* fclose(debug); */ + } +
+
+ /* + * testlibpq2.c + * Test of the asynchronous notification interface + * + populate a database with the following: +++ CREATE TABLE TBL1 (i int4); +
+ CREATE TABLE TBL2 (i int4); +
+ CREATE RULE r1 AS ON INSERT TO TBL1 DO [INSERT INTO TBL2 values (new.i); NOTIFY TBL2]; +
+ * Then start up this program + * After the program has begun, do +
+ INSERT INTO TBL1 values (10); +
+ * + * + */ + #include <stdio.h> + #include "libpq-fe.h" +
+ void exit_nicely(PGconn* conn) + { + PQfinish(conn); + exit(1); + } +
+ main() + { + char *pghost, *pgport, *pgoptions, *pgtty; + char* dbName; + int nFields; + int i,j; +
+ PGconn* conn; + PGresult* res; + PGnotify* notify; +
+ /* begin, by setting the parameters for a backend connection + if the parameters are null, then the system will try to use + reasonable defaults by looking up environment variables + or, failing that, using hardwired constants */ + pghost = NULL; /* host name of the backend server */ + pgport = NULL; /* port of the backend server */ + pgoptions = NULL; /* special options to start up the backend server */ + pgtty = NULL; /* debugging tty for the backend server */ + dbName = getenv("USER"); /* change this to the name of your test database*/ +
+ /* make a connection to the database */ + conn = PQsetdb(pghost, pgport, pgoptions, pgtty, dbName); + + /* check to see that the backend connection was successfully made */ + if (PQstatus(conn) == CONNECTION_BAD) { + fprintf(stderr,"Connection to database '%s' failed.0, dbName); + fprintf(stderr,"%s",PQerrorMessage(conn)); + exit_nicely(conn); + } +
+ res = PQexec(conn, "LISTEN TBL2"); + if (PQresultStatus(res) != PGRES_COMMAND_OK) { + fprintf(stderr,"LISTEN command failed0); + PQclear(res); + exit_nicely(conn); + } + /* should PQclear PGresult whenever it is no longer needed to avoid + memory leaks */ + PQclear(res); +
+ while (1) { + /* async notification only come back as a result of a query*/ + /* we can send empty queries */ + res = PQexec(conn, " "); + /* printf("res->status = %s0, pgresStatus[PQresultStatus(res)]); */ + /* check for asynchronous returns */ + notify = PQnotifies(conn); + if (notify) { + fprintf(stderr, + "ASYNC NOTIFY of '%s' from backend pid '%d' received0, + notify->relname, notify->be_pid); + free(notify); + break; + } + PQclear(res); + } +
+ /* close the connection to the database and cleanup */ + PQfinish(conn); +
+ } +
+
+ /* + * testlibpq3.c + * Test the C version of LIBPQ, the POSTGRES frontend library. + * tests the binary cursor interface + * + * + * + populate a database by doing the following: +++ CREATE TABLE test1 (i int4, d float4, p polygon); +
+ INSERT INTO test1 values (1, 3.567, '(3.0, 4.0, 1.0, 2.0)'::polygon); +
+ INSERT INTO test1 values (2, 89.05, '(4.0, 3.0, 2.0, 1.0)'::polygon); +
+ the expected output is: +
+ tuple 0: got + i = (4 bytes) 1, + d = (4 bytes) 3.567000, + p = (4 bytes) 2 points boundbox = (hi=3.000000/4.000000, lo = 1.000000,2.000000) + tuple 1: got + i = (4 bytes) 2, + d = (4 bytes) 89.050003, + p = (4 bytes) 2 points boundbox = (hi=4.000000/3.000000, lo = 2.000000,1.000000) +
+ * + */ + #include <stdio.h> + #include "libpq-fe.h" + #include "utils/geo-decls.h" /* for the POLYGON type */ +
+ void exit_nicely(PGconn* conn) + { + PQfinish(conn); + exit(1); + } +
+ main() + { + char *pghost, *pgport, *pgoptions, *pgtty; + char* dbName; + int nFields; + int i,j; + int i_fnum, d_fnum, p_fnum; +
+ PGconn* conn; + PGresult* res; +
+ /* begin, by setting the parameters for a backend connection + if the parameters are null, then the system will try to use + reasonable defaults by looking up environment variables + or, failing that, using hardwired constants */ + pghost = NULL; /* host name of the backend server */ + pgport = NULL; /* port of the backend server */ + pgoptions = NULL; /* special options to start up the backend server */ + pgtty = NULL; /* debugging tty for the backend server */ +
+ dbName = getenv("USER"); /* change this to the name of your test database*/ +
+ /* make a connection to the database */ + conn = PQsetdb(pghost, pgport, pgoptions, pgtty, dbName); +
+ /* check to see that the backend connection was successfully made */ + if (PQstatus(conn) == CONNECTION_BAD) { + fprintf(stderr,"Connection to database '%s' failed.0, dbName); + fprintf(stderr,"%s",PQerrorMessage(conn)); + exit_nicely(conn); + } +
+ /* start a transaction block */ + res = PQexec(conn,"BEGIN"); + if (PQresultStatus(res) != PGRES_COMMAND_OK) { + fprintf(stderr,"BEGIN command failed0); + PQclear(res); + exit_nicely(conn); + } + /* should PQclear PGresult whenever it is no longer needed to avoid + memory leaks */ + PQclear(res); +
+ /* fetch instances from the pg_database, the system catalog of databases*/ + res = PQexec(conn,"DECLARE mycursor BINARY CURSOR FOR select * from test1"); + if (PQresultStatus(res) != PGRES_COMMAND_OK) { + fprintf(stderr,"DECLARE CURSOR command failed0); + PQclear(res); + exit_nicely(conn); + } + PQclear(res); +
+ res = PQexec(conn,"FETCH ALL in mycursor"); + if (PQresultStatus(res) != PGRES_TUPLES_OK) { + fprintf(stderr,"FETCH ALL command didn't return tuples properly0); + PQclear(res); + exit_nicely(conn); + } +
+ i_fnum = PQfnumber(res,"i"); + d_fnum = PQfnumber(res,"d"); + p_fnum = PQfnumber(res,"p"); +
+ for (i=0;i<3;i++) { + printf("type[%d] = %d, size[%d] = %d0, + i, PQftype(res,i), + i, PQfsize(res,i)); + } + for (i=0; i < PQntuples(res); i++) { + int *ival; + float *dval; + int plen; + POLYGON* pval; + /* we hard-wire this to the 3 fields we know about */ + ival = (int*)PQgetvalue(res,i,i_fnum); + dval = (float*)PQgetvalue(res,i,d_fnum); + plen = PQgetlength(res,i,p_fnum); +
+ /* plen doesn't include the length field so need to increment by VARHDSZ*/ + pval = (POLYGON*) malloc(plen + VARHDRSZ); + pval->size = plen; + memmove((char*)&pval->npts, PQgetvalue(res,i,p_fnum), plen); + printf("tuple %d: got0, i); + printf(" i = (%d bytes) %d,0, + PQgetlength(res,i,i_fnum), *ival); + printf(" d = (%d bytes) %f,0, + PQgetlength(res,i,d_fnum), *dval); + printf(" p = (%d bytes) %d points boundbox = (hi=%f/%f, lo = %f,%f)0, + PQgetlength(res,i,d_fnum), + pval->npts, + pval->boundbox.xh, + pval->boundbox.yh, + pval->boundbox.xl, + pval->boundbox.yl); + } +
+ PQclear(res); +
+ /* close the portal */ + res = PQexec(conn, "CLOSE mycursor"); + PQclear(res); +
+ /* end the transaction */ + res = PQexec(conn, "END"); + PQclear(res); +
+ /* close the connection to the database and cleanup */ + PQfinish(conn); +
+ } +
+
Oid lo_creat(PGconn *conn, int mode) ++ creates a new large object. The mode is a bitmask + describing several different attributes of the new + object. The symbolic constants listed here are defined + in +
/usr/local/postgres95/src/backend/libpq/libpq-fs.h ++ The access type (read, write, or both) is controlled by + OR ing together the bits INV_READ and INV_WRITE. If + the large object should be archived -- that is, if + historical versions of it should be moved periodically to + a special archive relation -- then the INV_ARCHIVE bit + should be set. The low-order sixteen bits of mask are + the storage manager number on which the large object + should reside. For sites other than Berkeley, these + bits should always be zero. + The commands below create an (Inversion) large object: +
inv_oid = lo_creat(INV_READ|INV_WRITE|INV_ARCHIVE); ++ +
Oid + lo_import(PGconn *conn, text *filename) ++ The filename argument specifies the UNIX pathname of + the file to be imported as a large object. +
+
int + lo_export(PGconn *conn, Oid lobjId, text *filename) ++ The lobjId argument specifies the Oid of the large + object to export and the filename argument specifies + the UNIX pathname of the file. +
+
int + lo_open(PGconn *conn, Oid lobjId, int mode, ...) ++ The lobjId argument specifies the Oid of the large + object to open. The mode bits control whether the + object is opened for reading INV_READ), writing or + both. + A large object cannot be opened before it is created. + lo_open returns a large object descriptor for later use + in lo_read, lo_write, lo_lseek, lo_tell, and lo_close. +
+
int + lo_write(PGconn *conn, int fd, char *buf, int len) ++ writes len bytes from buf to large object fd. The fd + argument must have been returned by a previous lo_open. + The number of bytes actually written is returned. In + the event of an error, the return value is negative. +
+
int + lo_lseek(PGconn *conn, int fd, int offset, int whence) ++ This routine moves the current location pointer for the + large object described by fd to the new location specified + by offset. The valid values for .i whence are + SEEK_SET SEEK_CUR and SEEK_END. +
+
int + lo_close(PGconn *conn, int fd) ++ where fd is a large object descriptor returned by + lo_open. On success, lo_close returns zero. On error, + the return value is negative. + +
CREATE TABLE image ( + name text, + raster oid + ); + + INSERT INTO image (name, raster) + VALUES ('beautiful image', lo_import('/etc/motd')); + + SELECT lo_export(image.raster, "/tmp/motd") from image + WHERE name = 'beautiful image'; ++
../src/test/examples ++ Frontend applications which use the large object interface + in LIBPQ should include the header file + libpq/libpq-fs.h and link with the libpq library. + +
/*-------------------------------------------------------------- + * + * testlo.c-- + * test using large objects with libpq + * + * Copyright (c) 1994, Regents of the University of California + * + * + * IDENTIFICATION + * /usr/local/devel/pglite/cvs/src/doc/manual.me,v 1.16 1995/09/01 23:55:00 jolly Exp + * + *-------------------------------------------------------------- + */ + #include <stdio.h> + #include "libpq-fe.h" + #include "libpq/libpq-fs.h" +++ #define BUFSIZE 1024 +
+ /* + * importFile * import file "in_filename" into database as large object "lobjOid" + * + */ + Oid importFile(PGconn *conn, char *filename) + { + Oid lobjId; + int lobj_fd; + char buf[BUFSIZE]; + int nbytes, tmp; + int fd; +
+ /* + * open the file to be read in + */ + fd = open(filename, O_RDONLY, 0666); + if (fd < 0) { /* error */ + fprintf(stderr, "can't open unix file + } +
+ /* + * create the large object + */ + lobjId = lo_creat(conn, INV_READ|INV_WRITE); + if (lobjId == 0) { + fprintf(stderr, "can't create large object"); + } +
+ lobj_fd = lo_open(conn, lobjId, INV_WRITE); + /* + * read in from the Unix file and write to the inversion file + */ + while ((nbytes = read(fd, buf, BUFSIZE)) > 0) { + tmp = lo_write(conn, lobj_fd, buf, nbytes); + if (tmp < nbytes) { + fprintf(stderr, "error while reading + } + } +
+ (void) close(fd); + (void) lo_close(conn, lobj_fd); +
+ return lobjId; + } +
+ void pickout(PGconn *conn, Oid lobjId, int start, int len) + { + int lobj_fd; + char* buf; + int nbytes; + int nread; +
+ lobj_fd = lo_open(conn, lobjId, INV_READ); + if (lobj_fd < 0) { + fprintf(stderr,"can't open large object %d", + lobjId); + } +
+ lo_lseek(conn, lobj_fd, start, SEEK_SET); + buf = malloc(len+1); +
+ nread = 0; + while (len - nread > 0) { + nbytes = lo_read(conn, lobj_fd, buf, len - nread); + buf[nbytes] = ' '; + fprintf(stderr,">>> %s", buf); + nread += nbytes; + } + fprintf(stderr,"0); + lo_close(conn, lobj_fd); + } +
+ void overwrite(PGconn *conn, Oid lobjId, int start, int len) + { + int lobj_fd; + char* buf; + int nbytes; + int nwritten; + int i; +
+ lobj_fd = lo_open(conn, lobjId, INV_READ); + if (lobj_fd < 0) { + fprintf(stderr,"can't open large object %d", + lobjId); + } +
+ lo_lseek(conn, lobj_fd, start, SEEK_SET); + buf = malloc(len+1); +
+ for (i=0;i<len;i++) + buf[i] = 'X'; + buf[i] = ' '; +
+ nwritten = 0; + while (len - nwritten > 0) { + nbytes = lo_write(conn, lobj_fd, buf + nwritten, len - nwritten); + nwritten += nbytes; + } + fprintf(stderr,"0); + lo_close(conn, lobj_fd); + } +
+ + /* + * exportFile * export large object "lobjOid" to file "out_filename" + * + */ + void exportFile(PGconn *conn, Oid lobjId, char *filename) + { + int lobj_fd; + char buf[BUFSIZE]; + int nbytes, tmp; + int fd; +
+ /* + * create an inversion "object" + */ + lobj_fd = lo_open(conn, lobjId, INV_READ); + if (lobj_fd < 0) { + fprintf(stderr,"can't open large object %d", + lobjId); + } +
+ /* + * open the file to be written to + */ + fd = open(filename, O_CREAT|O_WRONLY, 0666); + if (fd < 0) { /* error */ + fprintf(stderr, "can't open unix file + filename); + } +
+ /* + * read in from the Unix file and write to the inversion file + */ + while ((nbytes = lo_read(conn, lobj_fd, buf, BUFSIZE)) > 0) { + tmp = write(fd, buf, nbytes); + if (tmp < nbytes) { + fprintf(stderr,"error while writing + filename); + } + } +
+ (void) lo_close(conn, lobj_fd); + (void) close(fd); +
+ return; + } +
+ void + exit_nicely(PGconn* conn) + { + PQfinish(conn); + exit(1); + } +
+ int + main(int argc, char **argv) + { + char *in_filename, *out_filename; + char *database; + Oid lobjOid; + PGconn *conn; + PGresult *res; +
+ if (argc != 4) { + fprintf(stderr, "Usage: %s database_name in_filename out_filename0, + argv[0]); + exit(1); + } +
+ database = argv[1]; + in_filename = argv[2]; + out_filename = argv[3]; +
+ /* + * set up the connection + */ + conn = PQsetdb(NULL, NULL, NULL, NULL, database); +
+ /* check to see that the backend connection was successfully made */ + if (PQstatus(conn) == CONNECTION_BAD) { + fprintf(stderr,"Connection to database '%s' failed.0, database); + fprintf(stderr,"%s",PQerrorMessage(conn)); + exit_nicely(conn); + } +
+ res = PQexec(conn, "begin"); + PQclear(res); + + printf("importing file + /* lobjOid = importFile(conn, in_filename); */ + lobjOid = lo_import(conn, in_filename); + /* + printf("as large object %d.0, lobjOid); +
+ printf("picking out bytes 1000-2000 of the large object0); + pickout(conn, lobjOid, 1000, 1000); +
+ printf("overwriting bytes 1000-2000 of the large object with X's0); + overwrite(conn, lobjOid, 1000, 1000); + */ +
+ printf("exporting large object to file + /* exportFile(conn, lobjOid, out_filename); */ + lo_export(conn, lobjOid,out_filename); +
+ res = PQexec(conn, "end"); + PQclear(res); + PQfinish(conn); + exit(0); + } +
+
+ Version 1.0 (September 5, 1995)
+
+ Andrew Yu
+ and
+ Jolly Chen
+ (with the POSTGRES Group)
+ Computer Science Div., Dept. of EECS
+ University of California at Berkeley
+
+
POSTGRES95 is copyright © 1994-5 by the Regents of the
+University of California.
+Converted to HTML by J. Douglas Dunlop
+<dunlop@eol.ists.ca>
+The file
+
+pg95user.tgz contains the complete manual for download.
/usr/local/postgres95/src/tutorial
. Refer to the
+ README
file in that directory for how to use them. To
+ start the tutorial, do the following:
+% cd /usr/local/postgres95/src/tutorial + % psql -s mydb + Welcome to the POSTGRES95 interactive sql monitor: + + type \? for help on slash commands + type \q to quit + type \g or terminate with semicolon to execute query + You are currently connected to the database: jolly + + + mydb=> \i basics.sql ++ The \i command read in queries from the specified + files. The -s option puts you in single step mode which + pauses before sending a query to the backend. Queries + in this section are in the file
basics.sql
.
+
+CREATE TABLE weather ( + city varchar(80), + temp_lo int, -- low temperature + temp_hi int, -- high temperature + prcp real, -- precipitation + date date + ); ++ Note that keywords are case-insensitive but identifiers + are case-sensitive. POSTGRES SQL supports the usual + SQL types int, float, real, smallint, char(N), + varchar(N), date, and time. As we will + see later, POSTGRES can be customized with an + arbitrary number of + user-defined data types. Consequently, type names are + not keywords. + So far, the POSTGRES create command looks exactly like + the command used to create a table in a traditional + relational system. However, we will presently see that + classes have properties that are extensions of the + relational model. + +
INSERT INTO weather + VALUES ('San Francisco', 46, 50, 0.25, '11/27/1994') ++ You can also use the copy command to perform load large + amounts of data from flat (ASCII) files. + +
SELECT * FROM WEATHER; ++ + and the output should be: +
+ +--------------+---------+---------+------+------------+ + |city | temp_lo | temp_hi | prcp | date | + +--------------+---------+---------+------+------------+ + |San Francisco | 46 | 50 | 0.25 | 11-27-1994 | + +--------------+---------+---------+------+------------+ + |San Francisco | 43 | 57 | 0 | 11-29-1994 | + +--------------+---------+---------+------+------------+ + |Hayward | 37 | 54 | | 11-29-1994 | + +--------------+---------+---------+------+------------+ ++ You may specify any aribitrary expressions in the target list. For example, you can do: +
* SELECT city, (temp_hi+temp_lo)/2 AS temp_avg, date FROM weather; ++ Arbitrary Boolean operators ( and, or and not) are + allowed in the qualification of any query. For example, +
SELECT * + FROM weather + WHERE city = 'San Francisco' + and prcp > 0.0; + + +--------------+---------+---------+------+------------+ + |city | temp_lo | temp_hi | prcp | date | + +--------------+---------+---------+------+------------+ + |San Francisco | 46 | 50 | 0.25 | 11-27-1994 | + +--------------+---------+---------+------+------------+ ++ + As a final note, you can specify that the results of a + select can be returned in a sorted order or with duplicate instances removed. +
SELECT DISTINCT city + FROM weather + ORDER BY city; ++ +
SELECT * INTO temp from weather; ++ This creates an implicit create command, creating a new + class temp with the attribute names and types specified + in the target list of the SELECT INTO command. We can + then, of course, perform any operations on the resulting + class that we can perform on other classes. + +
SELECT W1.city, W1.temp_lo, W1.temp_hi, + W2.city, W2.temp_lo, W2.temp_hi + FROM weather W1, weather W2 + WHERE W1.temp_lo < W2.temp_lo + and W1.temp_hi > W2.temp_hi; + + +--------------+---------+---------+---------------+---------+---------+ + |city | temp_lo | temp_hi | city | temp_lo | temp_hi | + +--------------+---------+---------+---------------+---------+---------+ + |San Francisco | 43 | 57 | San Francisco | 46 | 50 | + +--------------+---------+---------+---------------+---------+---------+ + |San Francisco | 37 | 54 | San Francisco | 46 | 50 | + +--------------+---------+---------+---------------+---------+---------+ ++ In this case, both W1 and W2 are surrogates for an + instance of the class weather, and both range over all + instances of the class. (In the terminology of most + database systems, W1 and W2 are known as "range variables.") + A query can contain an arbitrary number of + class names and surrogates.3 + +
* UPDATE weather + SET temp_hi = temp_hi - 2, temp_lo = temp_lo - 2 + WHERE date > '11/28/1994; ++ +
* DELETE FROM weather WHERE city = 'Hayward'; ++ All weather recording belongs to Hayward is removed. + One should be wary of queries of the form +
DELETE FROM classname; ++ Without a qualification, the delete command will simply + delete all instances of the given class, leaving it + empty. The system will not request confirmation before + doing this. + +
SELECT max(temp_lo) + FROM weather; ++ Aggregates may also have GROUP BY clauses: +
+ SELECT city, max(temp_lo) + FROM weather + GROUP BY city; ++
+ Some of the steps listed in this section will apply to + all POSTGRES users, and some will apply primarily to + the site database administrator. This site administrator + is the person who installed the software, created + the database directories and started the postmaster + process. This person does not have to be the UNIX + superuser, "root," or the computer system administrator. + In this section, items for end users are labelled + "User" and items intended for the site administrator + are labelled "Admin." + Throughout this manual, any examples that begin with + the character ``%'' are commands that should be typed + at the UNIX shell prompt. Examples that begin with the + character ``*'' are commands in the POSTGRES query + language, POSTGRES SQL. + +
% set path = ( /usr/local/postgres95/bin $path ) ++ in the .login file in your home directory. If you use + a variant of the Bourne shell, such as sh, ksh, or + bash, then you would add +
+ % PATH=/usr/local/postgres95/bin:$PATH + % export PATH ++ to the .profile file in your home directory. + From now on, we will assume that you have added the + POSTGRES bin directory to your path. In addition, we + will make frequent reference to "setting a shell + variable" or "setting an environment variable" throughout + this document. If you did not fully understand the + last paragraph on modifying your search path, you + should consult the UNIX manual pages that describe your + shell before going any further. + +
% postmaster & ++ The postmaster occasionally prints out messages which + are often helpful during troubleshooting. If you wish + to view debugging messages from the postmaster, you can + start it with the -d option and redirect the output to + the log file: +
% postmaster -d >& pm.log & ++ If you do not wish to see these messages, you can type +
% postmaster -S ++ and the postmaster will be "S"ilent. Notice that there + is no ampersand ("&") at the end of the last example. + +
connectDB() failed: Is the postmaster running at 'localhost' on port '4322'? ++ it is usually because (1) the postmaster is not running, or (2) you are attempting to connect to the wrong + server host. + If you get the following error message: +
FATAL 1:Feb 17 23:19:55:process userid (2360) != + database owner (268) ++ it means that the site administrator started the postmaster as the wrong user. Tell him to restart it as + the POSTGRES superuser. + +
% createdb mydb ++ + POSTGRES allows you to create any number of databases + at a given site and you automatically become the + database administrator of the database you just created. Database names must have an alphabetic first + character and are limited to 16 characters in length. + Not every user has authorization to become a database + administrator. If POSTGRES refuses to create databases + for you, then the site administrator needs to grant you + permission to create databases. Consult your site + administrator if this occurs. + +
% psql mydb ++ You will be greeted with the following message: +
Welcome to the POSTGRES95 interactive sql monitor: + + type \? for help on slash commands + type \q to quit + type \g or terminate with semicolon to execute query + You are currently connected to the database: mydb + + mydb=> +This prompt indicates that the terminal monitor is listening to you and that you can type SQL queries into a + workspace maintained by the terminal monitor. + The psql program responds to escape codes that begin + with the backslash character, "\". For example, you + can get help on the syntax of various POSTGRES SQL commands by typing: +
mydb=> \h ++ Once you have finished entering your queries into the + workspace, you can pass the contents of the workspace + to the POSTGRES server by typing: +
mydb=> \g ++ This tells the server to process the query. If you + terminate your query with a semicolon, the \g is not + necessary. psql will automatically process semicolon terminated queries. + To read queries from a file, say myFile, instead of + entering them interactively, type: +
mydb=> \i fileName ++ To get out of psql and return to UNIX, type +
mydb=> \q ++ and psql will quit and return you to your command + shell. (For more escape codes, type \h at the monitor + prompt.) + White space (i.e., spaces, tabs and newlines) may be + used freely in SQL queries. Comments are denoted by + --. Everything after the dashes up to the end of the + line is ignored. + +
% destroydb mydb ++ This action physically removes all of the UNIX files + associated with the database and cannot be undone, so + this should only be done with a great deal of fore-thought. + +
+
CREATE AGGREGATE complex_sum ( + sfunc1 = complex_add, + basetype = complex, + stype1 = complex, + initcond1 = '(0,0)' + ); + + + SELECT complex_sum(a) FROM test_complex; + + + +------------+ + |complex_sum | + +------------+ + |(34,53.9) | + +------------+ ++ + If we define only sfunc2, we are specifying an aggregate + that computes a running function that is independent of + the attribute values from each instance. + "Count" is the most common example of this kind of + aggregate. "Count" starts at zero and adds one to its + running total for each instance, ignoring the instance + value. Here, we use the built-in int4inc routine to do + the work for us. This routine increments (adds one to) + its argument. + +
CREATE AGGREGATE my_count (sfunc2 = int4inc, -- add one + basetype = int4, stype2 = int4, + initcond2 = '0') + + SELECT my_count(*) as emp_count from EMP; + + + +----------+ + |emp_count | + +----------+ + |5 | + +----------+ ++ + "Average" is an example of an aggregate that requires + both a function to compute the running sum and a function + to compute the running count. When all of the + instances have been processed, the final answer for the + aggregate is the running sum divided by the running + count. We use the int4pl and int4inc routines we used + before as well as the POSTGRES integer division + routine, int4div, to compute the division of the sum by + the count. + +
CREATE AGGREGATE my_average (sfunc1 = int4pl, -- sum + basetype = int4, + stype1 = int4, + sfunc2 = int4inc, -- count + stype2 = int4, + finalfunc = int4div, -- division + initcond1 = '0', + initcond2 = '0') + + SELECT my_average(salary) as emp_average FROM EMP; + + + +------------+ + |emp_average | + +------------+ + |1640 | + +------------+ ++
funcs.sql
+ and C-code/funcs.c
.
++
CREATE FUNCTION one() RETURNS int4 + AS 'SELECT 1 as RESULT' LANGUAGE 'sql'; + + + SELECT one() AS answer; + + +-------+ + |answer | + +-------+ + |1 | + +-------+ ++ Notice that we defined a target list for the function + (with the name RESULT), but the target list of the + query that invoked the function overrode the function's + target list. Hence, the result is labelled answer + instead of one. +
+ It's almost as easy to define SQL functions that take + base types as arguments. In the example below, notice + how we refer to the arguments within the function as $1 + and $2. + +
CREATE FUNCTION add_em(int4, int4) RETURNS int4 + AS 'SELECT $1 + $2;' LANGUAGE 'sql'; + + + SELECT add_em(1, 2) AS answer; + + + +-------+ + |answer | + +-------+ + |3 | + +-------+ ++ +
CREATE FUNCTION double_salary(EMP) RETURNS int4 + AS 'SELECT $1.salary * 2 AS salary;' LANGUAGE 'sql'; + + SELECT name, double_salary(EMP) AS dream + FROM EMP + WHERE EMP.dept = 'toy'; + + + +-----+-------+ + |name | dream | + +-----+-------+ + |Sam | 2400 | + +-----+-------+ ++ Notice the use of the syntax $1.salary. + Before launching into the subject of functions that + return composite types, we must first introduce the + function notation for projecting attributes. The simple way + to explain this is that we can usually use the + notation attribute(class) and class.attribute interchangably. + +
-- + -- this is the same as: + -- SELECT EMP.name AS youngster FROM EMP WHERE EMP.age < 30 + -- + SELECT name(EMP) AS youngster + FROM EMP + WHERE age(EMP) < 30; + + + +----------+ + |youngster | + +----------+ + |Sam | + +----------+ ++ As we shall see, however, this is not always the case. + This function notation is important when we want to use + a function that returns a single instance. We do this + by assembling the entire instance within the function, + attribute by attribute. This is an example of a function + that returns a single EMP instance: + +
CREATE FUNCTION new_emp() RETURNS EMP + AS 'SELECT \'None\'::text AS name, + 1000 AS salary, + 25 AS age, + \'none\'::char16 AS dept;' + LANGUAGE 'sql'; ++ + In this case we have specified each of the attributes + with a constant value, but any computation or expression + could have been substituted for these constants. + Defining a function like this can be tricky. Some of + the more important caveats are as follows: + + +
WARN::function declared to return type EMP does not retrieve (EMP.*) ++
SELECT name(new_emp()) AS nobody; + + + +-------+ + |nobody | + +-------+ + |None | + +-------+ ++
SELECT new_emp().name AS nobody; + WARN:parser: syntax error at or near "." ++
+ CREATE FUNCTION clean_EMP () RETURNS int4 + AS 'DELETE FROM EMP WHERE EMP.salary <= 0; + SELECT 1 AS ignore_this' + LANGUAGE 'sql'; + + SELECT clean_EMP(); + + + +--+ + |x | + +--+ + |1 | + +--+ ++
+ +
/* 4-byte integer, passed by value */ + typedef int int4; ++ + On the other hand, fixed-length types of any size may + be passed by-reference. For example, here is a sample + implementation of the POSTGRES char16 type: + +
/* 16-byte structure, passed by reference */ + typedef struct { + char data[16]; + } char16; ++ + Only pointers to such types can be used when passing + them in and out of POSTGRES functions. + Finally, all variable-length types must also be passed + by reference. All variable-length types must begin + with a length field of exactly 4 bytes, and all data to + be stored within that type must be located in the memory + immediately following that length field. The + length field is the total length of the structure + (i.e., it includes the size of the length field + itself). We can define the text type as follows: + +
typedef struct { + int4 length; + char data[1]; + } text; ++ + Obviously, the data field is not long enough to hold + all possible strings -- it's impossible to declare such + a structure in C. When manipulating variable-length + types, we must be careful to allocate the correct + amount of memory and initialize the length field. For + example, if we wanted to store 40 bytes in a text + structure, we might use a code fragment like this: + +
#include "postgres.h" + #include "utils/palloc.h" + + ... + + char buffer[40]; /* our source data */ + + ... + + text *destination = (text *) palloc(VARHDRSZ + 40); + destination->length = VARHDRSZ + 40; + memmove(destination->data, buffer, 40); + + ... + ++ Now that we've gone over all of the possible structures + for base types, we can show some examples of real functions. + Suppose
funcs.c
look like:
+
+#include <string.h> + #include "postgres.h" /* for char16, etc. */ + #include "utils/palloc.h" /* for palloc */ + + int + add_one(int arg) + { + return(arg + 1); + } + + char16 * + concat16(char16 *arg1, char16 *arg2) + { + char16 *new_c16 = (char16 *) palloc(sizeof(char16)); + + memset((void *) new_c16, 0, sizeof(char16)); + (void) strncpy(new_c16, arg1, 16); + return (char16 *)(strncat(new_c16, arg2, 16)); + } ++ On OSF/1 we would type: + ++ text * + copytext(text *t) + { + /* + * VARSIZE is the total size of the struct in bytes. + */ + text *new_t = (text *) palloc(VARSIZE(t)); +
+ memset(new_t, 0, VARSIZE(t)); +
+ VARSIZE(new_t) = VARSIZE(t); + /* + * VARDATA is a pointer to the data region of the struct. + */ + memcpy((void *) VARDATA(new_t), /* destination */ + (void *) VARDATA(t), /* source */ + VARSIZE(t)-VARHDRSZ); /* how many bytes */ +
+ return(new_t); + } +
CREATE FUNCTION add_one(int4) RETURNS int4 + AS '/usr/local/postgres95/tutorial/obj/funcs.so' LANGUAGE 'c'; + + CREATE FUNCTION concat16(char16, char16) RETURNS char16 + AS '/usr/local/postgres95/tutorial/obj/funcs.so' LANGUAGE 'c'; + + CREATE FUNCTION copytext(text) RETURNS text + AS '/usr/local/postgres95/tutorial/obj/funcs.so' LANGUAGE 'c'; ++ + On other systems, we might have to make the filename + end in .sl (to indicate that it's a shared library). +
+
* SELECT name, c_overpaid(EMP, 1500) AS overpaid + FROM EMP + WHERE name = 'Bill' or name = 'Sam'; ++ In the query above, we can define c_overpaid as: + +
#include "postgres.h" /* for char16, etc. */ + #include "libpq-fe.h" /* for TUPLE */ ++ + GetAttributeByName is the POSTGRES system function that + returns attributes out of the current instance. It has + three arguments: the argument of type TUPLE passed into + the function, the name of the desired attribute, and a + return parameter that describes whether the attribute + is null. GetAttributeByName will align data properly + so you can cast its return value to the desired type. + For example, if you have an attribute name which is of + the type char16, the GetAttributeByName call would look + like: + ++ bool + c_overpaid(TUPLE t,/* the current instance of EMP */ + int4 limit) + { + bool isnull = false; + int4 salary; +
+ salary = (int4) GetAttributeByName(t, "salary", &isnull); +
+ if (isnull) + return (false); + return(salary > limit); + } +
char *str; + ... + str = (char *) GetAttributeByName(t, "name", &isnull) ++ + The following query lets POSTGRES know about the + c_overpaid function: + +
* CREATE FUNCTION c_overpaid(EMP, int4) RETURNS bool + AS '/usr/local/postgres95/tutorial/obj/funcs.so' LANGUAGE 'c'; ++ While there are ways to construct new instances or modify + existing instances from within a C function, these + are far too complex to discuss in this manual. +
+
-I/usr/local/postgres95/include ++ on your cc command lines. Sometimes, you may + find that you require header files that are in + the server source itself (i.e., you need a file + we neglected to install in include). In those + cases you may need to add one or more of +
+ -I/usr/local/postgres95/src/backend + -I/usr/local/postgres95/src/backend/include + -I/usr/local/postgres95/src/backend/port/<PORTNAME> + -I/usr/local/postgres95/src/backend/obj ++ + (where <PORTNAME> is the name of the port, e.g., + alpha or sparc). +
+
+ Look back at Figure 3.
+ The right half shows the catalogs
+ that we must modify in order to tell POSTGRES how
+ to use a user-defined type and/or user-defined operators
+ with an index (i.e., pg_am, pg_amop, pg_amproc
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
+ class for the B-tree access method that sorts integers
+ in ascending absolute value order.
+
+ The pg_am
class contains one instance for every user
+ defined access method. Support for the heap access
+ method is built into POSTGRES, but every other access
+ method is described here. The schema is
+
+
amname | name of the access method | +amowner | object id of the owner's instance in pg_user | + +
amkind | not used at present, but set to 'o' as a place holder | +
amstrategies | number of strategies for this access method (see below) | +
amsupport | number of support routines for this access method (see below) | +
amgettuple + aminsert + ... |
+procedure identifiers for interface routines to the access + method. For example, regproc ids for opening, closing, and + getting instances from the access method appear here. | +
+
+ The object ID of the instance in pg_am
is used as a
+ foreign key in lots of other classes. You don't need
+ to add a new instance to this class; all you're interested in
+ is the object ID of the access method instance
+ you want to extend:
+
+
SELECT oid FROM pg_am WHERE amname = 'btree' + + +----+ + |oid | + +----+ + |403 | + +----+ ++ + The
amstrategies
attribute exists to standardize
+ comparisons across data types. For example, B-trees
+ impose a strict ordering on keys, lesser to greater.
+ Since POSTGRES allows the user to define operators,
+ POSTGRES cannot look at the name of an operator (eg, >
+ 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. POSTGRES 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 POSTGRES needs to know, for example, that
+ the <= and > operators partition a B-tree. POSTGRES
+ uses strategies to express these relationships between
+ operators and the way they can be used to scan indices.
+
+ 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
+ operator class. In the pg_am
class, the amstrategies
+ attribute is the number of strategies defined for this
+ access method. For B-trees, this number is 5. These
+ strategies correspond to
+
+ +
less than | 1 | +
less than or equal | 2 | +
equal | 3 | +
greater than or equal | 4 | +
greater than | 5 | +
+
+ The idea is that you'll need to add procedures corresponding
+ to the comparisons above 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
+ procedures yet; just understand that there must be a
+ set of these procedures for int2, int4, oid,
and every
+ other data type on which a B-tree can operate.
+
+ Sometimes, strategies aren't enough information for the + system to figure out how to use an index. Some access + methods require other 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 + intersections, unions, and sizes of rectangles. These + operations do not correspond to user qualifications in + SQL queries; they are administrative routines used by + the access methods, internally.
+
+ In order to manage diverse support routines
+ consistently across all POSTGRES access methods, pg_am
+ includes an attribute called amsupport
. This attribute
+ 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, or +1,
+ depending on whether the first key is less than, equal
+ to, or greater than the second.[8]
+
+ The amstrategies
entry in pg_am is just the number of
+ strategies defined for the access method in question.
+ The procedures 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.
+
+ The next class of interest is pg_opclass. This class
+ exists only to associate a name with an oid. In
+ pg_amop, every B-tree operator class has a set of
+ procedures, one through five, above. Some existing
+ opclasses are int2_ops, int4_ops, and oid_ops
. You
+ need to add an instance with your opclass name (for
+ example, complex_abs_ops
) to pg_opclass
. The oid
of
+ this instance is a foreign key in other classes.
+
+
INSERT INTO pg_opclass (opcname) VALUES ('complex_abs_ops'); + + SELECT oid, opcname + FROM pg_opclass + WHERE opcname = 'complex_abs_ops'; + + +------+--------------+ + |oid | opcname | + +------+--------------+ + |17314 | int4_abs_ops | + +------+--------------+ ++ + Note that the oid for your
pg_opclass
instance will be
+ different! You should substitute your value for 17314
+ wherever it appears in this discussion.+ + So now we have an access method and an operator class. + We still need a set of operators; the procedure for + defining operators was discussed earlier in this manual. + For the complex_abs_ops operator class on Btrees, + the operators we require are: + +
absolute value less-than + absolute value less-than-or-equal + absolute value equal + absolute value greater-than-or-equal + absolute value greater-than ++ + Suppose the code that implements the functions defined + is stored in the file + +
+ /usr/local/postgres95/src/tutorial/complex.c ++ + Part of the code look like this: (note that we will + only show the equality operator for the rest of the + examples. The other four operators are very similar. + Refer to
complex.c
or complex.sql
for the details.)
+
+#define Mag(c) ((c)->x*(c)->x + (c)->y*(c)->y) + + bool + complex_abs_eq(Complex *a, Complex *b) + { + double amag = Mag(a), bmag = Mag(b); + return (amag==bmag); + } ++ + There are a couple of important things that are happening below.
+
+ First, note that operators for less-than, less-than-or
+ equal, equal, greater-than-or-equal, and greater-than
+ for int4
are being defined. All of these operators are
+ already defined for int4
under the names <, <=, =, >=,
+ and >. The new operators behave differently, of
+ course. In order to guarantee that POSTGRES uses these
+ new operators rather than the old ones, they need to be
+ named differently from the old ones. This is a key
+ point: you can overload operators in POSTGRES, but only
+ if the operator isn't already defined for the argument
+ types. That is, if you have < defined for (int4,
+ int4), you can't define it again. POSTGRES does not
+ check this when you define your operator, so be careful.
+ To avoid this problem, odd names will be used for
+ the operators. If you get this wrong, the access methods
+ are likely to crash when you try to do scans.
+
+ The other important point is that all the operator
+ functions return Boolean values. The access methods
+ rely on this fact. (On the other hand, the support
+ function returns whatever the particular access method
+ expects -- in this case, a signed integer.)
+ The final routine in the file is the "support routine"
+ mentioned when we discussed the amsupport attribute of
+ the pg_am
class. We will use this later on. For now,
+ ignore it.
+
+
CREATE FUNCTION complex_abs_eq(complex, complex) + RETURNS bool + AS '/usr/local/postgres95/tutorial/obj/complex.so' + LANGUAGE 'c'; ++ + Now define the operators that use them. As noted, the + operator names must be unique among all operators that + take two
int4
operands. In order to see if the
+ operator names listed below are taken, we can do a query on
+ pg_operator
:
+
+/* + * this query uses the regular expression operator (~) + * to find three-character operator names that end in + * the character & + */ + SELECT * + FROM pg_operator + WHERE oprname ~ '^..&$'::text; ++ + to see if your name is taken for the types you want. + The important things here are the procedure (which are + the C functions defined above) and the restriction and + join selectivity functions. You should just use the + ones used below--note that there are different such + functions for the less-than, equal, and greater-than + cases. These must be supplied, or the access method + will crash when it tries to use the operator. You + should copy the names for restrict and join, but use + the procedure names you defined in the last step. + +
CREATE OPERATOR = ( + leftarg = complex, rightarg = complex, procedure = complex_abs_eq, + restrict = eqsel, join = eqjoinsel + ) ++ + Notice that five operators corresponding to less, less + equal, equal, greater, and greater equal are defined.
+
+ We're just about finished. the last thing we need to do
+ is to update the pg_amop
relation. To do this, we need
+ the following attributes:
+
+ +
amopid | the oid of the pg_am instance for B-tree
+ (== 403, see above) |
+
amopclaid | the oid of the
+ pg_opclass instance for int4_abs_ops (==
+ whatever you got instead of 17314 , see above) |
+
amopopr | the oid s of the operators for the opclass (which we'll
+ get in just a minute) |
+
amopselect, amopnpages | cost functions. | + +
+ The cost functions are used by the query optimizer to
+ decide whether or not to use a given index in a scan.
+ Fortunately, these already exist. The two functions
+ we'll use are btreesel
, which estimates the selectivity
+ of the B-tree, and btreenpage
, which estimates the
+ number of pages a search will touch in the tree.
+
+ So we need the oid
s of the operators we just defined.
+ We'll look up the names of all the operators that take
+ two int4
s, and pick ours out:
+
+
SELECT o.oid AS opoid, o.oprname + INTO 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'; + + which returns: + + +------+---------+ + |oid | oprname | + +------+---------+ + |17321 | < | + +------+---------+ + |17322 | <= | + +------+---------+ + |17323 | = | + +------+---------+ + |17324 | >= | + +------+---------+ + |17325 | > | + +------+---------+ ++ + (Again, some of your
oid
numbers will almost certainly
+ be different.) The operators we are interested in are
+ those with oid
s 17321 through 17325. The values you
+ get will probably be different, and you should
+ substitute them for the values below. We can look at the
+ operator names and pick out the ones we just added.
+
+ Now we're ready to update pg_amop
with our new operator
+ class. The most important thing in this entire
+ discussion is that the operators are ordered, from less equal
+ through greater equal, in pg_amop
. We add the
+ instances we need:
+
+
INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy, + amopselect, amopnpages) + SELECT am.oid, opcl.oid, c.opoid, 3, + 'btreesel'::regproc, 'btreenpage'::regproc + FROM pg_am am, pg_opclass opcl, complex_ops_tmp c + WHERE amname = 'btree' and opcname = 'complex_abs_ops' + and c.oprname = '='; ++ + 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 last step (finally!) is 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
class, keyed by the access method oid
and
+ the operator class oid
. First, we need to register the
+ function in POSTGRES (recall that we put the C code
+ that implements this routine in the bottom of the file
+ in which we implemented the operator routines):
+
+
CREATE FUNCTION int4_abs_cmp(int4, int4) + RETURNS int4 + AS '/usr/local/postgres95/tutorial/obj/complex.so' + LANGUAGE 'c'; + + SELECT oid, proname FROM pg_proc WHERE prname = 'int4_abs_cmp'; + + +------+--------------+ + |oid | proname | + +------+--------------+ + |17328 | int4_abs_cmp | + +------+--------------+ ++ (Again, your
oid
number will probably be different and
+ you should substitute the value you see for the value
+ below.) Recalling that the B-tree instance's oid is
+ 403 and that of int4_abs_ops
is 17314, we can add the
+ new instance as follows:
+
+INSERT INTO pg_amproc (amid, amopclaid, amproc, amprocnum) + VALUES ('403'::oid, -- btree oid + '17314'::oid, -- pg_opclass tuple + '17328'::oid, -- new pg_proc oid + '1'::int2); ++
+
+ CREATE FUNCTION complex_add(complex, complex) + RETURNS complex + AS '$PWD/obj/complex.so' + LANGUAGE 'c'; + + + CREATE OPERATOR + ( + leftarg = complex, + rightarg = complex, + procedure = complex_add, + commutator = + + ); ++ + We've shown how to create a binary operator here. To + create unary operators, just omit one of leftarg (for + left unary) or rightarg (for right unary). + If we give the system enough type information, it can + automatically figure out which operators to use. + +
+ SELECT (a + b) AS c FROM test_complex; + + + +----------------+ + |c | + +----------------+ + |(5.2,6.05) | + +----------------+ + |(133.42,144.95) | + +----------------+ ++
complex.sql
and complex.c
. Composite examples
+ are in funcs.sql
.
++
+
typedef struct Complex { + double x; + double y; + } Complex; ++ and a string of the form (x,y) as the external string + representation. + These functions are usually not hard to write, especially + the output function. However, there are a number of points + to remember. + +
Complex * + complex_in(char *str) + { + double x, y; + Complex *result; + + if (sscanf(str, " ( %lf , %lf )", &x, &y) != 2) { + elog(WARN, "complex_in: error in parsing + return NULL; + } + result = (Complex *)palloc(sizeof(Complex)); + result->x = x; + result->y = y; + return (result); + } ++ + The output function can simply be: + +
char * + complex_out(Complex *complex) + { + char *result; +++ if (complex == NULL) + return(NULL); +
+ result = (char *) palloc(60); + sprintf(result, "(%g,%g)", complex->x, complex->y); + return(result); + } +
CREATE FUNCTION complex_in(opaque) + RETURNS complex + AS '/usr/local/postgres95/tutorial/obj/complex.so' + LANGUAGE 'c'; + + CREATE FUNCTION complex_out(opaque) + RETURNS opaque + AS '/usr/local/postgres95/tutorial/obj/complex.so' + LANGUAGE 'c'; + + CREATE TYPE complex ( + internallength = 16, + input = complex_in, + output = complex_out + ); ++ + As discussed earlier, POSTGRES fully supports arrays of + base types. Additionally, POSTGRES supports arrays of + user-defined types as well. When you define a type, + POSTGRES automatically provides support for arrays of + that type. For historical reasons, the array type has + the same name as the user-defined type with the + underscore character _ prepended. + Composite types do not need any function defined on + them, since the system already understands what they + look like inside. +
+
+