suppress_redundant_updates_trigger function.

This commit is contained in:
Andrew Dunstan 2008-11-03 20:17:21 +00:00
parent 4ff0468371
commit f0dae70431
7 changed files with 194 additions and 5 deletions

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.452 2008/11/03 17:51:12 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/func.sgml,v 1.453 2008/11/03 20:17:20 adunstan Exp $ -->
<chapter id="functions">
<title>Functions and Operators</title>
@ -12846,4 +12846,55 @@ SELECT (pg_stat_file('filename')).modification;
</sect1>
<sect1 id="functions-trigger">
<title>Trigger Functions</title>
<indexterm>
<primary>suppress_redundant_updates_trigger</primary>
</indexterm>
<para>
Currently <productname>PostgreSQL</> provides one built in trigger
function, <function>suppress_redundant_updates_trigger</>,
which will prevent any update
that does not actually change the data in the row from taking place, in
contrast to the normal behaviour which always performs the update
regardless of whether or not the data has changed. (This normal behaviour
makes updates run faster, since no checking is required, and is also
useful in certain cases.)
</para>
<para>
Ideally, you should normally avoid running updates that don't actually
change the data in the record. Redundant updates can cost considerable
unnecessary time, especially if there are lots of indexes to alter,
and space in dead rows that will eventually have to be vacuumed.
However, detecting such situations in client code is not
always easy, or even possible, and writing expressions to detect
them can be error-prone. An alternative is to use
<function>suppress_redundant_updates_trigger</>, which will skip
updates that don't change the data. You should use this with care,
however. The trigger takes a small but non-trivial time for each record,
so if most of the records affected by an update are actually changed,
use of this trigger will actually make the update run slower.
</para>
<para>
The <function>suppress_redundant_updates_trigger</> function can be
added to a table like this:
<programlisting>
CREATE TRIGGER z_min_update
BEFORE UPDATE ON tablename
FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
</programlisting>
In most cases, you would want to fire this trigger last for each row.
Bearing in mind that triggers fire in name order, you would then
choose a trigger name that comes after the name of any other trigger
you might have on the table.
</para>
<para>
For more information about creating triggers, see
<xref linkend="SQL-CREATETRIGGER">.
</para>
</sect1>
</chapter>

View File

@ -1,7 +1,7 @@
#
# Makefile for utils/adt
#
# $PostgreSQL: pgsql/src/backend/utils/adt/Makefile,v 1.69 2008/02/19 10:30:08 petere Exp $
# $PostgreSQL: pgsql/src/backend/utils/adt/Makefile,v 1.70 2008/11/03 20:17:20 adunstan Exp $
#
subdir = src/backend/utils/adt
@ -25,7 +25,7 @@ OBJS = acl.o arrayfuncs.o array_userfuncs.o arrayutils.o bool.o \
tid.o timestamp.o varbit.o varchar.o varlena.o version.o xid.o \
network.o mac.o inet_net_ntop.o inet_net_pton.o \
ri_triggers.o pg_lzcompress.o pg_locale.o formatting.o \
ascii.o quote.o pgstatfuncs.o encode.o dbsize.o genfile.o \
ascii.o quote.o pgstatfuncs.o encode.o dbsize.o genfile.o trigfuncs.o \
tsginidx.o tsgistidx.o tsquery.o tsquery_cleanup.o tsquery_gist.o \
tsquery_op.o tsquery_rewrite.o tsquery_util.o tsrank.o \
tsvector.o tsvector_op.o tsvector_parser.o \

View File

@ -0,0 +1,77 @@
/*-------------------------------------------------------------------------
*
* trigfuncs.c
* Builtin functions for useful trigger support.
*
*
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/backend/utils/adt/trigfuncs.c,v 1.1 2008/11/03 20:17:20 adunstan Exp $
*
*-------------------------------------------------------------------------
*/
#include "postgres.h"
#include "commands/trigger.h"
#include "access/htup.h"
/*
* suppress_redundant_updates_trigger
*
* This trigger function will inhibit an update from being done
* if the OLD and NEW records are identical.
*
*/
Datum
suppress_redundant_updates_trigger(PG_FUNCTION_ARGS)
{
TriggerData *trigdata = (TriggerData *) fcinfo->context;
HeapTuple newtuple, oldtuple, rettuple;
HeapTupleHeader newheader, oldheader;
/* make sure it's called as a trigger */
if (!CALLED_AS_TRIGGER(fcinfo))
elog(ERROR, (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED),
errmsg("suppress_redundant_updates_trigger: must be called as trigger")));
/* and that it's called on update */
if (! TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
ereport(ERROR, (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED),
errmsg( "suppress_redundant_updates_trigger: may only be called on update")));
/* and that it's called before update */
if (! TRIGGER_FIRED_BEFORE(trigdata->tg_event))
ereport(ERROR, (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED),
errmsg( "suppress_redundant_updates_trigger: may only be called before update")));
/* and that it's called for each row */
if (! TRIGGER_FIRED_FOR_ROW(trigdata->tg_event))
ereport(ERROR, (errcode(ERRCODE_E_R_I_E_TRIGGER_PROTOCOL_VIOLATED),
errmsg( "suppress_redundant_updates_trigger: may only be called for each row")));
/* get tuple data, set default return */
rettuple = newtuple = trigdata->tg_newtuple;
oldtuple = trigdata->tg_trigtuple;
newheader = newtuple->t_data;
oldheader = oldtuple->t_data;
if (newtuple->t_len == oldtuple->t_len &&
newheader->t_hoff == oldheader->t_hoff &&
(HeapTupleHeaderGetNatts(newheader) ==
HeapTupleHeaderGetNatts(oldheader) ) &&
((newheader->t_infomask & ~HEAP_XACT_MASK) ==
(oldheader->t_infomask & ~HEAP_XACT_MASK) )&&
memcmp(((char *)newheader) + offsetof(HeapTupleHeaderData, t_bits),
((char *)oldheader) + offsetof(HeapTupleHeaderData, t_bits),
newtuple->t_len - offsetof(HeapTupleHeaderData, t_bits)) == 0)
{
rettuple = NULL;
}
return PointerGetDatum(rettuple);
}

View File

@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.521 2008/11/03 17:51:13 tgl Exp $
* $PostgreSQL: pgsql/src/include/catalog/pg_proc.h,v 1.522 2008/11/03 20:17:20 adunstan Exp $
*
* NOTES
* The script catalog/genbki.sh reads this file and generates .bki
@ -1580,6 +1580,9 @@ DESCR("convert int8 to oid");
DATA(insert OID = 1288 ( int8 PGNSP PGUID 12 1 0 0 f f t f i 1 20 "26" _null_ _null_ _null_ oidtoi8 _null_ _null_ _null_ ));
DESCR("convert oid to int8");
DATA(insert OID = 1291 ( suppress_redundant_updates_trigger PGNSP PGUID 12 1 0 0 f f t f v 0 2279 "" _null_ _null_ _null_ suppress_redundant_updates_trigger _null_ _null_ _null_ ));
DESCR("trigger to suppress updates when new and old records match");
DATA(insert OID = 1292 ( tideq PGNSP PGUID 12 1 0 0 f f t f i 2 16 "27 27" _null_ _null_ _null_ tideq _null_ _null_ _null_ ));
DESCR("equal");
DATA(insert OID = 1293 ( currtid PGNSP PGUID 12 1 0 0 f f t f v 2 27 "26 27" _null_ _null_ _null_ currtid_byreloid _null_ _null_ _null_ ));
@ -2289,6 +2292,7 @@ DESCR("result type of a function");
DATA(insert OID = 1686 ( pg_get_keywords PGNSP PGUID 12 10 400 0 f f t t s 0 2249 "" "{25,18,25}" "{o,o,o}" "{word,catcode,catdesc}" pg_get_keywords _null_ _null_ _null_ ));
DESCR("list of SQL keywords");
DATA(insert OID = 1619 ( pg_typeof PGNSP PGUID 12 1 0 0 f f f f i 1 2206 "2276" _null_ _null_ _null_ pg_typeof _null_ _null_ _null_ ));
DESCR("returns the type of the argument");

View File

@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2008, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
* $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.325 2008/11/03 17:51:13 tgl Exp $
* $PostgreSQL: pgsql/src/include/utils/builtins.h,v 1.326 2008/11/03 20:17:20 adunstan Exp $
*
*-------------------------------------------------------------------------
*/
@ -900,6 +900,9 @@ extern Datum RI_FKey_setnull_upd(PG_FUNCTION_ARGS);
extern Datum RI_FKey_setdefault_del(PG_FUNCTION_ARGS);
extern Datum RI_FKey_setdefault_upd(PG_FUNCTION_ARGS);
/* trigfuncs.c */
extern Datum suppress_redundant_updates_trigger(PG_FUNCTION_ARGS);
/* encoding support functions */
extern Datum getdatabaseencoding(PG_FUNCTION_ARGS);
extern Datum database_character_set(PG_FUNCTION_ARGS);

View File

@ -537,3 +537,28 @@ NOTICE: row 1 not changed
NOTICE: row 2 not changed
DROP TABLE trigger_test;
DROP FUNCTION mytrigger();
-- minimal update trigger
CREATE TABLE min_updates_test (
f1 text,
f2 int,
f3 int);
INSERT INTO min_updates_test VALUES ('a',1,2),('b','2',null);
CREATE TRIGGER z_min_update
BEFORE UPDATE ON min_updates_test
FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
\set QUIET false
UPDATE min_updates_test SET f1 = f1;
UPDATE 0
UPDATE min_updates_test SET f2 = f2 + 1;
UPDATE 2
UPDATE min_updates_test SET f3 = 2 WHERE f3 is null;
UPDATE 1
\set QUIET true
SELECT * FROM min_updates_test;
f1 | f2 | f3
----+----+----
a | 2 | 2
b | 3 | 2
(2 rows)
DROP TABLE min_updates_test;

View File

@ -415,3 +415,32 @@ UPDATE trigger_test SET f3 = NULL;
DROP TABLE trigger_test;
DROP FUNCTION mytrigger();
-- minimal update trigger
CREATE TABLE min_updates_test (
f1 text,
f2 int,
f3 int);
INSERT INTO min_updates_test VALUES ('a',1,2),('b','2',null);
CREATE TRIGGER z_min_update
BEFORE UPDATE ON min_updates_test
FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
\set QUIET false
UPDATE min_updates_test SET f1 = f1;
UPDATE min_updates_test SET f2 = f2 + 1;
UPDATE min_updates_test SET f3 = 2 WHERE f3 is null;
\set QUIET true
SELECT * FROM min_updates_test;
DROP TABLE min_updates_test;