836 lines
47 KiB
C#
836 lines
47 KiB
C#
using System;
|
|
using System.Threading.Tasks;
|
|
using Microsoft.Extensions.Logging;
|
|
using Microsoft.EntityFrameworkCore;
|
|
using AyaNova.Models;
|
|
|
|
namespace AyaNova.Util
|
|
{
|
|
|
|
//Key generator controller
|
|
public static class AySchema
|
|
{
|
|
private static ILogger log;
|
|
private static AyContext ct;
|
|
|
|
|
|
|
|
|
|
/////////////////////////////////////////////////////////////////
|
|
/////////// CHANGE THIS ON NEW SCHEMA UPDATE ////////////////////
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
private const int DESIRED_SCHEMA_LEVEL = 15;
|
|
|
|
internal const long EXPECTED_COLUMN_COUNT = 500;
|
|
internal const long EXPECTED_INDEX_COUNT = 145;
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
/////////////////////////////////////////////////////////////////
|
|
|
|
|
|
/*
|
|
|
|
MAXIMUM POSTGRES OBJECT NAME LENGTH: 63 CHARACTERS
|
|
CURRENCY: use decimal(19,4)
|
|
//DATA TYPES .net to postgres map
|
|
//http://www.npgsql.org/doc/types/basic.html
|
|
|
|
|
|
HOW TO INDEX
|
|
|
|
AyaNova does a lot of name fetching so any tables that contain a lot of columns in addition to the name will benefit from a compound index on (id,name)
|
|
|
|
Other indexes should be created with care and after a huge load and integration test periodically look for unused indexes and see how they are performing
|
|
HOW TO FIND SHITTY INDEXES: https://gist.github.com/jberkus/6b1bcaf7724dfc2a54f3
|
|
see core-performance.txt for the relevant queries to view this info
|
|
|
|
***************************** WARNING: Be careful here, if a standard field is hideable and also it's DB SCHEMA is set to NON NULLABLE then the CLIENT end needs to set a default
|
|
***************************** Otherwise the hidden field can't be set and the object can't be saved EVER
|
|
|
|
|
|
|
|
*/
|
|
#region unused index query
|
|
/*
|
|
COPY taken 2020-05-21 from link above "jerkus" :)
|
|
|
|
WITH table_scans as (
|
|
SELECT relid,
|
|
tables.idx_scan + tables.seq_scan as all_scans,
|
|
( tables.n_tup_ins + tables.n_tup_upd + tables.n_tup_del ) as writes,
|
|
pg_relation_size(relid) as table_size
|
|
FROM pg_stat_user_tables as tables
|
|
),
|
|
all_writes as (
|
|
SELECT sum(writes) as total_writes
|
|
FROM table_scans
|
|
),
|
|
indexes as (
|
|
SELECT idx_stat.relid, idx_stat.indexrelid,
|
|
idx_stat.schemaname, idx_stat.relname as tablename,
|
|
idx_stat.indexrelname as indexname,
|
|
idx_stat.idx_scan,
|
|
pg_relation_size(idx_stat.indexrelid) as index_bytes,
|
|
indexdef ~* 'USING btree' AS idx_is_btree
|
|
FROM pg_stat_user_indexes as idx_stat
|
|
JOIN pg_index
|
|
USING (indexrelid)
|
|
JOIN pg_indexes as indexes
|
|
ON idx_stat.schemaname = indexes.schemaname
|
|
AND idx_stat.relname = indexes.tablename
|
|
AND idx_stat.indexrelname = indexes.indexname
|
|
WHERE pg_index.indisunique = FALSE
|
|
),
|
|
index_ratios AS (
|
|
SELECT schemaname, tablename, indexname,
|
|
idx_scan, all_scans,
|
|
round(( CASE WHEN all_scans = 0 THEN 0.0::NUMERIC
|
|
ELSE idx_scan::NUMERIC/all_scans * 100 END),2) as index_scan_pct,
|
|
writes,
|
|
round((CASE WHEN writes = 0 THEN idx_scan::NUMERIC ELSE idx_scan::NUMERIC/writes END),2)
|
|
as scans_per_write,
|
|
pg_size_pretty(index_bytes) as index_size,
|
|
pg_size_pretty(table_size) as table_size,
|
|
idx_is_btree, index_bytes
|
|
FROM indexes
|
|
JOIN table_scans
|
|
USING (relid)
|
|
),
|
|
index_groups AS (
|
|
SELECT 'Never Used Indexes' as reason, *, 1 as grp
|
|
FROM index_ratios
|
|
WHERE
|
|
idx_scan = 0
|
|
and idx_is_btree
|
|
UNION ALL
|
|
SELECT 'Low Scans, High Writes' as reason, *, 2 as grp
|
|
FROM index_ratios
|
|
WHERE
|
|
scans_per_write <= 1
|
|
and index_scan_pct < 10
|
|
and idx_scan > 0
|
|
and writes > 100
|
|
and idx_is_btree
|
|
UNION ALL
|
|
SELECT 'Seldom Used Large Indexes' as reason, *, 3 as grp
|
|
FROM index_ratios
|
|
WHERE
|
|
index_scan_pct < 5
|
|
and scans_per_write > 1
|
|
and idx_scan > 0
|
|
and idx_is_btree
|
|
and index_bytes > 100000000
|
|
UNION ALL
|
|
SELECT 'High-Write Large Non-Btree' as reason, index_ratios.*, 4 as grp
|
|
FROM index_ratios, all_writes
|
|
WHERE
|
|
( writes::NUMERIC / ( total_writes + 1 ) ) > 0.02
|
|
AND NOT idx_is_btree
|
|
AND index_bytes > 100000000
|
|
ORDER BY grp, index_bytes DESC )
|
|
SELECT reason, schemaname, tablename, indexname,
|
|
index_scan_pct, scans_per_write, index_size, table_size
|
|
FROM index_groups;
|
|
*/
|
|
#endregion
|
|
|
|
static int startingSchema = -1;
|
|
public static int currentSchema = -1;
|
|
|
|
|
|
|
|
//check and update schema
|
|
public static async Task CheckAndUpdateAsync(AyContext context, ILogger logger)
|
|
{
|
|
ct = context;
|
|
log = logger;
|
|
|
|
//Check if ayschemaversion table exists
|
|
bool aySchemaVersionExists = false;
|
|
|
|
using (var command = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
command.CommandText = "SELECT * FROM information_schema.tables WHERE table_name = 'aschemaversion'";
|
|
await ct.Database.OpenConnectionAsync();
|
|
using (var result = await command.ExecuteReaderAsync())
|
|
{
|
|
if (result.HasRows)
|
|
{
|
|
aySchemaVersionExists = true;
|
|
}
|
|
await ct.Database.CloseConnectionAsync();
|
|
}
|
|
}
|
|
|
|
|
|
//Create schema table (v1)
|
|
if (!aySchemaVersionExists)
|
|
{
|
|
log.LogDebug("aschemaversion table not found, creating now");
|
|
//nope, no schema table, add it now and set to v1
|
|
using (var cm = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
await ct.Database.OpenConnectionAsync();
|
|
cm.CommandText = "CREATE TABLE aschemaversion (schema INTEGER NOT NULL, id text not null);";
|
|
await cm.ExecuteNonQueryAsync();
|
|
|
|
cm.CommandText = $"insert into aschemaversion (schema, id) values (1,'{AyaNova.Util.Hasher.GenerateSalt()}');";
|
|
await cm.ExecuteNonQueryAsync();
|
|
|
|
await ct.Database.CloseConnectionAsync();
|
|
startingSchema = 1;
|
|
currentSchema = 1;
|
|
}
|
|
}
|
|
else
|
|
{
|
|
//get current schema level
|
|
using (var cm = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
log.LogDebug("Fetching current schema version");
|
|
cm.CommandText = "SELECT schema FROM aschemaversion;";
|
|
await ct.Database.OpenConnectionAsync();
|
|
using (var result = await cm.ExecuteReaderAsync())
|
|
{
|
|
if (result.HasRows)
|
|
{
|
|
await result.ReadAsync();
|
|
currentSchema = startingSchema = result.GetInt32(0);
|
|
await ct.Database.CloseConnectionAsync();
|
|
log.LogDebug("AyaNova schema version is " + currentSchema.ToString());
|
|
}
|
|
else
|
|
{
|
|
await ct.Database.CloseConnectionAsync();
|
|
throw new System.Exception("AyaNova->AySchema->CheckAndUpdate: Error reading schema version");
|
|
}
|
|
}
|
|
}
|
|
}
|
|
|
|
//Bail early no update?
|
|
if (currentSchema == DESIRED_SCHEMA_LEVEL)
|
|
{
|
|
log.LogDebug("Current schema is at required schema version " + currentSchema.ToString());
|
|
return;
|
|
}
|
|
|
|
log.LogInformation("AyaNova database needs to be updated from schema version {0} to version {1}", currentSchema, DESIRED_SCHEMA_LEVEL);
|
|
|
|
//************* SCHEMA UPDATES ******************
|
|
|
|
//////////////////////////////////////////////////
|
|
// FOUNDATIONAL TABLES
|
|
//
|
|
if (currentSchema < 2)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//create global biz settings table
|
|
await ExecQueryAsync("CREATE TABLE aglobalbizsettings (id integer NOT NULL PRIMARY KEY, " +
|
|
"searchcasesensitiveonly bool default false)");
|
|
|
|
//create global ops BACKUP settings table
|
|
await ExecQueryAsync("CREATE TABLE aglobalopsbackupsettings (id integer NOT NULL PRIMARY KEY, active bool not null, " +
|
|
"backuptime timestamp, backupsetstokeep int, backupattachments bool)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE aglobalopsnotificationsettings (id integer NOT NULL PRIMARY KEY, smtpdeliveryactive bool not null, " +
|
|
"smtpserveraddress text, smtpaccount text, smtppassword text, connectionsecurity integer not null default 0, smtpserverport integer, notifyfromaddress text, ayanovaserverurl text)");
|
|
|
|
//create aevent biz event log table
|
|
await ExecQueryAsync("CREATE TABLE aevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created timestamp not null, userid bigint not null," +
|
|
"ayid bigint not null, ayatype integer not null, ayevent integer not null, textra varchar(255))");
|
|
//INDEX: Most selective first as there is more unique ID's than unique types
|
|
await ExecQueryAsync("CREATE INDEX aevent_typeid_idx ON aevent (ayid, ayatype);");
|
|
|
|
//TODO: this may be a very low used index, revisit it down the road
|
|
await ExecQueryAsync("CREATE INDEX aevent_userid_idx ON aevent (userid);");
|
|
|
|
|
|
//METRICS TABLES
|
|
//One minute metrics
|
|
await ExecQueryAsync("CREATE TABLE ametricmm (t timestamp not null, allocated bigint,workingset bigint,privatebytes bigint,cpu double precision)");
|
|
//One day metrics
|
|
await ExecQueryAsync("CREATE TABLE ametricdd (t timestamp not null, dbtotalsize bigint, attachmentfilesize bigint, attachmentfilecount bigint, attachmentfilesavailablespace bigint, utilityfilesize bigint, utilityfilecount bigint, utilityfilesavailablespace bigint)");
|
|
|
|
|
|
//SEARCH TABLES
|
|
await ExecQueryAsync("CREATE TABLE asearchdictionary (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, word varchar(255) not null unique)");
|
|
//Must be unique and also this is hit a *lot* during searches and also indexing
|
|
//On actual testing this index is never used so for now removing it, perhaps it is a case of bad data but I tested with Huge dataset
|
|
//await ExecQueryAsync("CREATE UNIQUE INDEX asearchdictionary_word_idx ON asearchdictionary (word);");
|
|
|
|
//search key
|
|
await ExecQueryAsync("CREATE TABLE asearchkey (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, wordid bigint not null REFERENCES asearchdictionary (id), objectid bigint not null, objecttype integer not null)");
|
|
//INDEX: Most selective first as there is more unique ID's than unique types
|
|
//to take advantage of this always query with where objectid=xx and objecttype=yy order
|
|
|
|
//Only delete would use this, but, likely not needed as it's not in a loop
|
|
//await ExecQueryAsync("CREATE INDEX asearchkey_typeid_idx ON asearchkey (objectid, objecttype );");
|
|
|
|
//This is what is needed during Searching
|
|
//search does a lot of hits on searchkey looking for the wordid and optionally objecttype
|
|
//In testing this did not pan out, in fact it was much faster to search both with and without a objecttype specified to simply have an index on wordid
|
|
// await ExecQueryAsync("CREATE INDEX asearchkey_wordid_otype_idx ON asearchkey (wordid, objecttype);");
|
|
await ExecQueryAsync("CREATE INDEX asearchkey_wordid_idx ON asearchkey (wordid);");
|
|
|
|
//Search indexing stored procedure
|
|
await ExecQueryAsync(@"
|
|
CREATE OR REPLACE PROCEDURE public.aydosearchindex(
|
|
wordlist text[],
|
|
ayobjectid bigint,
|
|
ayobjecttype integer,
|
|
cleanfirst boolean)
|
|
LANGUAGE 'plpgsql'
|
|
|
|
AS $BODY$DECLARE
|
|
s text;
|
|
wordid bigint;
|
|
BEGIN
|
|
IF ayobjectid=0 THEN
|
|
RAISE EXCEPTION 'Bad object id --> %', ayobjectid;
|
|
END IF;
|
|
|
|
IF ayobjecttype=0 THEN
|
|
RAISE EXCEPTION 'Bad object type --> %', ayobjecttype;
|
|
END IF;
|
|
|
|
IF cleanfirst=true THEN
|
|
delete from asearchkey where objectid=ayobjectid and objecttype=ayobjecttype;
|
|
END IF;
|
|
|
|
FOREACH s IN ARRAY wordlist
|
|
LOOP
|
|
SELECT id INTO wordid FROM asearchdictionary WHERE word = s;
|
|
IF wordid IS NULL THEN
|
|
insert into asearchdictionary (word) values(s) on conflict (word) do update set word=excluded.word returning id into wordid;
|
|
insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
|
ELSE
|
|
insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
|
END IF;
|
|
END LOOP;
|
|
END;
|
|
$BODY$;
|
|
");
|
|
|
|
//create translation text tables
|
|
await ExecQueryAsync("CREATE TABLE atranslation (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null, stock bool, cjkindex bool default false)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE atranslationitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, translationid bigint not null REFERENCES atranslation (id), key text not null, display text not null)");
|
|
//This is not a well used index, not sure what it's point is
|
|
// await ExecQueryAsync("CREATE INDEX atranslationitem_translationid_key_display_idx ON atranslationitem (translationid,key, display)");
|
|
|
|
//Load the default TRANSLATIONS
|
|
await AyaNova.Biz.PrimeData.PrimeTranslations();
|
|
|
|
|
|
//Add user table
|
|
await ExecQueryAsync("CREATE TABLE auser (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, active bool not null, name text not null unique, " +
|
|
"lastlogin timestamp, login text not null unique, password text not null, salt text not null, roles integer not null, currentauthtoken text, " +
|
|
"dlkey text, dlkeyexpire timestamp, passwordresetcode text, passwordresetcodeexpire timestamp, usertype integer not null, employeenumber text, notes text, customerid bigint, " +
|
|
"headofficeid bigint, vendorid bigint, wiki text, customfields text, tags varchar(255) ARRAY)");
|
|
|
|
//Index for name fetching
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX auser_name_id_idx ON auser (id, name);");
|
|
|
|
//Add user options table
|
|
await ExecQueryAsync("CREATE TABLE auseroptions (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " +
|
|
"userid bigint not null REFERENCES auser (id), translationid bigint not null REFERENCES atranslation (id), languageoverride text, timezoneoverride text, " +
|
|
"currencyname text, hour12 bool not null, emailaddress text, phone1 text, phone2 text, phone3 text, uicolor varchar(12) not null default '#000000', mapurltemplate text)");
|
|
|
|
|
|
//Prime the db with the default SuperUser account
|
|
await AyaNova.Biz.PrimeData.PrimeSuperUserAccount(ct);
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//LICENSE table
|
|
if (currentSchema < 3)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//Add user table
|
|
await ExecQueryAsync("CREATE TABLE alicense (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, dbid text, key text not null)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//WIDGET table for development testing
|
|
if (currentSchema < 4)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//Add widget table
|
|
//id, text, longtext, boolean, currency,
|
|
await ExecQueryAsync("CREATE TABLE awidget (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, serial bigint generated by default as identity not null," +
|
|
"startdate timestamp, enddate timestamp, dollaramount decimal(19,4), active bool, usertype int4, count integer," +
|
|
"notes text, userid bigint, wiki text, customfields text, tags varchar(255) ARRAY)");
|
|
|
|
//TEST TEST TEST ONLY FOR DEVELOPMENT TESTING TO ENSURE UNIQUENESS
|
|
//exec("CREATE UNIQUE INDEX awidget_serial_idx ON awidget (serial);");
|
|
|
|
|
|
//Compound index for name fetching
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX awidget_name_id_idx ON awidget (id, name);");
|
|
|
|
//Index for tags
|
|
await ExecQueryAsync("CREATE INDEX awidget_tags ON AWIDGET using GIN(tags)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// FileAttachment table
|
|
if (currentSchema < 5)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE afileattachment (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " +
|
|
"attachtoobjectid bigint not null, attachtoobjecttype integer not null, " +
|
|
"storedfilename text not null, displayfilename text not null, contenttype text, lastmodified timestamp not null, notes text, exists bool not null, size bigint not null)");
|
|
|
|
//index required for ops that need to check if file already in db (delete, count refs etc)
|
|
//LOOKAT: isn't this useless without the ID as well or is that not fetched?
|
|
await ExecQueryAsync("CREATE INDEX afileattachment_storedfilename_idx ON afileattachment (storedfilename);");
|
|
|
|
//index for the common issue of checking if an object has an attachment and retrieving them
|
|
//note always query (where clause) in this same order for best performance
|
|
await ExecQueryAsync("CREATE INDEX afileattachment_typeid_idx ON afileattachment (attachtoobjectid, attachtoobjecttype );");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// OPS LRO tables
|
|
if (currentSchema < 6)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE aopsjob (gid uuid PRIMARY KEY, name text not null, created timestamp not null, exclusive bool not null, " +
|
|
"startafter timestamp not null, jobtype integer not null, subtype integer, objectid bigint, objecttype integer, jobstatus integer not null, jobinfo text)");
|
|
await ExecQueryAsync("CREATE TABLE aopsjoblog (gid uuid PRIMARY KEY, jobid uuid not null, created timestamp not null, statustext text not null)");
|
|
// REFERENCES aopsjob (gid) took this out to allow for internal job logs with guid.empty and no parent job as there seems no need anyway
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//DATAFILTER / DATALISTTEMPLATE tables
|
|
if (currentSchema < 7)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE adatalistview (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, userid bigint not null, name text not null unique, public bool not null," +
|
|
"listkey varchar(255) not null, listview text)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// TAGS repository
|
|
if (currentSchema < 8)
|
|
{
|
|
LogUpdateMessage(log);
|
|
await ExecQueryAsync("CREATE TABLE atag (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, refcount bigint not null)");
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//FORMCUSTOM table
|
|
if (currentSchema < 9)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE aformcustom (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " +
|
|
"formkey varchar(255) not null, template text, UNIQUE(formkey))");
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//PICKLISTTEMPLATE table
|
|
if (currentSchema < 10)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE apicklisttemplate (id integer NOT NULL PRIMARY KEY, " +
|
|
"template text)");
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//MULTIPLE BIZ OBJECT tables
|
|
if (currentSchema < 11)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//MEMO
|
|
await ExecQueryAsync("CREATE TABLE amemo (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY, " +
|
|
"sent timestamp not null, viewed bool default false, replied bool default false, fromid bigint not null REFERENCES auser(id), toid bigint not null REFERENCES auser(id) )");
|
|
await ExecQueryAsync("CREATE INDEX amemo_tags ON amemo using GIN(tags)");
|
|
|
|
//CUSTOMER
|
|
await ExecQueryAsync("CREATE TABLE acustomer (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY, " +
|
|
"webaddress text, popupnotes text, billheadoffice bool, technotes text, accountnumber text, usesbanking bool, contractexpires timestamp null, " +
|
|
"phone1 text, phone2 text, phone3 text, phone4 text, phone5 text, emailaddress text, " +
|
|
"postaddress text, postcity text, postregion text, postcountry text, postcode text, address text, city text, region text, country text, latitude decimal(8,6), longitude decimal(9,6))");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX acustomer_name_id_idx ON acustomer (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX acustomer_tags ON acustomer using GIN(tags)");
|
|
await ExecQueryAsync("ALTER TABLE auser add FOREIGN KEY (customerid) REFERENCES acustomer(id)");
|
|
|
|
|
|
//CUSTOMER NOTES
|
|
await ExecQueryAsync("CREATE TABLE acustomernote (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " +
|
|
"customerid bigint not null REFERENCES acustomer(id), userid bigint not null REFERENCES auser(id), " +
|
|
"notedate timestamp not null, notes text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE INDEX acustomernote_tags ON acustomernote using GIN(tags)");
|
|
|
|
//CONTRACT
|
|
await ExecQueryAsync("CREATE TABLE acontract (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX acontract_name_id_idx ON acontract (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX acontract_tags ON acontract using GIN(tags)");
|
|
|
|
await ExecQueryAsync("ALTER TABLE acustomer add column contractid bigint null references acontract");
|
|
|
|
|
|
//HEADOFFICE
|
|
await ExecQueryAsync("CREATE TABLE aheadoffice (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY," +
|
|
"webaddress text, accountnumber text, usesbanking bool, contractexpires timestamp null, contractid bigint null references acontract(id), " +
|
|
"phone1 text, phone2 text, phone3 text, phone4 text, phone5 text, emailaddress text, " +
|
|
"postaddress text, postcity text, postregion text, postcountry text, postcode text, address text, city text, region text, country text, latitude decimal(8,6), longitude decimal(9,6)" +
|
|
|
|
" )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aheadoffice_name_id_idx ON aheadoffice (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aheadoffice_tags ON aheadoffice using GIN(tags)");
|
|
await ExecQueryAsync("ALTER TABLE acustomer add column headofficeid bigint null references aheadoffice");
|
|
await ExecQueryAsync("ALTER TABLE auser add FOREIGN KEY (headofficeid) REFERENCES aheadoffice(id)");
|
|
|
|
|
|
//LOANUNIT
|
|
await ExecQueryAsync("CREATE TABLE aloanunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aloanunit_name_id_idx ON aloanunit (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aloanunit_tags ON aloanunit using GIN(tags)");
|
|
|
|
//PART
|
|
await ExecQueryAsync("CREATE TABLE apart (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apart_name_id_idx ON apart (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apart_tags ON apart using GIN(tags)");
|
|
|
|
//PROJECT
|
|
await ExecQueryAsync("CREATE TABLE aproject (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aproject_name_id_idx ON aproject (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aproject_tags ON aproject using GIN(tags)");
|
|
|
|
//PURCHASEORDER
|
|
await ExecQueryAsync("CREATE TABLE apurchaseorder (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apurchaseorder_name_id_idx ON apurchaseorder (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apurchaseorder_tags ON apurchaseorder using GIN(tags)");
|
|
|
|
//UNIT
|
|
await ExecQueryAsync("CREATE TABLE aunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aunit_name_id_idx ON aunit (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aunit_tags ON aunit using GIN(tags)");
|
|
|
|
//UNITMODEL
|
|
await ExecQueryAsync("CREATE TABLE aunitmodel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aunitmodel_name_id_idx ON aunitmodel (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aunitmodel_tags ON aunitmodel using GIN(tags)");
|
|
|
|
//VENDOR
|
|
await ExecQueryAsync("CREATE TABLE avendor (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY, webaddress text, popupnotes text, accountnumber text, " +
|
|
"contact text, contactnotes text, phone1 text, phone2 text, phone3 text, phone4 text, phone5 text, emailaddress text, " +
|
|
"postaddress text, postcity text, postregion text, postcountry text, postcode text, address text, city text, region text, country text, latitude decimal(8,6), longitude decimal(9,6))");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX avendor_name_id_idx ON avendor (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX avendor_tags ON avendor using GIN(tags)");
|
|
await ExecQueryAsync("ALTER TABLE auser add FOREIGN KEY (vendorid) REFERENCES avendor(id)");
|
|
|
|
//----------
|
|
//WORKORDER
|
|
await ExecQueryAsync("CREATE TABLE aworkorder (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial bigint generated by default as identity not null, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE INDEX aworkorder_serial_id_idx ON aworkorder (id, serial);");//is this necessary or fruitful?
|
|
await ExecQueryAsync("CREATE INDEX aworkorder_tags ON aworkorder using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderid bigint not null REFERENCES aworkorder (id), " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitem_name_id_idx ON aworkorderitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitem_tags ON aworkorderitem using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitemexpense (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitemexpense_name_id_idx ON aworkorderitemexpense (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitemexpense_tags ON aworkorderitemexpense using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitemlabor (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitemlabor_name_id_idx ON aworkorderitemlabor (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitemlabor_tags ON aworkorderitemlabor using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitemloan (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitemloan_name_id_idx ON aworkorderitemloan (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitemloan_tags ON aworkorderitemloan using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitempart (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
//await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitempart_name_id_idx ON aworkorderitempart (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitempart_tags ON aworkorderitempart using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitempartrequest (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitempartrequest_name_id_idx ON aworkorderitempartrequest (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitempartrequest_tags ON aworkorderitempartrequest using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitemscheduleduser (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitemscheduleduser_name_id_idx ON aworkorderitemscheduleduser (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitemscheduleduser_tags ON aworkorderitemscheduleduser using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitemtask (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitemtask_name_id_idx ON aworkorderitemtask (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitemtask_tags ON aworkorderitemtask using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitemtravel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitemtravel_name_id_idx ON aworkorderitemtravel (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitemtravel_tags ON aworkorderitemtravel using GIN(tags)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitemunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), " +
|
|
"notes text, customfields text, tags varchar(255) ARRAY)");
|
|
// await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitemunit_name_id_idx ON aworkorderitemunit (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitemunit_tags ON aworkorderitemunit using GIN(tags)");
|
|
|
|
|
|
//----------
|
|
|
|
|
|
//WORKORDERTEMPLATE
|
|
await ExecQueryAsync("CREATE TABLE aworkordertemplate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aworkordertemplate_name_id_idx ON aworkordertemplate (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkordertemplate_tags ON aworkordertemplate using GIN(tags)");
|
|
await ExecQueryAsync("ALTER TABLE acustomer add column defaultservicetemplateid bigint null references aworkordertemplate");
|
|
|
|
//WORKORDERTEMPLATEITEM
|
|
await ExecQueryAsync("CREATE TABLE aworkordertemplateitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aworkordertemplateitem_name_id_idx ON aworkordertemplateitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkordertemplateitem_tags ON aworkordertemplateitem using GIN(tags)");
|
|
|
|
//QUOTE
|
|
await ExecQueryAsync("CREATE TABLE aquote (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial bigint generated by default as identity not null, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aquote_serial_id_idx ON aquote (id, serial);");//is this necessary or fruitful?
|
|
await ExecQueryAsync("CREATE INDEX aquote_tags ON aquote using GIN(tags)");
|
|
|
|
//QUOTEITEM
|
|
await ExecQueryAsync("CREATE TABLE aquoteitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteid bigint not null REFERENCES aquote (id), name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aquoteitem_name_id_idx ON aquoteitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aquoteitem_tags ON aquoteitem using GIN(tags)");
|
|
|
|
//QUOTETEMPLATE
|
|
await ExecQueryAsync("CREATE TABLE aquotetemplate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aquotetemplate_name_id_idx ON aquotetemplate (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aquotetemplate_tags ON aquotetemplate using GIN(tags)");
|
|
|
|
//QUOTETEMPLATEITEM
|
|
await ExecQueryAsync("CREATE TABLE aquotetemplateitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aquotetemplateitem_name_id_idx ON aquotetemplateitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aquotetemplateitem_tags ON aquotetemplateitem using GIN(tags)");
|
|
|
|
//PM
|
|
await ExecQueryAsync("CREATE TABLE apm (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial bigint generated by default as identity not null, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apm_serial_id_idx ON apm (id, serial);");//is this necessary or fruitful?
|
|
await ExecQueryAsync("CREATE INDEX apm_tags ON apm using GIN(tags)");
|
|
|
|
//PMITEM
|
|
await ExecQueryAsync("CREATE TABLE apmitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmid bigint not null REFERENCES apm (id), name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apmitem_name_id_idx ON apmitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apmitem_tags ON apmitem using GIN(tags)");
|
|
|
|
//PMTEMPLATE
|
|
await ExecQueryAsync("CREATE TABLE apmtemplate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apmtemplate_name_id_idx ON apmtemplate (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apmtemplate_tags ON apmtemplate using GIN(tags)");
|
|
|
|
//PMTEMPLATEITEM
|
|
await ExecQueryAsync("CREATE TABLE apmtemplateitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, wiki text, customfields text, tags varchar(255) ARRAY )");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apmtemplateitem_name_id_idx ON apmtemplateitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apmtemplateitem_tags ON apmtemplateitem using GIN(tags)");
|
|
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// NOTIFICATIONS tables
|
|
if (currentSchema < 12)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE anotifysubscription (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " +
|
|
"userid bigint not null REFERENCES auser (id), ayatype integer not null, eventtype integer not null, advancenotice interval not null, " +
|
|
"idvalue bigint not null, decvalue decimal(19,4) not null, agevalue interval not null, deliverymethod integer not null, " +
|
|
"deliveryaddress text, linkreportid bigint not null, tags varchar(255) ARRAY)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE anotifyevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created timestamp not null, " +
|
|
"ayatype integer not null, objectid bigint not null, name text not null, eventtype integer not null, notifysubscriptionid bigint not null references anotifysubscription(id) on delete cascade, " +
|
|
"userid bigint not null REFERENCES auser (id), idvalue bigint not null, decvalue decimal(19,4) not null, eventdate timestamp not null, message text)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE anotification (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, userid bigint not null REFERENCES auser (id), " +
|
|
"created timestamp not null, ayatype integer not null, objectid bigint not null, name text not null, eventtype integer not null, " +
|
|
"notifysubscriptionid bigint not null references anotifysubscription(id) on delete cascade, message text, fetched bool not null)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE anotifydeliverylog (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, processed timestamp not null, " +
|
|
"ayatype integer not null, objectid bigint not null, eventtype integer not null, notifysubscriptionid bigint not null, idvalue bigint not null, " +
|
|
"decvalue decimal(19,4) not null, userid bigint not null REFERENCES auser (id), deliverymethod integer not null, fail bool not null, error text)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
//////////////////////////////////////////////////
|
|
// LOGO table
|
|
if (currentSchema < 13)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE alogo (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " +
|
|
"large bytea, largetype text, medium bytea, mediumtype text, small bytea, smalltype text)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
//////////////////////////////////////////////////
|
|
// REPORT table
|
|
if (currentSchema < 14)
|
|
{
|
|
LogUpdateMessage(log);
|
|
await ExecQueryAsync("CREATE TABLE areport (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name text not null unique, active bool, " +
|
|
"notes text, roles integer not null, objecttype integer not null, template text, style text, jsprerender text, jshelpers text, rendertype integer not null, " +
|
|
"headertemplate text, footertemplate text, displayheaderfooter bool, paperformat integer not null, landscape bool, marginoptionsbottom text, " +
|
|
"marginoptionsleft text, marginoptionsright text, marginoptionstop text, pageranges text, prefercsspagesize bool, printbackground bool, scale decimal(19,4) )");
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
|
|
//Load the stock REPORT TEMPLATES
|
|
await AyaNova.Biz.PrimeData.PrimeReportTemplates();
|
|
}
|
|
|
|
//////////////////////////////////////////////////
|
|
//DATAFILTER / DATALISTTEMPLATE tables
|
|
if (currentSchema < 15)
|
|
{
|
|
LogUpdateMessage(log);
|
|
await ExecQueryAsync("CREATE TABLE adashboardview (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, userid bigint not null unique, view text not null)");
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
|
|
|
|
|
|
//#########################################
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
//////////////////////////////////////////////////
|
|
// FUTURE
|
|
// if (currentSchema < 10)
|
|
// {
|
|
// LogUpdateMessage(log);
|
|
|
|
// setSchemaLevel(++currentSchema);
|
|
// }
|
|
|
|
|
|
//MAKE SURE THE DESIRED SCHEMA WAS SET PROPERLY
|
|
if (currentSchema > DESIRED_SCHEMA_LEVEL)
|
|
throw new ArgumentOutOfRangeException("AySchema::DesiredSchemaLevel WASN'T SET PROPERLY");
|
|
|
|
|
|
|
|
log.LogInformation("Finished updating database schema to version {0}", currentSchema);
|
|
//*************************************************************************************
|
|
|
|
|
|
|
|
}//eofunction
|
|
|
|
|
|
|
|
private static async Task SetSchemaLevelAsync(int nCurrentSchema)
|
|
{
|
|
await ExecQueryAsync("UPDATE aschemaversion SET schema=" + nCurrentSchema.ToString());
|
|
}
|
|
|
|
//execute command query
|
|
private static async Task ExecQueryAsync(string q)
|
|
{
|
|
using (var cm = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
await ct.Database.OpenConnectionAsync();
|
|
cm.CommandText = q;
|
|
await cm.ExecuteNonQueryAsync();
|
|
await ct.Database.CloseConnectionAsync();
|
|
}
|
|
}
|
|
|
|
|
|
private static void LogUpdateMessage(ILogger log)
|
|
{
|
|
log.LogDebug($"Updating database to schema version {currentSchema + 1}");
|
|
}
|
|
|
|
|
|
//eoclass
|
|
}
|
|
//eons
|
|
} |