--- /dev/null
+
+Here are general trigger functions provided as workable examples
+of using SPI and triggers. "General" means that functions may be
+used for defining triggers for any tables but you have to specify
+table/field names (as described below) while creating a trigger.
+
+1. refint.c - functions for implementing referential integrity.
+
+check_primary_key () is to used for foreign keys of a table.
+
+ You are to create trigger (BEFORE INSERT OR UPDATE) using this
+function on a table referencing another table. You are to specify
+as function arguments: triggered table column names which correspond
+to foreign key, referenced table name and column names in referenced
+table which correspond to primary/unique key.
+ You may create as many triggers as you need - one trigger for
+one reference.
+
+check_foreign_key () is to used for primary/unique keys of a table.
+
+ You are to create trigger (BEFORE DELETE OR UPDATE) using this
+function on a table referenced by another table(s). You are to specify
+as function arguments: number of references for which function has to
+performe checking, action if referencing key found ('cascade' - to delete
+corresponding foreign key, 'restrict' - to abort transaction if foreign keys
+exist, 'setnull' - to set foreign key referencing primary/unique key
+being deleted to null), triggered table column names which correspond
+to primary/unique key, referencing table name and column names corresponding
+to foreign key (, ... - as many referencing tables/keys as specified
+by first argument).
+ Note, that NOT NULL constraint and unique index have to be defined by
+youself.
+
+ There are examples in refint.example and regression tests
+(sql/triggers.sql).
+
+ To CREATE FUNCTIONs use refint.sql (will be made by gmake from
+refint.source).
+
+
+
+
+# Excuse me for my bad english. Massimo Lambertini
+#
+#
+# New check foreign key
+#
+I think that cascade mode is to be considered like that the operation over
+main table is to be made also in referenced table .
+When i Delete , i must delete from referenced table ,
+but when i update , i update referenced table and not delete like unmodified refint.c .
+
+I made a new version of refint.c that when i update it check the type of modified key ( if is a text , char() i
+added '') and then create a update query that do the right thing .
+
+For my point of view that policy is helpfull because i do not have in referenced table
+loss of information .
+
+
+In preprocessor subdir i have placed a little utility that from a SQL92 table definition,
+it create all trigger for foreign key .
+
+
+the schema that i use to analyze the problem is this
+
+create table
+A
+( key int4 not null primary key ,...,
+) ;
+
+create table
+REFERENCED_B
+( key int 4 , ... ,
+foreign key ( key ) references A --
+);
+
+
+--
+-- Trigger for REFERENCED_B
+--
+
+CREATE INDEX I_REFERENCED_B_KEY ON REFERENCED_B ( KEY ) ;
+
+CREATE TRIGGER T_P_REFERENCED_B_A BEFORE INSERT OR UPDATE ON REFERENCED_B FOR EACH ROW
+EXECUTE PROCEDURE
+check_primary_key('KEY','A','KEY' );
+
+CREATE TRIGGER T_F_D_A_REFERENCED_B BEFORE DELETE ON A FOR EACH ROW
+EXECUTE PROCEDURE
+check_foreign_key(1,'cascade','KEY','REFERENCED_B ','KEY' );
+
+CREATE TRIGGER T_F_U_A_REFERENCED_B AFTER UPDATE ON A FOR EACH ROW
+EXECUTE PROCEDURE
+check_foreign_key(1,'cascade','KEY','REFERENCED_B ','KEY' );
+
+-- ********************************
+
+I write TRIGGER T_F_U_A_REFERENCED_B ( AFTER ) and not BEFORE because if i set
+BEFORE , when i try to modify ( update ) a key of A , i start a execution of TRIGGER T_P_REFERENCED_B_A
+( check_primary_key) before the real modification of key in A , then the execution of ( check_primary_key) return
+not ok.
+With AFTER Clausole i modify first key of A then a update the value of referenced table REFERENCED_B.
+
+Try also the new_example.sql to view the modified policy.
+I wish that my explain of problem is quite clear .
+If there is miss understanding ( cause my bad english ) please send email to massimo.lambertini@everex.it
+
+
+
Operating System (example: Linux 2.0.26 ELF) :
- PostgreSQL version (example: PostgreSQL-6.4) : PostgreSQL-6.4
+ PostgreSQL version (example: PostgreSQL-6.5) : PostgreSQL-6.5
Compiler used (example: gcc 2.8.0) :
-(1998-09-01)
+(1999-05-01)
PostgreSQL has a Web site at http://www.postgresql.org/ which carries details
on the latest release, upcoming features, and other information to make your
work or play with PostgreSQL more productive.
--- /dev/null
+#! /usr/local/bin/python
+# advanced.py - demo of advanced features of PostGres. Some may not be ANSI.
+# inspired from the Postgres tutorial
+# adapted to Python 1995 by Pascal Andre
+
+print "__________________________________________________________________"
+print "MODULE ADVANCED.PY : ADVANCED POSTGRES SQL COMMANDS TUTORIAL"
+print
+print "This module is designed for being imported from python prompt"
+print
+print "In order to run the samples included here, first create a connection"
+print "using : cnx = advanced.DB(...)"
+print "then start the demo with: advanced.demo(cnx)"
+print "__________________________________________________________________"
+
+from pgtools import *
+from pg import DB
+
+# inheritance features
+def inherit_demo(pgcnx):
+ print "-----------------------------"
+ print "-- Inheritance:"
+ print "-- a table can inherit from zero or more tables. A query"
+ print "-- can reference either all rows of a table or all rows "
+ print "-- of a table plus all of its descendants."
+ print "-----------------------------"
+ print
+ print "-- For example, the capitals table inherits from cities table."
+ print "-- (It inherits all data fields from cities.)"
+ print
+ print "CREATE TABLE cities ("
+ print " name text,"
+ print " population float8,"
+ print " altitude int"
+ print ")"
+ print
+ print "CREATE TABLE capitals ("
+ print " state varchar(2)"
+ print ") INHERITS (cities)"
+ pgcnx.query("CREATE TABLE cities (" \
+ "name text," \
+ "population float8," \
+ "altitude int)")
+ pgcnx.query("CREATE TABLE capitals (" \
+ "state varchar(2)) INHERITS (cities)")
+ wait_key()
+ print
+ print "-- now, let's populate the tables"
+ print
+ print "INSERT INTO cities VALUES ('San Francisco', 7.24E+5, 63)"
+ print "INSERT INTO cities VALUES ('Las Vegas', 2.583E+5, 2174)"
+ print "INSERT INTO cities VALUES ('Mariposa', 1200, 1953)"
+ print
+ print "INSERT INTO capitals VALUES ('Sacramento', 3.694E+5, 30, 'CA')"
+ print "INSERT INTO capitals VALUES ('Madison', 1.913E+5, 845, 'WI')"
+ print
+ pgcnx.query(
+ "INSERT INTO cities VALUES ('San Francisco', 7.24E+5, 63)")
+ pgcnx.query(
+ "INSERT INTO cities VALUES ('Las Vegas', 2.583E+5, 2174)")
+ pgcnx.query(
+ "INSERT INTO cities VALUES ('Mariposa', 1200, 1953)")
+ pgcnx.query("INSERT INTO capitals" \
+ " VALUES ('Sacramento', 3.694E+5, 30, 'CA')")
+ pgcnx.query("INSERT INTO capitals" \
+ " VALUES ('Madison', 1.913E+5, 845, 'WI')")
+ print
+ print "SELECT * FROM cities"
+ print pgcnx.query("SELECT * FROM cities")
+ print "SELECT * FROM capitals"
+ print pgcnx.query("SELECT * FROM capitals")
+ print
+ print "-- like before, a regular query references rows of the base"
+ print "-- table only"
+ print
+ print "SELECT name, altitude"
+ print "FROM cities"
+ print "WHERE altitude > 500;"
+ print pgcnx.query("SELECT name, altitude " \
+ "FROM cities " \
+ "WHERE altitude > 500")
+ print
+ print "-- on the other hand, you can find all cities, including "
+ print "-- capitals, that are located at an altitude of 500 'ft "
+ print "-- or higher by:"
+ print
+ print "SELECT c.name, c.altitude"
+ print "FROM cities* c"
+ print "WHERE c.altitude > 500"
+ print pgcnx.query("SELECT c.name, c.altitude " \
+ "FROM cities* c " \
+ "WHERE c.altitude > 500")
+
+# arrays attributes
+def array_demo(pgcnx):
+ print "----------------------"
+ print "-- Arrays:"
+ print "-- attributes can be arrays of base types or user-defined "
+ print "-- types"
+ print "----------------------"
+ print
+ print "CREATE TABLE sal_emp ("
+ print " name text,"
+ print " pay_by_quarter int4[],"
+ print " schedule text[][]"
+ print ")"
+ pgcnx.query("CREATE TABLE sal_emp (" \
+ "name text," \
+ "pay_by_quarter int4[]," \
+ "schedule text[][])")
+ wait_key()
+ print
+ print "-- insert instances with array attributes. "
+ print " Note the use of braces"
+ print
+ print "INSERT INTO sal_emp VALUES ("
+ print " 'Bill',"
+ print " '{10000,10000,10000,10000}',"
+ print " '{{\"meeting\", \"lunch\"}, {}}')"
+ print
+ print "INSERT INTO sal_emp VALUES ("
+ print " 'Carol',"
+ print " '{20000,25000,25000,25000}',"
+ print " '{{\"talk\", \"consult\"}, {\"meeting\"}}')"
+ print
+ pgcnx.query("INSERT INTO sal_emp VALUES (" \
+ "'Bill', '{10000,10000,10000,10000}'," \
+ "'{{\"meeting\", \"lunch\"}, {}}')")
+ pgcnx.query("INSERT INTO sal_emp VALUES (" \
+ "'Carol', '{20000,25000,25000,25000}'," \
+ "'{{\"talk\", \"consult\"}, {\"meeting\"}}')")
+ wait_key()
+ print
+ print "----------------------"
+ print "-- queries on array attributes"
+ print "----------------------"
+ print
+ print "SELECT name FROM sal_emp WHERE"
+ print " sal_emp.pay_by_quarter[1] <> sal_emp.pay_by_quarter[2]"
+ print
+ print pgcnx.query("SELECT name FROM sal_emp WHERE " \
+ "sal_emp.pay_by_quarter[1] <> sal_emp.pay_by_quarter[2]")
+ print
+ print "-- retrieve third quarter pay of all employees"
+ print
+ print "SELECT sal_emp.pay_by_quarter[3] FROM sal_emp"
+ print
+ print pgcnx.query("SELECT sal_emp.pay_by_quarter[3] FROM sal_emp")
+ print
+ print "-- select subarrays"
+ print
+ print "SELECT sal_emp.schedule[1:2][1:1] FROM sal_emp WHERE "
+ print " sal_emp.name = 'Bill'"
+ print pgcnx.query("SELECT sal_emp.schedule[1:2][1:1] FROM sal_emp WHERE " \
+ "sal_emp.name = 'Bill'")
+
+# base cleanup
+def demo_cleanup(pgcnx):
+ print "-- clean up (you must remove the children first)"
+ print "DROP TABLE sal_emp"
+ print "DROP TABLE capitals"
+ print "DROP TABLE cities;"
+ pgcnx.query("DROP TABLE sal_emp")
+ pgcnx.query("DROP TABLE capitals")
+ pgcnx.query("DROP TABLE cities")
+
+# main demo function
+def demo(pgcnx):
+ inherit_demo(pgcnx)
+ array_demo(pgcnx)
+ demo_cleanup(pgcnx)
--- /dev/null
+#! /usr/local/bin/python
+# basics.py - basic SQL commands tutorial
+# inspired from the Postgres95 tutorial
+# adapted to Python 1995 by Pascal ANDRE
+
+print "__________________________________________________________________"
+print "MODULE BASICS.PY : BASIC SQL COMMANDS TUTORIAL"
+print
+print "This module is designed for being imported from python prompt"
+print
+print "In order to run the samples included here, first create a connection"
+print "using : cnx = basics.DB(...)"
+print "then start the demo with: basics.demo(cnx)"
+print "__________________________________________________________________"
+
+from pg import DB
+from pgtools import *
+
+# table creation commands
+def create_table(pgcnx):
+ print "-----------------------------"
+ print "-- Creating a table:"
+ print "-- a CREATE TABLE is used to create base tables. POSTGRES"
+ print "-- SQL has its own set of built-in types. (Note that"
+ print "-- keywords are case-insensitive but identifiers are "
+ print "-- case-sensitive.)"
+ print "-----------------------------"
+ print
+ print "Sending query :"
+ print "CREATE TABLE weather ("
+ print " city varchar(80),"
+ print " temp_lo int,"
+ print " temp_hi int,"
+ print " prcp float8,"
+ print " date date"
+ print ")"
+ pgcnx.query("CREATE TABLE weather (city varchar(80), temp_lo int," \
+ "temp_hi int, prcp float8, date date)")
+ print
+ print "Sending query :"
+ print "CREATE TABLE cities ("
+ print " name varchar(80),"
+ print " location point"
+ print ")"
+ pgcnx.query("CREATE TABLE cities (" \
+ "name varchar(80)," \
+ "location point)")
+
+# data insertion commands
+def insert_data(pgcnx):
+ print "-----------------------------"
+ print "-- Inserting data:"
+ print "-- an INSERT statement is used to insert a new row into"
+ print "-- a table. There are several ways you can specify what"
+ print "-- columns the data should go to."
+ print "-----------------------------"
+ print
+ print "-- 1. the simplest case is when the list of value correspond to"
+ print "-- the order of the columns specified in CREATE TABLE."
+ print
+ print "Sending query :"
+ print "INSERT INTO weather "
+ print " VALUES ('San Francisco', 46, 50, 0.25, '11/27/1994')"
+ pgcnx.query("INSERT INTO weather " \
+ "VALUES ('San Francisco', 46, 50, 0.25, '11/27/1994')")
+ print
+ print "Sending query :"
+ print "INSERT INTO cities "
+ print " VALUES ('San Francisco', '(-194.0, 53.0)')"
+ pgcnx.query("INSERT INTO cities " \
+ "VALUES ('San Francisco', '(-194.0, 53.0)')")
+ print
+ wait_key()
+ print "-- 2. you can also specify what column the values correspond "
+ print " to. (The columns can be specified in any order. You may "
+ print " also omit any number of columns. eg. unknown precipitation"
+ print " below)"
+ print "Sending query :"
+ print "INSERT INTO weather (city, temp_lo, temp_hi, prcp, date)"
+ print " VALUES ('San Francisco', 43, 57, 0.0, '11/29/1994')"
+ pgcnx.query("INSERT INTO weather (date, city, temp_hi, temp_lo)" \
+ "VALUES ('11/29/1994', 'Hayward', 54, 37)")
+
+# direct selection commands
+def select_data1(pgcnx):
+ print "-----------------------------"
+ print "-- Retrieving data:"
+ print "-- a SELECT statement is used for retrieving data. The "
+ print "-- basic syntax is:"
+ print "-- SELECT columns FROM tables WHERE predicates"
+ print "-----------------------------"
+ print
+ print "-- a simple one would be the query:"
+ print "SELECT * FROM weather"
+ print
+ print "The result is :"
+ q = pgcnx.query("SELECT * FROM weather")
+ print q
+ print
+ print "-- you may also specify expressions in the target list (the "
+ print "-- 'AS column' specifies the column name of the result. It is "
+ print "-- optional.)"
+ print "The query :"
+ print " SELECT city, (temp_hi+temp_lo)/2 AS temp_avg, date "
+ print " FROM weather"
+ print "Gives :"
+ print pgcnx.query("SELECT city, (temp_hi+temp_lo)/2 " \
+ "AS temp_avg, date FROM weather")
+ print
+ print "-- if you want to retrieve rows that satisfy certain condition"
+ print "-- (ie. a restriction), specify the condition in WHERE. The "
+ print "-- following retrieves the weather of San Francisco on rainy "
+ print "-- days."
+ print "SELECT *"
+ print "FROM weather"
+ print "WHERE city = 'San Francisco' "
+ print " and prcp > 0.0"
+ print pgcnx.query("SELECT * FROM weather WHERE city = 'San Francisco'" \
+ " AND prcp > 0.0")
+ print
+ print "-- here is a more complicated one. Duplicates are removed when "
+ print "-- DISTINCT is specified. ORDER BY specifies the column to sort"
+ print "-- on. (Just to make sure the following won't confuse you, "
+ print "-- DISTINCT and ORDER BY can be used separately.)"
+ print "SELECT DISTINCT city"
+ print "FROM weather"
+ print "ORDER BY city;"
+ print pgcnx.query("SELECT DISTINCT city FROM weather ORDER BY city")
+
+# selection to a temporary table
+def select_data2(pgcnx):
+ print "-----------------------------"
+ print "-- Retrieving data into other classes:"
+ print "-- a SELECT ... INTO statement can be used to retrieve "
+ print "-- data into another class."
+ print "-----------------------------"
+ print
+ print "The query :"
+ print "SELECT * INTO TABLE temp "
+ print "FROM weather"
+ print "WHERE city = 'San Francisco' "
+ print " and prcp > 0.0"
+ pgcnx.query("SELECT * INTO TABLE temp FROM weather " \
+ "WHERE city = 'San Francisco' and prcp > 0.0")
+ print "Fills the table temp, that can be listed with :"
+ print "SELECT * from temp"
+ print pgcnx.query("SELECT * from temp")
+
+# aggregate creation commands
+def create_aggregate(pgcnx):
+ print "-----------------------------"
+ print "-- Aggregates"
+ print "-----------------------------"
+ print
+ print "Let's consider the query :"
+ print "SELECT max(temp_lo)"
+ print "FROM weather;"
+ print pgcnx.query("SELECT max(temp_lo) FROM weather")
+ print
+ print "-- Aggregate with GROUP BY"
+ print "SELECT city, max(temp_lo)"
+ print "FROM weather "
+ print "GROUP BY city;"
+ print pgcnx.query( "SELECT city, max(temp_lo)" \
+ "FROM weather GROUP BY city")
+
+# table join commands
+def join_table(pgcnx):
+ print "-----------------------------"
+ print "-- Joining tables:"
+ print "-- queries can access multiple tables at once or access"
+ print "-- the same table in such a way that multiple instances"
+ print "-- of the table are being processed at the same time."
+ print "-----------------------------"
+ print
+ print "-- suppose we want to find all the records that are in the "
+ print "-- temperature range of other records. W1 and W2 are aliases "
+ print "--for weather."
+ print
+ print "SELECT W1.city, W1.temp_lo, W1.temp_hi, "
+ print " W2.city, W2.temp_lo, W2.temp_hi"
+ print "FROM weather W1, weather W2"
+ print "WHERE W1.temp_lo < W2.temp_lo "
+ print " and W1.temp_hi > W2.temp_hi"
+ print
+ print pgcnx.query("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")
+ print
+ print "-- let's join two tables. The following joins the weather table"
+ print "-- and the cities table."
+ print
+ print "SELECT city, location, prcp, date"
+ print "FROM weather, cities"
+ print "WHERE name = city"
+ print
+ print pgcnx.query("SELECT city, location, prcp, date FROM weather, cities"\
+ " WHERE name = city")
+ print
+ print "-- since the column names are all different, we don't have to "
+ print "-- specify the table name. If you want to be clear, you can do "
+ print "-- the following. They give identical results, of course."
+ print
+ print "SELECT w.city, c.location, w.prcp, w.date"
+ print "FROM weather w, cities c"
+ print "WHERE c.name = w.city;"
+ print
+ print pgcnx.query("SELECT w.city, c.location, w.prcp, w.date " \
+ "FROM weather w, cities c WHERE c.name = w.city")
+
+# data updating commands
+def update_data(pgcnx):
+ print "-----------------------------"
+ print "-- Updating data:"
+ print "-- an UPDATE statement is used for updating data. "
+ print "-----------------------------"
+ print
+ print "-- suppose you discover the temperature readings are all off by"
+ print "-- 2 degrees as of Nov 28, you may update the data as follow:"
+ print
+ print "UPDATE weather"
+ print " SET temp_hi = temp_hi - 2, temp_lo = temp_lo - 2"
+ print " WHERE date > '11/28/1994'"
+ print
+ pgcnx.query("UPDATE weather " \
+ "SET temp_hi = temp_hi - 2, temp_lo = temp_lo - 2" \
+ "WHERE date > '11/28/1994'")
+ print
+ print "SELECT * from weather"
+ print pgcnx.query("SELECT * from weather")
+
+# data deletion commands
+def delete_data(pgcnx):
+ print "-----------------------------"
+ print "-- Deleting data:"
+ print "-- a DELETE statement is used for deleting rows from a "
+ print "-- table."
+ print "-----------------------------"
+ print
+ print "-- suppose you are no longer interested in the weather of "
+ print "-- Hayward, you can do the following to delete those rows from"
+ print "-- the table"
+ print
+ print "DELETE FROM weather WHERE city = 'Hayward'"
+ pgcnx.query("DELETE FROM weather WHERE city = 'Hayward'")
+ print
+ print "SELECT * from weather"
+ print
+ print pgcnx.query("SELECT * from weather")
+ print
+ print "-- you can also delete all the rows in a table by doing the "
+ print "-- following. (This is different from DROP TABLE which removes "
+ print "-- the table in addition to the removing the rows.)"
+ print
+ print "DELETE FROM weather"
+ pgcnx.query("DELETE FROM weather")
+ print
+ print "SELECT * from weather"
+ print pgcnx.query("SELECT * from weather")
+
+# table removal commands
+def remove_table(pgcnx):
+ print "-----------------------------"
+ print "-- Removing the tables:"
+ print "-- DROP TABLE is used to remove tables. After you have"
+ print "-- done this, you can no longer use those tables."
+ print "-----------------------------"
+ print
+ print "DROP TABLE weather, cities, temp"
+ pgcnx.query("DROP TABLE weather, cities, temp")
+
+# main demo function
+def demo(pgcnx):
+ create_table(pgcnx)
+ wait_key()
+ insert_data(pgcnx)
+ wait_key()
+ select_data1(pgcnx)
+ select_data2(pgcnx)
+ create_aggregate(pgcnx)
+ join_table(pgcnx)
+ update_data(pgcnx)
+ delete_data(pgcnx)
+ remove_table(pgcnx)
--- /dev/null
+# func.py - demonstrate the use of SQL functions
+# inspired from the PostgreSQL tutorial
+# adapted to Python 1995 by Pascal ANDRE
+
+print "__________________________________________________________________"
+print "MODULE FUNC.PY : SQL FUNCTION DEFINITION TUTORIAL"
+print
+print "This module is designed for being imported from python prompt"
+print
+print "In order to run the samples included here, first create a connection"
+print "using : cnx = func.DB(...)"
+print "then start the demo with: func.demo(cnx)"
+print "__________________________________________________________________"
+
+from pgtools import *
+from pg import DB
+
+# basic functions declaration
+def base_func(pgcnx):
+ print "-----------------------------"
+ print "-- Creating SQL Functions on Base Types"
+ print "-- a CREATE FUNCTION statement lets you create a new "
+ print "-- function that can be used in expressions (in SELECT, "
+ print "-- INSERT, etc.). We will start with functions that "
+ print "-- return values of base types."
+ print "-----------------------------"
+ print
+ print "--"
+ print "-- let's create a simple SQL function that takes no arguments"
+ print "-- and returns 1"
+ print
+ print "CREATE FUNCTION one() RETURNS int4"
+ print " AS 'SELECT 1 as ONE' LANGUAGE 'sql'"
+ pgcnx.query("CREATE FUNCTION one() RETURNS int4 " \
+ "AS 'SELECT 1 as ONE' LANGUAGE 'sql'")
+ wait_key()
+ print
+ print "--"
+ print "-- functions can be used in any expressions (eg. in the target"
+ print "-- list or qualifications)"
+ print
+ print "SELECT one() AS answer"
+ print pgcnx.query("SELECT one() AS answer")
+ print
+ print "--"
+ print "-- here's how you create a function that takes arguments. The"
+ print "-- following function returns the sum of its two arguments:"
+ print
+ print "CREATE FUNCTION add_em(int4, int4) RETURNS int4"
+ print " AS 'SELECT $1 + $2' LANGUAGE 'sql'"
+ pgcnx.query("CREATE FUNCTION add_em(int4, int4) RETURNS int4 " \
+ "AS 'SELECT $1 + $2' LANGUAGE 'sql'")
+ print
+ print "SELECT add_em(1, 2) AS answer"
+ print pgcnx.query("SELECT add_em(1, 2) AS answer")
+
+# functions on composite types
+def comp_func(pgcnx):
+ print "-----------------------------"
+ print "-- Creating SQL Functions on Composite Types"
+ print "-- it is also possible to create functions that return"
+ print "-- values of composite types."
+ print "-----------------------------"
+ print
+ print "-- before we create more sophisticated functions, let's "
+ print "-- populate an EMP table"
+ print
+ print "CREATE TABLE EMP ("
+ print " name text,"
+ print " salary int4,"
+ print " age int4,"
+ print " dept varchar(16)"
+ print ")"
+ pgcnx.query("CREATE TABLE EMP (" \
+ "name text," \
+ "salary int4," \
+ "age int4," \
+ "dept varchar(16))")
+ print
+ print "INSERT INTO EMP VALUES ('Sam', 1200, 16, 'toy')"
+ print "INSERT INTO EMP VALUES ('Claire', 5000, 32, 'shoe')"
+ print "INSERT INTO EMP VALUES ('Andy', -1000, 2, 'candy')"
+ print "INSERT INTO EMP VALUES ('Bill', 4200, 36, 'shoe')"
+ print "INSERT INTO EMP VALUES ('Ginger', 4800, 30, 'candy')"
+ pgcnx.query("INSERT INTO EMP VALUES ('Sam', 1200, 16, 'toy')")
+ pgcnx.query("INSERT INTO EMP VALUES ('Claire', 5000, 32, 'shoe')")
+ pgcnx.query("INSERT INTO EMP VALUES ('Andy', -1000, 2, 'candy')")
+ pgcnx.query("INSERT INTO EMP VALUES ('Bill', 4200, 36, 'shoe')")
+ pgcnx.query("INSERT INTO EMP VALUES ('Ginger', 4800, 30, 'candy')")
+ wait_key()
+ print
+ print "-- the argument of a function can also be a tuple. For "
+ print "-- instance, double_salary takes a tuple of the EMP table"
+ print
+ print "CREATE FUNCTION double_salary(EMP) RETURNS int4"
+ print " AS 'SELECT $1.salary * 2 AS salary' LANGUAGE 'sql'"
+ pgcnx.query("CREATE FUNCTION double_salary(EMP) RETURNS int4 " \
+ "AS 'SELECT $1.salary * 2 AS salary' LANGUAGE 'sql'")
+ print
+ print "SELECT name, double_salary(EMP) AS dream"
+ print "FROM EMP"
+ print "WHERE EMP.dept = 'toy'"
+ print pgcnx.query("SELECT name, double_salary(EMP) AS dream " \
+ "FROM EMP WHERE EMP.dept = 'toy'")
+ print
+ print "-- the return value of a function can also be a tuple. However,"
+ print "-- make sure that the expressions in the target list is in the "
+ print "-- same order as the columns of EMP."
+ print
+ print "CREATE FUNCTION new_emp() RETURNS EMP"
+ print " AS 'SELECT \'None\'::text AS name,"
+ print " 1000 AS salary,"
+ print " 25 AS age,"
+ print " \'none\'::varchar(16) AS dept'"
+ print " LANGUAGE 'sql'"
+ pgcnx.query("CREATE FUNCTION new_emp() RETURNS EMP " \
+ "AS 'SELECT \\\'None\\\'::text AS name, " \
+ "1000 AS salary, " \
+ "25 AS age, " \
+ "\\\'none\\\'::varchar(16) AS dept' " \
+ "LANGUAGE 'sql'")
+ wait_key()
+ print
+ print "-- you can then project a column out of resulting the tuple by"
+ print "-- using the \"function notation\" for projection columns. "
+ print "-- (ie. bar(foo) is equivalent to foo.bar) Note that we don't"
+ print "-- support new_emp().name at this moment."
+ print
+ print "SELECT name(new_emp()) AS nobody"
+ print pgcnx.query("SELECT name(new_emp()) AS nobody")
+ print
+ print "-- let's try one more function that returns tuples"
+ print "CREATE FUNCTION high_pay() RETURNS setof EMP"
+ print " AS 'SELECT * FROM EMP where salary > 1500'"
+ print " LANGUAGE 'sql'"
+ pgcnx.query("CREATE FUNCTION high_pay() RETURNS setof EMP " \
+ "AS 'SELECT * FROM EMP where salary > 1500' " \
+ "LANGUAGE 'sql'")
+ print
+ print "SELECT name(high_pay()) AS overpaid"
+ print pgcnx.query("SELECT name(high_pay()) AS overpaid")
+
+# function with multiple SQL commands
+def mult_func(pgcnx):
+ print "-----------------------------"
+ print "-- Creating SQL Functions with multiple SQL statements"
+ print "-- you can also create functions that do more than just a"
+ print "-- SELECT."
+ print "-----------------------------"
+ print
+ print "-- you may have noticed that Andy has a negative salary. We'll"
+ print "-- create a function that removes employees with negative "
+ print "-- salaries."
+ print
+ print "SELECT * FROM EMP"
+ print pgcnx.query("SELECT * FROM EMP")
+ print
+ print "CREATE FUNCTION clean_EMP () RETURNS int4"
+ print " AS 'DELETE FROM EMP WHERE EMP.salary <= 0"
+ print " SELECT 1 AS ignore_this'"
+ print " LANGUAGE 'sql'"
+ pgcnx.query("CREATE FUNCTION clean_EMP () RETURNS int4 AS 'DELETE FROM EMP WHERE EMP.salary <= 0; SELECT 1 AS ignore_this' LANGUAGE 'sql'")
+ print
+ print "SELECT clean_EMP()"
+ print pgcnx.query("SELECT clean_EMP()")
+ print
+ print "SELECT * FROM EMP"
+ print pgcnx.query("SELECT * FROM EMP")
+
+# base cleanup
+def demo_cleanup(pgcnx):
+ print "-- remove functions that were created in this file"
+ print
+ print "DROP FUNCTION clean_EMP()"
+ print "DROP FUNCTION high_pay()"
+ print "DROP FUNCTION new_emp()"
+ print "DROP FUNCTION add_em(int4, int4)"
+ print "DROP FUNCTION one()"
+ print
+ print "DROP TABLE EMP"
+ pgcnx.query("DROP FUNCTION clean_EMP()")
+ pgcnx.query("DROP FUNCTION high_pay()")
+ pgcnx.query("DROP FUNCTION new_emp()")
+ pgcnx.query("DROP FUNCTION add_em(int4, int4)")
+ pgcnx.query("DROP FUNCTION one()")
+ pgcnx.query("DROP TABLE EMP")
+
+# main demo function
+def demo(pgcnx):
+ base_func(pgcnx)
+ comp_func(pgcnx)
+ mult_func(pgcnx)
+ demo_cleanup(pgcnx)
--- /dev/null
+#! /usr/local/bin/python
+# pgtools.py - valuable functions for PostGreSQL tutorial
+# written 1995 by Pascal ANDRE
+
+import sys
+
+# number of rows
+scr_size = 24
+
+# waits for a key
+def wait_key():
+ print "Press <enter>"
+ sys.stdin.read(1)
+
+# displays a table for a select query result
+def display(fields, result):
+ print result
+ # gets cols width
+ fmt = []
+ sep = '+'
+ head = '|'
+ for i in range(0, len(fields)):
+ max = len(fields[i])
+ for j in range(0, len(result)):
+ if i < len(result[j]):
+ if len(result[j][i]) > max:
+ max = len(result[j][i])
+ fmt.append(" %%%ds |" % max)
+ for j in range(0, max):
+ sep = sep + '-'
+ sep = sep + '--+'
+ for i in range(0, len(fields)):
+ head = head + fmt[i] % fields[i]
+ print sep + '\n' + head + '\n' + sep
+ pos = 6
+ for i in range(0, len(result)):
+ str = '|'
+ for j in range(0, len(result[i])):
+ str = str + fmt[j] % result[i][j]
+ print str
+ pos = pos + 1
+ if pos == scr_size:
+ print sep
+ wait_key()
+ print sep + '\n' + head + '\n' + sep
+ pos = 6
+ print sep
+ wait_key()
--- /dev/null
+# syscat.py - parses some system catalogs
+# inspired from the PostgreSQL tutorial
+# adapted to Python 1995 by Pascal ANDRE
+
+print "____________________________________________________________________"
+print
+print "MODULE SYSCAT.PY : PARSES SOME POSTGRESQL SYSTEM CATALOGS"
+print
+print "This module is designed for being imported from python prompt"
+print
+print "In order to run the samples included here, first create a connection"
+print "using : cnx = syscat.DB(...)"
+print "then start the demo with: syscat.demo(cnx)"
+print
+print "Some results may be empty, depending on your base status."
+print
+print "____________________________________________________________________"
+print
+
+from pg import DB
+from pgtools import *
+
+# lists all simple indices
+def list_simple_ind(pgcnx):
+ result = pgcnx.query("select bc.relname " \
+ "as class_name, ic.relname as index_name, a.attname " \
+ "from pg_class bc, pg_class ic, pg_index i, pg_attribute a " \
+ "where i.indrelid = bc.oid and i.indexrelid = bc.oid " \
+ " and i.indkey[0] = a.attnum and a.attrelid = bc.oid " \
+ " and i.indproc = '0'::oid " \
+ "order by class_name, index_name, attname")
+ return result
+
+# list all user defined attributes and their type in user-defined classes
+def list_all_attr(pgcnx):
+ result = pgcnx.query("select c.relname, a.attname, t.typname " \
+ "from pg_class c, pg_attribute a, pg_type t " \
+ "where c.relkind = 'r' and c.relname !~ '^pg_' " \
+ " and c.relname !~ '^Inv' and a.attnum > 0 " \
+ " and a.attrelid = c.oid and a.atttypid = t.oid " \
+ "order by relname, attname")
+ return result
+
+# list all user defined base type
+def list_user_base_type(pgcnx):
+ result = pgcnx.query("select u.usename, t.typname " \
+ "from pg_type t, pg_user u " \
+ "where u.usesysid = int2in(int4out(t.typowner)) " \
+ " and t.typrelid = '0'::oid and t.typelem = '0'::oid " \
+ " and u.usename <> 'postgres' order by usename, typname")
+ return result
+
+# list all right-unary operators
+def list_right_unary_operator(pgcnx):
+ result = pgcnx.query("select o.oprname as right_unary, " \
+ " lt.typname as operand, result.typname as return_type " \
+ "from pg_operator o, pg_type lt, pg_type result " \
+ "where o.oprkind='r' and o.oprleft = lt.oid " \
+ " and o.oprresult = result.oid order by operand")
+ return result
+
+# list all left-unary operators
+def list_left_unary_operator(pgcnx):
+ result = pgcnx.query("select o.oprname as left_unary, " \
+ " rt.typname as operand, result.typname as return_type " \
+ "from pg_operator o, pg_type rt, pg_type result " \
+ "where o.oprkind='l' and o.oprright = rt.oid " \
+ " and o.oprresult = result.oid order by operand")
+ return result
+
+# list all binary operators
+def list_binary_operator(pgcnx):
+ result = pgcnx.query("select o.oprname as binary_op, " \
+ " rt.typname as right_opr, lt.typname as left_opr, " \
+ " result.typname as return_type " \
+ "from pg_operator o, pg_type rt, pg_type lt, pg_type result " \
+ "where o.oprkind = 'b' and o.oprright = rt.oid " \
+ " and o.oprleft = lt.oid and o.oprresult = result.oid")
+ return result
+
+# returns the name, args and return type from all function of lang l
+def list_lang_func(pgcnx, l):
+ result = pgcnx.query("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 = '%s' order by proname" % l)
+ return result
+
+# lists all the aggregate functions and the type to which they can be applied
+def list_agg_func(pgcnx):
+ result = pgcnx.query("select a.aggname, t.typname " \
+ "from pg_aggregate a, pg_type t " \
+ "where a.aggbasetype = t.oid order by aggname, typname")
+ return result
+
+# lists all 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
+def list_op_class(pgcnx):
+ result = pgcnx.query("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")
+ return result
+
+# demo function - runs all examples
+def demo(pgcnx):
+ #import sys, os
+ #save_stdout = sys.stdout
+ #sys.stdout = os.popen("more", "w")
+ print "Listing simple indices ..."
+ print list_simple_ind(pgcnx)
+ print "Listing all attributes ..."
+ print list_all_attr(pgcnx)
+ print "Listing all user-defined base types ..."
+ print list_user_base_type(pgcnx)
+ print "Listing all left-unary operators defined ..."
+ print list_left_unary_operator(pgcnx)
+ print "Listing all right-unary operators defined ..."
+ print list_right_unary_operator(pgcnx)
+ print "Listing all binary operators ..."
+ print list_binary_operator(pgcnx)
+ print "Listing C external function linked ..."
+ print list_lang_func(pgcnx, 'C')
+ print "Listing C internal functions ..."
+ print list_lang_func(pgcnx, 'internal')
+ print "Listing SQL functions defined ..."
+ print list_lang_func(pgcnx, 'sql')
+ print "Listing 'aggregate functions' ..."
+ print list_agg_func(pgcnx)
+ print "Listing 'operator classes' ..."
+ print list_op_class(pgcnx)
+ #del sys.stdout
+ #sys.stdout = save_stdout