mirror of https://github.com/postgres/postgres
General trigger functions for time-travel
This commit is contained in:
parent
f0b9b2152e
commit
af5c86e2d1
|
@ -9,12 +9,11 @@ ifdef REFINT_VERBOSE
|
|||
CFLAGS+= -DREFINT_VERBOSE
|
||||
endif
|
||||
|
||||
TARGETS= refint$(DLSUFFIX) refint.sql
|
||||
TARGETS= refint$(DLSUFFIX) refint.sql timetravel$(DLSUFFIX) timetravel.sql
|
||||
|
||||
CLEANFILES+= $(TARGETS)
|
||||
|
||||
all:: $(TARGETS)
|
||||
rm -f *.obj *.pic
|
||||
|
||||
%.sql: %.source
|
||||
rm -f $@; \
|
||||
|
@ -23,4 +22,4 @@ all:: $(TARGETS)
|
|||
-e "s:_DLSUFFIX_:$(DLSUFFIX):g" < $< > $@
|
||||
|
||||
clean:
|
||||
rm -f $(TARGETS) *.[op]*
|
||||
rm -f $(TARGETS)
|
||||
|
|
|
@ -28,10 +28,77 @@ being deleted to null), triggered table column names which correspond
|
|||
to primary/unique key, referencing table name and column names corresponding
|
||||
to foreign key (, ... - as many referencing tables/keys as specified
|
||||
by first argument).
|
||||
Note, that NOT NULL constraint and unique index have to be defined
|
||||
by youself.
|
||||
Note, that NOT NULL constraint and unique index have to be defined by
|
||||
youself.
|
||||
|
||||
There are examples in refint.example and regression tests
|
||||
(sql/triggers.sql).
|
||||
|
||||
To CREATE FUNCTIONs use refint.sql (will be made by gmake from
|
||||
refint.source).
|
||||
|
||||
|
||||
2. timetravel.c - functions for implementing time travel feature.
|
||||
|
||||
Old internally supported time-travel (TT) used insert/delete
|
||||
transaction commit times. To get the same feature using triggers
|
||||
you are to add to a table two columns of abstime type to store
|
||||
date when a tuple was inserted (start_date) and changed/deleted
|
||||
(stop_date):
|
||||
|
||||
CREATE TABLE XXX (
|
||||
... ...
|
||||
date_on abstime default currabstime(),
|
||||
date_off abstime default 'infinity'
|
||||
... ...
|
||||
);
|
||||
|
||||
- so, tuples being inserted with NULLs in date_on/date_off will get
|
||||
_current_date_ in date_on (name of start_date column in XXX) and INFINITY in
|
||||
date_off (name of stop_date column in XXX).
|
||||
|
||||
Tuples with stop_date equal INFINITY are "valid now": when trigger will
|
||||
be fired for UPDATE/DELETE of a tuple with stop_date NOT equal INFINITY then
|
||||
this tuple will not be changed/deleted!
|
||||
|
||||
If stop_date equal INFINITY then on
|
||||
|
||||
UPDATE: only stop_date in tuple being updated will be changed to current
|
||||
date and new tuple with new data (coming from SET ... in UPDATE) will be
|
||||
inserted. Start_date in this new tuple will be setted to current date and
|
||||
stop_date - to INFINITY.
|
||||
|
||||
DELETE: new tuple will be inserted with stop_date setted to current date
|
||||
(and with the same data in other columns as in tuple being deleted).
|
||||
|
||||
NOTE:
|
||||
1. To get tuples "valid now" you are to add _stop_date_ = 'infinity'
|
||||
to WHERE. Internally supported TT allowed to avoid this...
|
||||
Fixed rewriting RULEs could help here...
|
||||
As work arround you may use VIEWs...
|
||||
2. You can't change start/stop date columns with UPDATE!
|
||||
Use set_timetravel (below) if you need in this.
|
||||
|
||||
FUNCTIONs:
|
||||
|
||||
timetravel() is general trigger function.
|
||||
|
||||
You are to create trigger BEFORE (!!!) UPDATE OR DELETE using this
|
||||
function on a time-traveled table. You are to specify two arguments: name of
|
||||
start_date column and name of stop_date column in triggered table.
|
||||
|
||||
currabstime() may be used in DEFAULT for start_date column to get
|
||||
current date.
|
||||
|
||||
set_timetravel() allows you turn time-travel ON/OFF for a table:
|
||||
|
||||
set_timetravel('XXX', 1) will turn TT ON for table XXX (and report
|
||||
old status).
|
||||
set_timetravel('XXX', 0) will turn TT OFF for table XXX (-"-).
|
||||
|
||||
Turning TT OFF allows you do with a table ALL what you want.
|
||||
|
||||
There is example in timetravel.example.
|
||||
|
||||
To CREATE FUNCTIONs use timetravel.sql (will be made by gmake from
|
||||
timetravel.source).
|
||||
|
|
|
@ -0,0 +1,372 @@
|
|||
/*
|
||||
* timetravel.c -- function to get time travel feature
|
||||
* using general triggers.
|
||||
*/
|
||||
|
||||
#include "executor/spi.h" /* this is what you need to work with SPI */
|
||||
#include "commands/trigger.h" /* -"- and triggers */
|
||||
#include <ctype.h> /* tolower () */
|
||||
|
||||
#define ABSTIMEOID 702 /* it should be in pg_type.h */
|
||||
|
||||
AbsoluteTime currabstime(void);
|
||||
HeapTuple timetravel(void);
|
||||
int32 set_timetravel(Name relname, int32 on);
|
||||
|
||||
typedef struct
|
||||
{
|
||||
char *ident;
|
||||
void *splan;
|
||||
} EPlan;
|
||||
|
||||
static EPlan *Plans = NULL; /* for UPDATE/DELETE */
|
||||
static int nPlans = 0;
|
||||
|
||||
static char **TTOff = NULL;
|
||||
static int nTTOff = 0;
|
||||
|
||||
static EPlan *find_plan(char *ident, EPlan ** eplan, int *nplans);
|
||||
|
||||
/*
|
||||
* timetravel () --
|
||||
* 1. IF an update affects tuple with stop_date eq INFINITY
|
||||
* then form (and return) new tuple with stop_date eq current date
|
||||
* and all other column values as in old tuple, and insert tuple
|
||||
* with new data and start_date eq current date and
|
||||
* stop_date eq INFINITY
|
||||
* ELSE - skip updation of tuple.
|
||||
* 2. IF an delete affects tuple with stop_date eq INFINITY
|
||||
* then insert the same tuple with stop_date eq current date
|
||||
* ELSE - skip deletion of tuple.
|
||||
*
|
||||
* In CREATE TRIGGER you are to specify start_date and stop_date column
|
||||
* names:
|
||||
* EXECUTE PROCEDURE
|
||||
* timetravel ('date_on', 'date_off').
|
||||
*/
|
||||
|
||||
HeapTuple /* have to return HeapTuple to Executor */
|
||||
timetravel()
|
||||
{
|
||||
Trigger *trigger; /* to get trigger name */
|
||||
char **args; /* arguments */
|
||||
int attnum[2]; /* fnumbers of start/stop columns */
|
||||
Datum oldon, oldoff;
|
||||
Datum newon, newoff;
|
||||
Datum *cvals; /* column values */
|
||||
char *cnulls; /* column nulls */
|
||||
char *relname; /* triggered relation name */
|
||||
Relation rel; /* triggered relation */
|
||||
HeapTuple trigtuple;
|
||||
HeapTuple newtuple = NULL;
|
||||
HeapTuple rettuple;
|
||||
TupleDesc tupdesc; /* tuple description */
|
||||
int natts; /* # of attributes */
|
||||
EPlan *plan; /* prepared plan */
|
||||
char ident[2 * NAMEDATALEN];
|
||||
bool isnull; /* to know is some column NULL or not */
|
||||
int ret;
|
||||
int i;
|
||||
|
||||
/*
|
||||
* Some checks first...
|
||||
*/
|
||||
|
||||
/* Called by trigger manager ? */
|
||||
if (!CurrentTriggerData)
|
||||
elog(WARN, "timetravel: triggers are not initialized");
|
||||
|
||||
/* Should be called for ROW trigger */
|
||||
if (TRIGGER_FIRED_FOR_STATEMENT(CurrentTriggerData->tg_event))
|
||||
elog(WARN, "timetravel: can't process STATEMENT events");
|
||||
|
||||
/* Should be called BEFORE */
|
||||
if (TRIGGER_FIRED_AFTER(CurrentTriggerData->tg_event))
|
||||
elog(WARN, "timetravel: must be fired before event");
|
||||
|
||||
/* INSERT ? */
|
||||
if (TRIGGER_FIRED_BY_INSERT(CurrentTriggerData->tg_event))
|
||||
elog (WARN, "timetravel: can't process INSERT event");
|
||||
|
||||
if (TRIGGER_FIRED_BY_UPDATE(CurrentTriggerData->tg_event))
|
||||
newtuple = CurrentTriggerData->tg_newtuple;
|
||||
|
||||
trigtuple = CurrentTriggerData->tg_trigtuple;
|
||||
|
||||
rel = CurrentTriggerData->tg_relation;
|
||||
relname = SPI_getrelname(rel);
|
||||
|
||||
/* check if TT is OFF for this relation */
|
||||
for (i = 0; i < nTTOff; i++)
|
||||
if (strcasecmp (TTOff[i], relname) == 0)
|
||||
break;
|
||||
if (i < nTTOff) /* OFF - nothing to do */
|
||||
{
|
||||
pfree (relname);
|
||||
return ((newtuple != NULL) ? newtuple : trigtuple);
|
||||
}
|
||||
|
||||
trigger = CurrentTriggerData->tg_trigger;
|
||||
|
||||
if (trigger->tgnargs != 2)
|
||||
elog(WARN, "timetravel (%s): invalid (!= 2) number of arguments %d",
|
||||
relname, trigger->tgnargs);
|
||||
|
||||
args = trigger->tgargs;
|
||||
tupdesc = rel->rd_att;
|
||||
natts = tupdesc->natts;
|
||||
|
||||
/*
|
||||
* Setting CurrentTriggerData to NULL prevents direct calls to trigger
|
||||
* functions in queries. Normally, trigger functions have to be called
|
||||
* by trigger manager code only.
|
||||
*/
|
||||
CurrentTriggerData = NULL;
|
||||
|
||||
for (i = 0; i < 2; i++ )
|
||||
{
|
||||
attnum[i] = SPI_fnumber (tupdesc, args[i]);
|
||||
if ( attnum[i] < 0 )
|
||||
elog(WARN, "timetravel (%s): there is no attribute %s", relname, args[i]);
|
||||
if (SPI_gettypeid (tupdesc, attnum[i]) != ABSTIMEOID)
|
||||
elog(WARN, "timetravel (%s): attributes %s and %s must be of abstime type",
|
||||
relname, args[0], args[1]);
|
||||
}
|
||||
|
||||
oldon = SPI_getbinval (trigtuple, tupdesc, attnum[0], &isnull);
|
||||
if (isnull)
|
||||
elog(WARN, "timetravel (%s): %s must be NOT NULL", relname, args[0]);
|
||||
|
||||
oldoff = SPI_getbinval (trigtuple, tupdesc, attnum[1], &isnull);
|
||||
if (isnull)
|
||||
elog(WARN, "timetravel (%s): %s must be NOT NULL", relname, args[1]);
|
||||
|
||||
/*
|
||||
* If DELETE/UPDATE of tuple with stop_date neq INFINITY
|
||||
* then say upper Executor to skip operation for this tuple
|
||||
*/
|
||||
if (newtuple != NULL) /* UPDATE */
|
||||
{
|
||||
newon = SPI_getbinval (newtuple, tupdesc, attnum[0], &isnull);
|
||||
if (isnull)
|
||||
elog(WARN, "timetravel (%s): %s must be NOT NULL", relname, args[0]);
|
||||
newoff = SPI_getbinval (newtuple, tupdesc, attnum[1], &isnull);
|
||||
if (isnull)
|
||||
elog(WARN, "timetravel (%s): %s must be NOT NULL", relname, args[1]);
|
||||
|
||||
if ( oldon != newon || oldoff != newoff )
|
||||
elog (WARN, "timetravel (%s): you can't change %s and/or %s columns (use set_timetravel)",
|
||||
relname, args[0], args[1]);
|
||||
|
||||
if ( newoff != NOEND_ABSTIME )
|
||||
{
|
||||
pfree (relname); /* allocated in upper executor context */
|
||||
return (NULL);
|
||||
}
|
||||
}
|
||||
else if (oldoff != NOEND_ABSTIME) /* DELETE */
|
||||
{
|
||||
pfree (relname);
|
||||
return (NULL);
|
||||
}
|
||||
|
||||
newoff = GetCurrentAbsoluteTime ();
|
||||
|
||||
/* Connect to SPI manager */
|
||||
if ((ret = SPI_connect()) < 0)
|
||||
elog(WARN, "timetravel (%s): SPI_connect returned %d", relname, ret);
|
||||
|
||||
/* Fetch tuple values and nulls */
|
||||
cvals = (Datum *) palloc (natts * sizeof (Datum));
|
||||
cnulls = (char *) palloc (natts * sizeof (char));
|
||||
for (i = 0; i < natts; i++)
|
||||
{
|
||||
cvals[i] = SPI_getbinval ((newtuple != NULL) ? newtuple : trigtuple,
|
||||
tupdesc, i + 1, &isnull);
|
||||
cnulls[i] = (isnull) ? 'n' : ' ';
|
||||
}
|
||||
|
||||
/* change date column(s) */
|
||||
if (newtuple) /* UPDATE */
|
||||
{
|
||||
cvals[attnum[0] - 1] = newoff; /* start_date eq current date */
|
||||
cnulls[attnum[0] - 1] = ' ';
|
||||
cvals[attnum[1] - 1] = NOEND_ABSTIME; /* stop_date eq INFINITY */
|
||||
cnulls[attnum[1] - 1] = ' ';
|
||||
}
|
||||
else /* DELETE */
|
||||
{
|
||||
cvals[attnum[1] - 1] = newoff; /* stop_date eq current date */
|
||||
cnulls[attnum[1] - 1] = ' ';
|
||||
}
|
||||
|
||||
/*
|
||||
* Construct ident string as TriggerName $ TriggeredRelationId
|
||||
* and try to find prepared execution plan.
|
||||
*/
|
||||
sprintf(ident, "%s$%u", trigger->tgname, rel->rd_id);
|
||||
plan = find_plan(ident, &Plans, &nPlans);
|
||||
|
||||
/* if there is no plan ... */
|
||||
if (plan->splan == NULL)
|
||||
{
|
||||
void *pplan;
|
||||
Oid *ctypes;
|
||||
char sql[8192];
|
||||
|
||||
/* allocate ctypes for preparation */
|
||||
ctypes = (Oid *) palloc(natts * sizeof(Oid));
|
||||
|
||||
/*
|
||||
* Construct query:
|
||||
* INSERT INTO _relation_ VALUES ($1, ...)
|
||||
*/
|
||||
sprintf(sql, "INSERT INTO %s VALUES (", relname);
|
||||
for (i = 1; i <= natts; i++)
|
||||
{
|
||||
sprintf(sql + strlen(sql), "$%d%s",
|
||||
i, (i < natts) ? ", " : ")");
|
||||
ctypes[i - 1] = SPI_gettypeid(tupdesc, i);
|
||||
}
|
||||
|
||||
/* Prepare plan for query */
|
||||
pplan = SPI_prepare(sql, natts, ctypes);
|
||||
if (pplan == NULL)
|
||||
elog(WARN, "timetravel (%s): SPI_prepare returned %d", relname, SPI_result);
|
||||
|
||||
/*
|
||||
* Remember that SPI_prepare places plan in current memory context
|
||||
* - so, we have to save plan in Top memory context for latter
|
||||
* use.
|
||||
*/
|
||||
pplan = SPI_saveplan(pplan);
|
||||
if (pplan == NULL)
|
||||
elog(WARN, "timetravel (%s): SPI_saveplan returned %d", relname, SPI_result);
|
||||
|
||||
plan->splan = pplan;
|
||||
}
|
||||
|
||||
/*
|
||||
* Ok, execute prepared plan.
|
||||
*/
|
||||
ret = SPI_execp(plan->splan, cvals, cnulls, 0);
|
||||
|
||||
if (ret < 0)
|
||||
elog(WARN, "timetravel (%s): SPI_execp returned %d", relname, ret);
|
||||
|
||||
/* Tuple to return to upper Executor ... */
|
||||
if (newtuple) /* UPDATE */
|
||||
{
|
||||
HeapTuple tmptuple;
|
||||
|
||||
tmptuple = SPI_copytuple (trigtuple);
|
||||
rettuple = SPI_modifytuple (rel, tmptuple, 1, &(attnum[1]), &newoff, NULL);
|
||||
/*
|
||||
* SPI_copytuple allocates tmptuple in upper executor context -
|
||||
* have to free allocation using SPI_pfree
|
||||
*/
|
||||
SPI_pfree (tmptuple);
|
||||
}
|
||||
else /* DELETE */
|
||||
rettuple = trigtuple;
|
||||
|
||||
SPI_finish(); /* don't forget say Bye to SPI mgr */
|
||||
|
||||
pfree (relname);
|
||||
|
||||
return (rettuple);
|
||||
}
|
||||
|
||||
/*
|
||||
* set_timetravel () --
|
||||
* turn timetravel for specified relation ON/OFF
|
||||
*/
|
||||
int32
|
||||
set_timetravel(Name relname, int32 on)
|
||||
{
|
||||
char *rname;
|
||||
char *d;
|
||||
char *s;
|
||||
int i;
|
||||
|
||||
for (i = 0; i < nTTOff; i++)
|
||||
if (namestrcmp (relname, TTOff[i]) == 0)
|
||||
break;
|
||||
|
||||
if (i < nTTOff) /* OFF currently */
|
||||
{
|
||||
if (on == 0)
|
||||
return (0);
|
||||
|
||||
/* turn ON */
|
||||
free (TTOff[i]);
|
||||
if (nTTOff == 1)
|
||||
free (TTOff);
|
||||
else
|
||||
{
|
||||
if (i < nTTOff - 1)
|
||||
memcpy (&(TTOff[i]), &(TTOff[i + 1]), (nTTOff - i) * sizeof (char*));
|
||||
TTOff = realloc (TTOff, (nTTOff - 1) * sizeof (char*));
|
||||
}
|
||||
nTTOff--;
|
||||
return (0);
|
||||
}
|
||||
|
||||
/* ON currently */
|
||||
if (on != 0)
|
||||
return (1);
|
||||
|
||||
/* turn OFF */
|
||||
if (nTTOff == 0)
|
||||
TTOff = malloc (sizeof (char*));
|
||||
else
|
||||
TTOff = realloc (TTOff, (nTTOff + 1) * sizeof (char*));
|
||||
s = rname = nameout (relname);
|
||||
d = TTOff[nTTOff] = malloc (strlen (rname) + 1);
|
||||
while (*s)
|
||||
*d++ = tolower (*s++);
|
||||
*d = 0;
|
||||
pfree (rname);
|
||||
nTTOff++;
|
||||
|
||||
return (1);
|
||||
|
||||
}
|
||||
|
||||
AbsoluteTime
|
||||
currabstime ()
|
||||
{
|
||||
return (GetCurrentAbsoluteTime ());
|
||||
}
|
||||
|
||||
static EPlan *
|
||||
find_plan(char *ident, EPlan ** eplan, int *nplans)
|
||||
{
|
||||
EPlan *newp;
|
||||
int i;
|
||||
|
||||
if (*nplans > 0)
|
||||
{
|
||||
for (i = 0; i < *nplans; i++)
|
||||
{
|
||||
if (strcmp((*eplan)[i].ident, ident) == 0)
|
||||
break;
|
||||
}
|
||||
if (i != *nplans)
|
||||
return (*eplan + i);
|
||||
*eplan = (EPlan *) realloc(*eplan, (i + 1) * sizeof(EPlan));
|
||||
newp = *eplan + i;
|
||||
}
|
||||
else
|
||||
{
|
||||
newp = *eplan = (EPlan *) malloc(sizeof(EPlan));
|
||||
(*nplans) = i = 0;
|
||||
}
|
||||
|
||||
newp->ident = (char *) malloc(strlen(ident) + 1);
|
||||
strcpy(newp->ident, ident);
|
||||
newp->splan = NULL;
|
||||
(*nplans)++;
|
||||
|
||||
return (newp);
|
||||
}
|
|
@ -0,0 +1,63 @@
|
|||
drop table tttest;
|
||||
create table tttest (
|
||||
price_id int4,
|
||||
price_val int4,
|
||||
price_on abstime default currabstime(),
|
||||
price_off abstime default 'infinity'
|
||||
);
|
||||
|
||||
insert into tttest values (1, 1, null, null);
|
||||
insert into tttest values (2, 2, null, null);
|
||||
insert into tttest values (3, 3, null, null);
|
||||
|
||||
create trigger timetravel
|
||||
before delete or update on tttest
|
||||
for each row
|
||||
execute procedure
|
||||
timetravel (price_on, price_off);
|
||||
|
||||
select * from tttest;
|
||||
delete from tttest where price_id = 2;
|
||||
select * from tttest;
|
||||
-- what do we see ?
|
||||
|
||||
-- get current prices
|
||||
select * from tttest where price_off = 'infinity';
|
||||
|
||||
-- change price for price_id == 3
|
||||
update tttest set price_val = 30 where price_id = 3;
|
||||
select * from tttest;
|
||||
|
||||
-- now we want to change price_id from 3 to 5 in ALL tuples
|
||||
-- but this gets us not what we need
|
||||
update tttest set price_id = 5 where price_id = 3;
|
||||
select * from tttest;
|
||||
|
||||
-- restore data as before last update:
|
||||
select set_timetravel('tttest', 0); -- turn TT OFF!
|
||||
delete from tttest where price_id = 5;
|
||||
update tttest set price_off = 'infinity' where price_val = 30;
|
||||
select * from tttest;
|
||||
|
||||
-- and try change price_id now!
|
||||
update tttest set price_id = 5 where price_id = 3;
|
||||
select * from tttest;
|
||||
-- isn't it what we need ?
|
||||
|
||||
select set_timetravel('tttest', 1); -- turn TT ON!
|
||||
|
||||
-- we want to correct some date
|
||||
update tttest set price_on = 'Jan-01-1990 00:00:01' where price_id = 5 and
|
||||
price_off <> 'infinity';
|
||||
-- but this doesn't work
|
||||
|
||||
-- try in this way
|
||||
select set_timetravel('tttest', 0); -- turn TT OFF!
|
||||
update tttest set price_on = '01-Jan-1990 00:00:01' where price_id = 5 and
|
||||
price_off <> 'infinity';
|
||||
select * from tttest;
|
||||
-- isn't it what we need ?
|
||||
|
||||
-- get price for price_id == 5 as it was '10-Jan-1990'
|
||||
select * from tttest where price_id = 5 and
|
||||
price_on <= '10-Jan-1990' and price_off > '10-Jan-1990';
|
|
@ -0,0 +1,18 @@
|
|||
DROP FUNCTION currabstime();
|
||||
DROP FUNCTION timetravel();
|
||||
DROP FUNCTION set_timetravel(name, int4);
|
||||
|
||||
CREATE FUNCTION currabstime()
|
||||
RETURNS abstime
|
||||
AS '_OBJWD_/timetravel_DLSUFFIX_'
|
||||
LANGUAGE 'c';
|
||||
|
||||
CREATE FUNCTION timetravel()
|
||||
RETURNS opaque
|
||||
AS '_OBJWD_/timetravel_DLSUFFIX_'
|
||||
LANGUAGE 'c';
|
||||
|
||||
CREATE FUNCTION set_timetravel(name, int4)
|
||||
RETURNS int4
|
||||
AS '_OBJWD_/timetravel_DLSUFFIX_'
|
||||
LANGUAGE 'c';
|
Loading…
Reference in New Issue