diff --git a/src/engine/sql/PostgresBackend.h b/src/engine/sql/PostgresBackend.h index ac33f25cef..4d283ca774 100644 --- a/src/engine/sql/PostgresBackend.h +++ b/src/engine/sql/PostgresBackend.h @@ -92,7 +92,8 @@ Backend * pgendNew (void); typedef struct _checkpoint { const GUID *account_guid; const char * commodity; - Timespec datetime; + Timespec date_start; + Timespec date_end; gint64 balance; gint64 cleared_balance; gint64 reconciled_balance; diff --git a/src/engine/sql/checkpoint.c b/src/engine/sql/checkpoint.c index 077588764b..cb9f9bf0d8 100644 --- a/src/engine/sql/checkpoint.c +++ b/src/engine/sql/checkpoint.c @@ -48,19 +48,21 @@ static short module = MOD_BACKEND; static void pgendAccountRecomputeAllCheckpoints (PGBackend *be, const GUID *acct_guid) { - Timespec this_ts, prev_ts; + Timespec this_ts, next_ts; GMemChunk *chunk; GList *node, *checkpoints = NULL; PGresult *result; Checkpoint *bp; char *p; int i, nrows, nsplits; + int nck; Account *acc; - const char *commodity_name; + const char *commodity_name, *guid_string; if (!be) return; ENTER("be=%p", be); + guid_string = guid_to_string (acct_guid); acc = xaccLookupEntity (acct_guid, GNC_ID_ACCOUNT); commodity_name = gnc_commodity_get_unique_name (xaccAccountGetCommodity(acc)); @@ -85,100 +87,88 @@ pgendAccountRecomputeAllCheckpoints (PGBackend *be, const GUID *acct_guid) SEND_QUERY (be,be->buff, ); FINISH_QUERY(be->connection); - /* and now, fetch *all* of the splits in this account */ - p = be->buff; *p = 0; - p = stpcpy (p, "SELECT gncEntry.amount AS amount, " - " gncEntry.reconciled AS reconciled," - " gncTransaction.date_posted AS date_posted " - "FROM gncEntry, gncTransaction " - "WHERE gncEntry.transGuid = gncTransaction.transGuid " - "AND accountGuid='"); - p = guid_to_string_buff (acct_guid, p); - p = stpcpy (p, "' ORDER BY gncTransaction.date_posted ASC;"); - SEND_QUERY (be,be->buff, ); - - /* malloc a new checkpoint, set it to the dawn of AD time ... */ + /* malloc a new checkpoint, set it to the dawn of unix time ... */ bp = g_chunk_new0 (Checkpoint, chunk); checkpoints = g_list_prepend (checkpoints, bp); - this_ts = gnc_iso8601_to_timespec_local ("1970-04-15 08:35:46.00"); - bp->datetime = this_ts; + this_ts = gnc_iso8601_to_timespec_local ("1903-01-02 08:35:46.00"); + bp->date_start = this_ts; bp->account_guid = acct_guid; bp->commodity = commodity_name; - /* malloc a new checkpoint ... */ - nsplits = 0; - bp = g_chunk_new0 (Checkpoint, chunk); - checkpoints = g_list_prepend (checkpoints, bp); - bp->account_guid = acct_guid; - bp->commodity = commodity_name; + /* loop over entries, creating a set of evenly-spaced checkpoints */ + nck = MIN_CHECKPOINT_COUNT; + while (1) + { + p = be->buff; *p = 0; + p = stpcpy (p, "SELECT gncTransaction.date_posted" + " FROM gncTransaction, gncEntry" + " WHERE" + " gncEntry.transguid = gncTransaction.transguid AND" + " gncEntry.accountguid='"); + p = stpcpy (p, guid_string); + p = stpcpy (p, "'" + " ORDER BY gncTransaction.date_posted ASC" + " LIMIT 2 OFFSET "); + p += sprintf (p, "%d", nck); + p = stpcpy (p, ";"); + SEND_QUERY (be,be->buff, ); - /* start adding up balances */ - i=0; nrows=0; - do { - GET_RESULTS (be->connection, result); - { - int j, jrows; - int ncols = PQnfields (result); - jrows = PQntuples (result); - nrows += jrows; - PINFO ("query result %d has %d rows and %d cols", - i, nrows, ncols); - - for (j=0; jconnection, result); { - gint64 amt; - char recn; - - /* lets see if its time to start a new checkpoint */ - /* look for splits that occur at least ten seconds apart */ - prev_ts = this_ts; - prev_ts.tv_sec += 10; - this_ts = gnc_iso8601_to_timespec_local (DB_GET_VAL("date_posted",j)); - if ((MIN_CHECKPOINT_COUNT < nsplits) && - (timespec_cmp (&prev_ts, &this_ts) < 0)) - { - Checkpoint *next_bp; + int j, jrows; + int ncols = PQnfields (result); + jrows = PQntuples (result); + PINFO ("query result %d has %d rows and %d cols", + i, jrows, ncols); - /* Set checkpoint five seconds back. This is safe, - * because we looked for a 10 second gap above */ - this_ts.tv_sec -= 5; - bp->datetime = this_ts; - - /* and now, build a new checkpoint */ - nsplits = 0; - next_bp = g_chunk_new0 (Checkpoint, chunk); - checkpoints = g_list_prepend (checkpoints, next_bp); - *next_bp = *bp; - bp = next_bp; - bp->account_guid = acct_guid; - bp->commodity = commodity_name; - } - nsplits ++; - - /* accumulate balances */ - amt = atoll (DB_GET_VAL("amount",j)); - recn = (DB_GET_VAL("reconciled",j))[0]; - bp->balance += amt; - if (NREC != recn) - { - bp->cleared_balance += amt; - } - if (YREC == recn) - { - bp->reconciled_balance += amt; + if (0 == jrows) { + FINISH_QUERY(be->connection); + goto done; } + if (0 == i) this_ts = gnc_iso8601_to_timespec_local (DB_GET_VAL("date_posted",0)); + if (2 == jrows) { + next_ts = gnc_iso8601_to_timespec_local (DB_GET_VAL("date_posted",1)); + } else if (1 == i) { + next_ts = gnc_iso8601_to_timespec_local (DB_GET_VAL("date_posted",0)); + } + PQclear (result); + i++; } - } + } while (result); - PQclear (result); - i++; - } while (result); - - /* set the timestamp on the final checkpoint, - * 8 seconds past the very last split */ - this_ts.tv_sec += 8; - bp->datetime = this_ts; + /* lets see if its time to start a new checkpoint */ + /* look for splits that occur at least ten seconds apart */ + this_ts.tv_sec += 10; + if (timespec_cmp (&this_ts, &next_ts) < 0) + { + /* Set checkpoint five seconds back. This is safe, + * because we looked for a 10 second gap above */ + this_ts.tv_sec -= 5; + bp->date_end = this_ts; + + /* and build a new checkpoint */ + bp = g_chunk_new0 (Checkpoint, chunk); + checkpoints = g_list_prepend (checkpoints, bp); + bp->date_start = this_ts; + bp->account_guid = acct_guid; + bp->commodity = commodity_name; + nck += MIN_CHECKPOINT_COUNT; + } + else + { + /* step one at a time until we find at least a ten-second gap */ + nck += 1; + } + } + +done: + + /* set the timestamp on the final checkpoint into the distant future */ + this_ts = gnc_iso8601_to_timespec_local ("2038-01-02 08:35:46.00"); + bp->date_end = this_ts; /* now store the checkpoints */ for (node = checkpoints; node; node = node->next) @@ -190,10 +180,21 @@ pgendAccountRecomputeAllCheckpoints (PGBackend *be, const GUID *acct_guid) g_list_free (checkpoints); g_mem_chunk_destroy (chunk); - p = "COMMIT WORK;"; - SEND_QUERY (be,p, ); + /* finally, let the sql server do the heavy lifting of computing the + * subtotal balances */ + p = be->buff; *p = 0; + p = stpcpy (p, "UPDATE gncCheckpoint SET " + " balance = (gncsubtotalbalance (accountGuid, date_start, date_end ))," + " cleared_balance = (gncsubtotalclearedbalance (accountGuid, date_start, date_end ))," + " reconciled_balance = (gncsubtotalreconedbalance (accountGuid, date_start, date_end )) " + "WHERE accountGuid='"); + p = stpcpy (p, guid_string); + p = stpcpy (p, "'; "); + p = stpcpy (p, "COMMIT WORK;"); + SEND_QUERY (be,be->buff, ); FINISH_QUERY(be->connection); + g_free ((gpointer) guid_string); } /* ============================================================= */ @@ -230,6 +231,7 @@ pgendAccountGetCheckpoint (PGBackend *be, Checkpoint *chk) if (!be || !chk) return; ENTER("be=%p", be); +/* XXX this is totally wrong */ /* create the query we need */ p = be->buff; *p = 0; p = stpcpy (p, "SELECT balance, cleared_balance, reconciled_balance " @@ -239,7 +241,7 @@ pgendAccountGetCheckpoint (PGBackend *be, Checkpoint *chk) p = stpcpy (p, "' AND commodity='"); p = stpcpy (p, chk->commodity); p = stpcpy (p, "' AND date_start <'"); - p = gnc_timespec_to_iso8601_buff (chk->datetime, p); + p = gnc_timespec_to_iso8601_buff (chk->date_start, p); p = stpcpy (p, "' ORDER BY date_start DESC LIMIT 1;"); SEND_QUERY (be,be->buff, ); @@ -287,8 +289,9 @@ pgendGroupGetAllCheckpoints (PGBackend *be, AccountGroup*grp) if (!be || !grp) return; ENTER("be=%p", be); - chk.datetime.tv_sec = time(0); - chk.datetime.tv_nsec = 0; +/* XXX hack alert this is all wrong */ + chk.date_start.tv_sec = time(0); + chk.date_start.tv_nsec = 0; acclist = xaccGroupGetSubAccounts (grp); diff --git a/src/engine/sql/design.txt b/src/engine/sql/design.txt index 7f85375c3e..1f8e329df3 100644 --- a/src/engine/sql/design.txt +++ b/src/engine/sql/design.txt @@ -86,14 +86,17 @@ m4 macros --------- Some of the code is auto-gen'ed from m4 macros. This mostly just simplifies some rather repetitive, cut-n-paste code that's identical -from function to function. If you can think of a better way ... +from function to function. If you can think of a better way, let me +know. String escapes -------------- -Any string is valid; the builder.c routine sqlBuilder_escape() converts +The GUI and the engine support all any characters within a string; however, +in SQL some characters are reserved. These reserved characters are escaped +in builder.c routine sqlBuilder_escape() before storage. These convert single-quotes and backslashes to escaped quotes & backslashes to prevent -sql corruption. +SQL corruption. KVP frames @@ -135,8 +138,26 @@ are not using NTP for time synchronization; or, e.g. if one machine failed to have daylight-savings time set correctly: its transactions would be an hour newer/older than the others, leading to bad updates). +Prices need to have version numbers added. + Balances -------- +The GUI displays a running balance in the register display. When the +engine has a copy of all data, this is easy to compute. However, if +the dataset is large, then we don't want the engine to have a copy of +all of the data; we want to leave the bulk of it in the database. +However, that presents a problem for computing the running balances. +We could store a running balance with each journal entry. However, +this has the potential of making balance updates slow: potentially +a lot of entries would need to be updated. + +As an alternate technique, we store running balances in a set of +'checkpoints', each showing a subtotal balance for a date interval. +Unfortunately, there is quite a bit of machinery that needs to be +implemented in order to make this effective. + + +In order Account balances can be computed using advanced SQL statements. The basic idea looks like this: @@ -149,7 +170,7 @@ works. Note that this statement updates *all* checkpoints for the indicated accountguid. UPDATE gnccheckpoint - SET balance = (SELECT sum(gncentry.valuenum) + SET balance = (SELECT sum(gncentry.amount) FROM gncentry, gnctransaction WHERE gncentry.accountguid = gnccheckpoint.accountguid AND @@ -162,7 +183,7 @@ Its a better to create a function that does the computation: CREATE FUNCTION gncsubtotal (char(32), datetime, datetime) RETURNS numeric - AS 'SELECT sum(gncentry.valuenum) + AS 'SELECT sum(gncentry.amount) FROM gncentry, gnctransaction WHERE gncentry.accountguid = $1 AND @@ -173,24 +194,40 @@ Its a better to create a function that does the computation: and use it like this: UPDATE gnccheckpoint - SET balance = (gncsubtotal ('4c9cad7be044559705988c63ea7affc5', - date_xpoint, date_xpoint + 360 )) - WHERE accountguid='111'; + SET balance = (gncsubtotal (accountGuid, date_start, date_end )) + WHERE accountguid='4c9cad7be044559705988c63ea7affc5'; +We can find dates for creating checkpoints like so: +SELECT gnctransaction.date_posted + FROM gnctransaction, gncentry + WHERE + gncentry.transguid = gnctransaction.transguid AND + gncentry.accountguid='4c9cad7be044559705988c63ea7affc5' + ORDER BY gnctransaction.date_posted ASC + LIMIT 2 OFFSET 10; + ---------------------------- nothing but junk below/test demo -CREATE FUNCTION gncsubtotal (char(32), datetime, datetime, int8) - RETURNS numeric - AS 'SELECT $4 * sum(gncentry.valuenum numeric/ gncentry.valuedenom -numeric ) - FROM gncentry, gnctransaction - WHERE - gncentry.accountguid = $1 AND - gncentry.transguid = gnctransaction.transguid AND - gnctransaction.date_posted BETWEEN $2 AND $3' - LANGUAGE 'sql'; + UPDATE gnccheckpoint + SET balance = (gncsubtotalbalance (accountGuid, + date_start, date_start+360)), + cleared_balance = (gncsubtotalclearedbalance (accountguid, + date_start, date_start+360)), + reconciled_balance = (gncsubtotalreconedbalance (accountguid, + date_start, date_start+360)) + WHERE accountguid='4c9cad7be044559705988c63ea7affc5'; + + UPDATE gnccheckpoint + SET cleared_balance = (gncsubtotalclearedbalance (accountguid, + date_start, date_start+360)); + + UPDATE gnccheckpoint + SET reconciled_balance = (gncsubtotalreconedbalance (accountguid, + date_start, date_start+360)); + + UPDATE gnccheckpoint @@ -208,3 +245,4 @@ WHERE accountguid='111'; INSERT INTO gnccheckpoint (accountguid, date_xpoint, commodity, balance) VALUES (111, '1997-01-01 12:00:00-05', 'FLOOP::GLOP', 0); + diff --git a/src/engine/sql/table-create.sql b/src/engine/sql/table-create.sql index ea859dac25..912c086abd 100644 --- a/src/engine/sql/table-create.sql +++ b/src/engine/sql/table-create.sql @@ -36,8 +36,6 @@ CREATE TABLE gncCommodity ( -- Account structure -- parentGUID points to parent account -- guid. There is no supports for Groups in this schema. -- (there seems to be no strong need to have groups in the DB.) --- --- hack alert -- add kvp frames, CREATE TABLE gncAccount ( accountGuid CHAR(32) PRIMARY KEY, @@ -54,8 +52,6 @@ CREATE TABLE gncAccount ( -- CREATE INDEX gncAccount_pg_idx ON gncAccount (parentGuid); -- CREATE INDEX gncAccount_ch_idx ON gncAccount (childrenGuid); --- hack alert -- add kvp frames ?? - CREATE TABLE gncTransaction ( transGuid CHAR(32) PRIMARY KEY, last_modified DATETIME DEFAULT 'NOW', @@ -93,12 +89,15 @@ CREATE INDEX gncEntry_trn_idx ON gncEntry (transGuid); -- in multiple currencies. -- (e.g. report stock account balances in shares of stock, -- and in dollars) +-- the 'type' field indicates what type of balance this is +-- (simple, FIFO, LIFO, or other accounting method) CREATE TABLE gncCheckpoint ( accountGuid CHAR(32) NOT NULL, date_start DATETIME NOT NULL, --- date_end DATETIME NOT NULL, + date_end DATETIME NOT NULL, commodity TEXT NOT NULL CHECK (commodity <>''), + type TEXT DEFAULT 'simple', balance INT8 DEFAULT '0', cleared_balance INT8 DEFAULT '0', reconciled_balance INT8 DEFAULT '0', @@ -188,3 +187,37 @@ CREATE TABLE gncKVPvalue_list ( data TEXT[] ) INHERITS (gncKVPvalue); +-- utility functions to compute chackpoint balance subtotals + +CREATE FUNCTION gncSubtotalBalance (CHAR(32), DATETIME, DATETIME) + RETURNS NUMERIC + AS 'SELECT sum(gncentry.value) + FROM gncentry, gnctransaction + WHERE + gncentry.accountguid = $1 AND + gncentry.transguid = gnctransaction.transguid AND + gnctransaction.date_posted BETWEEN $2 AND $3' + LANGUAGE 'sql'; + +CREATE FUNCTION gncSubtotalClearedBalance (char(32), DATETIME, DATETIME) + RETURNS NUMERIC + AS 'SELECT sum(gncentry.value) + FROM gncentry, gnctransaction + WHERE + gncentry.accountguid = $1 AND + gncentry.transguid = gnctransaction.transguid AND + gnctransaction.date_posted BETWEEN $2 AND $3 AND + gncentry.reconciled <> \\'n\\'' + LANGUAGE 'sql'; + +CREATE FUNCTION gncSubtotalReconedBalance (CHAR(32), DATETIME, DATETIME) + RETURNS NUMERIC + AS 'SELECT sum(gncentry.value) + FROM gncentry, gnctransaction + WHERE + gncentry.accountguid = $1 AND + gncentry.transguid = gnctransaction.transguid AND + gnctransaction.date_posted BETWEEN $2 AND $3 AND + gncentry.reconciled = \\'y\\'' + LANGUAGE 'sql'; + diff --git a/src/engine/sql/table.m4 b/src/engine/sql/table.m4 index 2395367790..9e5f0985d1 100644 --- a/src/engine/sql/table.m4 +++ b/src/engine/sql/table.m4 @@ -63,7 +63,8 @@ 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->datetime, + date_start, , Timespec, ptr->date_start, + date_end, , Timespec, ptr->date_end, commodity, , char *, ptr->commodity, accountGuid, , GUID *, ptr->account_guid, ')