Matthew Vanneck's Postgres patch:

Here's the HEAD patch we talked about on #gnucash.  Fixes the
   transaction handling for upgrades.  Also made some changes to
   newtables.h.  I fixed the multibook_support() upgrade too, as it
   was broken.  The only upgrade currently that does not work is the
   1.0.0 --> 1.1.1 upgrade.  That one doesn't work due to missing SQL
   for the gncGUIDcache table (which I asked about in a different
   message).  Perhaps we can remove that upgrade? 1.1.1 -> 1.2.1 ->
   1.3.1 -> 1.4.1 -> 1.5.1 all work normally now, though, with this
   patch.


git-svn-id: svn+ssh://svn.gnucash.org/repo/gnucash/trunk@9069 57a11ea4-9604-0410-9ed3-97b8803252fd
This commit is contained in:
Derek Atkins 2003-08-13 15:17:03 +00:00
parent 5961f42544
commit 2043343901
6 changed files with 126 additions and 68 deletions

View File

@ -1,3 +1,31 @@
2003-08-13 Matt Vanecek <mevanecek@yahoo.com>
* src/backend/postgres/PostgresBackend.c pgend_session_begin():
Moved the pgendUpdgradeDB() call outside of the SQL transaction,
because the upgrades performed each have their own separate
transaction.
* src/backend/postgres/newtables.h: A little bit of cleanup. Also
changed all the INSERTs to specify column names, to prevent
problems with column orders between old/new tables.
* src/backend/postgres/table-audit.sql: Moved bookGuid in
gncPriceTrail to be the second column.
* src/backend/postgres/table-create.sql: Moved bookGuid in
gncPrice to be the second column.
* src/backend/postgres/upgrade.c: (re)Added transaction control
to each upgrade function. Also, the following fixes came out
of regression testing:
- add_multiple_book_support(): Removed the "NOT NULL" from the
ADD COLUMN statements, and placed them in an ALTER TABLE...SET
NULL construct. The original is not supported in Postgresql
and fails to execute.
- Changed the stpcpy() to use g_strdup_printf() instead, for dynamic
query assembly.
- Made a few cosmetic changes to comparisons for readability.
2003-08-10 David Hampton <hampton@employees.org>
* src/gnome/gnc-splash.[ch]:

View File

@ -2204,10 +2204,10 @@ pgend_session_begin (QofBackend *backend,
qof_backend_set_error (&be->be, ERR_SQL_DB_BUSY);
return;
}
pgendUpgradeDB (be);
p = "COMMIT;\n";
SEND_QUERY (be,p, );
FINISH_QUERY(be->connection);
pgendUpgradeDB (be);
}
else
{

View File

@ -78,7 +78,7 @@ const char *drop_functions =
const char *alter_tables =
"ALTER TABLE gncVersion RENAME TO gncVersion_old;\n"
"ALTER TABLE gncTransaction RENAME TO gncTransaction_old;\n"
"ALTER TABLE gncEntry RENAME TO gncSplit_old;\n"
"ALTER TABLE gncEntry RENAME TO gncEntry_old;\n"
"ALTER TABLE gncCheckpoint RENAME TO gncCheckpoint_old;\n"
"ALTER TABLE gncPrice RENAME TO gncPrice_old;\n"
"ALTER TABLE gncSession RENAME TO gncSession_old;\n"
@ -148,6 +148,7 @@ const char *create_new_tables =
"-- \n"
"CREATE TABLE gncPrice ( \n"
" priceGuid CHAR(32) PRIMARY KEY, \n"
" bookGuid CHAR(32) NOT NULL, \n"
" commodity TEXT NOT NULL CHECK (commodity <>''), \n"
" currency TEXT NOT NULL CHECK (commodity <>''), \n"
" time TIMESTAMP WITH TIME ZONE, \n"
@ -155,8 +156,7 @@ const char *create_new_tables =
" type TEXT, \n"
" valueNum INT8 DEFAULT '0', \n"
" valueDenom INT4 DEFAULT '100', \n"
" version INT4 NOT NULL, \n"
" bookGuid CHAR(32) NOT NULL \n"
" version INT4 NOT NULL \n"
"); \n"
"-- \n"
"CREATE TABLE gncSession ( \n"
@ -191,34 +191,47 @@ const char *create_functions =
;
const char *insert_new_data =
"INSERT INTO gncVersion select * from gncVersion_old;\n"
"INSERT INTO gncTransaction select * from gncTransaction_old;\n"
"INSERT INTO gncSplit select * from gncSplit_old;\n"
"INSERT INTO gncCheckpoint select * from gncCheckpoint_old;\n"
"INSERT INTO gncPrice select * from gncPrice_old;\n"
"INSERT INTO gncSession select * from gncSession_old;\n"
"INSERT INTO gncKVPvalue_timespec select * from gncKVPvalue_timespec_old;\n"
"INSERT INTO gncAuditTrail SELECT * FROM gncAuditTrail_old;\n"
"INSERT INTO gncAccountTrail SELECT * FROM gncAccountTrail_old;\n"
"INSERT INTO gncBookTrail SELECT * FROM gncBookTrail_old;\n"
"INSERT INTO gncCommodityTrail SELECT * FROM gncCommodityTrail_old;\n"
"INSERT INTO gncKVPvalueTrail SELECT * FROM gncKVPvalueTrail_old;\n"
"INSERT INTO gncKVPvalue_int64Trail SELECT * FROM gncKVPvalue_int64Trail_old;\n"
"INSERT INTO gncKVPvalue_dblTrail SELECT * FROM gncKVPvalue_dblTrail_old;\n"
"INSERT INTO gncKVPvalue_numericTrail SELECT * FROM gncKVPvalue_numericTrail_old;\n"
"INSERT INTO gncKVPvalue_strTrail SELECT * FROM gncKVPvalue_strTrail_old;\n"
"INSERT INTO gncKVPvalue_guidTrail SELECT * FROM gncKVPvalue_guidTrail_old;\n"
"INSERT INTO gncKVPvalue_listTrail SELECT * FROM gncKVPvalue_listTrail_old;\n"
"INSERT INTO gncSplitTrail SELECT * FROM gncEntryTrail_old;\n"
"INSERT INTO gncPriceTrail SELECT * FROM gncPriceTrail_old;\n"
"INSERT INTO gncTransactionTrail SELECT * FROM gncTransactionTrail_old;\n"
"INSERT INTO gncKVPvalue_timespecTrail SELECT * FROM gncKVPvalue_timespecTrail_old;\n"
"INSERT INTO gncVersion (major, minor, rev, name, date) SELECT major, minor, rev, name, date from gncVersion_old; \n"
"INSERT INTO gncTransaction (transGuid,last_modified,date_entered,date_posted,num,description,currency,version,iguid) "
" SELECT transGuid,last_modified,date_entered,date_posted,num,description,currency,version,iguid FROM gncTransaction_old; \n"
"INSERT INTO gncSplit (splitGuid,accountGuid,transGuid,memo,action,reconciled,date_reconciled,amount,value,iguid) "
" SELECT entryGuid,accountGuid,transGuid,memo,action,reconciled,date_reconciled,amount,value,iguid from gncEntry_old;\n"
"INSERT INTO gncCheckpoint (accountGuid,date_start,date_end,commodity,type,balance,cleared_balance,reconciled_balance) "
" SELECT accountGuid,date_start,date_end,commodity,type,balance,cleared_balance,reconciled_balance FROM gncCheckpoint_old;\n"
"INSERT INTO gncPrice (priceGuid,commodity,currency,time,source,type,valueNum,valueDenom,version,bookGuid) "
" SELECT priceGuid,commodity,currency,time,source,type,valueNum,valueDenom,version,bookGuid FROM gncPrice_old;\n"
"INSERT INTO gncSession (sessionGuid,session_mode,hostname,login_name,gecos,time_on,time_off) "
" SELECT sessionGuid,session_mode,hostname,login_name,gecos,time_on,time_off FROM gncSession_old;\n"
"INSERT INTO gncKVPvalue_timespec (data) SELECT data FROM gncKVPvalue_timespec_old;\n"
"--\n"
"--INSERT INTO gncAuditTrail (sessionGuid,date_changed,change,objtype) "
"-- SELECT sessionGuid,date_changed,change,objtype FROM gncAuditTrail_old;\n"
"INSERT INTO gncAccountTrail (sessionGuid,date_changed,change,objtype,accountGuid,parentGuid,bookGuid,accountName,accountCode,description,type,commodity,version,iguid) "
" SELECT sessionGuid,date_changed,change,objtype,accountGuid,parentGuid,bookGuid,accountName,accountCode,description,type,commodity,version,iguid FROM gncAccountTrail_old;\n"
"INSERT INTO gncBookTrail (sessionGuid,date_changed,change,objtype,bookGuid,book_open,version,iguid) "
" SELECT sessionGuid,date_changed,change,objtype,bookGuid,book_open,version,iguid FROM gncBookTrail_old;\n"
"INSERT INTO gncCommodityTrail (sessionGuid,date_changed,change,objtype,commodity,fullname,namespace,mnemonic,code,fraction) "
" SELECT sessionGuid,date_changed,change,objtype,commodity,fullname,namespace,mnemonic,code,fraction FROM gncCommodityTrail_old;\n"
"INSERT INTO gncSplitTrail (sessionGuid,date_changed,change,objtype,splitGuid,accountGuid,transGuid,memo,action,reconciled,date_reconciled,amount,value,iguid) "
" SELECT sessionGuid,date_changed,change,objtype,entryGuid,accountGuid,transGuid,memo,action,reconciled,date_reconciled,amount,value,iguid from gncEntryTrail_old;\n"
"INSERT INTO gncPriceTrail (sessionGuid,date_changed,change,objtype,priceGuid,commodity,currency,time,source,type,valueNum,valueDenom,version,bookGuid) "
" SELECT sessionGuid,date_changed,change,objtype,priceGuid,commodity,currency,time,source,type,valueNum,valueDenom,version,bookGuid FROM gncPriceTrail_old;\n"
"INSERT INTO gncTransactionTrail (sessionGuid,date_changed,change,objtype,transGuid,last_modified,date_entered,date_posted,num,description,currency,version,iguid) "
" SELECT sessionGuid,date_changed,change,objtype,transGuid,last_modified,date_entered,date_posted,num,description,currency,version,iguid from gncTransactionTrail_old;\n"
"INSERT INTO gncKVPvalueTrail (sessionGuid,date_changed,change,objtype,iguid,ipath,type) SELECT sessionGuid,date_changed,change,objtype,iguid,ipath,type FROM gncKvpValueTrail_old;\n"
"INSERT INTO gncKVPvalue_int64Trail (sessionGuid,date_changed,change,objtype,iguid,ipath,type,data) SELECT sessionGuid,date_changed,change,objtype,iguid,ipath,type,data FROM gncKVPvalue_int64trail_old;\n"
"INSERT INTO gncKVPvalue_dblTrail (sessionGuid,date_changed,change,objtype,iguid,ipath,type,data) SELECT sessionGuid,date_changed,change,objtype,iguid,ipath,type,data FROM gncKVPvalue_dbltrail_old;\n"
"INSERT INTO gncKVPvalue_numericTrail (sessionGuid,date_changed,change,objtype,iguid,ipath,type,num,denom) SELECT sessionGuid,date_changed,change,objtype,iguid,ipath,type,num,denom FROM gncKVPvalue_numericTrail_old;\n"
"INSERT INTO gncKVPvalue_strTrail (sessionGuid,date_changed,change,objtype,iguid,ipath,type,data) SELECT sessionGuid,date_changed,change,objtype,iguid,ipath,type,data FROM gncKVPvalue_strtrail_old;\n"
"INSERT INTO gncKVPvalue_guidTrail (sessionGuid,date_changed,change,objtype,iguid,ipath,type,data) SELECT sessionGuid,date_changed,change,objtype,iguid,ipath,type,data FROM gncKVPvalue_guidtrail_old;\n"
"INSERT INTO gncKVPvalue_timespecTrail (sessionGuid,date_changed,change,objtype,iguid,ipath,type,data) SELECT sessionGuid,date_changed,change,objtype,iguid,ipath,type,data FROM gncKVPvalue_timespectrail_old;\n"
"INSERT INTO gncKVPvalue_listTrail (sessionGuid,date_changed,change,objtype,iguid,ipath,type,data) SELECT sessionGuid,date_changed,change,objtype,iguid,ipath,type,data FROM gncKVPvalue_listtrail_old;\n"
;
const char *drop_old_tables =
"DROP TABLE gncVersion_old;\n"
"DROP TABLE gncTransaction_old;\n"
"DROP TABLE gncSplit_old;\n"
"DROP TABLE gncEntry_old;\n"
"DROP TABLE gncCheckpoint_old;\n"
"DROP TABLE gncPrice_old;\n"
"DROP TABLE gncSession_old;\n"

View File

@ -80,6 +80,7 @@
" \n"
"CREATE TABLE gncPriceTrail ( \n"
" priceGuid CHAR(32) NOT NULL, -- override, not a primary key anymore \n"
" bookGuid CHAR(32) NOT NULL, \n"
" commodity TEXT NOT NULL CHECK (commodity <>''), \n"
" currency TEXT NOT NULL CHECK (commodity <>''), \n"
" time TIMESTAMP WITH TIME ZONE, \n"
@ -87,8 +88,7 @@
" type TEXT, \n"
" valueNum INT8 DEFAULT '0', \n"
" valueDenom INT4 DEFAULT '100', \n"
" version INT4 NOT NULL, \n"
" bookGuid CHAR(32) NOT NULL \n"
" version INT4 NOT NULL \n"
") INHERITS (gncAuditTrail); \n"
" \n"
"CREATE TABLE gncTransactionTrail ( \n"

View File

@ -122,6 +122,7 @@
"-- in units of 'currency' \n"
"CREATE TABLE gncPrice ( \n"
" priceGuid CHAR(32) PRIMARY KEY, \n"
" bookGuid CHAR(32) NOT NULL, \n"
" commodity TEXT NOT NULL CHECK (commodity <>''), \n"
" currency TEXT NOT NULL CHECK (commodity <>''), \n"
" time TIMESTAMP WITH TIME ZONE, \n"
@ -129,8 +130,7 @@
" type TEXT, \n"
" valueNum INT8 DEFAULT '0', \n"
" valueDenom INT4 DEFAULT '100', \n"
" version INT4 NOT NULL, \n"
" bookGuid CHAR(32) NOT NULL \n"
" version INT4 NOT NULL \n"
"); \n"
" \n"
" \n"

View File

@ -27,6 +27,7 @@
#include <libpq-fe.h>
#include <stdlib.h>
#include <glib.h>
#include "PostgresBackend.h"
#include "messages.h"
@ -135,7 +136,8 @@ put_iguid_in_tables (PGBackend *be)
{
char *p, buff[200];
guint iguid;
execQuery(be, "BEGIN");
p = "LOCK TABLE gncAccount IN ACCESS EXCLUSIVE MODE;\n"
"LOCK TABLE gncEntry IN ACCESS EXCLUSIVE MODE;\n"
"LOCK TABLE gncTransaction IN ACCESS EXCLUSIVE MODE;\n"
@ -220,6 +222,8 @@ put_iguid_in_tables (PGBackend *be)
" (1,1,1,'End Put iGUID in Main Tables');";
SEND_QUERY (be,p, );
FINISH_QUERY(be->connection);
execQuery(be, "COMMIT");
}
/* ============================================================= */
@ -228,6 +232,8 @@ static void
fix_reconciled_balance_func (PGBackend *be)
{
char *p;
execQuery(be, "BEGIN");
p = "LOCK TABLE gncVersion IN ACCESS EXCLUSIVE MODE;\n "
"INSERT INTO gncVersion (major,minor,rev,name) VALUES \n"
@ -259,6 +265,7 @@ fix_reconciled_balance_func (PGBackend *be)
" (1,2,1,'End Fix gncSubtotalReconedBalance');";
SEND_QUERY (be,p, );
FINISH_QUERY(be->connection);
execQuery(be, "COMMIT");
}
/* ============================================================= */
@ -268,6 +275,8 @@ add_kvp_timespec_tables (PGBackend *be)
{
char *p;
execQuery(be, "BEGIN");
p = "LOCK TABLE gncVersion IN ACCESS EXCLUSIVE MODE;\n "
"INSERT INTO gncVersion (major,minor,rev,name) VALUES \n"
" (1,3,0,'Start Add kvp_timespec tables');";
@ -293,6 +302,8 @@ add_kvp_timespec_tables (PGBackend *be)
" (1,3,1,'End Add kvp_timespec tables');";
SEND_QUERY (be,p, );
FINISH_QUERY(be->connection);
execQuery(be, "COMMIT");
}
/* ============================================================= */
@ -300,9 +311,12 @@ add_kvp_timespec_tables (PGBackend *be)
static void
add_multiple_book_support (PGBackend *be)
{
char buff[4000];
char *p;
gchar *buff;
gchar *p;
const gchar *guid;
execQuery(be, "BEGIN");
p = "LOCK TABLE gncAccount IN ACCESS EXCLUSIVE MODE;\n"
"LOCK TABLE gncAccountTrail IN ACCESS EXCLUSIVE MODE;\n"
"LOCK TABLE gncPrice IN ACCESS EXCLUSIVE MODE;\n"
@ -332,45 +346,48 @@ add_multiple_book_support (PGBackend *be)
SEND_QUERY (be,p, );
FINISH_QUERY(be->connection);
p = "ALTER TABLE gncAccount ADD COLUMN bookGuid CHAR(32) NOT NULL;\n"
"ALTER TABLE gncAccountTrail ADD COLUMN bookGuid CHAR(32) NOT NULL;\n"
"ALTER TABLE gncPrice ADD COLUMN bookGuid CHAR(32) NOT NULL;\n"
"ALTER TABLE gncPriceTrail ADD COLUMN bookGuid CHAR(32) NOT NULL;\n";
p = "ALTER TABLE gncAccount ADD COLUMN bookGuid CHAR(32);\n"
"ALTER TABLE gncAccountTrail ADD COLUMN bookGuid CHAR(32);\n"
"ALTER TABLE gncPrice ADD COLUMN bookGuid CHAR(32);\n"
"ALTER TABLE gncPriceTrail ADD COLUMN bookGuid CHAR(32);\n";
SEND_QUERY (be,p, );
FINISH_QUERY(be->connection);
p = buff;
p = stpcpy (p, "UPDATE gncAccount SET bookGuid = '");
p = guid_to_string_buff (qof_book_get_guid (be->book), p);
p = stpcpy (p, "';\n");
p = stpcpy (p, "UPDATE gncAccountTrail SET bookGuid = '");
p = guid_to_string_buff (qof_book_get_guid (be->book), p);
p = stpcpy (p, "';\n");
guid = guid_to_string(qof_book_get_guid(pgendGetBook(be)));
PINFO("guid = %s", guid);
buff = g_strdup_printf("UPDATE gncAccount SET bookGuid = '%s';\n"
"UPDATE gncAccountTrail SET bookGuid = '%s';\n"
"UPDATE gncPrice SET bookGuid = '%s';\n"
"UPDATE gncPriceTrail SET bookGuid = '%s';\n",
guid, guid, guid, guid);
SEND_QUERY (be,buff, );
FINISH_QUERY(be->connection);
p = buff;
p = stpcpy (p, "UPDATE gncPrice SET bookGuid = '");
p = guid_to_string_buff (qof_book_get_guid (be->book), p);
p = stpcpy (p, "';\n");
p = stpcpy (p, "UPDATE gncPriceTrail SET bookGuid = '");
p = guid_to_string_buff (qof_book_get_guid (be->book), p);
p = stpcpy (p, "';\n");
g_free(buff);
buff = g_strdup_printf("INSERT INTO gncBook (bookGuid, book_open, version, iguid) "
"VALUES ('%s', 'y', 1, 0);", guid);
SEND_QUERY (be,buff, );
FINISH_QUERY(be->connection);
p = buff;
p = stpcpy (p, "INSERT INTO gncBook (bookGuid, book_open, version, iguid) "
"VALUES ('");
p = guid_to_string_buff (qof_book_get_guid (be->book), p);
p = stpcpy (p, "', 'y', 1, 0);");
SEND_QUERY (be,buff, );
g_free(buff);
p = "ALTER TABLE gncAccount ALTER COLUMN bookGuid SET NOT NULL;\n"
"ALTER TABLE gncAccountTrail ALTER COLUMN bookGuid SET NOT NULL;\n"
"ALTER TABLE gncPrice ALTER COLUMN bookGuid SET NOT NULL;\n"
"ALTER TABLE gncPriceTrail ALTER COLUMN bookGuid SET NOT NULL;\n";
SEND_QUERY (be,p, );
FINISH_QUERY(be->connection);
p = "INSERT INTO gncVersion (major,minor,rev,name) VALUES \n"
" (1,4,1,'End Add multiple book support');";
SEND_QUERY (be,p, );
FINISH_QUERY(be->connection);
execQuery(be, "COMMIT");
}
static void
@ -387,7 +404,7 @@ add_timezone_support(PGBackend *be) {
}
if (execQuery(be, "BEGIN WORK;\n") != PGRES_COMMAND_OK) {
LEAVE("Failed at BEGIN WORK (2)");
LEAVE("Failed at BEGIN WORK (1)");
return;
}
@ -407,7 +424,7 @@ add_timezone_support(PGBackend *be) {
/* execQuery sets the backend error message if one occurs */
if (execQuery(be, "BEGIN WORK") != PGRES_COMMAND_OK) {
LEAVE("Failed at BEGIN WORK");
LEAVE("Failed at BEGIN WORK (2)");
return;
}
@ -482,7 +499,7 @@ add_timezone_support(PGBackend *be) {
}
/* Everything worked thus far, commit it now! */
execQuery(be, "COMMIT WORK;\n");
execQuery(be, "COMMIT WORK");
/* Clean up crud, Drop the _old tables, vacuum to
* bring the indexes into use.
@ -551,22 +568,22 @@ pgendUpgradeDB (PGBackend *be)
vers = pgendGetVersion(be);
/* start adding features to bring database up to date */
if (1 == vers.major)
if (vers.major == 1)
{
/* version 1.1.0 add iguids to transaction and entry tables */
if (1 > vers.minor)
if (vers.minor < 1)
{
put_iguid_in_tables(be);
}
if (2 > vers.minor)
if (vers.minor < 2)
{
fix_reconciled_balance_func (be);
}
if (3 > vers.minor)
if (vers.minor < 3)
{
add_kvp_timespec_tables (be);
}
if (4 > vers.minor)
if (vers.minor < 4)
{
add_multiple_book_support (be);
}