├── README.txt ├── doc ├── example_database.dot ├── example_database.png ├── example_database.sql └── example_database.svg ├── install_example_database.sh ├── sql ├── data │ └── ObjectTypes.sql ├── install.sql ├── install_example_database.sql ├── reinstall-functions.sql ├── schema │ ├── grant.sql │ ├── pg_catalog │ │ └── functions │ │ │ └── pg_describe_object.sql │ ├── pov │ │ ├── functions │ │ │ ├── Get_Object.sql │ │ │ ├── Get_Revision.sql │ │ │ ├── Hash.sql │ │ │ ├── New_Revision.sql │ │ │ ├── Set_Object.sql │ │ │ ├── Set_Revision.sql │ │ │ ├── _format_type.sql │ │ │ ├── pg_get_aggregate_create_def.sql │ │ │ ├── pg_get_aggregate_drop_def.sql │ │ │ └── tsort.pl │ │ ├── tables │ │ │ ├── ObjectTypes.sql │ │ │ ├── Objects.sql │ │ │ ├── Revisions.sql │ │ │ └── Snapshots.sql │ │ └── views │ │ │ ├── pg_all_objects_unique_columns.sql │ │ │ ├── pg_depend_definitions.sql │ │ │ ├── pg_depend_dot.sql │ │ │ ├── pg_depend_oid_concat.sql │ │ │ ├── pg_depend_remapped.sql │ │ │ └── pg_depend_tsort.sql │ └── public │ │ ├── functions │ │ └── pov.sql │ │ └── views │ │ └── view_snapshots.sql └── uninstall.sql ├── test.sh ├── test.sql ├── test.stderr └── test.stdout /README.txt: -------------------------------------------------------------------------------- 1 | pov - PostgreSQL Object Version control system 2 | 3 | DESCRIPTION 4 | 5 | Take a snapshot or rollback all "non-data" objects in a PostgreSQL database. 6 | Without losing any of your data, you can travel in time and restore the state of any snapshot taken. 7 | 8 | 9 | 10 | RATIONALE 11 | 12 | Before reading any further, ask yourselves the following questions. 13 | 14 | 1. Have you ever, 15 | a) modified stored procedures in your production database and 16 | b) thought it went OK because all your tests passed and 17 | c) later on realized "something is wrong" and 18 | d) not being able to find nor fix the bug immediately 19 | leaving you no other option than to do a revert? 20 | If so, go to step 2. 21 | If not, go to step 4. 22 | 23 | 2. During the minutes/hours while your malfunctional patch made a mess 24 | in the production database, was there any user activity causing 25 | important writes to the database? 26 | If so, go to step 3. 27 | If not, go to step 4. 28 | 29 | 3. Did you enjoy the revert experience in step 1? 30 | If so, go to step 4. 31 | If not, go to step 5. 32 | 33 | 4. Are any of the following statements TRUE? 34 | a) your application is not very database centric. 35 | b) your users won't stop using your service if you lose their data. 36 | c) your application is read-only. 37 | d) your application does not have a lot of user traffic. 38 | If so, lucky you! 39 | If not, you probably have a good solution to my problem already, 40 | I would highly appreciate if you wanted to share it with me, 41 | please contact me at joel@gluefinance.com. 42 | 43 | 5. This proposed solution might be interesting for you. 44 | I would highly appreciate your feedback on how to improve it, 45 | please contact me at joel@gluefinance.com. 46 | 47 | 48 | 49 | INTRODUCTION 50 | 51 | pov can take a snapshot of all your database functions and objects 52 | depending on them, such as constraints and views using functions. 53 | 54 | pov can rollback to a previous snapshot without modifying any of your 55 | data or tables. It will only execute the minimum set of drop/create commands 56 | to carry out the rollback. 57 | 58 | pov will use SHA1 if the pgcrypto contrib package is available, 59 | otherwise MD5 will be used as the hash algorithm. 60 | 61 | 62 | 63 | TERMINOLOGY 64 | 65 | object type objects of the same type are created and dropped the same way, 66 | i.e. they use the same functions to build proper create and 67 | drop SQL-commands. 68 | 69 | object is of an object type and has a hash of its content 70 | consisting of two SQL-commands, one to create and another to 71 | drop the object. 72 | 73 | revision has a timestamp when it was created and a list of objects 74 | 75 | snapshot has a timestamp when it was taken and has a revision 76 | 77 | active snapshot the last snapshot taken 78 | 79 | take snapshot create a new revision of all objects currently live in the 80 | database and then create a new snapshot if the revision 81 | is different compared to the active snapshot. 82 | 83 | rollback restores a previously taken snapshot 84 | 85 | 86 | 87 | SYNOPSIS 88 | 89 | -- 1. Take a snapshot. 90 | 91 | test=# SELECT * FROM pov(); 92 | _snapshotid | _revisionid 93 | -------------+------------------------------------------ 94 | 1 | 8ba39bf65949adc6b69aa356c29725cf06c77e26 95 | (1 row) 96 | 97 | 98 | -- 2. Take a snapshot. 99 | 100 | test=# SELECT * FROM pov(); 101 | _snapshotid | _revisionid 102 | -------------+------------------------------------------ 103 | 1 | 8ba39bf65949adc6b69aa356c29725cf06c77e26 104 | (1 row) 105 | 106 | 107 | -- 3. We notice nothing changed between step 1 and 2. 108 | 109 | 110 | -- 4. Modify your functions. 111 | 112 | test=# CREATE FUNCTION myfunc() RETURNS VOID AS $$ $$ LANGUAGE sql; 113 | CREATE FUNCTION 114 | test=# \df myfunc 115 | List of functions 116 | Schema | Name | Result data type | Argument data types | Type 117 | --------+--------+------------------+---------------------+-------- 118 | public | myfunc | void | | normal 119 | (1 row) 120 | 121 | 122 | -- 5. Take a snapshot. 123 | 124 | test=# SELECT * FROM pov(); 125 | _snapshotid | _revisionid 126 | -------------+------------------------------------------ 127 | 2 | 6c4c86015a45d9361889ce29908937b387e4dde0 128 | (1 row) 129 | 130 | 131 | -- 4. Rollback to pov 1. 132 | 133 | test=# SELECT * FROM pov(1); 134 | _snapshotid | _revisionid 135 | -------------+------------------------------------------ 136 | 3 | 8ba39bf65949adc6b69aa356c29725cf06c77e26 137 | (1 row) 138 | 139 | 140 | -- 5. We notice the function we created in step 4 has been dropped. 141 | 142 | postgres=# \df myfunc 143 | List of functions 144 | Schema | Name | Result data type | Argument data types | Type 145 | --------+------+------------------+---------------------+------ 146 | (0 rows) 147 | 148 | 149 | -- 6. Rollback to pov 2. 150 | 151 | test=# SELECT * FROM pov(2); 152 | _snapshotid | _revisionid 153 | -------------+------------------------------------------ 154 | 4 | 6c4c86015a45d9361889ce29908937b387e4dde0 155 | (1 row) 156 | 157 | 158 | -- 7. We notice the function we created in step 4 has been created. 159 | 160 | postgres=# \df myfunc 161 | List of functions 162 | Schema | Name | Result data type | Argument data types | Type 163 | --------+--------+------------------+---------------------+-------- 164 | public | myfunc | void | | normal 165 | (1 row) 166 | 167 | -------------------------------------------------------------------------------- /doc/example_database.dot: -------------------------------------------------------------------------------- 1 | digraph pg_depend { 2 | "function plpgsql_call_handler() 1255.11599.0" -> "language plpgsql 2612.11602.0" [color=black label=n] 3 | "function plpgsql_inline_handler(internal) 1255.11600.0" -> "language plpgsql 2612.11602.0" [color=black label=n] 4 | "function plpgsql_validator(oid) 1255.11601.0" -> "language plpgsql 2612.11602.0" [color=black label=n] 5 | "function plperl_call_handler() 1255.23562.0" -> "language plperl 2612.23565.0" [color=black label=n] 6 | "function plperl_inline_handler(internal) 1255.23563.0" -> "language plperl 2612.23565.0" [color=black label=n] 7 | "function plperl_validator(oid) 1255.23564.0" -> "language plperl 2612.23565.0" [color=black label=n] 8 | "function f1(integer) 1255.23656.0" -> "view v4 1259.23688.0" [color=black label=n] 9 | "function f1(integer) 1255.23656.0" -> "constraint t3_id_check on table t3 2606.23673.0" [color=black label=n] 10 | "table t1 1259.23651.0" -> "table t1 column id 1259.23651.1" [color=yellow label=an] 11 | "table t1 column id 1259.23651.1" -> "view v1 1259.23676.0" [color=black label=n] 12 | "table t1 column id 1259.23651.1" -> "constraint t1_pkey on table t1 2606.23655.0" [color=blue label=a] 13 | "table t1 column id 1259.23651.1" -> "constraint t2_id_fkey on table t2 2606.23664.0" [color=black label=n] 14 | "sequence s1 1259.23657.0" -> "default for table t3 column id 2604.23672.0" [color=black label=n] 15 | "table t2 1259.23659.0" -> "table t2 column id 1259.23659.1" [color=yellow label=an] 16 | "table t2 column id 1259.23659.1" -> "view v2 1259.23680.0" [color=black label=n] 17 | "table t2 column id 1259.23659.1" -> "constraint t2_pkey on table t2 2606.23663.0" [color=blue label=a] 18 | "table t2 column id 1259.23659.1" -> "constraint t2_id_fkey on table t2 2606.23664.0" [color=blue label=a] 19 | "table t3 1259.23669.0" -> "table t3 column id 1259.23669.1" [color=yellow label=an] 20 | "table t3 column id 1259.23669.1" -> "default for table t3 column id 2604.23672.0" [color=blue label=a] 21 | "table t3 column id 1259.23669.1" -> "constraint t3_id_check on table t3 2606.23673.0" [color=yellow label=na] 22 | "table t3 column id 1259.23669.1" -> "constraint t3_pkey on table t3 2606.23675.0" [color=blue label=a] 23 | "view v1 1259.23676.0" -> "view v1 column id 1259.23676.1" [color=black label=n] 24 | "view v1 column id 1259.23676.1" -> "view v3 1259.23684.0" [color=black label=n] 25 | "view v2 1259.23680.0" -> "view v2 column id 1259.23680.1" [color=black label=n] 26 | "view v2 column id 1259.23680.1" -> "view v3 1259.23684.0" [color=black label=n] 27 | "view v3 1259.23684.0" -> "view v3 column id1 1259.23684.1" [color=black label=n] 28 | "view v3 1259.23684.0" -> "view v3 column id2 1259.23684.2" [color=black label=n] 29 | "view v3 column id1 1259.23684.1" -> "view v4 1259.23688.0" [color=black label=n] 30 | "view v3 column id2 1259.23684.2" -> "view v4 1259.23688.0" [color=black label=n] 31 | "constraint t1_pkey on table t1 2606.23655.0" -> "constraint t2_id_fkey on table t2 2606.23664.0" [color=black label=n] 32 | "schema public 2615.2200.0" -> "function f1(integer) 1255.23656.0" [color=black label=n] 33 | "schema public 2615.2200.0" -> "table t1 1259.23651.0" [color=black label=n] 34 | "schema public 2615.2200.0" -> "sequence s1 1259.23657.0" [color=black label=n] 35 | "schema public 2615.2200.0" -> "table t2 1259.23659.0" [color=black label=n] 36 | "schema public 2615.2200.0" -> "table t3 1259.23669.0" [color=black label=n] 37 | "schema public 2615.2200.0" -> "view v1 1259.23676.0" [color=black label=n] 38 | "schema public 2615.2200.0" -> "view v2 1259.23680.0" [color=black label=n] 39 | "schema public 2615.2200.0" -> "view v3 1259.23684.0" [color=black label=n] 40 | "schema public 2615.2200.0" -> "view v4 1259.23688.0" [color=black label=n] 41 | } -------------------------------------------------------------------------------- /doc/example_database.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/gluefinance/pov/15fa8b6608a05ab0b0cc6f9e1b9659d3fdb89f16/doc/example_database.png -------------------------------------------------------------------------------- /doc/example_database.sql: -------------------------------------------------------------------------------- 1 | -- This is an example of some functionality provided and used by pov (PostgreSQL Object version control system). 2 | -- Most of, if not all, this stuff has already been implemented in pg_dump, 3 | -- but since pov is a SQL-based system it was necessary to implement the same functionality 4 | -- using only sql/plpgsql/plperl. 5 | -- 6 | -- Author: Joel Jacobson, Glue Finance AB, Sweden, 7 | -- Datestamp: 2011-01-13 23:42 Europe/Stockholm 8 | -- License: MIT (http://www.opensource.org/licenses/mit-license.php) 9 | -- 10 | -- We will learn how to do a lot of PostgreSQL-magic only by using the nice system table "pg_depend". 11 | -- Today we will, 12 | -- a) create nice directional graphs of all object dependencies, 13 | -- b) sort all objects in a truly sorted topological creatable order, 14 | -- c) show create/drop commands for most of the objects. 15 | -- 16 | -- Let the show begin! 17 | -- 18 | -- Installation: 19 | -- 20 | -- $ git clone git@github.com:gluefinance/pov.git 21 | -- $ cd pov 22 | -- $ sh install_example_database.sh 23 | -- 24 | -- a) Generate directional graph in DOT-format. 25 | -- COPY (SELECT diagraph FROM pov.pg_depend_dot) TO '/tmp/example_database.dot'; 26 | -- 27 | -- Then use the dot (http://www.graphviz.org/) to generate graphs in svg, png, or any format. 28 | -- dot -oexample_database.png -Tpng example_database.dot 29 | -- dot -oexample_database.svg -Tsvg example_database.dot 30 | -- 31 | -- Or view it in the SQL prompt: 32 | -- 33 | -- test=# select * from pov.pg_depend_dot; 34 | -- diagraph 35 | -- ----------------------------------------------------------------------------------------------------------------------------- 36 | -- digraph pg_depend { 37 | -- "function plpgsql_call_handler() 1255.11599.0" -> "language plpgsql 2612.11602.0" [color=black label=n] 38 | -- "function plpgsql_inline_handler(internal) 1255.11600.0" -> "language plpgsql 2612.11602.0" [color=black label=n] 39 | -- "function plpgsql_validator(oid) 1255.11601.0" -> "language plpgsql 2612.11602.0" [color=black label=n] 40 | -- "function plperl_call_handler() 1255.23562.0" -> "language plperl 2612.23565.0" [color=black label=n] 41 | -- "function plperl_inline_handler(internal) 1255.23563.0" -> "language plperl 2612.23565.0" [color=black label=n] 42 | -- "function plperl_validator(oid) 1255.23564.0" -> "language plperl 2612.23565.0" [color=black label=n] 43 | -- "function f1(integer) 1255.23656.0" -> "view v4 1259.23688.0" [color=black label=n] 44 | -- "function f1(integer) 1255.23656.0" -> "constraint t3_id_check on table t3 2606.23673.0" [color=black label=n] 45 | -- "table t1 1259.23651.0" -> "table t1 column id 1259.23651.1" [color=yellow label=an] 46 | -- "table t1 column id 1259.23651.1" -> "view v1 1259.23676.0" [color=black label=n] 47 | -- "table t1 column id 1259.23651.1" -> "constraint t1_pkey on table t1 2606.23655.0" [color=blue label=a] 48 | -- "table t1 column id 1259.23651.1" -> "constraint t2_id_fkey on table t2 2606.23664.0" [color=black label=n] 49 | -- "sequence s1 1259.23657.0" -> "default for table t3 column id 2604.23672.0" [color=black label=n] 50 | -- "table t2 1259.23659.0" -> "table t2 column id 1259.23659.1" [color=yellow label=an] 51 | -- "table t2 column id 1259.23659.1" -> "view v2 1259.23680.0" [color=black label=n] 52 | -- "table t2 column id 1259.23659.1" -> "constraint t2_pkey on table t2 2606.23663.0" [color=blue label=a] 53 | -- "table t2 column id 1259.23659.1" -> "constraint t2_id_fkey on table t2 2606.23664.0" [color=blue label=a] 54 | -- "table t3 1259.23669.0" -> "table t3 column id 1259.23669.1" [color=yellow label=an] 55 | -- "table t3 column id 1259.23669.1" -> "default for table t3 column id 2604.23672.0" [color=blue label=a] 56 | -- "table t3 column id 1259.23669.1" -> "constraint t3_id_check on table t3 2606.23673.0" [color=yellow label=na] 57 | -- "table t3 column id 1259.23669.1" -> "constraint t3_pkey on table t3 2606.23675.0" [color=blue label=a] 58 | -- "view v1 1259.23676.0" -> "view v1 column id 1259.23676.1" [color=black label=n] 59 | -- "view v1 column id 1259.23676.1" -> "view v3 1259.23684.0" [color=black label=n] 60 | -- "view v2 1259.23680.0" -> "view v2 column id 1259.23680.1" [color=black label=n] 61 | -- "view v2 column id 1259.23680.1" -> "view v3 1259.23684.0" [color=black label=n] 62 | -- "view v3 1259.23684.0" -> "view v3 column id1 1259.23684.1" [color=black label=n] 63 | -- "view v3 1259.23684.0" -> "view v3 column id2 1259.23684.2" [color=black label=n] 64 | -- "view v3 column id1 1259.23684.1" -> "view v4 1259.23688.0" [color=black label=n] 65 | -- "view v3 column id2 1259.23684.2" -> "view v4 1259.23688.0" [color=black label=n] 66 | -- "constraint t1_pkey on table t1 2606.23655.0" -> "constraint t2_id_fkey on table t2 2606.23664.0" [color=black label=n] 67 | -- "schema public 2615.2200.0" -> "function f1(integer) 1255.23656.0" [color=black label=n] 68 | -- "schema public 2615.2200.0" -> "table t1 1259.23651.0" [color=black label=n] 69 | -- "schema public 2615.2200.0" -> "sequence s1 1259.23657.0" [color=black label=n] 70 | -- "schema public 2615.2200.0" -> "table t2 1259.23659.0" [color=black label=n] 71 | -- "schema public 2615.2200.0" -> "table t3 1259.23669.0" [color=black label=n] 72 | -- "schema public 2615.2200.0" -> "view v1 1259.23676.0" [color=black label=n] 73 | -- "schema public 2615.2200.0" -> "view v2 1259.23680.0" [color=black label=n] 74 | -- "schema public 2615.2200.0" -> "view v3 1259.23684.0" [color=black label=n] 75 | -- "schema public 2615.2200.0" -> "view v4 1259.23688.0" [color=black label=n] 76 | -- } 77 | -- (41 rows) 78 | 79 | -- b) Sort all objects in lexically sorted order. 80 | -- 81 | -- test=# select * from pov.pg_depend_tsort ; 82 | -- row_number | description | classid | objid | objsubid 83 | -- ------------+-------------------------------------------+---------+-------+---------- 84 | -- 1 | function plperl_call_handler() | 1255 | 23562 | 0 85 | -- 2 | function plperl_inline_handler(internal) | 1255 | 23563 | 0 86 | -- 3 | function plperl_validator(oid) | 1255 | 23564 | 0 87 | -- 4 | function plpgsql_call_handler() | 1255 | 11599 | 0 88 | -- 5 | function plpgsql_inline_handler(internal) | 1255 | 11600 | 0 89 | -- 6 | function plpgsql_validator(oid) | 1255 | 11601 | 0 90 | -- 7 | language plperl | 2612 | 23565 | 0 91 | -- 8 | language plpgsql | 2612 | 11602 | 0 92 | -- 9 | schema public | 2615 | 2200 | 0 93 | -- 10 | function f1(integer) | 1255 | 23656 | 0 94 | -- 11 | sequence s1 | 1259 | 23657 | 0 95 | -- 12 | table t1 | 1259 | 23651 | 0 96 | -- 13 | table t1 column id | 1259 | 23651 | 1 97 | -- 14 | constraint t1_pkey on table t1 | 2606 | 23655 | 0 98 | -- 15 | table t2 | 1259 | 23659 | 0 99 | -- 16 | table t2 column id | 1259 | 23659 | 1 100 | -- 17 | constraint t2_id_fkey on table t2 | 2606 | 23664 | 0 101 | -- 18 | constraint t2_pkey on table t2 | 2606 | 23663 | 0 102 | -- 19 | table t3 | 1259 | 23669 | 0 103 | -- 20 | table t3 column id | 1259 | 23669 | 1 104 | -- 21 | constraint t3_id_check on table t3 | 2606 | 23673 | 0 105 | -- 22 | constraint t3_pkey on table t3 | 2606 | 23675 | 0 106 | -- 23 | default for table t3 column id | 2604 | 23672 | 0 107 | -- 24 | view v1 | 1259 | 23676 | 0 108 | -- 25 | view v1 column id | 1259 | 23676 | 1 109 | -- 26 | view v2 | 1259 | 23680 | 0 110 | -- 27 | view v2 column id | 1259 | 23680 | 1 111 | -- 28 | view v3 | 1259 | 23684 | 0 112 | -- 29 | view v3 column id1 | 1259 | 23684 | 1 113 | -- 30 | view v3 column id2 | 1259 | 23684 | 2 114 | -- 31 | view v4 | 1259 | 23688 | 0 115 | -- (31 rows) 116 | -- 117 | -- c) Get create/drop commands for most of the objects: 118 | -- 119 | -- test=# select * from pov.pg_depend_definitions ; 120 | -- row_number | description | classid | objid | objsubid | create_definition | drop_definition 121 | -- 122 | -- ------------+------------------------------------+---------+-------+----------+------------------------------------------------------------------------------------+-------------------------------------------------------- 123 | -- 7 | language plperl | 2612 | 23565 | 0 | CREATE LANGUAGE plperl | DROP LANGUAGE plperl 124 | -- 8 | language plpgsql | 2612 | 11602 | 0 | CREATE LANGUAGE plpgsql | DROP LANGUAGE plpgsql 125 | -- 9 | schema public | 2615 | 2200 | 0 | CREATE SCHEMA public;ALTER SCHEMA public OWNER TO ubuntu | DROP SCHEMA public 126 | -- 10 | function f1(integer) | 1255 | 23656 | 0 | CREATE OR REPLACE FUNCTION public.f1(integer) +| DROP FUNCTION public.f1(integer) 127 | -- | | | | | RETURNS boolean +| 128 | -- | | | | | LANGUAGE sql +| 129 | -- | | | | | AS $function$ SELECT $1 > 1; $function$ +| 130 | -- | | | | | ;ALTER FUNCTION public.f1(integer) OWNER TO postgres | 131 | -- 13 | table t1 column id | 1259 | 23651 | 1 | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' 132 | -- 14 | constraint t1_pkey on table t1 | 2606 | 23655 | 0 | ALTER TABLE public.t1 ADD CONSTRAINT t1_pkey PRIMARY KEY (id) | ALTER TABLE public.t1 DROP CONSTRAINT t1_pkey 133 | -- 16 | table t2 column id | 1259 | 23659 | 1 | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' 134 | -- 17 | constraint t2_id_fkey on table t2 | 2606 | 23664 | 0 | ALTER TABLE public.t2 ADD CONSTRAINT t2_id_fkey FOREIGN KEY (id) REFERENCES t1(id) | ALTER TABLE public.t2 DROP CONSTRAINT t2_id_fkey 135 | -- 18 | constraint t2_pkey on table t2 | 2606 | 23663 | 0 | ALTER TABLE public.t2 ADD CONSTRAINT t2_pkey PRIMARY KEY (id) | ALTER TABLE public.t2 DROP CONSTRAINT t2_pkey 136 | -- 20 | table t3 column id | 1259 | 23669 | 1 | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' 137 | -- 21 | constraint t3_id_check on table t3 | 2606 | 23673 | 0 | ALTER TABLE public.t3 ADD CONSTRAINT t3_id_check CHECK (f1(id)) | ALTER TABLE public.t3 DROP CONSTRAINT t3_id_check 138 | -- 22 | constraint t3_pkey on table t3 | 2606 | 23675 | 0 | ALTER TABLE public.t3 ADD CONSTRAINT t3_pkey PRIMARY KEY (id) | ALTER TABLE public.t3 DROP CONSTRAINT t3_pkey 139 | -- 25 | view v1 column id | 1259 | 23676 | 1 | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' 140 | -- 27 | view v2 column id | 1259 | 23680 | 1 | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' 141 | -- 29 | view v3 column id1 | 1259 | 23684 | 1 | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' 142 | -- 30 | view v3 column id2 | 1259 | 23684 | 2 | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' | RAISE EXCEPTION 'Sorry, pg_class is not supported yet' 143 | -- (16 rows) 144 | -------------------------------------------------------------------------------- /doc/example_database.svg: -------------------------------------------------------------------------------- 1 | 2 | 4 | 6 | 7 | 9 | 10 | pg_depend 11 | 12 | 13 | function plpgsql_call_handler() 1255.11599.0 14 | 15 | function plpgsql_call_handler() 1255.11599.0 16 | 17 | 18 | language plpgsql 2612.11602.0 19 | 20 | language plpgsql 2612.11602.0 21 | 22 | 23 | function plpgsql_call_handler() 1255.11599.0->language plpgsql 2612.11602.0 24 | 25 | 26 | n 27 | 28 | 29 | function plpgsql_inline_handler(internal) 1255.11600.0 30 | 31 | function plpgsql_inline_handler(internal) 1255.11600.0 32 | 33 | 34 | function plpgsql_inline_handler(internal) 1255.11600.0->language plpgsql 2612.11602.0 35 | 36 | 37 | n 38 | 39 | 40 | function plpgsql_validator(oid) 1255.11601.0 41 | 42 | function plpgsql_validator(oid) 1255.11601.0 43 | 44 | 45 | function plpgsql_validator(oid) 1255.11601.0->language plpgsql 2612.11602.0 46 | 47 | 48 | n 49 | 50 | 51 | function plperl_call_handler() 1255.23562.0 52 | 53 | function plperl_call_handler() 1255.23562.0 54 | 55 | 56 | language plperl 2612.23565.0 57 | 58 | language plperl 2612.23565.0 59 | 60 | 61 | function plperl_call_handler() 1255.23562.0->language plperl 2612.23565.0 62 | 63 | 64 | n 65 | 66 | 67 | function plperl_inline_handler(internal) 1255.23563.0 68 | 69 | function plperl_inline_handler(internal) 1255.23563.0 70 | 71 | 72 | function plperl_inline_handler(internal) 1255.23563.0->language plperl 2612.23565.0 73 | 74 | 75 | n 76 | 77 | 78 | function plperl_validator(oid) 1255.23564.0 79 | 80 | function plperl_validator(oid) 1255.23564.0 81 | 82 | 83 | function plperl_validator(oid) 1255.23564.0->language plperl 2612.23565.0 84 | 85 | 86 | n 87 | 88 | 89 | function f1(integer) 1255.23656.0 90 | 91 | function f1(integer) 1255.23656.0 92 | 93 | 94 | view v4 1259.23688.0 95 | 96 | view v4 1259.23688.0 97 | 98 | 99 | function f1(integer) 1255.23656.0->view v4 1259.23688.0 100 | 101 | 102 | n 103 | 104 | 105 | constraint t3_id_check on table t3 2606.23673.0 106 | 107 | constraint t3_id_check on table t3 2606.23673.0 108 | 109 | 110 | function f1(integer) 1255.23656.0->constraint t3_id_check on table t3 2606.23673.0 111 | 112 | 113 | n 114 | 115 | 116 | table t1 1259.23651.0 117 | 118 | table t1 1259.23651.0 119 | 120 | 121 | table t1 column id 1259.23651.1 122 | 123 | table t1 column id 1259.23651.1 124 | 125 | 126 | table t1 1259.23651.0->table t1 column id 1259.23651.1 127 | 128 | 129 | an 130 | 131 | 132 | view v1 1259.23676.0 133 | 134 | view v1 1259.23676.0 135 | 136 | 137 | table t1 column id 1259.23651.1->view v1 1259.23676.0 138 | 139 | 140 | n 141 | 142 | 143 | constraint t1_pkey on table t1 2606.23655.0 144 | 145 | constraint t1_pkey on table t1 2606.23655.0 146 | 147 | 148 | table t1 column id 1259.23651.1->constraint t1_pkey on table t1 2606.23655.0 149 | 150 | 151 | a 152 | 153 | 154 | constraint t2_id_fkey on table t2 2606.23664.0 155 | 156 | constraint t2_id_fkey on table t2 2606.23664.0 157 | 158 | 159 | table t1 column id 1259.23651.1->constraint t2_id_fkey on table t2 2606.23664.0 160 | 161 | 162 | n 163 | 164 | 165 | view v1 column id 1259.23676.1 166 | 167 | view v1 column id 1259.23676.1 168 | 169 | 170 | view v1 1259.23676.0->view v1 column id 1259.23676.1 171 | 172 | 173 | n 174 | 175 | 176 | constraint t1_pkey on table t1 2606.23655.0->constraint t2_id_fkey on table t2 2606.23664.0 177 | 178 | 179 | n 180 | 181 | 182 | sequence s1 1259.23657.0 183 | 184 | sequence s1 1259.23657.0 185 | 186 | 187 | default for table t3 column id 2604.23672.0 188 | 189 | default for table t3 column id 2604.23672.0 190 | 191 | 192 | sequence s1 1259.23657.0->default for table t3 column id 2604.23672.0 193 | 194 | 195 | n 196 | 197 | 198 | table t2 1259.23659.0 199 | 200 | table t2 1259.23659.0 201 | 202 | 203 | table t2 column id 1259.23659.1 204 | 205 | table t2 column id 1259.23659.1 206 | 207 | 208 | table t2 1259.23659.0->table t2 column id 1259.23659.1 209 | 210 | 211 | an 212 | 213 | 214 | table t2 column id 1259.23659.1->constraint t2_id_fkey on table t2 2606.23664.0 215 | 216 | 217 | a 218 | 219 | 220 | view v2 1259.23680.0 221 | 222 | view v2 1259.23680.0 223 | 224 | 225 | table t2 column id 1259.23659.1->view v2 1259.23680.0 226 | 227 | 228 | n 229 | 230 | 231 | constraint t2_pkey on table t2 2606.23663.0 232 | 233 | constraint t2_pkey on table t2 2606.23663.0 234 | 235 | 236 | table t2 column id 1259.23659.1->constraint t2_pkey on table t2 2606.23663.0 237 | 238 | 239 | a 240 | 241 | 242 | view v2 column id 1259.23680.1 243 | 244 | view v2 column id 1259.23680.1 245 | 246 | 247 | view v2 1259.23680.0->view v2 column id 1259.23680.1 248 | 249 | 250 | n 251 | 252 | 253 | table t3 1259.23669.0 254 | 255 | table t3 1259.23669.0 256 | 257 | 258 | table t3 column id 1259.23669.1 259 | 260 | table t3 column id 1259.23669.1 261 | 262 | 263 | table t3 1259.23669.0->table t3 column id 1259.23669.1 264 | 265 | 266 | an 267 | 268 | 269 | table t3 column id 1259.23669.1->constraint t3_id_check on table t3 2606.23673.0 270 | 271 | 272 | na 273 | 274 | 275 | table t3 column id 1259.23669.1->default for table t3 column id 2604.23672.0 276 | 277 | 278 | a 279 | 280 | 281 | constraint t3_pkey on table t3 2606.23675.0 282 | 283 | constraint t3_pkey on table t3 2606.23675.0 284 | 285 | 286 | table t3 column id 1259.23669.1->constraint t3_pkey on table t3 2606.23675.0 287 | 288 | 289 | a 290 | 291 | 292 | view v3 1259.23684.0 293 | 294 | view v3 1259.23684.0 295 | 296 | 297 | view v1 column id 1259.23676.1->view v3 1259.23684.0 298 | 299 | 300 | n 301 | 302 | 303 | view v3 column id1 1259.23684.1 304 | 305 | view v3 column id1 1259.23684.1 306 | 307 | 308 | view v3 1259.23684.0->view v3 column id1 1259.23684.1 309 | 310 | 311 | n 312 | 313 | 314 | view v3 column id2 1259.23684.2 315 | 316 | view v3 column id2 1259.23684.2 317 | 318 | 319 | view v3 1259.23684.0->view v3 column id2 1259.23684.2 320 | 321 | 322 | n 323 | 324 | 325 | view v2 column id 1259.23680.1->view v3 1259.23684.0 326 | 327 | 328 | n 329 | 330 | 331 | view v3 column id1 1259.23684.1->view v4 1259.23688.0 332 | 333 | 334 | n 335 | 336 | 337 | view v3 column id2 1259.23684.2->view v4 1259.23688.0 338 | 339 | 340 | n 341 | 342 | 343 | schema public 2615.2200.0 344 | 345 | schema public 2615.2200.0 346 | 347 | 348 | schema public 2615.2200.0->function f1(integer) 1255.23656.0 349 | 350 | 351 | n 352 | 353 | 354 | schema public 2615.2200.0->view v4 1259.23688.0 355 | 356 | 357 | n 358 | 359 | 360 | schema public 2615.2200.0->table t1 1259.23651.0 361 | 362 | 363 | n 364 | 365 | 366 | schema public 2615.2200.0->view v1 1259.23676.0 367 | 368 | 369 | n 370 | 371 | 372 | schema public 2615.2200.0->sequence s1 1259.23657.0 373 | 374 | 375 | n 376 | 377 | 378 | schema public 2615.2200.0->table t2 1259.23659.0 379 | 380 | 381 | n 382 | 383 | 384 | schema public 2615.2200.0->view v2 1259.23680.0 385 | 386 | 387 | n 388 | 389 | 390 | schema public 2615.2200.0->table t3 1259.23669.0 391 | 392 | 393 | n 394 | 395 | 396 | schema public 2615.2200.0->view v3 1259.23684.0 397 | 398 | 399 | n 400 | 401 | 402 | 403 | -------------------------------------------------------------------------------- /install_example_database.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | dropdb test 2> /dev/null 3 | createdb test 4 | psql test -f sql/install_example_database.sql 5 | echo Installed! 6 | -------------------------------------------------------------------------------- /sql/data/ObjectTypes.sql: -------------------------------------------------------------------------------- 1 | INSERT INTO pov.ObjectTypes (ObjectTypeID, Name) VALUES (1, 'function'); 2 | INSERT INTO pov.ObjectTypes (ObjectTypeID, Name) VALUES (2, 'constraint'); 3 | INSERT INTO pov.ObjectTypes (ObjectTypeID, Name) VALUES (3, 'view'); 4 | -------------------------------------------------------------------------------- /sql/install.sql: -------------------------------------------------------------------------------- 1 | -- Users belonging to the pov_group group will have access to the functions in the schema/public/functions/ directory 2 | CREATE GROUP pov_group; 3 | 4 | -- When a user of the pov_group group executes pov() or pov([hash]::text), 5 | -- it is executed as the pov user. 6 | -- The pov user has the necessary superuser access to create/drop objects. 7 | CREATE USER pov WITH SUPERUSER; 8 | 9 | -- Create separate schema for pov to avoid conflicts with other contribs. 10 | CREATE SCHEMA AUTHORIZATION pov; 11 | 12 | -- Create plpgsql language, you will get an error if it already exists, which is safe to ignore. 13 | CREATE LANGUAGE plpgsql; 14 | CREATE LANGUAGE plperl; 15 | 16 | SET ROLE TO pov; 17 | 18 | BEGIN; 19 | 20 | SET LOCAL search_path TO public; 21 | 22 | -- API functions 23 | \i sql/schema/public/functions/pov.sql 24 | 25 | SET LOCAL search_path TO pov, public; 26 | -- Tables 27 | \i sql/schema/pov/tables/ObjectTypes.sql 28 | \i sql/schema/pov/tables/Objects.sql 29 | \i sql/schema/pov/tables/Revisions.sql 30 | \i sql/schema/pov/tables/Snapshots.sql 31 | 32 | -- Populate control data 33 | \i sql/data/ObjectTypes.sql 34 | 35 | -- Internal functions 36 | \i sql/schema/pov/functions/Get_Object.sql 37 | \i sql/schema/pov/functions/Get_Revision.sql 38 | \i sql/schema/pov/functions/New_Revision.sql 39 | \i sql/schema/pov/functions/Set_Object.sql 40 | \i sql/schema/pov/functions/Set_Revision.sql 41 | \i sql/schema/pov/functions/Hash.sql 42 | \i sql/schema/pov/functions/_format_type.sql 43 | \i sql/schema/pov/functions/tsort.pl 44 | \i sql/schema/pov/functions/pg_get_aggregate_create_def.sql 45 | \i sql/schema/pov/functions/pg_get_aggregate_drop_def.sql 46 | 47 | -- Internal views 48 | \i sql/schema/pov/views/pg_all_objects_unique_columns.sql 49 | \i sql/schema/pov/views/pg_depend_remapped.sql 50 | \i sql/schema/pov/views/pg_depend_oid_concat.sql 51 | \i sql/schema/pov/views/pg_depend_dot.sql 52 | \i sql/schema/pov/views/pg_depend_tsort.sql 53 | \i sql/schema/pov/views/pg_depend_definitions.sql 54 | 55 | SET LOCAL search_path TO public; 56 | 57 | -- Public views 58 | \i sql/schema/public/views/view_snapshots.sql 59 | 60 | -- Grant permissions 61 | \i sql/schema/grant.sql 62 | 63 | COMMIT; 64 | -------------------------------------------------------------------------------- /sql/install_example_database.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA pov; 2 | CREATE LANGUAGE plperl; 3 | CREATE LANGUAGE plpgsql; 4 | \i sql/schema/pov/functions/_format_type.sql 5 | \i sql/schema/pov/functions/tsort.pl 6 | \i sql/schema/pov/views/pg_all_objects_unique_columns.sql 7 | \i sql/schema/pov/views/pg_depend_remapped.sql 8 | \i sql/schema/pov/views/pg_depend_oid_concat.sql 9 | \i sql/schema/pov/views/pg_depend_dot.sql 10 | \i sql/schema/pov/views/pg_depend_tsort.sql 11 | \i sql/schema/pov/views/pg_depend_definitions.sql 12 | 13 | -- Dependency level 1 (directly under public schema:) 14 | CREATE TABLE t1 ( id integer, PRIMARY KEY (id) ); 15 | CREATE FUNCTION f1 ( integer ) RETURNS boolean AS $$ SELECT $1 > 1; $$ LANGUAGE sql; 16 | CREATE SEQUENCE s1; 17 | 18 | -- Dependency level 2: 19 | CREATE TABLE t2 ( id integer, PRIMARY KEY (id), FOREIGN KEY (id) REFERENCES t1(id) ); 20 | CREATE TABLE t3 ( id integer not null default nextval('s1'), PRIMARY KEY (id), CHECK(f1(id)) ); 21 | 22 | -- Dependency level 3: 23 | CREATE VIEW v1 AS SELECT * FROM t1; 24 | CREATE VIEW v2 AS SELECT * FROM t2; 25 | 26 | -- Dependency level 4: 27 | CREATE VIEW v3 AS SELECT v1.id AS id1, v2.id AS id2 FROM v1, v2; 28 | 29 | -- Dependency level 5: 30 | CREATE VIEW v4 AS SELECT *, f1(id1) FROM v3; 31 | 32 | -------------------------------------------------------------------------------- /sql/reinstall-functions.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | SET ROLE TO pov; 4 | 5 | SET LOCAL search_path TO public; 6 | -- API functions 7 | \i sql/schema/public/functions/pov.sql 8 | 9 | SET LOCAL search_path TO pov; 10 | 11 | -- Internal functions 12 | \i sql/schema/pov/functions/Get_Object.sql 13 | \i sql/schema/pov/functions/Get_Revision.sql 14 | \i sql/schema/pov/functions/New_Revision.sql 15 | \i sql/schema/pov/functions/Set_Object.sql 16 | \i sql/schema/pov/functions/Set_Revision.sql 17 | \i sql/schema/pov/functions/Hash.sql 18 | 19 | COMMIT; 20 | -------------------------------------------------------------------------------- /sql/schema/grant.sql: -------------------------------------------------------------------------------- 1 | GRANT USAGE ON SCHEMA pov TO GROUP pov_group; 2 | 3 | GRANT EXECUTE ON FUNCTION public.pov() TO pov_group; 4 | 5 | GRANT EXECUTE ON FUNCTION public.pov(bigint) TO pov_group; 6 | 7 | GRANT SELECT ON TABLE pov.Objects TO pov_group; 8 | GRANT SELECT ON TABLE pov.Revisions TO pov_group; 9 | GRANT SELECT ON TABLE pov.Snapshots TO pov_group; 10 | -------------------------------------------------------------------------------- /sql/schema/pg_catalog/functions/pg_describe_object.sql: -------------------------------------------------------------------------------- 1 | -- SQL version of the pg_catalog.pg_describe_object function, 2 | -- for those of us not running PostgreSQL 9. 3 | -- 4 | CREATE OR REPLACE FUNCTION pg_catalog.pg_describe_object(oid, oid, integer) RETURNS TEXT AS $BODY$ 5 | WITH 6 | object AS (SELECT $1::oid AS classoid, $2::oid AS objoid, $3::integer AS objsubid), 7 | cols AS ( 8 | SELECT * FROM pov.pg_all_objects_unique_columns WHERE classid = $1 AND objid = $2 AND objsubid = $3 9 | ), 10 | function_num_arguments AS ( 11 | SELECT array_upper(cols.function_input_argument_types,1)+1 AS function_num_arguments FROM cols 12 | ), 13 | function_argument_position AS ( 14 | SELECT function_argument_position 15 | FROM pg_catalog.generate_series(1,(SELECT function_num_arguments FROM function_num_arguments)) AS function_argument_position 16 | ), 17 | function_args_in_order AS ( 18 | SELECT function_argument_position, pov._format_type(cols.function_input_argument_types[function_argument_position-1],NULL) AS typname 19 | FROM function_argument_position, cols 20 | ORDER BY function_argument_position 21 | ), 22 | function_info AS ( 23 | SELECT array_to_string(array_agg(function_args_in_order.typname),',') AS function_arguments FROM function_args_in_order 24 | ), 25 | formatted_text AS ( 26 | SELECT 27 | CASE 28 | WHEN object.classoid = 'pg_ts_template'::regclass THEN 'text search template ' || cols.text_search_template_name 29 | WHEN object.classoid = 'pg_ts_parser'::regclass THEN 'text search parser ' || cols.text_search_parser_name 30 | WHEN object.classoid = 'pg_ts_config'::regclass THEN 'text search configuration ' || cols.text_search_configuration_name 31 | WHEN object.classoid = 'pg_ts_dict'::regclass THEN 'text search dictionary ' || cols.text_search_dictionary_name 32 | WHEN object.classoid = 'pg_database'::regclass THEN 'database ' || cols.database_name 33 | WHEN object.classoid = 'pg_namespace'::regclass THEN 'schema ' || cols.namespace_name 34 | WHEN object.classoid = 'pg_language'::regclass THEN 'language ' || cols.language_name 35 | WHEN object.classoid = 'pg_conversion'::regclass THEN 'conversion ' || cols.conversion_name 36 | WHEN object.classoid = 'pg_constraint'::regclass THEN 'constraint ' || cols.namespace_name || '.' || cols.constraint_name || COALESCE(' on table ' || cols.relation_name,'') 37 | WHEN object.classoid = 'pg_rewrite'::regclass THEN 'rule ' || cols.rule_name || ' on ' || cols.relation_kind || ' ' || cols.namespace_name || '.' || cols.relation_name 38 | WHEN object.classoid = 'pg_trigger'::regclass THEN 'trigger ' || cols.trigger_name || ' on ' || cols.relation_kind || ' ' || cols.namespace_name || '.' || cols.relation_name 39 | WHEN object.classoid = 'pg_cast'::regclass THEN 'cast from ' || cols.source_data_type_name || ' to ' || cols.target_data_type_name 40 | WHEN object.classoid = 'pg_amproc'::regclass THEN 'function ' || cols.support_function_number || ' ' || cols.support_function_name || ' of operator family ' || cols.operator_family_name || ' for access method ' || cols.access_method_name 41 | WHEN object.classoid = 'pg_operator'::regclass THEN 'operator ' || cols.namespace_name || '.' || cols.operator_name || '(' || cols.left_data_type_name || ',' || cols.right_data_type_name || ')' 42 | WHEN object.classoid = 'pg_amop'::regclass THEN 'operator ' || cols.operator_strategy_number || ' ' || cols.namespace_name || '.' || cols.operator_name || '(' || cols.left_data_type_name || ',' || cols.right_data_type_name || ')' || ' of operator family ' || cols.operator_family_name || ' for access method ' || cols.access_method_name 43 | WHEN object.classoid = 'pg_opfamily'::regclass THEN 'operator family ' || cols.operator_family_name || ' for access method ' || cols.access_method_name 44 | WHEN object.classoid = 'pg_opclass'::regclass THEN 'operator class ' || cols.operator_class_name || ' for access method ' || cols.access_method_name 45 | WHEN object.classoid = 'pg_class'::regclass THEN cols.relation_kind || ' ' || cols.namespace_name || '.' || cols.relation_name 46 | WHEN object.classoid = 'pg_type'::regclass THEN 'type ' || cols.data_type_name 47 | WHEN object.classoid = 'pg_proc'::regclass THEN 'function ' || cols.namespace_name || '.' || cols.function_name || '(' || COALESCE(function_info.function_arguments,'') || ')' 48 | WHEN object.classoid = 'pg_attrdef'::regclass THEN 'default for ' || cols.relation_kind || ' ' || cols.relation_name || ' column ' || cols.attribute_name 49 | END || CASE WHEN object.classoid = 'pg_class'::regclass AND object.objsubid <> 0 THEN ' column ' || cols.attribute_name ELSE '' END 50 | AS identifier 51 | FROM object, cols, function_info 52 | ) 53 | SELECT identifier FROM formatted_text 54 | $BODY$ LANGUAGE sql STABLE; 55 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/Get_Object.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION Get_Object(_ObjectID text) RETURNS TEXT AS $BODY$ 2 | DECLARE 3 | _Content text; 4 | BEGIN 5 | SELECT Content INTO _Content FROM Objects WHERE ObjectID = _ObjectID; 6 | IF NOT FOUND THEN 7 | RAISE EXCEPTION 'ERROR_OBJECT_NOT_FOUND ObjectID %', _ObjectID; 8 | END IF; 9 | RETURN _Content; 10 | END; 11 | $BODY$ LANGUAGE plpgsql STABLE; -------------------------------------------------------------------------------- /sql/schema/pov/functions/Get_Revision.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION Get_Revision(_RevisionID text) RETURNS TEXT[] AS $BODY$ 2 | DECLARE 3 | _ObjectIDs text[]; 4 | BEGIN 5 | SELECT ObjectIDs INTO _ObjectIDs FROM Revisions WHERE RevisionID = _RevisionID; 6 | IF NOT FOUND THEN 7 | RAISE EXCEPTION 'ERROR_REVISION_NOT_FOUND RevisionID %', _RevisionID; 8 | END IF; 9 | RETURN _ObjectIDs; 10 | END; 11 | $BODY$ LANGUAGE plpgsql STABLE; 12 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/Hash.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION Hash(_Text text) RETURNS TEXT AS $BODY$ 2 | DECLARE 3 | _Hash text; 4 | BEGIN 5 | PERFORM 1 FROM pg_proc WHERE proname = 'digest' AND probin = '$libdir/pgcrypto'; 6 | IF FOUND THEN 7 | -- If we have contrib/pgcrypto, use SHA1 8 | _Hash := encode(public.digest($1, 'sha1'), 'hex'); 9 | ELSE 10 | -- Default to MD5 11 | _Hash := md5($1); 12 | END IF; 13 | RETURN _Hash; 14 | END; 15 | $BODY$ LANGUAGE plpgsql IMMUTABLE; 16 | 17 | CREATE OR REPLACE FUNCTION Hash(_Text text[]) RETURNS TEXT AS $BODY$ 18 | SELECT pov.Hash(array_to_string(array_agg(pov.Hash(unnest)),'')) FROM unnest($1) 19 | $BODY$ LANGUAGE sql IMMUTABLE; 20 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/New_Revision.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION New_Revision( 2 | OUT _RevisionID text 3 | ) RETURNS TEXT AS $BODY$ 4 | DECLARE 5 | BEGIN 6 | 7 | SET LOCAL search_path TO pov; 8 | 9 | -- Create new RevisionID of collection of ObjectIDs. 10 | -- If a revision already exists with the same set of objects, its RevisionID will be selected. 11 | SELECT Set_Revision(ObjectIDs) INTO STRICT _RevisionID FROM ( 12 | -- Make array of all objects 13 | SELECT 14 | array_agg(ObjectID) AS ObjectIDs 15 | FROM ( 16 | -- Create new ObjectID for each function. 17 | -- If a object already exists with the same content (function definition), its ObjectID will be selected. 18 | SELECT Set_Object(ARRAY[create_definition,drop_definition],description) AS ObjectID FROM pov.pg_depend_definitions 19 | WHERE create_definition IS NOT NULL AND drop_definition IS NOT NULL AND description ~ '^(constraint|default|function|trigger|view)' 20 | ORDER BY row_number 21 | ) AS Objects 22 | ) AS Revision; 23 | 24 | RETURN; 25 | END; 26 | $BODY$ LANGUAGE plpgsql VOLATILE; 27 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/Set_Object.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION Set_Object(_Content text[], _ObjectType text) RETURNS TEXT AS $BODY$ 2 | DECLARE 3 | _ObjectID text; 4 | _ObjectTypeContent text[]; 5 | BEGIN 6 | IF _Content IS NULL THEN 7 | RAISE EXCEPTION 'ERROR_POV_OBJECT_CONTENT_IS_NULL'; 8 | END IF; 9 | 10 | -- Append the ObjectType to beginning of the Content 11 | _ObjectTypeContent := array_cat(ARRAY[_ObjectType], _Content); 12 | 13 | _ObjectID := Hash(_ObjectTypeContent); 14 | 15 | PERFORM 1 FROM Objects WHERE ObjectID = _ObjectID; 16 | IF FOUND THEN 17 | RETURN _ObjectID; 18 | END IF; 19 | INSERT INTO Objects (ObjectID,Content) VALUES (_ObjectID,_ObjectTypeContent) RETURNING ObjectID INTO STRICT _ObjectID; 20 | RETURN _ObjectID; 21 | END; 22 | $BODY$ LANGUAGE plpgsql VOLATILE; 23 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/Set_Revision.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION Set_Revision(_ObjectIDs text[]) RETURNS TEXT AS $BODY$ 2 | DECLARE 3 | _RevisionID text; 4 | BEGIN 5 | IF _ObjectIDs IS NULL THEN 6 | RAISE EXCEPTION 'ERROR_POV_OBJECTIDS_IS_NULL'; 7 | END IF; 8 | _RevisionID := Hash(_ObjectIDs); 9 | PERFORM 1 FROM Revisions WHERE RevisionID = _RevisionID; 10 | IF FOUND THEN 11 | RETURN _RevisionID; 12 | END IF; 13 | INSERT INTO Revisions (RevisionID,ObjectIDs) VALUES (_RevisionID,_ObjectIDs) RETURNING RevisionID INTO STRICT _RevisionID; 14 | RETURN _RevisionID; 15 | END; 16 | $BODY$ LANGUAGE plpgsql VOLATILE; 17 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/_format_type.sql: -------------------------------------------------------------------------------- 1 | -- Necessary because the regular format_type function returns "-" for non existing oids, 2 | -- while for pg_describe_object uses "NONE" 3 | CREATE OR REPLACE FUNCTION pov._format_type(oid, integer) RETURNS TEXT AS $BODY$ 4 | SELECT CASE WHEN $1 = 0 THEN 'NONE' ELSE format_type($1, $2) END; 5 | $BODY$ LANGUAGE sql STABLE; 6 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/pg_get_aggregate_create_def.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION pov.pg_get_aggregate_create_def(oid) RETURNS TEXT AS $BODY$ 2 | SELECT 'CREATE AGGREGATE ' || pg_catalog.pg_namespace.nspname || '.' || pg_catalog.pg_proc.proname || '(' || pg_catalog.pg_get_function_identity_arguments(pg_catalog.pg_proc.oid) || E') (\n' || 3 | ' SFUNC = ' || pg_catalog.pg_aggregate.aggtransfn::text || E',\n' || 4 | ' STYPE = ' || pg_catalog.pg_aggregate.aggtranstype::regtype::text || 5 | CASE WHEN pg_catalog.pg_aggregate.aggfinalfn::text = '-' THEN '' ELSE E',\n FINALFUNC = ' || pg_catalog.pg_aggregate.aggfinalfn::text END || 6 | CASE WHEN pg_catalog.pg_aggregate.agginitval IS NULL THEN '' ELSE E',\n INITCOND = ' || pg_catalog.quote_literal(pg_catalog.pg_aggregate.agginitval) END || 7 | CASE WHEN pg_catalog.pg_operator.oprname IS NULL THEN '' ELSE E',\n SORTOP = ' || pg_catalog.quote_literal(pg_catalog.pg_operator.oprname) END || 8 | E'\n)' 9 | FROM pg_catalog.pg_proc 10 | JOIN pg_catalog.pg_aggregate ON (pg_catalog.pg_aggregate.aggfnoid = pg_catalog.pg_proc.oid) 11 | JOIN pg_catalog.pg_namespace ON (pg_catalog.pg_namespace.oid = pg_catalog.pg_proc.pronamespace) 12 | LEFT JOIN pg_catalog.pg_operator ON (pg_catalog.pg_operator.oid = pg_catalog.pg_aggregate.aggsortop) 13 | WHERE pg_catalog.pg_proc.oid = $1; 14 | $BODY$ LANGUAGE sql STABLE; 15 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/pg_get_aggregate_drop_def.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION pov.pg_get_aggregate_drop_def(oid) RETURNS TEXT AS $BODY$ 2 | SELECT 'DROP AGGREGATE ' || pg_catalog.pg_namespace.nspname || '.' || pg_catalog.pg_proc.proname || '(' || pg_catalog.pg_get_function_identity_arguments(pg_catalog.pg_proc.oid) || ')' 3 | FROM pg_catalog.pg_proc 4 | JOIN pg_catalog.pg_aggregate ON (pg_catalog.pg_aggregate.aggfnoid = pg_catalog.pg_proc.oid) 5 | JOIN pg_catalog.pg_namespace ON (pg_catalog.pg_namespace.oid = pg_catalog.pg_proc.pronamespace) 6 | WHERE pg_catalog.pg_proc.oid = $1; 7 | $BODY$ LANGUAGE sql STABLE; 8 | -------------------------------------------------------------------------------- /sql/schema/pov/functions/tsort.pl: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION pov.tsort(OUT nodes text[], edges text, delimiter text, debug integer, algorithm text, selection text, operator text, nodes text, direction text) RETURNS TEXT[] AS $BODY$ 2 | # tsort - return a tree's nodes in topological order 3 | # 4 | # Author: Joel Jacobson, Glue Finance AB, Sweden, 5 | # Datestamp: 2011-01-13 23:42 Europe/Stockholm 6 | # License: MIT (http://www.opensource.org/licenses/mit-license.php) 7 | # 8 | # Code stolen from: 9 | # Don Knuth (I, Section 2.2.3) 10 | # \- Jon Bentley (I, pp. 20-23) 11 | # \- Jeffrey S. Haemer (Perl Power Tools->tcsort, http://cpansearch.perl.org/src/CWEST/ppt-0.14/html/commands/tsort/tcsort) 12 | # Jarkko Hietaniemi (http://search.cpan.org/~jhi/Graph-0.94/) 13 | 14 | # plperl compatible way of doing use strict; use warnings; 15 | BEGIN { 16 | strict->import(); 17 | warnings->import(); 18 | } 19 | # read input 20 | my ($edges_string, $delimiter, $debug, $algorithm, $selection_mode, $operator, $selection_nodes, $direction) = @_; 21 | 22 | # set readme 23 | my $readme = ' 24 | DESCRIPTION 25 | tsort - return a tree\'s nodes in topological order 26 | 27 | 28 | SYNOPSIS 29 | tsort(edges text, delimiter text, debug integer, algorithm text, 30 | selection text, operator text, nodes text, direction text); 31 | 32 | OUTPUT 33 | nodes text[] Array of nodes in topologically sorted order 34 | 35 | INPUT PARAMETERS 36 | Parameter Type Regex Description 37 | ============================================================================ 38 | edges text ^.+$ Node pairs, separated by [delimiter]. 39 | 40 | delimiter text ^.*$ Node separator in [edges], 41 | default is \' \', i.e. single blank space. 42 | 43 | debug integer Print debug information using RAISE DEBUG: 44 | 0 no debug (default) 45 | 1 some debug 46 | 2 verbose debug 47 | 48 | algorithm text Sorting algorithm: 49 | DFS depth-first (default) 50 | explores as far as possible along each 51 | branch before backtracking. 52 | BFS breadth-first 53 | explores all the neighboring nodes, 54 | then for each of those nearest nodes, 55 | it explores their unexplored neighbor 56 | nodes, and so on. 57 | ^sub sort using perl subroutine. 58 | examples: 59 | # sort numerically ascending 60 | sub {$a <=> $b} 61 | 62 | # sort numerically descending 63 | sub {$b <=> $a} 64 | 65 | #sort lexically ascending 66 | sub {$a cmp $b} 67 | 68 | # sort lexically descending 69 | sub {$b cmp $a} 70 | 71 | # sort case-insensitively 72 | sub {uc($a) cmp uc($b)} 73 | 74 | For more examples, please goto: 75 | http://perldoc.perl.org/functions/sort.html 76 | 77 | The following options will not affect the order of the nodes in the result, 78 | they only control which nodes are included in the result: 79 | 80 | Parameter Type Regex Description 81 | ============================================================================ 82 | selection text Selection of nodes, used by [operator]: 83 | ALL select all nodes (default) 84 | ISOLATED select nodes without any 85 | successors nor predecessors 86 | SOURCE select nodes with successors 87 | but no predecessors 88 | SINK select nodes with predecessors 89 | but no successors 90 | CONN_INCL select nodes connected to [nodes], 91 | including [nodes] 92 | CONN_EXCL select nodes connected to [nodes], 93 | excluding [nodes] 94 | separated by [delimiter] 95 | 96 | operator text Include or exclude nodes in [selection]: 97 | INCLUDE include nodes (default) 98 | EXCLUDE exclude nodes 99 | 100 | The following options are only applicable if, 101 | [selection] is CONN_INCL or CONN_EXCL 102 | 103 | Parameter Type Regex Description 104 | ============================================================================ 105 | 106 | nodes text select nodes connected to [nodes] 107 | NULL not applicable (default) 108 | [nodes] the start nodes, separated by [delimiter] 109 | 110 | 111 | direction text direction to look for connected nodes 112 | BOTH traverse both successors and 113 | predecessors (default) 114 | UP only traverse predecessors 115 | DOWN only traverse successors 116 | 117 | '; 118 | 119 | # SELECT pov.tsort(); -- shows help 120 | if (defined $debug && $debug == -1) { 121 | return [$readme]; 122 | } 123 | 124 | # declare variables 125 | my $node; # a node in the tree 126 | my $left; # left node in edge 127 | my $right; # right node in edge 128 | my %pairs; # hash, key=$left, value=hash which key=$right, i.e. $pairs{$left}{$right} 129 | my %num_predecessors; # hash, key=node, value=number of predecessors for node 130 | my %num_successors; # hash, key=node, value=number of successors for node 131 | my %successors; # hash, key=node, value=array of the successor nodes 132 | my %predecessors; # hash, key=node, value=array of the predecessor nodes 133 | my @source_nodes; # array of nodes with successors but no predecessors 134 | my %source_nodes_hash; # array of nodes with successors but no predecessors 135 | my @sink_nodes; # array of nodes with predecessors but no successors 136 | my @isolated_nodes; # array of nodes without any successors nor predecessors 137 | my @sorted_nodes; # array of nodes in topologically sorted order (output variable) 138 | 139 | # validate input arguments 140 | die "edges is undefined\n\n$readme" unless defined $edges_string; 141 | die "invalid algorithm: $algorithm\n\n$readme" if defined $algorithm && $algorithm !~ '^(DFS|BFS|ISOLATED|SOURCE|SINK|sub\s+{.+})$'; 142 | die "invalid selection: $selection_mode\n\n$readme" if defined $selection_mode && $selection_mode !~ '^(ALL|ISOLATED|SOURCE|SINK|CONN_INCL|CONN_EXCL)$'; 143 | die "invalid operator: $operator\n\n$readme" if defined $operator && $operator !~ '^(INCLUDE|EXCLUDE|SPLIT)$'; 144 | die "invalid direction: $direction\n\n$readme" if defined $direction && $direction !~ '^(BOTH|UP|DOWN)$'; 145 | 146 | # set defaults 147 | $algorithm = 'DFS' unless defined $algorithm; 148 | $delimiter = ' ' unless defined $delimiter; 149 | $debug = 0 unless defined $debug; 150 | $selection_mode = 'ALL' unless defined $selection_mode; 151 | $operator = 'INCLUDE' unless defined $operator; 152 | $direction = 'BOTH' unless defined $direction; 153 | 154 | # A. PARSE STRING OF NODES 155 | 156 | # create edges array, e.g. 'a b a c' -> ('a','b','a','c') 157 | my @edges = split $delimiter, $edges_string; 158 | 159 | # check balance 160 | die "input edges contains an odd number of nodes\n\n$readme" unless @edges % 2 == 0; 161 | 162 | # B. CREATE DATA STRUCTURES 163 | 164 | $debug > 0 && elog(DEBUG, "1. build data structures pairs, successors, predecessors"); 165 | foreach $node (@edges) { 166 | unless( defined $left ) { 167 | $left = $node; 168 | next; 169 | } 170 | $right = $node; 171 | $pairs{$left}{$right}++; 172 | $debug > 1 && elog(DEBUG, ' 1.1. ' . $pairs{$left}{$right} . ' $left=' . $left . ' $right=' . $right); 173 | # for every unique pair (first time seen): 174 | if ($pairs{$left}{$right} == 1) { 175 | $num_predecessors{$left} = 0 unless exists $num_predecessors{$left}; 176 | $num_successors{$right} = 0 unless exists $num_successors{$right}; 177 | ++$num_successors{$left}; 178 | ++$num_predecessors{$right}; 179 | push @{$successors{$left}}, $right; 180 | push @{$predecessors{$right}}, $left; 181 | } 182 | undef $left; 183 | undef $right; 184 | } 185 | 186 | # C. SPECIAL SORTING, PHASE 1 187 | 188 | # if algorithm begins with "sub", compile sort algorithm 189 | my $sort_sub; 190 | if ($algorithm =~ /^sub/) { 191 | $sort_sub = eval "$algorithm"; 192 | } 193 | 194 | # sort successors 195 | $debug > 0 && elog(DEBUG,"2. sort successors and predecessors"); 196 | if ($sort_sub) { 197 | foreach $node (keys %successors) { 198 | $debug > 1 && elog(DEBUG," 2.1. sorting successor node $node"); 199 | @{$successors{$node}} = sort $sort_sub @{$successors{$node}}; 200 | $debug > 1 && elog(DEBUG," 2.2. sorted successors for node $node: " . join($delimiter,@{$successors{$node}}) ); 201 | } 202 | } 203 | 204 | # sort predecessors 205 | if ($sort_sub) { 206 | foreach $node (keys %predecessors) { 207 | $debug > 1 && elog(DEBUG," 2.3. sorting predecessor node $node"); 208 | @{$predecessors{$node}} = sort $sort_sub @{$predecessors{$node}}; 209 | $debug > 1 && elog(DEBUG," 2.4. sorted predecessors for node $node: " . join($delimiter,@{$predecessors{$node}}) ); 210 | } 211 | } 212 | 213 | # D. FIND ISOLATED, SOURCE AND SINK NODES 214 | 215 | $debug > 0 && elog(DEBUG, "3. find isolated, source and sink nodes"); 216 | # the hashes %num_predecessors and %num_successors both contain all the nodes, 217 | # we could use any of them to get the isolated nodes 218 | @isolated_nodes = grep {!$num_predecessors{$_} && !$num_successors{$_}} keys %num_predecessors; 219 | # find source nodes 220 | @source_nodes = grep {!$num_predecessors{$_}} keys %num_predecessors; 221 | @source_nodes_hash{@source_nodes} = @source_nodes; 222 | # find sink nodes 223 | @sink_nodes = grep {!$num_successors{$_}} keys %num_successors; 224 | 225 | # E. SPECIAL SORTING, PHASE 2 226 | 227 | # should we sort? 228 | $debug > 0 && elog(DEBUG, "4. check if we sort sort isolated, source and sink arrays"); 229 | if ($sort_sub) { 230 | @isolated_nodes = sort $sort_sub @isolated_nodes; 231 | @source_nodes = sort $sort_sub @source_nodes; 232 | @sink_nodes = sort $sort_sub @sink_nodes; 233 | } 234 | 235 | ################################################################################ 236 | # F. <--- RETURN #1, ISOLATED, SOURCE OR SINK NODES # 237 | ################################################################################ 238 | $debug > 0 && elog(DEBUG, "5. return if algorithm is ISOLATED, SOURCE or SINK"); 239 | return \@isolated_nodes if $selection_mode eq 'ISOLATED' && $operator eq 'INCLUDE'; 240 | return \@source_nodes if $selection_mode eq 'SOURCE' && $operator eq 'INCLUDE'; 241 | return \@sink_nodes if $selection_mode eq 'SINK' && $operator eq 'INCLUDE'; 242 | ################################################################################ 243 | 244 | # G. EXECUTE TOPOLOGICAL SORT ALGORITHM 245 | 246 | $debug > 0 && elog(DEBUG, "6. start search at source nodes"); 247 | my @nodes = @source_nodes; 248 | 249 | while (@nodes) { 250 | if ($sort_sub) { 251 | $debug > 1 && elog(DEBUG, " 6.1. unsorted nodes: " . join($delimiter,@nodes)); 252 | # Sort nodes, then pick the first one 253 | @nodes = sort $sort_sub @nodes; 254 | $debug > 1 && elog(DEBUG, " 6.2. sorted nodes: " . join($delimiter,@nodes)); 255 | $node = shift @nodes; 256 | $debug > 1 && elog(DEBUG, " 6.3. shifted node: $node"); 257 | } else { 258 | # No extra sorting 259 | $node = pop @nodes; 260 | $debug > 1 && elog(DEBUG, " 6.4. pop node: $node"); 261 | } 262 | 263 | $debug > 1 && elog(DEBUG, " 6.5. for each child to $node"); 264 | if ($operator eq 'SPLIT' && $source_nodes_hash{$node}) { 265 | push @sorted_nodes, undef; 266 | } 267 | push @sorted_nodes, $node; 268 | foreach my $child (@{$successors{$node}}) { 269 | if ($algorithm eq 'BFS') { 270 | $debug > 1 && elog(DEBUG, " 6.5.1. unshift child $child"); 271 | unshift @nodes, $child unless --$num_predecessors{$child}; 272 | } elsif ($algorithm eq 'DFS' || defined $sort_sub) { 273 | $debug > 1 && elog(DEBUG, " 6.5.2. push child $child"); 274 | push @nodes, $child unless --$num_predecessors{$child}; 275 | } else { 276 | die "invalid algorithm"; 277 | } 278 | } 279 | } 280 | 281 | $debug > 1 && elog(DEBUG, "7. Debug:"); 282 | # H. COMPOSE DEBUG MESSAGE 283 | $debug > 1 && elog(DEBUG, " 7.1. edges:"); 284 | foreach $left (sort %pairs) { 285 | foreach $right (sort keys %{ $pairs{$left} }) { 286 | $debug > 1 && elog(DEBUG, " 7.1.1. $left$delimiter$right$delimiter$pairs{$left}{$right}"); 287 | } 288 | } 289 | $debug > 1 && elog(DEBUG, " 7.2. num_successors:"); 290 | foreach $node (sort keys %num_successors) { 291 | $debug > 1 && elog(DEBUG, " 7.2.1. $node$delimiter$num_successors{$node}"); 292 | } 293 | $debug > 1 && elog(DEBUG, " 7.3. num_predecessors:"); 294 | foreach $node (sort keys %num_predecessors) { 295 | $debug > 1 && elog(DEBUG, " 7.3.1. $node$delimiter$num_predecessors{$node}"); 296 | } 297 | $debug > 1 && elog(DEBUG, " 7.4. successors:"); 298 | foreach $left (sort keys %successors) { 299 | my $tmp = "$left"; 300 | foreach $right ( @{ $successors{$left} }) { 301 | $tmp .= "$delimiter$right"; 302 | } 303 | $debug > 1 && elog(DEBUG, " 7.4.1. $tmp"); 304 | } 305 | $debug > 1 && elog(DEBUG, " 7.5. predecessors:"); 306 | foreach $right (sort keys %predecessors) { 307 | my $tmp = "$right"; 308 | foreach $left ( @{ $predecessors{$right} }) { 309 | $tmp .= "$delimiter$left"; 310 | } 311 | $debug > 1 && elog(DEBUG, " 7.5.1. $tmp"); 312 | } 313 | $debug > 1 && elog(DEBUG, " 7.6. sorted_nodes:"); 314 | foreach $node (@sorted_nodes) { 315 | $debug > 1 && elog(DEBUG, " 7.6.1 $node"); 316 | } 317 | 318 | # I. DETECT CYCLE 319 | if (grep {$num_predecessors{$_}} keys %num_predecessors) { 320 | die "cycle detected"; 321 | } 322 | 323 | ################################################################################ 324 | # J. RETURN #2, ALL SORTED NODES # 325 | ################################################################################ 326 | return \@sorted_nodes if $selection_mode eq 'ALL'; 327 | ################################################################################ 328 | 329 | # K. FILTER OUTPUT BASED ON NODES 330 | 331 | my @filter_nodes; 332 | 333 | return \@isolated_nodes if $selection_mode eq 'ISOLATED' && $operator eq 'INCLUDE'; 334 | return \@source_nodes if $selection_mode eq 'SOURCE' && $operator eq 'INCLUDE'; 335 | return \@sink_nodes if $selection_mode eq 'SINK' && $operator eq 'INCLUDE'; 336 | 337 | 338 | die "nodes is undefined or empty string" unless defined $selection_nodes && $selection_nodes ne ''; 339 | 340 | # create nodes array, e.g. 'a b a c' -> ('a','b','a','c') 341 | my @init = split $delimiter, $selection_nodes; 342 | my %selection_nodes; 343 | @selection_nodes{@init} = @init; 344 | 345 | # find successors recursively (stolen from Graph::_all_successors) 346 | my $traverse = sub { 347 | my ($init, $neighbours, $pairs) = @_; 348 | my %todo; 349 | @todo{@$init} = @$init; 350 | my %found; 351 | my %init = %todo; 352 | my %self; 353 | while (keys %todo) { 354 | my @todo = values %todo; 355 | for my $node (@todo) { 356 | $found{$node} = delete $todo{$node}; 357 | foreach my $child (@{$neighbours->{$node}}) { 358 | $self{$child} = $child if exists $init{$child}; 359 | $todo{$child} = $child unless exists $found{$child}; 360 | } 361 | } 362 | } 363 | for my $node (@$init) { 364 | delete $found{$node} unless exists $pairs->{$node}{$node} || $self{$node}; 365 | } 366 | return \%found; 367 | }; 368 | 369 | $debug > 0 && elog(DEBUG, "8. find nodes connected to: " . join($delimiter,@init)); 370 | my $nodes_successors = &$traverse(\@init, \%successors, \%pairs); 371 | my $nodes_predecessors = &$traverse(\@init, \%predecessors, \%pairs); 372 | $debug > 0 && elog(DEBUG, " 8.1. successors : " . join($delimiter,sort keys %$nodes_successors)); 373 | $debug > 0 && elog(DEBUG, " 8.2. predecessors: " . join($delimiter,sort keys %$nodes_predecessors)); 374 | 375 | $debug > 0 && elog(DEBUG, "9. filter nodes:"); 376 | 377 | my %special_nodes; 378 | if ($selection_mode eq 'ISOLATED') { 379 | @special_nodes{@isolated_nodes} = @isolated_nodes; 380 | } elsif ($selection_mode eq 'SOURCE') { 381 | @special_nodes{@source_nodes} = @source_nodes; 382 | } elsif ($selection_mode eq 'SINK') { 383 | @special_nodes{@sink_nodes} = @sink_nodes; 384 | } 385 | 386 | $debug > 0 && elog(DEBUG, " 9.1. special nodes: " . join $delimiter, keys %special_nodes ); 387 | 388 | foreach $node (@sorted_nodes) { 389 | my $is_in_selection = 0; 390 | if ($selection_mode eq 'CONN_INCL' || $selection_mode eq 'CONN_EXCL') { 391 | if ($direction eq 'UP') { 392 | $is_in_selection = exists $nodes_predecessors->{$node}; 393 | } elsif ($direction eq 'DOWN') { 394 | $is_in_selection = exists $nodes_successors->{$node}; 395 | } elsif ($direction eq 'BOTH') { 396 | $is_in_selection = exists $nodes_predecessors->{$node} || exists $nodes_successors->{$node}; 397 | } else { 398 | die "invalid direction option: $direction"; 399 | } 400 | } elsif (keys %special_nodes > 0) { 401 | $is_in_selection = exists $special_nodes{$node}; 402 | } 403 | $is_in_selection = 1 if $selection_mode eq 'CONN_INCL' && exists $selection_nodes{$node}; 404 | 405 | $debug > 1 && elog(DEBUG, " 9.2. node $node in selection: " . ($is_in_selection ? 'yes' : 'no')); 406 | 407 | if ($operator eq 'INCLUDE' || $operator eq 'SPLIT') { 408 | # $is_in_selection = $is_in_selection; 409 | } elsif ($operator eq 'EXCLUDE') { 410 | $is_in_selection = !$is_in_selection; 411 | } else { 412 | die "invalid operator option: $operator"; 413 | } 414 | if ($is_in_selection ) { 415 | $debug > 1 && elog(DEBUG, " 9.3. including $node"); 416 | push @filter_nodes, $node; 417 | } 418 | } 419 | return \@filter_nodes; 420 | $BODY$ LANGUAGE plperl IMMUTABLE; 421 | 422 | CREATE OR REPLACE FUNCTION pov.tsort(OUT nodes text[], edges text, delimiter text, debug integer, algorithm text, selection text, nodes text, operator text) RETURNS TEXT[] AS $BODY$ 423 | SELECT pov.tsort($1,$2,$3,$4,$5,$6,$7,NULL); 424 | $BODY$ LANGUAGE sql IMMUTABLE; 425 | 426 | CREATE OR REPLACE FUNCTION pov.tsort(OUT nodes text[], edges text, delimiter text, debug integer, algorithm text, selection text, nodes text) RETURNS TEXT[] AS $BODY$ 427 | SELECT pov.tsort($1,$2,$3,$4,$5,$6,NULL,NULL); 428 | $BODY$ LANGUAGE sql IMMUTABLE; 429 | 430 | CREATE OR REPLACE FUNCTION pov.tsort(OUT nodes text[], edges text, delimiter text, debug integer, algorithm text, selection text) RETURNS TEXT[] AS $BODY$ 431 | SELECT pov.tsort($1,$2,$3,$4,$5,NULL,NULL,NULL); 432 | $BODY$ LANGUAGE sql IMMUTABLE; 433 | 434 | CREATE OR REPLACE FUNCTION pov.tsort(OUT nodes text[], edges text, delimiter text, debug integer, algorithm text) RETURNS TEXT[] AS $BODY$ 435 | SELECT pov.tsort($1,$2,$3,$4,NULL,NULL,NULL,NULL); 436 | $BODY$ LANGUAGE sql IMMUTABLE; 437 | 438 | CREATE OR REPLACE FUNCTION pov.tsort(OUT nodes text[], edges text, delimiter text, debug integer) RETURNS TEXT[] AS $BODY$ 439 | SELECT pov.tsort($1,$2,$3,NULL,NULL,NULL,NULL,NULL); 440 | $BODY$ LANGUAGE sql IMMUTABLE; 441 | 442 | CREATE OR REPLACE FUNCTION pov.tsort(OUT nodes text[], edges text, delimiter text) RETURNS TEXT[] AS $BODY$ 443 | SELECT pov.tsort($1,$2,NULL,NULL,NULL,NULL,NULL,NULL); 444 | $BODY$ LANGUAGE sql IMMUTABLE; 445 | 446 | CREATE OR REPLACE FUNCTION pov.tsort(OUT nodes text[], edges text) RETURNS TEXT[] AS $BODY$ 447 | SELECT pov.tsort($1,NULL,NULL,NULL,NULL,NULL,NULL,NULL); 448 | $BODY$ LANGUAGE sql IMMUTABLE; 449 | 450 | CREATE OR REPLACE FUNCTION pov.tsort(OUT help text) RETURNS TEXT AS $BODY$ 451 | SELECT (pov.tsort(NULL,NULL,-1,NULL,NULL,NULL,NULL,NULL))[1]; 452 | $BODY$ LANGUAGE sql IMMUTABLE; 453 | -------------------------------------------------------------------------------- /sql/schema/pov/tables/ObjectTypes.sql: -------------------------------------------------------------------------------- 1 | -- The ObjectTypeID determines the order of creating/dropping objects 2 | CREATE TABLE ObjectTypes ( 3 | ObjectTypeID integer not null, 4 | Name text not null, 5 | PRIMARY KEY (ObjectTypeID), 6 | UNIQUE(Name) 7 | ); 8 | -------------------------------------------------------------------------------- /sql/schema/pov/tables/Objects.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE Objects ( 2 | ObjectID text not null, 3 | Content text[] not null, 4 | PRIMARY KEY (ObjectID) 5 | ); 6 | -------------------------------------------------------------------------------- /sql/schema/pov/tables/Revisions.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE Revisions ( 2 | RevisionID text not null, 3 | ObjectIDs text[] not null, 4 | Datestamp timestamptz not null default now(), 5 | PRIMARY KEY (RevisionID) 6 | ); 7 | -------------------------------------------------------------------------------- /sql/schema/pov/tables/Snapshots.sql: -------------------------------------------------------------------------------- 1 | CREATE SEQUENCE seqSnapshots; 2 | 3 | CREATE TABLE Snapshots ( 4 | SnapshotID bigint not null default nextval('seqSnapshots'), 5 | RevisionID text not null, 6 | Datestamp timestamptz not null default now(), 7 | Heartbeat timestamptz not null default now(), 8 | Active integer not null default 1, 9 | PRIMARY KEY (SnapshotID), 10 | FOREIGN KEY (RevisionID) REFERENCES Revisions(RevisionID) 11 | ); 12 | 13 | CREATE UNIQUE INDEX Index_Snapshots_Active ON Snapshots(Active) WHERE Active = 1; 14 | -------------------------------------------------------------------------------- /sql/schema/pov/views/pg_all_objects_unique_columns.sql: -------------------------------------------------------------------------------- 1 | -- View of all objects and their respective unique columns. 2 | -- It is guaranteed no two objects in the database can share the exact same values of all unique columns, 3 | -- thanks to the unique index for each object class. 4 | CREATE OR REPLACE VIEW pov.pg_all_objects_unique_columns AS 5 | SELECT 6 | 'pg_foreign_data_wrapper'::regclass::text AS class_name, 7 | 'pg_foreign_data_wrapper'::regclass::oid AS classid, 8 | pg_foreign_data_wrapper.oid AS objid, 9 | 0::integer AS objsubid, 10 | NULL::int2 AS column_number, 11 | NULL::name AS access_method_name, 12 | NULL::int2 AS operator_strategy_number, 13 | NULL::int2 AS support_function_number, 14 | NULL::text AS support_function_name, 15 | NULL::name AS attribute_name, 16 | NULL::name AS role_name, 17 | NULL::name AS relation_name, 18 | NULL::text AS relation_kind, 19 | NULL::name AS constraint_name, 20 | NULL::name AS conversion_name, 21 | NULL::name AS database_name, 22 | NULL::name AS enumerator_name, 23 | pg_foreign_data_wrapper.fdwname AS foreign_data_wrapper_name, 24 | NULL::name AS foreign_server_name, 25 | NULL::name AS language_name, 26 | NULL::name AS namespace_name, 27 | NULL::name AS operator_class_name, 28 | NULL::name AS operator_name, 29 | NULL::name AS operator_family_name, 30 | NULL::text AS function_name, 31 | NULL::oidvector AS function_input_argument_types, 32 | NULL::name AS rule_name, 33 | NULL::name AS tablespace_name, 34 | NULL::name AS trigger_name, 35 | NULL::text AS data_type_name, 36 | NULL::text AS source_data_type_name, 37 | NULL::text AS target_data_type_name, 38 | NULL::text AS left_data_type_name, 39 | NULL::text AS right_data_type_name, 40 | NULL::name AS text_search_configuration_name, 41 | NULL::name AS text_search_dictionary_name, 42 | NULL::name AS text_search_parser_name, 43 | NULL::name AS text_search_template_name 44 | FROM pg_foreign_data_wrapper 45 | UNION ALL 46 | SELECT 47 | 'pg_authid'::regclass::text AS class_name, 48 | 'pg_authid'::regclass::oid AS classid, 49 | pg_authid.oid AS objid, 50 | 0 AS objsubid, 51 | NULL, 52 | NULL, 53 | NULL, 54 | NULL, 55 | NULL, 56 | NULL, 57 | pg_authid.rolname, 58 | NULL, 59 | NULL, 60 | NULL, 61 | NULL, 62 | NULL, 63 | NULL, 64 | NULL, 65 | NULL, 66 | NULL, 67 | NULL, 68 | NULL, 69 | NULL, 70 | NULL, 71 | NULL, 72 | NULL, 73 | NULL, 74 | NULL, 75 | NULL, 76 | NULL, 77 | NULL, 78 | NULL, 79 | NULL, 80 | NULL, 81 | NULL, 82 | NULL, 83 | NULL, 84 | NULL 85 | FROM pg_authid 86 | UNION ALL 87 | SELECT 88 | 'pg_foreign_server'::regclass::text AS class_name, 89 | 'pg_foreign_server'::regclass::oid AS classid, 90 | pg_foreign_server.oid AS objid, 91 | 0 AS objsubid, 92 | NULL, 93 | NULL, 94 | NULL, 95 | NULL, 96 | NULL, 97 | NULL, 98 | NULL, 99 | NULL, 100 | NULL, 101 | NULL, 102 | NULL, 103 | NULL, 104 | NULL, 105 | NULL, 106 | pg_foreign_server.srvname, 107 | NULL, 108 | NULL, 109 | NULL, 110 | NULL, 111 | NULL, 112 | NULL, 113 | NULL, 114 | NULL, 115 | NULL, 116 | NULL, 117 | NULL, 118 | NULL, 119 | NULL, 120 | NULL, 121 | NULL, 122 | NULL, 123 | NULL, 124 | NULL, 125 | NULL 126 | FROM pg_foreign_server 127 | UNION ALL 128 | SELECT 129 | 'pg_am'::regclass::text AS class_name, 130 | 'pg_am'::regclass::oid AS classid, 131 | pg_am.oid AS objid, 132 | 0 AS objsubid, 133 | NULL, 134 | pg_am.amname, 135 | NULL, 136 | NULL, 137 | NULL, 138 | NULL, 139 | NULL, 140 | NULL, 141 | NULL, 142 | NULL, 143 | NULL, 144 | NULL, 145 | NULL, 146 | NULL, 147 | NULL, 148 | NULL, 149 | NULL, 150 | NULL, 151 | NULL, 152 | NULL, 153 | NULL, 154 | NULL, 155 | NULL, 156 | NULL, 157 | NULL, 158 | NULL, 159 | NULL, 160 | NULL, 161 | NULL, 162 | NULL, 163 | NULL, 164 | NULL, 165 | NULL, 166 | NULL 167 | FROM pg_am 168 | UNION ALL 169 | SELECT 170 | 'pg_namespace'::regclass::text AS class_name, 171 | 'pg_namespace'::regclass::oid AS classid, 172 | pg_namespace.oid AS objid, 173 | 0 AS objsubid, 174 | NULL, 175 | NULL, 176 | NULL, 177 | NULL, 178 | NULL, 179 | NULL, 180 | NULL, 181 | NULL, 182 | NULL, 183 | NULL, 184 | NULL, 185 | NULL, 186 | NULL, 187 | NULL, 188 | NULL, 189 | NULL, 190 | pg_namespace.nspname, 191 | NULL, 192 | NULL, 193 | NULL, 194 | NULL, 195 | NULL, 196 | NULL, 197 | NULL, 198 | NULL, 199 | NULL, 200 | NULL, 201 | NULL, 202 | NULL, 203 | NULL, 204 | NULL, 205 | NULL, 206 | NULL, 207 | NULL 208 | FROM pg_namespace 209 | UNION ALL 210 | SELECT 211 | 'pg_tablespace'::regclass::text AS class_name, 212 | 'pg_tablespace'::regclass::oid AS classid, 213 | pg_tablespace.oid AS objid, 214 | 0 AS objsubid, 215 | NULL, 216 | NULL, 217 | NULL, 218 | NULL, 219 | NULL, 220 | NULL, 221 | NULL, 222 | NULL, 223 | NULL, 224 | NULL, 225 | NULL, 226 | NULL, 227 | NULL, 228 | NULL, 229 | NULL, 230 | NULL, 231 | NULL, 232 | NULL, 233 | NULL, 234 | NULL, 235 | NULL, 236 | NULL, 237 | NULL, 238 | pg_tablespace.spcname, 239 | NULL, 240 | NULL, 241 | NULL, 242 | NULL, 243 | NULL, 244 | NULL, 245 | NULL, 246 | NULL, 247 | NULL, 248 | NULL 249 | FROM pg_tablespace 250 | UNION ALL 251 | SELECT 252 | 'pg_user_mapping'::regclass::text AS class_name, 253 | 'pg_user_mapping'::regclass::oid AS classid, 254 | pg_user_mapping.oid AS objid, 255 | 0 AS objsubid, 256 | NULL, 257 | NULL, 258 | NULL, 259 | NULL, 260 | NULL, 261 | NULL, 262 | pg_authid.rolname, 263 | NULL, 264 | NULL, 265 | NULL, 266 | NULL, 267 | NULL, 268 | NULL, 269 | NULL, 270 | pg_foreign_server.srvname, 271 | NULL, 272 | NULL, 273 | NULL, 274 | NULL, 275 | NULL, 276 | NULL, 277 | NULL, 278 | NULL, 279 | NULL, 280 | NULL, 281 | NULL, 282 | NULL, 283 | NULL, 284 | NULL, 285 | NULL, 286 | NULL, 287 | NULL, 288 | NULL, 289 | NULL 290 | FROM pg_user_mapping 291 | JOIN pg_authid ON (pg_authid.oid = pg_user_mapping.umuser) 292 | JOIN pg_foreign_server ON (pg_foreign_server.oid = pg_user_mapping.umserver) 293 | UNION ALL 294 | SELECT 295 | 'pg_constraint'::regclass::text AS class_name, 296 | 'pg_constraint'::regclass::oid AS classid, 297 | pg_constraint.oid AS objid, 298 | 0 AS objsubid, 299 | NULL, 300 | NULL, 301 | NULL, 302 | NULL, 303 | NULL, 304 | NULL, 305 | NULL, 306 | pg_class.relname, 307 | NULL, 308 | pg_constraint.conname, 309 | NULL, 310 | NULL, 311 | NULL, 312 | NULL, 313 | NULL, 314 | NULL, 315 | pg_namespace.nspname, 316 | NULL, 317 | NULL, 318 | NULL, 319 | NULL, 320 | NULL, 321 | NULL, 322 | NULL, 323 | NULL, 324 | NULL, 325 | NULL, 326 | NULL, 327 | NULL, 328 | NULL, 329 | NULL, 330 | NULL, 331 | NULL, 332 | NULL 333 | FROM pg_constraint 334 | JOIN pg_namespace ON (pg_namespace.oid = pg_constraint.connamespace) 335 | LEFT JOIN pg_class ON (pg_constraint.conrelid = pg_class.oid) 336 | UNION ALL 337 | SELECT 338 | 'pg_conversion'::regclass::text AS class_name, 339 | 'pg_conversion'::regclass::oid AS classid, 340 | pg_conversion.oid AS objid, 341 | 0 AS objsubid, 342 | NULL, 343 | NULL, 344 | NULL, 345 | NULL, 346 | NULL, 347 | NULL, 348 | NULL, 349 | NULL, 350 | NULL, 351 | NULL, 352 | pg_conversion.conname, 353 | NULL, 354 | NULL, 355 | NULL, 356 | NULL, 357 | NULL, 358 | pg_namespace.nspname, 359 | NULL, 360 | NULL, 361 | NULL, 362 | NULL, 363 | NULL, 364 | NULL, 365 | NULL, 366 | NULL, 367 | NULL, 368 | NULL, 369 | NULL, 370 | NULL, 371 | NULL, 372 | NULL, 373 | NULL, 374 | NULL, 375 | NULL 376 | FROM pg_conversion 377 | JOIN pg_namespace ON (pg_namespace.oid = pg_conversion.connamespace) 378 | UNION ALL 379 | SELECT 380 | 'pg_opclass'::regclass::text AS class_name, 381 | 'pg_opclass'::regclass::oid AS classid, 382 | pg_opclass.oid AS objid, 383 | 0 AS objsubid, 384 | NULL, 385 | pg_am.amname, 386 | NULL, 387 | NULL, 388 | NULL, 389 | NULL, 390 | NULL, 391 | NULL, 392 | NULL, 393 | NULL, 394 | NULL, 395 | NULL, 396 | NULL, 397 | NULL, 398 | NULL, 399 | NULL, 400 | pg_namespace.nspname, 401 | pg_opclass.opcname, 402 | NULL, 403 | NULL, 404 | NULL, 405 | NULL, 406 | NULL, 407 | NULL, 408 | NULL, 409 | NULL, 410 | NULL, 411 | NULL, 412 | NULL, 413 | NULL, 414 | NULL, 415 | NULL, 416 | NULL, 417 | NULL 418 | FROM pg_opclass 419 | JOIN pg_am ON (pg_am.oid = pg_opclass.opcmethod) 420 | JOIN pg_namespace ON (pg_namespace.oid = pg_opclass.opcnamespace) 421 | UNION ALL 422 | SELECT 423 | 'pg_opfamily'::regclass::text AS class_name, 424 | 'pg_opfamily'::regclass::oid AS classid, 425 | pg_opfamily.oid AS objid, 426 | 0 AS objsubid, 427 | NULL, 428 | pg_am.amname, 429 | NULL, 430 | NULL, 431 | NULL, 432 | NULL, 433 | NULL, 434 | NULL, 435 | NULL, 436 | NULL, 437 | NULL, 438 | NULL, 439 | NULL, 440 | NULL, 441 | NULL, 442 | NULL, 443 | pg_namespace.nspname, 444 | NULL, 445 | NULL, 446 | pg_opfamily.opfname, 447 | NULL, 448 | NULL, 449 | NULL, 450 | NULL, 451 | NULL, 452 | NULL, 453 | NULL, 454 | NULL, 455 | NULL, 456 | NULL, 457 | NULL, 458 | NULL, 459 | NULL, 460 | NULL 461 | FROM pg_opfamily 462 | JOIN pg_am ON (pg_am.oid = pg_opfamily.opfmethod) 463 | JOIN pg_namespace ON (pg_namespace.oid = pg_opfamily.opfnamespace) 464 | UNION ALL 465 | SELECT 466 | 'pg_type'::regclass::text AS class_name, 467 | 'pg_type'::regclass::oid AS classid, 468 | pg_type.oid AS objid, 469 | 0 AS objsubid, 470 | NULL, 471 | NULL, 472 | NULL, 473 | NULL, 474 | NULL, 475 | NULL, 476 | NULL, 477 | NULL, 478 | NULL, 479 | NULL, 480 | NULL, 481 | NULL, 482 | NULL, 483 | NULL, 484 | NULL, 485 | NULL, 486 | pg_namespace.nspname, 487 | NULL, 488 | NULL, 489 | NULL, 490 | NULL, 491 | NULL, 492 | NULL, 493 | NULL, 494 | NULL, 495 | pov._format_type(pg_catalog.pg_type.oid,NULL), 496 | NULL, 497 | NULL, 498 | NULL, 499 | NULL, 500 | NULL, 501 | NULL, 502 | NULL, 503 | NULL 504 | FROM pg_type 505 | JOIN pg_namespace ON (pg_namespace.oid = pg_type.typnamespace) 506 | UNION ALL 507 | SELECT 508 | 'pg_enum'::regclass::text AS class_name, 509 | 'pg_enum'::regclass::oid AS classid, 510 | pg_enum.oid AS objid, 511 | 0 AS objsubid, 512 | NULL, 513 | NULL, 514 | NULL, 515 | NULL, 516 | NULL, 517 | NULL, 518 | NULL, 519 | NULL, 520 | NULL, 521 | NULL, 522 | NULL, 523 | NULL, 524 | pg_enum.enumlabel, 525 | NULL, 526 | NULL, 527 | NULL, 528 | pg_namespace.nspname, 529 | NULL, 530 | NULL, 531 | NULL, 532 | NULL, 533 | NULL, 534 | NULL, 535 | NULL, 536 | NULL, 537 | pov._format_type(pg_catalog.pg_type.oid,NULL), 538 | NULL, 539 | NULL, 540 | NULL, 541 | NULL, 542 | NULL, 543 | NULL, 544 | NULL, 545 | NULL 546 | FROM pg_enum 547 | JOIN pg_type ON (pg_type.oid = pg_enum.enumtypid) 548 | JOIN pg_namespace ON (pg_namespace.oid = pg_type.typnamespace) 549 | UNION ALL 550 | SELECT 551 | 'pg_cast'::regclass::text AS class_name, 552 | 'pg_cast'::regclass::oid AS classid, 553 | pg_cast.oid AS objid, 554 | 0 AS objsubid, 555 | NULL, 556 | NULL, 557 | NULL, 558 | NULL, 559 | NULL, 560 | NULL, 561 | NULL, 562 | NULL, 563 | NULL, 564 | NULL, 565 | NULL, 566 | NULL, 567 | NULL, 568 | NULL, 569 | NULL, 570 | NULL, 571 | NULL, 572 | NULL, 573 | NULL, 574 | NULL, 575 | NULL, 576 | NULL, 577 | NULL, 578 | NULL, 579 | NULL, 580 | NULL, 581 | pov._format_type(pg_cast.castsource,NULL), 582 | pov._format_type(pg_cast.casttarget,NULL), 583 | NULL, 584 | NULL, 585 | NULL, 586 | NULL, 587 | NULL, 588 | NULL 589 | FROM pg_cast 590 | UNION ALL 591 | SELECT 592 | 'pg_operator'::regclass::text AS class_name, 593 | 'pg_operator'::regclass::oid AS classid, 594 | pg_operator.oid AS objid, 595 | 0 AS objsubid, 596 | NULL, 597 | NULL, 598 | NULL, 599 | NULL, 600 | NULL, 601 | NULL, 602 | NULL, 603 | NULL, 604 | NULL, 605 | NULL, 606 | NULL, 607 | NULL, 608 | NULL, 609 | NULL, 610 | NULL, 611 | NULL, 612 | pg_namespace.nspname, 613 | NULL, 614 | pg_operator.oprname, 615 | NULL, 616 | NULL, 617 | NULL, 618 | NULL, 619 | NULL, 620 | NULL, 621 | NULL, 622 | NULL, 623 | NULL, 624 | pov._format_type(pg_operator.oprleft,NULL), 625 | pov._format_type(pg_operator.oprright,NULL), 626 | NULL, 627 | NULL, 628 | NULL, 629 | NULL 630 | FROM pg_operator 631 | JOIN pg_namespace ON (pg_namespace.oid = pg_operator.oprnamespace) 632 | UNION ALL 633 | SELECT 634 | 'pg_language'::regclass::text AS class_name, 635 | 'pg_language'::regclass::oid AS classid, 636 | pg_language.oid AS objid, 637 | 0 AS objsubid, 638 | NULL, 639 | NULL, 640 | NULL, 641 | NULL, 642 | NULL, 643 | NULL, 644 | NULL, 645 | NULL, 646 | NULL, 647 | NULL, 648 | NULL, 649 | NULL, 650 | NULL, 651 | NULL, 652 | NULL, 653 | pg_language.lanname, 654 | NULL, 655 | NULL, 656 | NULL, 657 | NULL, 658 | NULL, 659 | NULL, 660 | NULL, 661 | NULL, 662 | NULL, 663 | NULL, 664 | NULL, 665 | NULL, 666 | NULL, 667 | NULL, 668 | NULL, 669 | NULL, 670 | NULL, 671 | NULL 672 | FROM pg_language 673 | UNION ALL 674 | SELECT 675 | 'pg_proc'::regclass::text AS class_name, 676 | 'pg_proc'::regclass::oid AS classid, 677 | pg_proc.oid AS objid, 678 | 0 AS objsubid, 679 | NULL, 680 | NULL, 681 | NULL, 682 | NULL, 683 | NULL, 684 | NULL, 685 | NULL, 686 | NULL, 687 | NULL, 688 | NULL, 689 | NULL, 690 | NULL, 691 | NULL, 692 | NULL, 693 | NULL, 694 | NULL, 695 | pg_namespace.nspname, 696 | NULL, 697 | NULL, 698 | NULL, 699 | quote_ident(pg_proc.proname), 700 | pg_proc.proargtypes, 701 | NULL, 702 | NULL, 703 | NULL, 704 | NULL, 705 | NULL, 706 | NULL, 707 | NULL, 708 | NULL, 709 | NULL, 710 | NULL, 711 | NULL, 712 | NULL 713 | FROM pg_proc 714 | JOIN pg_namespace ON (pg_namespace.oid = pg_proc.pronamespace) 715 | UNION ALL 716 | SELECT 717 | 'pg_ts_config'::regclass::text AS class_name, 718 | 'pg_ts_config'::regclass::oid AS classid, 719 | pg_ts_config.oid AS objid, 720 | 0 AS objsubid, 721 | NULL, 722 | NULL, 723 | NULL, 724 | NULL, 725 | NULL, 726 | NULL, 727 | NULL, 728 | NULL, 729 | NULL, 730 | NULL, 731 | NULL, 732 | NULL, 733 | NULL, 734 | NULL, 735 | NULL, 736 | NULL, 737 | pg_namespace.nspname, 738 | NULL, 739 | NULL, 740 | NULL, 741 | NULL, 742 | NULL, 743 | NULL, 744 | NULL, 745 | NULL, 746 | NULL, 747 | NULL, 748 | NULL, 749 | NULL, 750 | NULL, 751 | pg_ts_config.cfgname, 752 | NULL, 753 | NULL, 754 | NULL 755 | FROM pg_ts_config 756 | JOIN pg_namespace ON (pg_namespace.oid = pg_ts_config.cfgnamespace) 757 | UNION ALL 758 | SELECT 759 | 'pg_ts_dict'::regclass::text AS class_name, 760 | 'pg_ts_dict'::regclass::oid AS classid, 761 | pg_ts_dict.oid AS objid, 762 | 0 AS objsubid, 763 | NULL, 764 | NULL, 765 | NULL, 766 | NULL, 767 | NULL, 768 | NULL, 769 | NULL, 770 | NULL, 771 | NULL, 772 | NULL, 773 | NULL, 774 | NULL, 775 | NULL, 776 | NULL, 777 | NULL, 778 | NULL, 779 | pg_namespace.nspname, 780 | NULL, 781 | NULL, 782 | NULL, 783 | NULL, 784 | NULL, 785 | NULL, 786 | NULL, 787 | NULL, 788 | NULL, 789 | NULL, 790 | NULL, 791 | NULL, 792 | NULL, 793 | NULL, 794 | pg_ts_dict.dictname, 795 | NULL, 796 | NULL 797 | FROM pg_ts_dict 798 | JOIN pg_namespace ON (pg_namespace.oid = pg_ts_dict.dictnamespace) 799 | UNION ALL 800 | SELECT 801 | 'pg_ts_parser'::regclass::text AS class_name, 802 | 'pg_ts_parser'::regclass::oid AS classid, 803 | pg_ts_parser.oid AS objid, 804 | 0 AS objsubid, 805 | NULL, 806 | NULL, 807 | NULL, 808 | NULL, 809 | NULL, 810 | NULL, 811 | NULL, 812 | NULL, 813 | NULL, 814 | NULL, 815 | NULL, 816 | NULL, 817 | NULL, 818 | NULL, 819 | NULL, 820 | NULL, 821 | pg_namespace.nspname, 822 | NULL, 823 | NULL, 824 | NULL, 825 | NULL, 826 | NULL, 827 | NULL, 828 | NULL, 829 | NULL, 830 | NULL, 831 | NULL, 832 | NULL, 833 | NULL, 834 | NULL, 835 | NULL, 836 | NULL, 837 | pg_ts_parser.prsname, 838 | NULL 839 | FROM pg_ts_parser 840 | JOIN pg_namespace ON (pg_namespace.oid = pg_ts_parser.prsnamespace) 841 | UNION ALL 842 | SELECT 843 | 'pg_ts_template'::regclass::text AS class_name, 844 | 'pg_ts_template'::regclass::oid AS classid, 845 | pg_ts_template.oid AS objid, 846 | 0 AS objsubid, 847 | NULL, 848 | NULL, 849 | NULL, 850 | NULL, 851 | NULL, 852 | NULL, 853 | NULL, 854 | NULL, 855 | NULL, 856 | NULL, 857 | NULL, 858 | NULL, 859 | NULL, 860 | NULL, 861 | NULL, 862 | NULL, 863 | pg_namespace.nspname, 864 | NULL, 865 | NULL, 866 | NULL, 867 | NULL, 868 | NULL, 869 | NULL, 870 | NULL, 871 | NULL, 872 | NULL, 873 | NULL, 874 | NULL, 875 | NULL, 876 | NULL, 877 | NULL, 878 | NULL, 879 | NULL, 880 | pg_ts_template.tmplname 881 | FROM pg_ts_template 882 | JOIN pg_namespace ON (pg_namespace.oid = pg_ts_template.tmplnamespace) 883 | UNION ALL 884 | SELECT 885 | 'pg_amop'::regclass::text AS class_name, 886 | 'pg_amop'::regclass::oid AS classid, 887 | pg_amop.oid AS objid, 888 | 0 AS objsubid, 889 | NULL, 890 | pg_am.amname, 891 | pg_amop.amopstrategy, 892 | NULL, 893 | NULL, 894 | NULL, 895 | NULL, 896 | NULL, 897 | NULL, 898 | NULL, 899 | NULL, 900 | NULL, 901 | NULL, 902 | NULL, 903 | NULL, 904 | NULL, 905 | pg_namespace.nspname, 906 | NULL, 907 | pg_operator.oprname, 908 | pg_opfamily.opfname, 909 | NULL, 910 | NULL, 911 | NULL, 912 | NULL, 913 | NULL, 914 | NULL, 915 | NULL, 916 | NULL, 917 | pov._format_type(pg_operator.oprleft,NULL), 918 | pov._format_type(pg_operator.oprright,NULL), 919 | NULL, 920 | NULL, 921 | NULL, 922 | NULL 923 | FROM pg_amop 924 | JOIN pg_opfamily ON (pg_opfamily.oid = pg_amop.amopfamily) 925 | JOIN pg_am ON (pg_am.oid = pg_opfamily.opfmethod) 926 | JOIN pg_operator ON (pg_operator.oid = pg_amop.amopopr) 927 | JOIN pg_namespace ON (pg_namespace.oid = pg_operator.oprnamespace AND pg_namespace.oid = pg_opfamily.opfnamespace) 928 | UNION ALL 929 | SELECT 930 | 'pg_amproc'::regclass::text AS class_name, 931 | 'pg_amproc'::regclass::oid AS classid, 932 | pg_amproc.oid AS objid, 933 | 0 AS objsubid, 934 | NULL, 935 | pg_am.amname, 936 | NULL, 937 | pg_amproc.amprocnum, 938 | pg_amproc.amproc::regprocedure::text, 939 | NULL, 940 | NULL, 941 | NULL, 942 | NULL, 943 | NULL, 944 | NULL, 945 | NULL, 946 | NULL, 947 | NULL, 948 | NULL, 949 | NULL, 950 | pg_namespace.nspname, 951 | NULL, 952 | NULL, 953 | pg_opfamily.opfname, 954 | NULL, 955 | NULL, 956 | NULL, 957 | NULL, 958 | NULL, 959 | NULL, 960 | NULL, 961 | NULL, 962 | NULL, 963 | NULL, 964 | NULL, 965 | NULL, 966 | NULL, 967 | NULL 968 | FROM pg_amproc 969 | JOIN pg_opfamily ON (pg_opfamily.oid = pg_amproc.amprocfamily) 970 | JOIN pg_am ON (pg_am.oid = pg_opfamily.opfmethod) 971 | JOIN pg_namespace ON (pg_namespace.oid = pg_opfamily.opfnamespace) 972 | UNION ALL 973 | SELECT 974 | 'pg_database'::regclass::text AS class_name, 975 | 'pg_database'::regclass::oid AS classid, 976 | pg_database.oid AS objid, 977 | 0 AS objsubid, 978 | NULL, 979 | NULL, 980 | NULL, 981 | NULL, 982 | NULL, 983 | NULL, 984 | NULL, 985 | NULL, 986 | NULL, 987 | NULL, 988 | NULL, 989 | pg_database.datname, 990 | NULL, 991 | NULL, 992 | NULL, 993 | NULL, 994 | NULL, 995 | NULL, 996 | NULL, 997 | NULL, 998 | NULL, 999 | NULL, 1000 | NULL, 1001 | NULL, 1002 | NULL, 1003 | NULL, 1004 | NULL, 1005 | NULL, 1006 | NULL, 1007 | NULL, 1008 | NULL, 1009 | NULL, 1010 | NULL, 1011 | NULL 1012 | FROM pg_database 1013 | UNION ALL 1014 | SELECT 1015 | 'pg_class'::regclass::text AS class_name, 1016 | 'pg_class'::regclass::oid AS classid, 1017 | pg_class.oid AS objid, 1018 | 0 AS objsubid, 1019 | NULL, 1020 | NULL, 1021 | NULL, 1022 | NULL, 1023 | NULL, 1024 | NULL, 1025 | NULL, 1026 | pg_class.relname, 1027 | CASE pg_class.relkind WHEN 'c' THEN 'composite type' WHEN 'i' THEN 'index' WHEN 'r' THEN 'table' WHEN 't' THEN 'toast table' WHEN 'v' THEN 'view' WHEN 'S' THEN 'sequence' END::text, 1028 | NULL, 1029 | NULL, 1030 | NULL, 1031 | NULL, 1032 | NULL, 1033 | NULL, 1034 | NULL, 1035 | pg_namespace.nspname, 1036 | NULL, 1037 | NULL, 1038 | NULL, 1039 | NULL, 1040 | NULL, 1041 | NULL, 1042 | NULL, 1043 | NULL, 1044 | NULL, 1045 | NULL, 1046 | NULL, 1047 | NULL, 1048 | NULL, 1049 | NULL, 1050 | NULL, 1051 | NULL, 1052 | NULL 1053 | FROM pg_class 1054 | JOIN pg_namespace ON (pg_namespace.oid = pg_class.relnamespace) 1055 | UNION ALL 1056 | SELECT 1057 | 'pg_class'::regclass::text AS class_name, 1058 | 'pg_class'::regclass::oid AS classid, 1059 | pg_class.oid AS objid, 1060 | pg_attribute.attnum AS objsubid, 1061 | NULL, 1062 | NULL, 1063 | NULL, 1064 | NULL, 1065 | NULL, 1066 | pg_attribute.attname, 1067 | NULL, 1068 | pg_class.relname, 1069 | CASE pg_class.relkind WHEN 'c' THEN 'composite type' WHEN 'i' THEN 'index' WHEN 'r' THEN 'table' WHEN 't' THEN 'toast table' WHEN 'v' THEN 'view' WHEN 'S' THEN 'sequence' END::text, 1070 | NULL, 1071 | NULL, 1072 | NULL, 1073 | NULL, 1074 | NULL, 1075 | NULL, 1076 | NULL, 1077 | pg_namespace.nspname, 1078 | NULL, 1079 | NULL, 1080 | NULL, 1081 | NULL, 1082 | NULL, 1083 | NULL, 1084 | NULL, 1085 | NULL, 1086 | NULL, 1087 | NULL, 1088 | NULL, 1089 | NULL, 1090 | NULL, 1091 | NULL, 1092 | NULL, 1093 | NULL, 1094 | NULL 1095 | FROM pg_class 1096 | JOIN pg_namespace ON (pg_namespace.oid = pg_class.relnamespace) 1097 | JOIN pg_attribute ON (pg_attribute.attrelid = pg_class.oid) 1098 | UNION ALL 1099 | SELECT 1100 | 'pg_attrdef'::regclass::text AS class_name, 1101 | 'pg_attrdef'::regclass::oid AS classid, 1102 | pg_attrdef.oid AS objid, 1103 | 0 AS objsubid, 1104 | pg_attrdef.adnum, 1105 | NULL, 1106 | NULL, 1107 | NULL, 1108 | NULL, 1109 | pg_attribute.attname, 1110 | NULL, 1111 | pg_class.relname, 1112 | CASE pg_class.relkind WHEN 'c' THEN 'composite type' WHEN 'i' THEN 'index' WHEN 'r' THEN 'table' WHEN 't' THEN 'toast table' WHEN 'v' THEN 'view' WHEN 'S' THEN 'sequence' END::text, 1113 | NULL, 1114 | NULL, 1115 | NULL, 1116 | NULL, 1117 | NULL, 1118 | NULL, 1119 | NULL, 1120 | pg_namespace.nspname, 1121 | NULL, 1122 | NULL, 1123 | NULL, 1124 | NULL, 1125 | NULL, 1126 | NULL, 1127 | NULL, 1128 | NULL, 1129 | NULL, 1130 | NULL, 1131 | NULL, 1132 | NULL, 1133 | NULL, 1134 | NULL, 1135 | NULL, 1136 | NULL, 1137 | NULL 1138 | FROM pg_attrdef 1139 | JOIN pg_class ON (pg_class.oid = pg_attrdef.adrelid) 1140 | JOIN pg_namespace ON (pg_namespace.oid = pg_class.relnamespace) 1141 | JOIN pg_attribute ON (pg_attribute.attrelid = pg_class.oid AND pg_attribute.attnum::integer = pg_attrdef.adnum) 1142 | UNION ALL 1143 | SELECT 1144 | 'pg_rewrite'::regclass::text AS class_name, 1145 | 'pg_rewrite'::regclass::oid AS classid, 1146 | pg_rewrite.oid AS objid, 1147 | 0 AS objsubid, 1148 | NULL, 1149 | NULL, 1150 | NULL, 1151 | NULL, 1152 | NULL, 1153 | NULL, 1154 | NULL, 1155 | pg_class.relname, 1156 | CASE pg_class.relkind WHEN 'c' THEN 'composite type' WHEN 'i' THEN 'index' WHEN 'r' THEN 'table' WHEN 't' THEN 'toast table' WHEN 'v' THEN 'view' END::text, 1157 | NULL, 1158 | NULL, 1159 | NULL, 1160 | NULL, 1161 | NULL, 1162 | NULL, 1163 | NULL, 1164 | pg_namespace.nspname, 1165 | NULL, 1166 | NULL, 1167 | NULL, 1168 | NULL, 1169 | NULL, 1170 | pg_rewrite.rulename, 1171 | NULL, 1172 | NULL, 1173 | NULL, 1174 | NULL, 1175 | NULL, 1176 | NULL, 1177 | NULL, 1178 | NULL, 1179 | NULL, 1180 | NULL, 1181 | NULL 1182 | FROM pg_rewrite 1183 | JOIN pg_class ON (pg_class.oid = pg_rewrite.ev_class) 1184 | JOIN pg_namespace ON (pg_namespace.oid = pg_class.relnamespace) 1185 | UNION ALL 1186 | SELECT 1187 | 'pg_trigger'::regclass::text AS class_name, 1188 | 'pg_trigger'::regclass::oid AS classid, 1189 | pg_trigger.oid AS objid, 1190 | 0 AS objsubid, 1191 | NULL, 1192 | NULL, 1193 | NULL, 1194 | NULL, 1195 | NULL, 1196 | NULL, 1197 | NULL, 1198 | pg_class.relname, 1199 | CASE pg_class.relkind WHEN 'c' THEN 'composite type' WHEN 'i' THEN 'index' WHEN 'r' THEN 'table' WHEN 't' THEN 'toast table' WHEN 'v' THEN 'view' END::text, 1200 | NULL, 1201 | NULL, 1202 | NULL, 1203 | NULL, 1204 | NULL, 1205 | NULL, 1206 | NULL, 1207 | pg_namespace.nspname, 1208 | NULL, 1209 | NULL, 1210 | NULL, 1211 | NULL, 1212 | NULL, 1213 | NULL, 1214 | NULL, 1215 | pg_trigger.tgname, 1216 | NULL, 1217 | NULL, 1218 | NULL, 1219 | NULL, 1220 | NULL, 1221 | NULL, 1222 | NULL, 1223 | NULL, 1224 | NULL 1225 | FROM pg_trigger 1226 | JOIN pg_class ON (pg_class.oid = pg_trigger.tgrelid) 1227 | JOIN pg_namespace ON (pg_namespace.oid = pg_class.relnamespace) 1228 | ; 1229 | -------------------------------------------------------------------------------- /sql/schema/pov/views/pg_depend_definitions.sql: -------------------------------------------------------------------------------- 1 | -- Topological sort of all non-system objects. 2 | -- 3 | CREATE OR REPLACE VIEW pov.pg_depend_definitions AS 4 | SELECT 5 | pov.pg_depend_tsort.row_number, 6 | pov.pg_depend_tsort.description, 7 | pov.pg_depend_tsort.classid, 8 | pov.pg_depend_tsort.objid, 9 | pov.pg_depend_tsort.objsubid, 10 | CASE 11 | 12 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_language' THEN 13 | 'CREATE LANGUAGE ' || pov.pg_all_objects_unique_columns.language_name 14 | 15 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_namespace' THEN 16 | 'CREATE SCHEMA ' || pov.pg_all_objects_unique_columns.namespace_name || ';' || 17 | 'ALTER SCHEMA ' || pov.pg_all_objects_unique_columns.namespace_name || ' OWNER TO ' || pg_catalog.pg_get_userbyid((SELECT pg_catalog.pg_namespace.nspowner FROM pg_catalog.pg_namespace WHERE pg_catalog.pg_namespace.oid = pov.pg_all_objects_unique_columns.objid)) 18 | 19 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_class' AND pov.pg_all_objects_unique_columns.relation_kind = 'sequence' THEN 20 | 'CREATE SEQUENCE ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name || ';' 21 | 'ALTER SEQUENCE ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name || ' OWNER TO ' || pg_catalog.pg_get_userbyid((SELECT pg_catalog.pg_class.relowner FROM pg_catalog.pg_class WHERE pg_catalog.pg_class.oid = pov.pg_all_objects_unique_columns.objid)) 22 | 23 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_class' AND pov.pg_all_objects_unique_columns.relation_kind = 'view' AND pov.pg_depend_tsort.objsubid = 0 THEN 24 | 'CREATE VIEW ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name || ' AS ' || pg_catalog.pg_get_viewdef(pov.pg_all_objects_unique_columns.objid) || 25 | 'ALTER VIEW ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name || ' OWNER TO ' || pg_catalog.pg_get_userbyid((SELECT pg_catalog.pg_class.relowner FROM pg_catalog.pg_class WHERE pg_catalog.pg_class.oid = pov.pg_all_objects_unique_columns.objid)) 26 | 27 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_constraint' THEN 28 | 'ALTER TABLE ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name || ' ADD CONSTRAINT ' || pov.pg_all_objects_unique_columns.constraint_name || ' ' || pg_catalog.pg_get_constraintdef(pov.pg_all_objects_unique_columns.objid) 29 | 30 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_attrdef' THEN 31 | 'ALTER TABLE ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name || ' ALTER COLUMN ' || pov.pg_all_objects_unique_columns.attribute_name || ' SET DEFAULT ' || (SELECT pg_catalog.pg_attrdef.adsrc FROM pg_catalog.pg_attrdef WHERE pg_catalog.pg_attrdef.oid = pov.pg_all_objects_unique_columns.objid) 32 | 33 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_trigger' THEN 34 | pg_get_triggerdef(pov.pg_all_objects_unique_columns.objid) 35 | 36 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_proc' THEN 37 | CASE 38 | WHEN pov.pg_get_aggregate_create_def(pov.pg_all_objects_unique_columns.objid) IS NOT NULL 39 | THEN pov.pg_get_aggregate_create_def(pov.pg_all_objects_unique_columns.objid) || ';' || 40 | 'ALTER AGGREGATE ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.function_name || '(' || pg_catalog.pg_get_function_identity_arguments(pov.pg_all_objects_unique_columns.objid) || ') OWNER TO ' || pg_catalog.pg_get_userbyid((SELECT pg_catalog.pg_proc.proowner FROM pg_catalog.pg_proc WHERE pg_catalog.pg_proc.oid = pov.pg_all_objects_unique_columns.objid)) 41 | ELSE 42 | pg_catalog.pg_get_functiondef(pov.pg_all_objects_unique_columns.objid) || ';' || 43 | 'ALTER FUNCTION ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.function_name || '(' || pg_catalog.pg_get_function_identity_arguments(pov.pg_all_objects_unique_columns.objid) || ') OWNER TO ' || pg_catalog.pg_get_userbyid((SELECT pg_catalog.pg_proc.proowner FROM pg_catalog.pg_proc WHERE pg_catalog.pg_proc.oid = pov.pg_all_objects_unique_columns.objid)) 44 | END 45 | 46 | END AS create_definition, 47 | 48 | CASE 49 | 50 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_language' THEN 51 | 'DROP LANGUAGE ' || pov.pg_all_objects_unique_columns.language_name 52 | 53 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_namespace' THEN 54 | 'DROP SCHEMA ' || pov.pg_all_objects_unique_columns.namespace_name 55 | 56 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_class' AND pov.pg_all_objects_unique_columns.relation_kind = 'sequence' THEN 57 | 'DROP SEQUENCE ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name 58 | 59 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_constraint' THEN 60 | 'ALTER TABLE ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name || ' DROP CONSTRAINT ' || pov.pg_all_objects_unique_columns.constraint_name 61 | 62 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_attrdef' THEN 63 | 'ALTER TABLE ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name || ' ALTER COLUMN ' || pov.pg_all_objects_unique_columns.attribute_name || ' DROP DEFAULT' 64 | 65 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_class' AND pov.pg_all_objects_unique_columns.relation_kind = 'view' AND pov.pg_depend_tsort.objsubid = 0 THEN 66 | 'DROP VIEW ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name 67 | 68 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_trigger' THEN 69 | 'DROP TRIGGER ' || pov.pg_all_objects_unique_columns.trigger_name || ' ON ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.relation_name 70 | 71 | WHEN pov.pg_all_objects_unique_columns.class_name = 'pg_proc' THEN 72 | CASE 73 | WHEN pov.pg_get_aggregate_drop_def(pov.pg_all_objects_unique_columns.objid) IS NOT NULL 74 | THEN pov.pg_get_aggregate_drop_def(pov.pg_all_objects_unique_columns.objid) 75 | ELSE 76 | 'DROP FUNCTION ' || pov.pg_all_objects_unique_columns.namespace_name || '.' || pov.pg_all_objects_unique_columns.function_name || '(' || pg_catalog.pg_get_function_identity_arguments(pov.pg_all_objects_unique_columns.objid) || ')' 77 | END 78 | END AS drop_definition 79 | 80 | FROM pov.pg_all_objects_unique_columns, pov.pg_depend_tsort 81 | WHERE pov.pg_all_objects_unique_columns.objsubid = pov.pg_depend_tsort.objsubid 82 | AND pov.pg_all_objects_unique_columns.classid = pov.pg_depend_tsort.classid 83 | AND pov.pg_all_objects_unique_columns.objid = pov.pg_depend_tsort.objid 84 | AND ( 85 | pov.pg_all_objects_unique_columns.namespace_name IS NULL 86 | OR 87 | pov.pg_all_objects_unique_columns.namespace_name NOT IN ('pg_catalog','information_schema','pg_toast','pov') 88 | ) 89 | AND pov.pg_depend_tsort.description NOT IN ('view public.view_snapshots','function public.pov()','function public.pov(bigint)') 90 | ORDER BY pov.pg_depend_tsort.row_number 91 | ; 92 | -------------------------------------------------------------------------------- /sql/schema/pov/views/pg_depend_dot.sql: -------------------------------------------------------------------------------- 1 | -- Generate directional graph of pg_depend in DOT-language. 2 | -- 3 | -- To generate a svg or png graph, using the dot tool from Graphviz, 4 | -- put the output from this view in a file, e.g. pg_depend.dot, then do: 5 | -- dot -opg_depend.svg -Tsvg pg_depend.dot 6 | -- dot -opg_depend.png -Tpng pg_depend.dot 7 | -- 8 | CREATE OR REPLACE VIEW pov.pg_depend_dot AS 9 | SELECT 'digraph pg_depend {' AS diagraph 10 | UNION ALL 11 | SELECT ' "' || 12 | pg_describe_object( 13 | split_part(refobj,'.',1)::oid, 14 | split_part(refobj,'.',2)::oid, 15 | split_part(refobj,'.',3)::integer 16 | ) || ' ' || refobj 17 | || '" -> "' || 18 | pg_describe_object( 19 | split_part(obj,'.',1)::oid, 20 | split_part(obj,'.',2)::oid, 21 | split_part(obj,'.',3)::integer 22 | ) || ' ' || obj 23 | || '" [' || CASE 24 | WHEN array_to_string(array_agg(deptype),'') ~ '^n+$' THEN 'color=black' 25 | WHEN array_to_string(array_agg(deptype),'') ~ '^i+$' THEN 'color=red' 26 | WHEN array_to_string(array_agg(deptype),'') ~ '^a+$' THEN 'color=blue' 27 | WHEN array_to_string(array_agg(deptype),'') ~ '^(ni|in)[ni]*$' THEN 'color=green' 28 | WHEN array_to_string(array_agg(deptype),'') ~ '^(na|an)[na]*$' THEN 'color=yellow' 29 | ELSE 'style=dotted' 30 | END 31 | || ' label=' || array_to_string(array_agg(deptype),'') || ']' 32 | FROM pov.pg_depend_oid_concat GROUP BY refobj, obj 33 | UNION ALL 34 | SELECT '}' 35 | ; 36 | -------------------------------------------------------------------------------- /sql/schema/pov/views/pg_depend_oid_concat.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE VIEW pov.pg_depend_oid_concat AS 2 | WITH 3 | -- Get all objects not in a specific schema (such as language), 4 | -- and all objects in a namespace other than the system namespaces 5 | user_objects AS ( 6 | SELECT DISTINCT classid, objid FROM pov.pg_all_objects_unique_columns 7 | WHERE namespace_name IS NULL OR namespace_name NOT IN ('pg_catalog','information_schema','pg_toast','pov') 8 | ), 9 | -- Create an array with all such objects 10 | user_objects_row AS ( 11 | SELECT array_agg(classid::text || '.' || objid::text) AS id FROM user_objects 12 | ), 13 | -- Select from pg_depend_remapped, 14 | -- and concat the deptypes, 15 | -- for objects with more than one linkage. 16 | pg_depend_deptype_agg AS ( 17 | SELECT 18 | pg_depend_remapped.classid, 19 | pg_depend_remapped.objid, 20 | pg_depend_remapped.objsubid, 21 | pg_depend_remapped.refclassid, 22 | pg_depend_remapped.refobjid, 23 | pg_depend_remapped.refobjsubid, 24 | array_to_string(array_agg(pg_depend_remapped.deptype),'') AS deptype 25 | FROM pov.pg_depend_remapped, user_objects_row 26 | WHERE (pg_depend_remapped.classid::text || '.' || pg_depend_remapped.objid::text) = ANY(user_objects_row.id) 27 | GROUP BY pg_depend_remapped.classid, 28 | pg_depend_remapped.objid, 29 | pg_depend_remapped.objsubid, 30 | pg_depend_remapped.refclassid, 31 | pg_depend_remapped.refobjid, 32 | pg_depend_remapped.refobjsubid 33 | ) 34 | SELECT 35 | refclassid || '.' || refobjid || '.' || refobjsubid AS refobj, 36 | classid || '.' || objid || '.' || objsubid AS obj, 37 | deptype 38 | FROM pg_depend_deptype_agg 39 | ; 40 | -------------------------------------------------------------------------------- /sql/schema/pov/views/pg_depend_remapped.sql: -------------------------------------------------------------------------------- 1 | -- Author: Joel Jacobson, Glue Finance AB, Sweden, 2 | -- Datestamp: 2011-01-13 23:42 Europe/Stockholm 3 | -- License: MIT (http://www.opensource.org/licenses/mit-license.php) 4 | -- 5 | -- This view folds the internal linkages in pg_depend and replaces them 6 | -- with a links to the objects they belong to. 7 | -- 8 | -- This is necessary to be able to topologically sort all the objects, 9 | -- which is done using the tsort() function also provided in the pov project. 10 | -- The toposort gives the "creatable order" of all objects. 11 | -- 12 | -- Meaning of the arrows: 13 | -- this object must be created ---before---> this other object can be created 14 | -- 15 | -- Original pg_depend: 16 | -- (view myview) --i--> (rule _RETURN on view myview) <--n-- (table mytable) 17 | -- 18 | -- We remove the internal object (the rule _RETURN on view myview) and get the following instead: 19 | -- (view myview) <--n-- (table mytable) 20 | -- 21 | -- Now the meaning of the digraph is "(table mytable) must be created before (view myview) can be created", 22 | -- which is exactly what we wanted. 23 | -- 24 | -- Since there can be a chain of internal objects, we need a recursive query to find the "source object" 25 | -- Example: 26 | -- (table mytable) --i--> (type mytable) --i--> (type mytable[]) 27 | -- 28 | -- If an object would depend on (type mytable[]), it actually depends on (table mytable), 29 | -- which is why all arrows (edges) pointing to (type mytable[]) should instead point to (table mytable) 30 | -- 31 | -- And yes, the query below can probably be optimized quite a lot. 32 | -- 33 | CREATE OR REPLACE VIEW pov.pg_depend_remapped AS 34 | WITH RECURSIVE 35 | edges AS ( 36 | SELECT 37 | ARRAY[refclassid::int, refobjid::int, refobjsubid] AS from_obj, 38 | ARRAY[classid::int, objid::int, objsubid] AS to_obj, 39 | deptype 40 | FROM pg_catalog.pg_depend 41 | UNION 42 | -- Add dependencies from "main object" (objsubid=0) to sub object (objsubid>0): 43 | SELECT 44 | ARRAY[refclassid::int, refobjid::int, 0] AS from_obj, 45 | ARRAY[refclassid::int, refobjid::int, refobjsubid] AS to_obj, 46 | deptype 47 | FROM pg_catalog.pg_depend WHERE refobjsubid > 0 48 | UNION 49 | SELECT 50 | ARRAY[classid::int, objid::int, 0] AS from_obj, 51 | ARRAY[classid::int, objid::int, objsubid] AS to_obj, 52 | deptype 53 | FROM pg_catalog.pg_depend WHERE objsubid > 0 54 | ), 55 | objects_with_internal_objects AS ( 56 | -- have internal edge pointing from object 57 | SELECT from_obj AS obj FROM edges WHERE deptype = 'i' 58 | EXCEPT 59 | -- doesn't have internal edge pointing to object 60 | SELECT to_obj FROM edges WHERE deptype = 'i' 61 | ), 62 | objects_without_internal_objects AS ( 63 | SELECT from_obj AS obj FROM edges WHERE deptype IN ('n','a') 64 | UNION 65 | SELECT to_obj AS obj FROM edges WHERE deptype IN ('n','a') 66 | EXCEPT 67 | SELECT obj FROM objects_with_internal_objects 68 | ), 69 | find_internal_recursively AS ( 70 | SELECT 71 | objects_with_internal_objects.obj AS normal_obj, 72 | objects_with_internal_objects.obj AS internal_obj 73 | FROM objects_with_internal_objects 74 | UNION ALL 75 | SELECT 76 | find_internal_recursively.normal_obj, 77 | edges.to_obj 78 | FROM find_internal_recursively 79 | JOIN edges ON (edges.deptype = 'i' AND edges.from_obj = find_internal_recursively.internal_obj) 80 | ), 81 | remap_edges AS ( 82 | SELECT 83 | COALESCE(remap_from.normal_obj,edges.from_obj) AS from_obj, 84 | COALESCE(remap_to.normal_obj,edges.to_obj) AS to_obj, 85 | edges.deptype 86 | FROM edges 87 | LEFT JOIN find_internal_recursively AS remap_from ON (edges.from_obj = remap_from.internal_obj) 88 | LEFT JOIN find_internal_recursively AS remap_to ON (edges.to_obj = remap_to.internal_obj) 89 | WHERE edges.deptype IN ('n','a') 90 | ), 91 | unconcat AS ( 92 | SELECT 93 | from_obj[1]::oid AS refclassid, 94 | from_obj[2]::oid AS refobjid, 95 | from_obj[3]::integer AS refobjsubid, 96 | to_obj[1]::oid AS classid, 97 | to_obj[2]::oid AS objid, 98 | to_obj[3]::integer AS objsubid, 99 | deptype 100 | FROM remap_edges 101 | ) 102 | SELECT * FROM unconcat WHERE NOT (refclassid = classid AND refobjid = objid AND refobjsubid = objsubid) 103 | ; 104 | -------------------------------------------------------------------------------- /sql/schema/pov/views/pg_depend_tsort.sql: -------------------------------------------------------------------------------- 1 | -- Topological sort of all non-system objects. 2 | -- 3 | -- Before selecting the next possible object to created, 4 | -- the list of such objects will be lexically sorted, 5 | -- to 6 | -- 7 | -- The object description must not contain the delimiter ";!;!;!;". 8 | -- This can be replaced to any bogus string. 9 | -- 10 | CREATE OR REPLACE VIEW pov.pg_depend_tsort AS 11 | SELECT 12 | row_number() OVER (), 13 | regexp_replace(unnest,'^(.+) ([0-9]+)[.]([0-9]+)[.]([0-9]+)$',E'\\1') AS description, 14 | regexp_replace(unnest,'^(.+) ([0-9]+)[.]([0-9]+)[.]([0-9]+)$',E'\\2')::oid AS classid, 15 | regexp_replace(unnest,'^(.+) ([0-9]+)[.]([0-9]+)[.]([0-9]+)$',E'\\3')::oid AS objid, 16 | regexp_replace(unnest,'^(.+) ([0-9]+)[.]([0-9]+)[.]([0-9]+)$',E'\\4')::integer AS objsubid 17 | FROM unnest( 18 | ( 19 | -- tsort takes a lot of more arguments than these, 20 | -- but we don't need them for this 21 | SELECT pov.tsort( 22 | -- edges: 23 | array_to_string( 24 | array_agg( 25 | pg_describe_object( 26 | split_part(refobj,'.',1)::oid, 27 | split_part(refobj,'.',2)::oid, 28 | split_part(refobj,'.',3)::integer 29 | ) || ' ' || refobj 30 | || ';!;!;!;' || 31 | pg_describe_object( 32 | split_part(obj,'.',1)::oid, 33 | split_part(obj,'.',2)::oid, 34 | split_part(obj,'.',3)::integer 35 | ) || ' ' || obj 36 | ), 37 | ';!;!;!;' 38 | ), 39 | -- delimiter: 40 | ';!;!;!;', 41 | -- no debug: 42 | 0, 43 | -- perl-style sort function sub: 44 | 'sub {$a cmp $b}' 45 | ) FROM pov.pg_depend_oid_concat 46 | ) 47 | ); 48 | -------------------------------------------------------------------------------- /sql/schema/public/functions/pov.sql: -------------------------------------------------------------------------------- 1 | -- This file contains the definition for the two API functions with same name but with different arguments. 2 | 3 | CREATE OR REPLACE FUNCTION pov( 4 | OUT _SnapshotID bigint, 5 | OUT _RevisionID text 6 | ) RETURNS RECORD AS $BODY$ 7 | -- Takes a new pov 8 | -- Example: 9 | -- SELECT pov(); 10 | DECLARE 11 | BEGIN 12 | 13 | SET LOCAL search_path TO pov; 14 | 15 | -- Create new revision, unless it already exists, in which case the existing one will be returned. 16 | _RevisionID := New_Revision(); 17 | 18 | -- If unmodified, only update its heartbeat and return its SnapshotID. 19 | UPDATE Snapshots SET Heartbeat = now() WHERE Active = 1 AND RevisionID = _RevisionID RETURNING SnapshotID INTO _SnapshotID; 20 | IF FOUND THEN 21 | SET LOCAL search_path TO public; 22 | RETURN; 23 | END IF; 24 | 25 | -- Deactivate existing pov, if any. (might affect 0 rows, it's not a bug we lack IF NOT FOUND here) 26 | UPDATE Snapshots SET Active = 0 WHERE Active = 1; 27 | 28 | -- Create a new SnapshotID. The RevisionID might be identical to a previous pov. 29 | INSERT INTO Snapshots (RevisionID) VALUES (_RevisionID) RETURNING SnapshotID INTO STRICT _SnapshotID; 30 | 31 | -- Return _SnapshotID and _RevisionID 32 | SET LOCAL search_path TO public; 33 | RETURN; 34 | 35 | END; 36 | $BODY$ LANGUAGE plpgsql VOLATILE SECURITY DEFINER; 37 | 38 | 39 | 40 | CREATE OR REPLACE FUNCTION pov( 41 | OUT _SnapshotID bigint, 42 | OUT _RevisionID text, 43 | _RestoreSnapshotID bigint 44 | ) RETURNS RECORD AS $BODY$ 45 | -- Rollback to given pov 46 | -- Example: 47 | -- SELECT pov(1); 48 | DECLARE 49 | _ObjectIDs text[]; 50 | _FunctionID oid; 51 | _ObjectID text; 52 | _SQL text; 53 | _ObjectType text; 54 | 55 | _CurrentSnapshotID bigint; 56 | _CurrentRevisionID text; 57 | _CurrentObjectIDs text[]; 58 | 59 | _RestoredRevisionID text; 60 | _TYPE integer := 1; 61 | _CREATE integer := 2; 62 | _DROP integer := 3; 63 | _i integer; 64 | _Num_Objects integer; 65 | BEGIN 66 | 67 | -- Disable check_function_bodies to allow creation of sql functions depending on not-yet-created functions, 68 | -- which will be created later in the restore process. 69 | SET check_function_bodies = false; 70 | 71 | SET LOCAL search_path TO public; 72 | 73 | SELECT * INTO STRICT _CurrentSnapshotID, _CurrentRevisionID FROM pov(); 74 | 75 | SET LOCAL search_path TO pov; 76 | 77 | SELECT ObjectIDs INTO _CurrentObjectIDs FROM Revisions WHERE RevisionID = _CurrentRevisionID; 78 | IF NOT FOUND THEN 79 | RAISE EXCEPTION 'ERROR_POV_REVISION_NOT_FOUND RevisionID %', _CurrentRevisionID; 80 | END IF; 81 | 82 | -- Lookup RevisionID and ObjectIDs for SnapshotID to restore 83 | SELECT Snapshots.RevisionID, Revisions.ObjectIDs INTO _RevisionID, _ObjectIDs FROM Snapshots 84 | INNER JOIN Revisions ON (Revisions.RevisionID = Snapshots.RevisionID) 85 | WHERE Snapshots.SnapshotID = _RestoreSnapshotID; 86 | IF NOT FOUND THEN 87 | RAISE EXCEPTION 'ERROR_POV_SNAPSHOT_NOT_FOUND SnapshotID %', _RestoreSnapshotID; 88 | END IF; 89 | 90 | SET LOCAL search_path TO public; 91 | 92 | -- Drop objects not part of the revision. 93 | _Num_Objects := array_upper(_CurrentObjectIDs,1); 94 | FOR _i IN 1.._Num_Objects 95 | LOOP 96 | _ObjectID := _CurrentObjectIDs[_Num_Objects-_i+1]; 97 | IF NOT _ObjectID = ANY(_ObjectIDs) THEN 98 | SELECT Content[_TYPE], Content[_DROP] INTO STRICT _ObjectType, _SQL FROM pov.Objects WHERE ObjectID = _ObjectID; 99 | RAISE DEBUG E'\n-%\n%\n%', _ObjectID, '- ' || _ObjectType, '- ' || replace(_SQL,E'\n',E'\n- '); 100 | EXECUTE _SQL; 101 | END IF; 102 | END LOOP; 103 | 104 | -- Create unpresent objects part of the revision. 105 | _Num_Objects := array_upper(_ObjectIDs,1); 106 | FOR _i IN 1.._Num_Objects 107 | LOOP 108 | _ObjectID := _ObjectIDs[_i]; 109 | IF NOT _ObjectID = ANY(_CurrentObjectIDs) THEN 110 | SELECT Content[_TYPE], Content[_CREATE] INTO STRICT _ObjectType, _SQL FROM pov.Objects WHERE ObjectID = _ObjectID; 111 | RAISE DEBUG E'\n-%\n%\n%', _ObjectID, '+ ' || _ObjectType, '+ ' || replace(_SQL,E'\n',E'\n+ '); 112 | EXECUTE _SQL; 113 | END IF; 114 | END LOOP; 115 | 116 | SELECT * INTO STRICT _SnapshotID, _RestoredRevisionID FROM pov(); 117 | 118 | IF _RevisionID <> _RestoredRevisionID THEN 119 | RAISE EXCEPTION 'ERROR_POV_REVISION_DIFF RevisionID % RestoredRevisionID %', _RevisionID, _RestoredRevisionID; 120 | END IF; 121 | 122 | -- Return new _SnapshotID and the restored _RevisionID. 123 | SET LOCAL search_path TO public; 124 | RETURN; 125 | END; 126 | $BODY$ LANGUAGE plpgsql VOLATILE SECURITY DEFINER; -------------------------------------------------------------------------------- /sql/schema/public/views/view_snapshots.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE VIEW view_snapshots AS 2 | SELECT 3 | pov.Snapshots.SnapshotID, 4 | pov.Revisions.RevisionID, 5 | array_upper(pov.Revisions.ObjectIDs,1) AS NumObjects, 6 | pov.Snapshots.Datestamp AS povAt, 7 | pov.Revisions.Datestamp AS RevisionAt, 8 | pov.Snapshots.Heartbeat, 9 | pov.Snapshots.Active 10 | FROM pov.Snapshots 11 | INNER JOIN pov.Revisions ON (pov.Revisions.RevisionID = pov.Snapshots.RevisionID) 12 | ORDER BY pov.Snapshots.SnapshotID; 13 | -------------------------------------------------------------------------------- /sql/uninstall.sql: -------------------------------------------------------------------------------- 1 | DROP SCHEMA pov CASCADE; 2 | DROP FUNCTION public.pov(); 3 | DROP FUNCTION public.pov(bigint); 4 | DROP USER pov; 5 | DROP GROUP pov_group; 6 | -------------------------------------------------------------------------------- /test.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | dropdb test 2> /dev/null 3 | createdb test 4 | psql test -f $PGSRC/contrib/pgcrypto/pgcrypto.sql 5 | psql -f sql/uninstall.sql test 2> /dev/null 6 | psql -f sql/install.sql test 7 | psql -f test.sql test 1>test.stdout.tmp 2>test.stderr.tmp 8 | diff test.stdout test.stdout.tmp 9 | diff test.stderr test.stderr.tmp 10 | -------------------------------------------------------------------------------- /test.sql: -------------------------------------------------------------------------------- 1 | BEGIN; 2 | 3 | SET client_min_messages = 'debug'; 4 | 5 | -- Test creating/dropping/restoring function 6 | SELECT * FROM pov(); -- Take snapshot #1 7 | CREATE FUNCTION myfunc() RETURNS VOID AS $$ $$ LANGUAGE sql; 8 | \df myfunc 9 | SELECT * FROM pov(); -- Take snapshot #2 10 | SELECT * FROM pov(1); -- Rollback to snapshot #1, new snapshot #3 11 | \df myfunc 12 | 13 | -- Test creating/dropping/restoring function and the constraint which depends on it 14 | CREATE FUNCTION mycheckfunc(int) RETURNS BOOLEAN AS $$ SELECT $1 > 1 $$ LANGUAGE sql; 15 | CREATE TABLE mytable(id int, PRIMARY KEY(id), CHECK(mycheckfunc(id))); 16 | \df mycheckfunc 17 | \d mytable 18 | SELECT * FROM pov(); -- Take snapshot #4 19 | SELECT * FROM pov(3); -- Rollback to snapshot #3, new snapshot #5 20 | \df mycheckfunc 21 | \d mytable 22 | SELECT * FROM pov(4); -- Rollback to snapshot #4, new snapshot #6 23 | \df mycheckfunc 24 | \d mytable 25 | 26 | -- Test creating/dropping/restoring a view which depends on a function 27 | CREATE VIEW myview AS SELECT *, mycheckfunc(id) FROM mytable; 28 | \d myview 29 | SELECT * FROM pov(); -- Take snapshot #7 30 | SELECT * FROM pov(6); -- Rollback to snapshot #6, new snapshot #8 31 | \d myview 32 | \df mycheckfunc 33 | \d mytable 34 | SELECT * FROM pov(7); -- Take snapshot #9 35 | \d myview 36 | \df mycheckfunc 37 | \d mytable 38 | 39 | 40 | ROLLBACK; 41 | -------------------------------------------------------------------------------- /test.stderr: -------------------------------------------------------------------------------- 1 | psql:test.sql:7: LOG: statement: CREATE FUNCTION myfunc() RETURNS VOID AS $$ $$ LANGUAGE sql; 2 | psql:test.sql:10: DEBUG: 3 | -19e81ebbf8eced64bac4a73c3981deb818b58a99 4 | - DROP FUNCTION public.myfunc() 5 | psql:test.sql:14: LOG: statement: CREATE FUNCTION mycheckfunc(int) RETURNS BOOLEAN AS $$ SELECT $1 > 1 $$ LANGUAGE sql; 6 | psql:test.sql:15: LOG: statement: CREATE TABLE mytable(id int, PRIMARY KEY(id), CHECK(mycheckfunc(id))); 7 | psql:test.sql:15: NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "mytable_pkey" for table "mytable" 8 | psql:test.sql:19: DEBUG: 9 | -cb045f5342557919d35ea99e0214aeb2c0e46caa 10 | - ALTER TABLE public.mytable DROP CONSTRAINT mytable_id_check 11 | psql:test.sql:19: DEBUG: 12 | -d99627b987ce66e11197e30fef86a8d701660f28 13 | - DROP FUNCTION public.mycheckfunc(integer) 14 | psql:test.sql:22: DEBUG: 15 | +d99627b987ce66e11197e30fef86a8d701660f28 16 | + CREATE OR REPLACE FUNCTION public.mycheckfunc(integer) 17 | + RETURNS boolean 18 | + LANGUAGE sql 19 | + AS $function$ SELECT $1 > 1 $function$ 20 | + ;ALTER FUNCTION public.mycheckfunc(integer) OWNER TO postgres 21 | psql:test.sql:22: DEBUG: 22 | +cb045f5342557919d35ea99e0214aeb2c0e46caa 23 | + ALTER TABLE public.mytable ADD CONSTRAINT mytable_id_check CHECK (public.mycheckfunc(id)) 24 | psql:test.sql:27: LOG: statement: CREATE VIEW myview AS SELECT *, mycheckfunc(id) FROM mytable; 25 | psql:test.sql:30: DEBUG: 26 | -fb23e8c06791024105e531ab4a9bd42ea4b033de 27 | - DROP VIEW public.myview 28 | psql:test.sql:30: DEBUG: drop auto-cascades to type public.myview 29 | CONTEXT: SQL statement "DROP VIEW public.myview" 30 | PL/pgSQL function "pov" line 55 at EXECUTE statement 31 | psql:test.sql:30: DEBUG: drop auto-cascades to type public.myview[] 32 | CONTEXT: SQL statement "DROP VIEW public.myview" 33 | PL/pgSQL function "pov" line 55 at EXECUTE statement 34 | psql:test.sql:30: DEBUG: drop auto-cascades to rule _RETURN on view public.myview 35 | CONTEXT: SQL statement "DROP VIEW public.myview" 36 | PL/pgSQL function "pov" line 55 at EXECUTE statement 37 | Did not find any relation named "myview". 38 | psql:test.sql:34: DEBUG: 39 | +fb23e8c06791024105e531ab4a9bd42ea4b033de 40 | + CREATE VIEW public.myview AS SELECT mytable.id, public.mycheckfunc(mytable.id) AS mycheckfunc FROM public.mytable;;ALTER VIEW public.myview OWNER TO postgres 41 | -------------------------------------------------------------------------------- /test.stdout: -------------------------------------------------------------------------------- 1 | BEGIN 2 | SET 3 | _snapshotid | _revisionid 4 | -------------+------------------------------------------ 5 | 1 | 8ba39bf65949adc6b69aa356c29725cf06c77e26 6 | (1 row) 7 | 8 | CREATE FUNCTION 9 | List of functions 10 | Schema | Name | Result data type | Argument data types | Type 11 | --------+--------+------------------+---------------------+-------- 12 | public | myfunc | void | | normal 13 | (1 row) 14 | 15 | _snapshotid | _revisionid 16 | -------------+------------------------------------------ 17 | 2 | 6c4c86015a45d9361889ce29908937b387e4dde0 18 | (1 row) 19 | 20 | _snapshotid | _revisionid 21 | -------------+------------------------------------------ 22 | 3 | 8ba39bf65949adc6b69aa356c29725cf06c77e26 23 | (1 row) 24 | 25 | List of functions 26 | Schema | Name | Result data type | Argument data types | Type 27 | --------+------+------------------+---------------------+------ 28 | (0 rows) 29 | 30 | CREATE FUNCTION 31 | CREATE TABLE 32 | List of functions 33 | Schema | Name | Result data type | Argument data types | Type 34 | --------+-------------+------------------+---------------------+-------- 35 | public | mycheckfunc | boolean | integer | normal 36 | (1 row) 37 | 38 | Table "public.mytable" 39 | Column | Type | Modifiers 40 | --------+---------+----------- 41 | id | integer | not null 42 | Indexes: 43 | "mytable_pkey" PRIMARY KEY, btree (id) 44 | Check constraints: 45 | "mytable_id_check" CHECK (mycheckfunc(id)) 46 | 47 | _snapshotid | _revisionid 48 | -------------+------------------------------------------ 49 | 4 | 93f931218b488029eebac61161ddc1066d05d995 50 | (1 row) 51 | 52 | _snapshotid | _revisionid 53 | -------------+------------------------------------------ 54 | 5 | 8ba39bf65949adc6b69aa356c29725cf06c77e26 55 | (1 row) 56 | 57 | List of functions 58 | Schema | Name | Result data type | Argument data types | Type 59 | --------+------+------------------+---------------------+------ 60 | (0 rows) 61 | 62 | Table "public.mytable" 63 | Column | Type | Modifiers 64 | --------+---------+----------- 65 | id | integer | not null 66 | Indexes: 67 | "mytable_pkey" PRIMARY KEY, btree (id) 68 | 69 | _snapshotid | _revisionid 70 | -------------+------------------------------------------ 71 | 6 | 93f931218b488029eebac61161ddc1066d05d995 72 | (1 row) 73 | 74 | List of functions 75 | Schema | Name | Result data type | Argument data types | Type 76 | --------+-------------+------------------+---------------------+-------- 77 | public | mycheckfunc | boolean | integer | normal 78 | (1 row) 79 | 80 | Table "public.mytable" 81 | Column | Type | Modifiers 82 | --------+---------+----------- 83 | id | integer | not null 84 | Indexes: 85 | "mytable_pkey" PRIMARY KEY, btree (id) 86 | Check constraints: 87 | "mytable_id_check" CHECK (mycheckfunc(id)) 88 | 89 | CREATE VIEW 90 | View "public.myview" 91 | Column | Type | Modifiers 92 | -------------+---------+----------- 93 | id | integer | 94 | mycheckfunc | boolean | 95 | View definition: 96 | SELECT mytable.id, mycheckfunc(mytable.id) AS mycheckfunc 97 | FROM mytable; 98 | 99 | _snapshotid | _revisionid 100 | -------------+------------------------------------------ 101 | 7 | dbb55f28beaa96efc23326a9fca5f0aa0488ed9d 102 | (1 row) 103 | 104 | _snapshotid | _revisionid 105 | -------------+------------------------------------------ 106 | 8 | 93f931218b488029eebac61161ddc1066d05d995 107 | (1 row) 108 | 109 | List of functions 110 | Schema | Name | Result data type | Argument data types | Type 111 | --------+-------------+------------------+---------------------+-------- 112 | public | mycheckfunc | boolean | integer | normal 113 | (1 row) 114 | 115 | Table "public.mytable" 116 | Column | Type | Modifiers 117 | --------+---------+----------- 118 | id | integer | not null 119 | Indexes: 120 | "mytable_pkey" PRIMARY KEY, btree (id) 121 | Check constraints: 122 | "mytable_id_check" CHECK (mycheckfunc(id)) 123 | 124 | _snapshotid | _revisionid 125 | -------------+------------------------------------------ 126 | 9 | dbb55f28beaa96efc23326a9fca5f0aa0488ed9d 127 | (1 row) 128 | 129 | View "public.myview" 130 | Column | Type | Modifiers 131 | -------------+---------+----------- 132 | id | integer | 133 | mycheckfunc | boolean | 134 | View definition: 135 | SELECT mytable.id, mycheckfunc(mytable.id) AS mycheckfunc 136 | FROM mytable; 137 | 138 | List of functions 139 | Schema | Name | Result data type | Argument data types | Type 140 | --------+-------------+------------------+---------------------+-------- 141 | public | mycheckfunc | boolean | integer | normal 142 | (1 row) 143 | 144 | Table "public.mytable" 145 | Column | Type | Modifiers 146 | --------+---------+----------- 147 | id | integer | not null 148 | Indexes: 149 | "mytable_pkey" PRIMARY KEY, btree (id) 150 | Check constraints: 151 | "mytable_id_check" CHECK (mycheckfunc(id)) 152 | 153 | ROLLBACK 154 | --------------------------------------------------------------------------------