postgis/doc/extras_historytable.xml

144 lines
6.2 KiB
XML

<?xml version="1.0" encoding="UTF-8"?>
<sect1 id="History_Table">
<title>History Tracking</title>
<sect1info>
<abstract>
<para>Suppose you have a table of data that represents the current state of a particular geographic feature.
A parcels table, or a roads table, or a fruit trees table, whatever.
Generally, GIS tools understand a table as a single entity into which they can update, insert and delete rows from.
How you do allow common GIS tools to work against your data, while maintaining an audit trail of what changes have been made, by whom, and what the past state of the data is?</para>
<para>This <varname>history_table</varname> extra module provides some utility functions for creating and maintaining history.</para>
</abstract>
</sect1info>
<note><para>The <varname>history_table</varname> was also packaged in PostGIS 1.5, but added to the documentation in PostGIS 2.0. This package is written in plpgsql and located in the <varname>extras/history_table</varname> of PostGIS source tar balls and source repository.</para></note>
<para>If you have a table 'roads', this module will maintain a 'roads_history' side table, which contains all the columns of the parent table, and the following additional columns:</para>
<programlisting>history_id | integer | not null default
date_added | timestamp without time zone | not null default now()
date_deleted | timestamp without time zone |
last_operation | character varying(30) | not null
active_user | character varying(90) | not null default "current_user"()
current_version | text | not null</programlisting>
<orderedlist>
<listitem>
<para>When you insert a new record into 'roads' a record is automatically inserted into 'roads_history', with the 'date_added' filled in the 'date_deleted' set to NULL, a unique 'history_id', a 'last_operation' of 'INSERT' and 'active_user' set.</para>
</listitem>
<listitem>
<para>When you delete a record in 'roads', the record in the history table is *not* deleted, but the 'date_deleted' is set to the current date.</para>
</listitem>
<listitem>
<para>When you update a record in 'roads', the current record has 'date_deleted' filled in and a new record is created with the 'date_added' set and 'date_deleted' NULL.</para>
</listitem>
</orderedlist>
<para>With this information maintained, it is possible to retrieve the history of any record in the roads table:</para>
<programlisting>SELECT * FROM roads_history WHERE roads_pk = 111;</programlisting>
<para>Or, to retrieve a view of the roads table at any point in the past:</para>
<programlisting>SELECT * FROM roads_history
WHERE date_added &lt; 'January 1, 2001' AND
( date_deleted &gt;= 'January 1, 2001' OR date_deleted IS NULL );</programlisting>
<refentry id="Postgis_Install_History">
<refnamediv>
<refname>Postgis_Install_History</refname>
<refpurpose>Creates a table that will hold some interesting values for managing history tables.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>void <function>Postgis_Install_History</function></funcdef>
<paramdef></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Creates a table that will hold some interesting values for managing history tables. Creates a table called <varname>historic_information</varname></para>
<!-- use this format if new function -->
<para>Availability: 1.5.0</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>SELECT postgis_install_history();</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
</refsection>
</refentry>
<refentry id="Postgis_Enable_History">
<refnamediv>
<refname>Postgis_Enable_History</refname>
<refpurpose>Registers a table in the history_information table for tracking and also adds in side line history table and insert, update, delete rules on the table.</refpurpose>
</refnamediv>
<refsynopsisdiv>
<funcsynopsis>
<funcprototype>
<funcdef>boolean <function>Postgis_Enable_History</function></funcdef>
<paramdef><type>text </type> <parameter>p_schema</parameter></paramdef>
<paramdef><type>text </type> <parameter>p_table</parameter></paramdef>
</funcprototype>
</funcsynopsis>
</refsynopsisdiv>
<refsection>
<title>Description</title>
<para>Registers a table in the history_information table for tracking and also adds in side line history table with same name as table but prefixed with <varname>history</varname> in the same schema as the original table. Puts in insert, update, delete rules on the table.
Any inserts,updates,deletes of the geometry are recorded in the history table.</para>
<note><para>This function currently relies on a geometry column being registered in <varname>geometry_columns</varname> and fails if the geometry column is not present in <varname>geometry_columns</varname> table.</para></note>
<!-- use this format if new function -->
<para>Availability: 1.5.0</para>
</refsection>
<refsection>
<title>Examples</title>
<programlisting>CREATE TABLE roads(gid SERIAL PRIMARY KEY, road_name varchar(150));
SELECT AddGeometryColumn('roads', 'geom', 26986, 'LINESTRING', 2);
SELECT postgis_enable_history('public', 'roads', 'geom') As register_table;
register_table
--------------
t
INSERT INTO roads(road_name, geom)
VALUES('Test Street', ST_GeomFromText('LINESTRING(231660.5 832170,231647 832202,231627.5 832250.5)',26986));
-- check transaction detail --
SELECT date_added, last_operation, current_version
FROM roads_history
WHERE road_name = 'Test Street' ORDER BY date_added DESC;
date_added | last_operation | current_version
------------------------+----------------+-----------------
2011-02-07 12:44:36.92 | INSERT | 2
</programlisting>
</refsection>
<!-- Optionally add a "See Also" section -->
<refsection>
<title>See Also</title>
</refsection>
</refentry>
</sect1>