General function for SERIAL/IDENTITY/AUTOINCREMENT feature.
Handle INSERT event in timetravel().
This commit is contained in:
parent
cd7c56eeeb
commit
d75206fdf5
@ -9,7 +9,8 @@ ifdef REFINT_VERBOSE
|
|||||||
CFLAGS+= -DREFINT_VERBOSE
|
CFLAGS+= -DREFINT_VERBOSE
|
||||||
endif
|
endif
|
||||||
|
|
||||||
TARGETS= refint$(DLSUFFIX) refint.sql timetravel$(DLSUFFIX) timetravel.sql
|
TARGETS= refint$(DLSUFFIX) refint.sql timetravel$(DLSUFFIX) timetravel.sql \
|
||||||
|
autoinc$(DLSUFFIX) autoinc.sql
|
||||||
|
|
||||||
CLEANFILES+= $(TARGETS)
|
CLEANFILES+= $(TARGETS)
|
||||||
|
|
||||||
|
@ -8,8 +8,8 @@ table/field names (as described below) while creating a trigger.
|
|||||||
|
|
||||||
check_primary_key () is to used for foreign keys of a table.
|
check_primary_key () is to used for foreign keys of a table.
|
||||||
|
|
||||||
You are to create trigger (BEFORE INSERT OR UPDATE) using this
|
You have to create trigger (BEFORE INSERT OR UPDATE) using this
|
||||||
function on a table referencing another table. You are to specify
|
function on a table referencing another table. You have to specify
|
||||||
as function arguments: triggered table column names which correspond
|
as function arguments: triggered table column names which correspond
|
||||||
to foreign key, referenced table name and column names in referenced
|
to foreign key, referenced table name and column names in referenced
|
||||||
table which correspond to primary/unique key.
|
table which correspond to primary/unique key.
|
||||||
@ -18,8 +18,8 @@ one reference.
|
|||||||
|
|
||||||
check_foreign_key () is to used for primary/unique keys of a table.
|
check_foreign_key () is to used for primary/unique keys of a table.
|
||||||
|
|
||||||
You are to create trigger (BEFORE DELETE OR UPDATE) using this
|
You have to create trigger (BEFORE DELETE OR UPDATE) using this
|
||||||
function on a table referenced by another table(s). You are to specify
|
function on a table referenced by another table(s). You have to specify
|
||||||
as function arguments: number of references for which function has to
|
as function arguments: number of references for which function has to
|
||||||
performe checking, action if referencing key found ('cascade' - to delete
|
performe checking, action if referencing key found ('cascade' - to delete
|
||||||
corresponding foreign key, 'restrict' - to abort transaction if foreign keys
|
corresponding foreign key, 'restrict' - to abort transaction if foreign keys
|
||||||
@ -42,20 +42,26 @@ refint.source).
|
|||||||
|
|
||||||
Old internally supported time-travel (TT) used insert/delete
|
Old internally supported time-travel (TT) used insert/delete
|
||||||
transaction commit times. To get the same feature using triggers
|
transaction commit times. To get the same feature using triggers
|
||||||
you are to add to a table two columns of abstime type to store
|
you have to add to a table two columns of abstime type to store
|
||||||
date when a tuple was inserted (start_date) and changed/deleted
|
date when a tuple was inserted (start_date) and changed/deleted
|
||||||
(stop_date):
|
(stop_date):
|
||||||
|
|
||||||
CREATE TABLE XXX (
|
CREATE TABLE XXX (
|
||||||
... ...
|
... ...
|
||||||
date_on abstime default currabstime(),
|
date_on abstime,
|
||||||
date_off abstime default 'infinity'
|
date_off abstime
|
||||||
... ...
|
... ...
|
||||||
);
|
);
|
||||||
|
|
||||||
- so, tuples being inserted with NULLs in date_on/date_off will get
|
CREATE TRIGGER timetravel
|
||||||
_current_date_ in date_on (name of start_date column in XXX) and INFINITY in
|
BEFORE INSERT OR DELETE OR UPDATE ON tttest
|
||||||
date_off (name of stop_date column in XXX).
|
FOR EACH ROW
|
||||||
|
EXECUTE PROCEDURE
|
||||||
|
timetravel (date_on, date_off);
|
||||||
|
|
||||||
|
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
|
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
|
be fired for UPDATE/DELETE of a tuple with stop_date NOT equal INFINITY then
|
||||||
@ -72,7 +78,7 @@ 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).
|
(and with the same data in other columns as in tuple being deleted).
|
||||||
|
|
||||||
NOTE:
|
NOTE:
|
||||||
1. To get tuples "valid now" you are to add _stop_date_ = 'infinity'
|
1. To get tuples "valid now" you have to add _stop_date_ = 'infinity'
|
||||||
to WHERE. Internally supported TT allowed to avoid this...
|
to WHERE. Internally supported TT allowed to avoid this...
|
||||||
Fixed rewriting RULEs could help here...
|
Fixed rewriting RULEs could help here...
|
||||||
As work arround you may use VIEWs...
|
As work arround you may use VIEWs...
|
||||||
@ -83,12 +89,9 @@ DELETE: new tuple will be inserted with stop_date setted to current date
|
|||||||
|
|
||||||
timetravel() is general trigger function.
|
timetravel() is general trigger function.
|
||||||
|
|
||||||
You are to create trigger BEFORE (!!!) UPDATE OR DELETE using this
|
You have to create trigger BEFORE (!!!) INSERT OR UPDATE OR DELETE using
|
||||||
function on a time-traveled table. You are to specify two arguments: name of
|
this function on a time-traveled table. You have to specify two arguments:
|
||||||
start_date column and name of stop_date column in triggered table.
|
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() allows you turn time-travel ON/OFF for a table:
|
||||||
|
|
||||||
@ -96,9 +99,26 @@ set_timetravel() allows you turn time-travel ON/OFF for a table:
|
|||||||
old status).
|
old status).
|
||||||
set_timetravel('XXX', 0) will turn TT OFF for table XXX (-"-).
|
set_timetravel('XXX', 0) will turn TT OFF for table XXX (-"-).
|
||||||
|
|
||||||
Turning TT OFF allows you do with a table ALL what you want.
|
Turning TT OFF allows you do with a table ALL what you want!
|
||||||
|
|
||||||
There is example in timetravel.example.
|
There is example in timetravel.example.
|
||||||
|
|
||||||
To CREATE FUNCTIONs use timetravel.sql (will be made by gmake from
|
To CREATE FUNCTIONs use timetravel.sql (will be made by gmake from
|
||||||
timetravel.source).
|
timetravel.source).
|
||||||
|
|
||||||
|
|
||||||
|
3. autoinc.c - function for implementing AUTOINCREMENT/IDENTITY feature.
|
||||||
|
|
||||||
|
You have to create BEFORE INSERT OR UPDATE trigger using function
|
||||||
|
autoinc(). You have to specify as function arguments: column name
|
||||||
|
(of int4 type) for which you want to get this feature and name of
|
||||||
|
SEQUENCE from which next value has to be fetched when NULL or 0
|
||||||
|
value is being inserted into column (, ... - you are able to specify
|
||||||
|
as many column/sequence pairs as you need).
|
||||||
|
|
||||||
|
There is example in autoinc.example.
|
||||||
|
|
||||||
|
To CREATE FUNCTION use autoinc.sql (will be made by gmake from
|
||||||
|
autoinc.source).
|
||||||
|
|
||||||
|
|
||||||
|
100
contrib/spi/autoinc.c
Normal file
100
contrib/spi/autoinc.c
Normal file
@ -0,0 +1,100 @@
|
|||||||
|
|
||||||
|
#include "executor/spi.h" /* this is what you need to work with SPI */
|
||||||
|
#include "commands/trigger.h" /* -"- and triggers */
|
||||||
|
|
||||||
|
HeapTuple autoinc(void);
|
||||||
|
|
||||||
|
extern int4 nextval(struct varlena * seqin);
|
||||||
|
|
||||||
|
HeapTuple
|
||||||
|
autoinc()
|
||||||
|
{
|
||||||
|
Trigger *trigger; /* to get trigger name */
|
||||||
|
int nargs; /* # of arguments */
|
||||||
|
int *chattrs; /* attnums of attributes to change */
|
||||||
|
int chnattrs = 0; /* # of above */
|
||||||
|
Datum *newvals; /* vals of above */
|
||||||
|
char **args; /* arguments */
|
||||||
|
char *relname; /* triggered relation name */
|
||||||
|
Relation rel; /* triggered relation */
|
||||||
|
HeapTuple rettuple = NULL;
|
||||||
|
TupleDesc tupdesc; /* tuple description */
|
||||||
|
bool isnull;
|
||||||
|
int i;
|
||||||
|
|
||||||
|
if (!CurrentTriggerData)
|
||||||
|
elog(WARN, "autoinc: triggers are not initialized");
|
||||||
|
if (TRIGGER_FIRED_FOR_STATEMENT(CurrentTriggerData->tg_event))
|
||||||
|
elog(WARN, "autoinc: can't process STATEMENT events");
|
||||||
|
if (TRIGGER_FIRED_AFTER(CurrentTriggerData->tg_event))
|
||||||
|
elog(WARN, "autoinc: must be fired before event");
|
||||||
|
|
||||||
|
if (TRIGGER_FIRED_BY_INSERT(CurrentTriggerData->tg_event))
|
||||||
|
rettuple = CurrentTriggerData->tg_trigtuple;
|
||||||
|
else if (TRIGGER_FIRED_BY_UPDATE(CurrentTriggerData->tg_event))
|
||||||
|
rettuple = CurrentTriggerData->tg_newtuple;
|
||||||
|
else
|
||||||
|
elog(WARN, "autoinc: can't process DELETE events");
|
||||||
|
|
||||||
|
rel = CurrentTriggerData->tg_relation;
|
||||||
|
relname = SPI_getrelname(rel);
|
||||||
|
|
||||||
|
trigger = CurrentTriggerData->tg_trigger;
|
||||||
|
|
||||||
|
nargs = trigger->tgnargs;
|
||||||
|
if (nargs <= 0 || nargs % 2 != 0)
|
||||||
|
elog(WARN, "autoinc (%s): even number gt 0 of arguments was expected", relname);
|
||||||
|
|
||||||
|
args = trigger->tgargs;
|
||||||
|
tupdesc = rel->rd_att;
|
||||||
|
|
||||||
|
CurrentTriggerData = NULL;
|
||||||
|
|
||||||
|
chattrs = (int *) palloc (nargs/2 * sizeof (int));
|
||||||
|
newvals = (Datum *) palloc (nargs/2 * sizeof (Datum));
|
||||||
|
|
||||||
|
for (i = 0; i < nargs; )
|
||||||
|
{
|
||||||
|
struct varlena *seqname;
|
||||||
|
int attnum = SPI_fnumber (tupdesc, args[i]);
|
||||||
|
int32 val;
|
||||||
|
|
||||||
|
if ( attnum < 0 )
|
||||||
|
elog(WARN, "autoinc (%s): there is no attribute %s", relname, args[i]);
|
||||||
|
if (SPI_gettypeid (tupdesc, attnum) != INT4OID)
|
||||||
|
elog(WARN, "autoinc (%s): attribute %s must be of INT4 type",
|
||||||
|
relname, args[i]);
|
||||||
|
|
||||||
|
val = DatumGetInt32 (SPI_getbinval (rettuple, tupdesc, attnum, &isnull));
|
||||||
|
|
||||||
|
if (!isnull && val != 0)
|
||||||
|
{
|
||||||
|
i += 2;
|
||||||
|
continue;
|
||||||
|
}
|
||||||
|
|
||||||
|
i++;
|
||||||
|
chattrs[chnattrs] = attnum;
|
||||||
|
seqname = textin (args[i]);
|
||||||
|
newvals[chnattrs] = Int32GetDatum (nextval (seqname));
|
||||||
|
if ( DatumGetInt32 (newvals[chnattrs]) == 0 )
|
||||||
|
newvals[chnattrs] = Int32GetDatum (nextval (seqname));
|
||||||
|
pfree (seqname);
|
||||||
|
chnattrs++;
|
||||||
|
i++;
|
||||||
|
}
|
||||||
|
|
||||||
|
if (chnattrs > 0)
|
||||||
|
{
|
||||||
|
rettuple = SPI_modifytuple (rel, rettuple, chnattrs, chattrs, newvals, NULL);
|
||||||
|
if ( rettuple == NULL )
|
||||||
|
elog (WARN, "autoinc (%s): %d returned by SPI_modifytuple",
|
||||||
|
relname, SPI_result);
|
||||||
|
}
|
||||||
|
|
||||||
|
pfree (relname);
|
||||||
|
pfree (chattrs);
|
||||||
|
pfree (newvals);
|
||||||
|
|
||||||
|
return (rettuple);
|
||||||
|
}
|
35
contrib/spi/autoinc.example
Normal file
35
contrib/spi/autoinc.example
Normal file
@ -0,0 +1,35 @@
|
|||||||
|
DROP SEQUENCE next_id;
|
||||||
|
DROP TABLE ids;
|
||||||
|
|
||||||
|
CREATE SEQUENCE next_id START -2 MINVALUE -2;
|
||||||
|
|
||||||
|
CREATE TABLE ids (
|
||||||
|
id int4,
|
||||||
|
idesc text
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TRIGGER ids_nextid
|
||||||
|
BEFORE INSERT OR UPDATE ON ids
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE PROCEDURE autoinc (id, next_id);
|
||||||
|
|
||||||
|
INSERT INTO ids VALUES (0, 'first (-2 ?)');
|
||||||
|
INSERT INTO ids VALUES (null, 'second (-1 ?)');
|
||||||
|
INSERT INTO ids(idesc) VALUES ('third (1 ?!)');
|
||||||
|
|
||||||
|
SELECT * FROM ids;
|
||||||
|
|
||||||
|
UPDATE ids SET id = null, idesc = 'first: -2 --> 2'
|
||||||
|
WHERE idesc = 'first (-2 ?)';
|
||||||
|
UPDATE ids SET id = 0, idesc = 'second: -1 --> 3'
|
||||||
|
WHERE id = -1;
|
||||||
|
UPDATE ids SET id = 4, idesc = 'third: 1 --> 4'
|
||||||
|
WHERE id = 1;
|
||||||
|
|
||||||
|
SELECT * FROM ids;
|
||||||
|
|
||||||
|
SELECT 'Wasn''t it 4 ?' as nextval, nextval ('next_id') as value;
|
||||||
|
|
||||||
|
insert into ids (idesc) select textcat (idesc, '. Copy.') from ids;
|
||||||
|
|
||||||
|
SELECT * FROM ids;
|
6
contrib/spi/autoinc.source
Normal file
6
contrib/spi/autoinc.source
Normal file
@ -0,0 +1,6 @@
|
|||||||
|
DROP FUNCTION autoinc();
|
||||||
|
|
||||||
|
CREATE FUNCTION autoinc()
|
||||||
|
RETURNS opaque
|
||||||
|
AS '_OBJWD_/autoinc_DLSUFFIX_'
|
||||||
|
LANGUAGE 'c';
|
@ -38,6 +38,8 @@ static EPlan *find_plan(char *ident, EPlan ** eplan, int *nplans);
|
|||||||
* 2. IF an delete affects tuple with stop_date eq INFINITY
|
* 2. IF an delete affects tuple with stop_date eq INFINITY
|
||||||
* then insert the same tuple with stop_date eq current date
|
* then insert the same tuple with stop_date eq current date
|
||||||
* ELSE - skip deletion of tuple.
|
* ELSE - skip deletion of tuple.
|
||||||
|
* 3. On INSERT, if start_date is NULL then current date will be
|
||||||
|
* inserted, if stop_date is NULL then INFINITY will be inserted.
|
||||||
*
|
*
|
||||||
* In CREATE TRIGGER you are to specify start_date and stop_date column
|
* In CREATE TRIGGER you are to specify start_date and stop_date column
|
||||||
* names:
|
* names:
|
||||||
@ -65,6 +67,7 @@ timetravel()
|
|||||||
EPlan *plan; /* prepared plan */
|
EPlan *plan; /* prepared plan */
|
||||||
char ident[2 * NAMEDATALEN];
|
char ident[2 * NAMEDATALEN];
|
||||||
bool isnull; /* to know is some column NULL or not */
|
bool isnull; /* to know is some column NULL or not */
|
||||||
|
bool isinsert = false;
|
||||||
int ret;
|
int ret;
|
||||||
int i;
|
int i;
|
||||||
|
|
||||||
@ -86,7 +89,7 @@ timetravel()
|
|||||||
|
|
||||||
/* INSERT ? */
|
/* INSERT ? */
|
||||||
if (TRIGGER_FIRED_BY_INSERT(CurrentTriggerData->tg_event))
|
if (TRIGGER_FIRED_BY_INSERT(CurrentTriggerData->tg_event))
|
||||||
elog (WARN, "timetravel: can't process INSERT event");
|
isinsert = true;
|
||||||
|
|
||||||
if (TRIGGER_FIRED_BY_UPDATE(CurrentTriggerData->tg_event))
|
if (TRIGGER_FIRED_BY_UPDATE(CurrentTriggerData->tg_event))
|
||||||
newtuple = CurrentTriggerData->tg_newtuple;
|
newtuple = CurrentTriggerData->tg_newtuple;
|
||||||
@ -133,6 +136,50 @@ timetravel()
|
|||||||
relname, args[0], args[1]);
|
relname, args[0], args[1]);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
if (isinsert) /* INSERT */
|
||||||
|
{
|
||||||
|
int chnattrs = 0;
|
||||||
|
int chattrs[2];
|
||||||
|
Datum newvals[2];
|
||||||
|
|
||||||
|
oldon = SPI_getbinval (trigtuple, tupdesc, attnum[0], &isnull);
|
||||||
|
if (isnull)
|
||||||
|
{
|
||||||
|
newvals[chnattrs] = GetCurrentAbsoluteTime ();
|
||||||
|
chattrs[chnattrs] = attnum[0];
|
||||||
|
chnattrs++;
|
||||||
|
}
|
||||||
|
|
||||||
|
oldoff = SPI_getbinval (trigtuple, tupdesc, attnum[1], &isnull);
|
||||||
|
if (isnull)
|
||||||
|
{
|
||||||
|
if ((chnattrs == 0 && DatumGetInt32 (oldon) >= NOEND_ABSTIME) ||
|
||||||
|
(chnattrs > 0 && DatumGetInt32 (newvals[0]) >= NOEND_ABSTIME))
|
||||||
|
elog (WARN, "timetravel (%s): %s ge %s",
|
||||||
|
relname, args[0], args[1]);
|
||||||
|
newvals[chnattrs] = NOEND_ABSTIME;
|
||||||
|
chattrs[chnattrs] = attnum[1];
|
||||||
|
chnattrs++;
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
if ((chnattrs == 0 && DatumGetInt32 (oldon) >=
|
||||||
|
DatumGetInt32 (oldoff)) ||
|
||||||
|
(chnattrs > 0 && DatumGetInt32 (newvals[0]) >=
|
||||||
|
DatumGetInt32 (oldoff)))
|
||||||
|
elog (WARN, "timetravel (%s): %s ge %s",
|
||||||
|
relname, args[0], args[1]);
|
||||||
|
}
|
||||||
|
|
||||||
|
pfree (relname);
|
||||||
|
if ( chnattrs <= 0 )
|
||||||
|
return (trigtuple);
|
||||||
|
|
||||||
|
rettuple = SPI_modifytuple (rel, trigtuple, chnattrs,
|
||||||
|
chattrs, newvals, NULL);
|
||||||
|
return (rettuple);
|
||||||
|
}
|
||||||
|
|
||||||
oldon = SPI_getbinval (trigtuple, tupdesc, attnum[0], &isnull);
|
oldon = SPI_getbinval (trigtuple, tupdesc, attnum[0], &isnull);
|
||||||
if (isnull)
|
if (isnull)
|
||||||
elog(WARN, "timetravel (%s): %s must be NOT NULL", relname, args[0]);
|
elog(WARN, "timetravel (%s): %s must be NOT NULL", relname, args[0]);
|
||||||
@ -140,7 +187,6 @@ timetravel()
|
|||||||
oldoff = SPI_getbinval (trigtuple, tupdesc, attnum[1], &isnull);
|
oldoff = SPI_getbinval (trigtuple, tupdesc, attnum[1], &isnull);
|
||||||
if (isnull)
|
if (isnull)
|
||||||
elog(WARN, "timetravel (%s): %s must be NOT NULL", relname, args[1]);
|
elog(WARN, "timetravel (%s): %s must be NOT NULL", relname, args[1]);
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* If DELETE/UPDATE of tuple with stop_date neq INFINITY
|
* If DELETE/UPDATE of tuple with stop_date neq INFINITY
|
||||||
* then say upper Executor to skip operation for this tuple
|
* then say upper Executor to skip operation for this tuple
|
||||||
|
@ -1,21 +1,26 @@
|
|||||||
drop table tttest;
|
drop table tttest;
|
||||||
|
|
||||||
create table tttest (
|
create table tttest (
|
||||||
price_id int4,
|
price_id int4,
|
||||||
price_val int4,
|
price_val int4,
|
||||||
price_on abstime default currabstime(),
|
price_on abstime,
|
||||||
price_off abstime default 'infinity'
|
price_off abstime
|
||||||
);
|
);
|
||||||
|
|
||||||
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
|
create trigger timetravel
|
||||||
before delete or update on tttest
|
before insert or delete or update on tttest
|
||||||
for each row
|
for each row
|
||||||
execute procedure
|
execute procedure
|
||||||
timetravel (price_on, price_off);
|
timetravel (price_on, price_off);
|
||||||
|
|
||||||
|
insert into tttest values (1, 1, null, null);
|
||||||
|
insert into tttest(price_id, price_val) values (2, 2);
|
||||||
|
insert into tttest(price_id, price_val,price_off) values (3, 3, 'infinity');
|
||||||
|
|
||||||
|
insert into tttest(price_id, price_val,price_off) values (3, 3,
|
||||||
|
datetime_abstime(datetime_mi_span('now', '100')));
|
||||||
|
insert into tttest(price_id, price_val,price_on) values (3, 3, 'infinity');
|
||||||
|
|
||||||
select * from tttest;
|
select * from tttest;
|
||||||
delete from tttest where price_id = 2;
|
delete from tttest where price_id = 2;
|
||||||
select * from tttest;
|
select * from tttest;
|
||||||
|
@ -1,12 +1,6 @@
|
|||||||
DROP FUNCTION currabstime();
|
|
||||||
DROP FUNCTION timetravel();
|
DROP FUNCTION timetravel();
|
||||||
DROP FUNCTION set_timetravel(name, int4);
|
DROP FUNCTION set_timetravel(name, int4);
|
||||||
|
|
||||||
CREATE FUNCTION currabstime()
|
|
||||||
RETURNS abstime
|
|
||||||
AS '_OBJWD_/timetravel_DLSUFFIX_'
|
|
||||||
LANGUAGE 'c';
|
|
||||||
|
|
||||||
CREATE FUNCTION timetravel()
|
CREATE FUNCTION timetravel()
|
||||||
RETURNS opaque
|
RETURNS opaque
|
||||||
AS '_OBJWD_/timetravel_DLSUFFIX_'
|
AS '_OBJWD_/timetravel_DLSUFFIX_'
|
||||||
|
Loading…
x
Reference in New Issue
Block a user