add audit trails

git-svn-id: svn+ssh://svn.gnucash.org/repo/gnucash/trunk@4491 57a11ea4-9604-0410-9ed3-97b8803252fd
This commit is contained in:
Linas Vepstas 2001-06-06 17:46:27 +00:00
parent 580912cc5a
commit cc3e162ba4
11 changed files with 256 additions and 69 deletions

View File

@ -9,5 +9,6 @@ base-autogen.c
check-autogen.c
functions.c
kvp-autogen.c
table-audit.c
table-create.c
table-drop.c

View File

@ -31,6 +31,7 @@ EXTRA_DIST = \
functions.sql \
kvp-objects.m4 \
table.m4 \
table-audit.sql \
table-create.sql \
table-drop.sql \
demo.c
@ -46,8 +47,8 @@ LDADD = ${GLIB_LIBS}
# Some of the required C files are built with the m4 pre-processor
# As a result, we need to manually specify dependencies, clean targets.
PostgresBackend.o: base-autogen.c table-create.c table-drop.c functions.c
PostgresBackend.lo: base-autogen.c table-create.c table-drop.c functions.c
PostgresBackend.o: base-autogen.c table-audit.c table-create.c table-drop.c functions.c
PostgresBackend.lo: base-autogen.c table-audit.c table-create.c table-drop.c functions.c
checkpoint.o: check-autogen.c
checkpoint.lo: check-autogen.c
@ -70,11 +71,11 @@ functions.c: functions.sql
cat functions.sql >> functions.c
echo \" >> functions.c
table-drop.c: table-drop.sql
echo \" > table-drop.c
echo "-- DO NOT EDIT THIS FILE. IT IS AUTOGENERATED." >> table-drop.c
cat table-drop.sql >> table-drop.c
echo \" >> table-drop.c
table-audit.c: table-audit.sql
echo \" > table-audit.c
echo "-- DO NOT EDIT THIS FILE. IT IS AUTOGENERATED." >> table-audit.c
cat table-audit.sql >> table-audit.c
echo \" >> table-audit.c
table-create.c: table-create.sql
echo \" > table-create.c
@ -82,6 +83,12 @@ table-create.c: table-create.sql
cat table-create.sql >> table-create.c
echo \" >> table-create.c
table-drop.c: table-drop.sql
echo \" > table-drop.c
echo "-- DO NOT EDIT THIS FILE. IT IS AUTOGENERATED." >> table-drop.c
cat table-drop.sql >> table-drop.c
echo \" >> table-drop.c
clean:
-rm -f base-autogen.c check-autogen.c kvp-autogen.c

View File

@ -216,6 +216,10 @@ get_version_cb (PGBackend *be, PGresult *result, int j, gpointer data)
#include "base-autogen.c"
static const char *table_audit_str =
#include "table-audit.c"
;
static const char *table_create_str =
#include "table-create.c"
;
@ -2875,6 +2879,8 @@ pgend_session_begin (GNCBook *sess, const char * sessionid,
*/
SEND_QUERY (be,table_create_str, );
FINISH_QUERY(be->connection);
SEND_QUERY (be,table_audit_str, );
FINISH_QUERY(be->connection);
SEND_QUERY (be,sql_functions_str, );
FINISH_QUERY(be->connection);
}

View File

@ -227,6 +227,9 @@ multi-user mode is fundamentally broken unless they are fixed.
Failure to do so causes the fill-out algorithm to pull in all
data.
-- Implement logging history/audit-trail in the SQL server.
(partly done; delete not implemented. ) Need indexes on kvp ...
-- if another user deletes a transaction, or an account, there is no way
for us to know. Thus, any sort of sync will probably (incorrectly)
add the deleted transaction back in. Question: what is the best way
@ -263,11 +266,6 @@ multi-user mode is fundamentally broken unless they are fixed.
note, however, that the file format needs to save the version number
...
-- Implement logging history/audit-trail in the SQL server.
i.e. save the old copies of stuff in log tables. Make the username
part of the logging scheme. Having 'audit trails' is considered
to be an important accounting feature.
-- let all attached clients receive update events via SQL LISTEN/NOTIFY
events.

View File

@ -13,6 +13,12 @@ store_one_only(split)
store_one_only(transaction)
store_one_only(price)
store_audit(account)
store_audit(modity)
store_audit(split)
store_audit(transaction)
store_audit(price)
compare_one_only(account)
compare_one_only(modity)
compare_one_only(split)

View File

@ -157,6 +157,15 @@ sqlBuild_Table (sqlBuilder *b, const char *tablename, sqlBuild_QType qt)
b->pval = stpcpy(b->pval, tablename);
b->pval = stpcpy(b->pval, " WHERE ");
break;
case SQL_DELETE:
b->ptag = stpcpy(b->ptag, "DELETE ");
b->pval = stpcpy(b->pval, " FROM ");
b->pval = stpcpy(b->pval, tablename);
b->pval = stpcpy(b->pval, " WHERE ");
break;
};
}
@ -198,6 +207,9 @@ sqlBuild_Set_Str (sqlBuilder *b, const char *tag, const char *val)
b->ptag = stpcpy(b->ptag, tag);
break;
case SQL_DELETE:
break;
default:
PERR ("mustn't happen");
};
@ -282,6 +294,9 @@ sqlBuild_Set_Int64 (sqlBuilder *b, const char *tag, gint64 nval)
b->ptag = stpcpy(b->ptag, tag);
break;
case SQL_DELETE:
break;
default:
PERR ("mustn't happen");
};
@ -312,6 +327,7 @@ sqlBuild_Where_Str (sqlBuilder *b, const char *tag, const char *val)
case SQL_UPDATE:
case SQL_SELECT:
case SQL_DELETE:
if (b->where_need_and) b->pval = stpcpy(b->pval, " AND ");
b->where_need_and = 1;
@ -365,6 +381,7 @@ sqlBuild_Query (sqlBuilder *b)
case SQL_UPDATE:
case SQL_SELECT:
case SQL_DELETE:
b->ptag = stpcpy(b->ptag, b->val_base);
b->ptag = stpcpy(b->ptag, ";");
break;

View File

@ -42,9 +42,10 @@
#include "guid.h"
typedef enum {
SQL_UPDATE=1,
SQL_INSERT,
SQL_SELECT
SQL_UPDATE = 'm', /* m == modify */
SQL_INSERT = 'a', /* a == add */
SQL_SELECT = 'q', /* q == query */
SQL_DELETE = 'd' /* d == drop, delete */
} sqlBuild_QType;
typedef struct _builder sqlBuilder;

View File

@ -11,6 +11,12 @@ store_one_only(kvp_numeric)
store_one_only(kvp_string)
store_one_only(kvp_guid)
store_audit(kvp_gint64)
store_audit(kvp_double)
store_audit(kvp_numeric)
store_audit(kvp_string)
store_audit(kvp_guid)
compare_one_only(kvp_gint64)
compare_one_only(kvp_double)
compare_one_only(kvp_numeric)

View File

@ -0,0 +1,134 @@
--
-- FILE:
-- table-audit.sql
--
-- FUNCTION:
-- Define the audit trail tables
-- Note that these tables must be kept manually in sync with those
-- in table-create.sql
--
-- HISTORY:
-- Copyright (C) 2000, 2001 Linas Vepstas
--
-- audit trail tables
-- The change may be 'a' -- add, 'd' -- delete/drop, 'm' -- modify
CREATE TABLE gncAuditTrail (
sessionGuid CHAR(32) NOT NULL, -- who changed it
date_changed DATETIME, -- when they changed it
change CHAR NOT NULL
);
-- would love to inherit, but can't because this wrecks the primary key
CREATE TABLE gncAccountTrail (
accountGuid CHAR(32) NOT NULL, -- override, not a primary key anymore
parentGuid CHAR(32) NOT NULL,
accountName TEXT NOT NULL CHECK (accountName <> ''),
accountCode TEXT,
description TEXT,
notes TEXT,
type TEXT NOT NULL,
commodity TEXT NOT NULL CHECK (commodity <>''),
version INT4 NOT NULL
) INHERITS (gncAuditTrail);
CREATE INDEX gncAccountTrail_account_idx ON gncAccountTrail (accountGuid);
CREATE TABLE gncCommodityTrail (
commodity TEXT NOT NULL, -- override, not a primary key anymore
fullname TEXT,
namespace TEXT NOT NULL,
mnemonic TEXT NOT NULL,
code TEXT,
fraction INT DEFAULT '100'
) INHERITS (gncAuditTrail);
CREATE INDEX gncCommodityTrail_commodity_idx ON gncCommodityTrail (commodity);
CREATE TABLE gncEntryTrail (
entryGuid CHAR(32) NOT NULL, -- override, not a primary key anymore
accountGuid CHAR(32) NOT NULL,
transGuid CHAR(32) NOT NULL,
memo TEXT,
action TEXT,
reconciled CHAR DEFAULT 'n',
date_reconciled DATETIME,
amount INT8 DEFAULT '0',
value INT8 DEFAULT '0'
) INHERITS (gncAuditTrail);
CREATE INDEX gncEntryTrail_entry_idx ON gncEntryTrail (entryGuid);
CREATE TABLE gncPriceTrail (
priceGuid CHAR(32) NOT NULL, -- override, not a primary key anymore
commodity TEXT NOT NULL CHECK (commodity <>''),
currency TEXT NOT NULL CHECK (commodity <>''),
time DATETIME,
source TEXT,
type TEXT,
valueNum INT8 DEFAULT '0',
valueDenom INT4 DEFAULT '100',
version INT4 NOT NULL
) INHERITS (gncAuditTrail);
CREATE INDEX gncPriceTrail_price_idx ON gncPriceTrail (priceGuid);
CREATE TABLE gncTransactionTrail (
transGuid CHAR(32) NOT NULL, -- override, not a primary key anymore
last_modified DATETIME DEFAULT 'NOW',
date_entered DATETIME,
date_posted DATETIME,
num TEXT,
description TEXT,
currency TEXT NOT NULL CHECK (currency <> ''),
version INT4 NOT NULL
) INHERITS (gncAuditTrail);
CREATE INDEX gncTransactionTrail_trans_idx ON gncTransactionTrail (transGuid);
CREATE TABLE gncKVPvalue_int64Trail (
iguid INT4,
ipath INT4,
type char(4),
data INT8
) INHERITS (gncAuditTrail);
CREATE TABLE gncKVPvalue_dblTrail (
iguid INT4,
ipath INT4,
type char(4),
data FLOAT8
) INHERITS (gncAuditTrail);
CREATE TABLE gncKVPvalue_numericTrail (
iguid INT4,
ipath INT4,
type char(4),
num INT8,
denom INT8
) INHERITS (gncAuditTrail);
CREATE TABLE gncKVPvalue_strTrail (
iguid INT4,
ipath INT4,
type char(4),
data TEXT
) INHERITS (gncAuditTrail);
CREATE TABLE gncKVPvalue_guidTrail (
iguid INT4,
ipath INT4,
type char(4),
data CHAR(32)
) INHERITS (gncAuditTrail);
CREATE TABLE gncKVPvalue_listTrail (
iguid INT4,
ipath INT4,
type char(4),
data TEXT[]
) INHERITS (gncAuditTrail);
-- end of file

View File

@ -9,6 +9,9 @@
-- TransactionP.h, AccountP.h, gnc-commodity.c
-- Please refer to the C files to get the right level of documentation.
--
-- If these tables are changed or added to, a correspionding
-- audit-trail table (in table-audit.sql) must be updated as well.
--
-- These tables are specifically designed for the
-- postgres database server, but are hopefull relatively portable.
--
@ -188,43 +191,4 @@ CREATE TABLE gncKVPvalue_list (
data TEXT[]
) INHERITS (gncKVPvalue);
-- audit trail tables
-- The change may be 'a' -- add, 'd' -- delete/drop, 'm' -- modify
CREATE TABLE gncAuditTrail (
sessionGuid CHAR(32) NOT NULL, -- who changed it
date_changed DATETIME, -- when they changed it
change CHAR NOT NULL
);
CREATE TABLE gncAccountTrail (
accountGuid CHAR(32) NOT NULL -- override, not a primary key anymore
) INHERITS (gncAccount,gncAuditTrail);
CREATE INDEX gncAccountTrail_account_idx ON gncAccountTrail (accountGuid);
CREATE TABLE gncCommodityTrail (
commodity TEXT NOT NULL -- override, not a primary key anymore
) INHERITS (gncCommodity,gncAuditTrail);
CREATE INDEX gncCommodityTrail_commodity_idx ON gncCommodityTrail (commodity);
CREATE TABLE gncEntryTrail (
entryGuid CHAR(32) NOT NULL -- override, not a primary key anymore
) INHERITS (gncEntry,gncAuditTrail);
CREATE INDEX gncEntryTrail_entry_idx ON gncEntryTrail (entryGuid);
CREATE TABLE gncPriceTrail (
priceGuid CHAR(32) NOT NULL -- override, not a primary key anymore
) INHERITS (gncPrice,gncAuditTrail);
CREATE INDEX gncPriceTrail_price_idx ON gncPriceTrail (priceGuid);
CREATE TABLE gncTransactionTrail (
transGuid CHAR(32) NOT NULL -- override, not a primary key anymore
) INHERITS (gncTransaction,gncAuditTrail);
CREATE INDEX gncTransactionTrail_trans_idx ON gncTransactionTrail (transGuid);
-- end of file

View File

@ -17,7 +17,6 @@ define(`account', `gncAccount, Account, Account,
accountGUID, KEY, GUID *, xaccAccountGetGUID(ptr),
')
define(`split', `gncEntry, Split, Split,
accountGUID, , GUID *, xaccAccountGetGUID(xaccSplitGetAccount(ptr)),
transGUID, , GUID *, xaccTransGetGUID(xaccSplitGetParent(ptr)),
@ -59,17 +58,6 @@ define(`modity', `gncCommodity, Commodity, gnc_commodity,
')
define(`checkpoint', `gncCheckpoint, Checkpoint, Checkpoint,
balance, , int64, ptr->balance,
cleared_balance, , int64, ptr->cleared_balance,
reconciled_balance, , int64, ptr->reconciled_balance,
date_start, , Timespec, ptr->date_start,
date_end, , Timespec, ptr->date_end,
commodity, , char *, ptr->commodity,
accountGuid, , GUID *, ptr->account_guid,
')
define(`price', `gncPrice, Price, GNCPrice,
commodity, , commod, gnc_commodity_get_unique_name(gnc_price_get_commodity(ptr)),
currency, , commod, gnc_commodity_get_unique_name(gnc_price_get_currency(ptr)),
@ -83,6 +71,17 @@ define(`price', `gncPrice, Price, GNCPrice,
')
define(`checkpoint', `gncCheckpoint, Checkpoint, Checkpoint,
balance, , int64, ptr->balance,
cleared_balance, , int64, ptr->cleared_balance,
reconciled_balance, , int64, ptr->reconciled_balance,
date_start, , Timespec, ptr->date_start,
date_end, , Timespec, ptr->date_end,
commodity, , char *, ptr->commodity,
accountGuid, , GUID *, ptr->account_guid,
')
define(`session', `gncSession, Session, void,
session_mode, , char *, pgendSessionGetMode(be),
hostname, , char *, pgendGetHostname(be),
@ -216,7 +215,7 @@ define(`store_one_only',
/* ------------------------------------------------------ */
/* This routine stores/updates one record in the database.
* It does not do any traversals, it does not lock.
* It just pokes the data in
* It just pokes the data in.
*/
static void
@ -303,9 +302,17 @@ pgendPutOne`'func_name($@)`'Only (PGBackend *be, xacc_type($@) *ptr)
ndiffs = pgendCompareOne`'func_name($@)`'Only (be, ptr);
/* update the record if there are differences ... */
if (0<ndiffs) pgendStoreOne`'func_name($@)`'Only (be, ptr, SQL_UPDATE);
if (0<ndiffs)
{
pgendStoreOne`'func_name($@)`'Only (be, ptr, SQL_UPDATE);
pgendStoreAudit`'func_name($@)`' (be, ptr, SQL_UPDATE);
}
/* insert the record if it doesnt exist */
if (0>ndiffs) pgendStoreOne`'func_name($@)`'Only (be, ptr, SQL_INSERT);
if (0>ndiffs)
{
pgendStoreOne`'func_name($@)`'Only (be, ptr, SQL_INSERT);
pgendStoreAudit`'func_name($@)`' (be, ptr, SQL_INSERT);
}
}
')
@ -340,5 +347,45 @@ pgend`'func_name($@)`'CompareVersion (PGBackend *be, xacc_type($@) *ptr)
')
define(`store_audit',
`
/* ------------------------------------------------------ */
/* This routine stores one autdit record in the database.
* It does not do any traversals, it does not lock.
* It just pokes the data in.
*/
static void
pgendStoreAudit`'func_name($@)`' (PGBackend *be,
xacc_type($@) *ptr,
sqlBuild_QType update)
{
const char *buf;
ENTER ("be=%p, xacc_type($@)=%p", be, ptr);
if (!be || !ptr) return;
/* build the sql query */
sqlBuild_Table (be->builder, "tablename($@)" "Trail", SQL_INSERT);
#define sqlBuild_Where_Str sqlBuild_Set_Str
#define sqlBuild_Where_GUID sqlBuild_Set_GUID
#define sqlBuild_Where_Int32 sqlBuild_Set_Int32
set_fields($@)
#undef sqlBuild_Where_Str
#undef sqlBuild_Where_GUID
#undef sqlBuild_Where_Int32
sqlBuild_Set_Str (be->builder, "date_changed", "NOW");
sqlBuild_Set_GUID (be->builder, "sessionGUID", be->sessionGuid);
sqlBuild_Set_Char (be->builder, "change", update);
buf = sqlBuild_Query (be->builder);
SEND_QUERY (be,buf, );
/* complete/commit the transaction, check the status */
FINISH_QUERY(be->connection);
LEAVE (" ");
}
')
divert
/* DO NOT EDIT THIS FILE -- it is autogenerated -- edit table.m4 instead */