Files
raven/server/AyaNova/util/AySchema.cs
2021-01-30 19:45:23 +00:00

985 lines
57 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 = 710;
internal const long EXPECTED_INDEX_COUNT = 124;
//!!!!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
https://www.postgresqltutorial.com/postgresql-indexes/postgresql-create-index/
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
Official guidance on index analysis
https://www.postgresql.org/docs/13/monitoring-stats.html
*/
#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, "
+ "useinventory BOOL default true "
+ ")");
//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 idx_aevent_ayid_aytype ON aevent (ayid, ayatype);");
//TODO: this may be a very low used index, revisit it down the road
await ExecQueryAsync("CREATE INDEX idx_aevent_userid 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 idx_asearchkey_wordid 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$;
");
//Name fetcher function
//CoreBizObject ADD here
await ExecQueryAsync(@"
CREATE OR REPLACE FUNCTION PUBLIC.AYGETNAME(IN AYOBJECTID BIGINT, IN AYOBJECTTYPE INTEGER) RETURNS TEXT AS $BODY$
DECLARE
aytable TEXT DEFAULT '';
aynamecolumn TEXT DEFAULT 'name';
returnstr TEXT DEFAULT '';
BEGIN
case ayobjecttype
when 0 then return 'LT:NoType';
when 1 then return 'LT:Global';
when 2 then aytable = 'awidget';
when 3 then aytable = 'auser';
when 4 then return 'LT:ServerState';
when 5 then return 'LT:License';
when 6 then return 'LT:LogFile';
when 7 then return 'LT:PickListTemplate';
when 8 then aytable = 'acustomer';
when 9 then return 'LT:ServerJob';
when 10 then aytable = 'acontract';
when 11 then return 'LT:TrialSeeder';
when 12 then return 'LT:ServerMetrics';
when 13 then aytable = 'atranslation';
when 14 then return 'LT:UserOptions';
when 15 then aytable = 'aheadoffice';
when 16 then aytable = 'aloanunit';
when 17 then aytable = 'afileattachment'; aynamecolumn ='displayfilename';
when 18 then aytable = 'adatalistsavedfilter';
when 19 then aytable = 'aformcustom'; aynamecolumn = 'formkey';
when 20 then aytable = 'apart'; aynamecolumn ='partnumber';
when 21 then aytable = 'apm'; aynamecolumn ='serial';
when 22 then aytable = 'apmitem';
when 23 then aytable = 'apmtemplate';
when 24 then aytable = 'apmtemplateitem';
when 25 then aytable = 'aproject';
when 26 then aytable = 'apurchaseorder'; aynamecolumn = 'serial';
when 27 then aytable = 'aquote'; aynamecolumn = 'serial';
when 28 then aytable = 'aquoteitem';
when 29 then aytable = 'aquotetemplate';
when 30 then aytable = 'aquotetemplateitem';
when 31 then aytable = 'aunit'; aynamecolumn = 'serial';
when 32 then aytable = 'aunitmodel'; aynamecolumn = 'number';
when 33 then aytable = 'avendor';
when 34 then aytable = 'aworkorder'; aynamecolumn = 'serial';
when 35 then return 'LT:WorkOrderItem';
when 36 then return 'LT:WorkOrderItemExpense';
when 37 then return 'LT:WorkOrderItemLabor';
when 38 then return 'LT:aworkorderitemloan';
when 39 then return 'LT:WorkOrderItemPart';
when 40 then return 'LT:WorkOrderItemPartRequest';
when 41 then return 'LT:WorkOrderItemScheduledUser';
when 42 then return 'LT:WorkOrderItemTask';
when 43 then return 'LT:WorkOrderItemTravel';
when 44 then return 'LT:WorkOrderItemUnit';
when 45 then aytable = 'aworkordertemplate';
when 46 then aytable = 'aworkordertemplateitem';
when 47 then return 'LT:GlobalOps';
when 48 then return 'LT:BizMetrics';
when 49 then return 'LT:Backup';
when 50 then aytable = 'anotification';
when 51 then return 'LT:NotifySubscription';
when 52 then aytable = 'areminder';
when 53 then return 'LT:UnitMeterReading';
when 54 then aytable = 'acustomerservicerequest';
when 55 then aytable = 'aservicebank';
when 56 then return 'LT:OpsNotificationSettings';
when 57 then aytable = 'areport';
when 58 then return 'LT:DashBoardView';
when 59 then aytable = 'acustomernote'; aynamecolumn = 'notedate';
when 60 then aytable = 'amemo';
when 61 then aytable = 'areview';
when 62 then aytable = 'aservicerate';
when 63 then aytable = 'atravelrate';
when 64 then aytable = 'ataxcode';
when 65 then aytable = 'apartassembly';
when 66 then aytable = 'apartwarehouse';
when 67 then aytable = 'apartinventory'; aynamecolumn='description';
when 68 then return format('DataListColumnView %L', ayobjectid);
else
RETURN returnstr;
end case;
EXECUTE format('SELECT %I FROM %I WHERE id = %L', aynamecolumn, aytable, ayobjectid) INTO returnstr;
RETURN returnstr;
END;
$BODY$ LANGUAGE PLPGSQL STABLE");
//Usage: select created, textra, AYGETNAME(aevent.ayid, aevent.ayatype) as name from aevent order by created
//create translation TEXT tables
await ExecQueryAsync("CREATE TABLE atranslation (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, 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)");
//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)");
//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 NOT NULL, usertype int4, count INTEGER," +
"notes TEXT, userid BIGINT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY)");
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 idx_afileattachment_storedfilename 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 idx_afileattachment_attachtoobjectid_attachtoobjecttype 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);
}
//////////////////////////////////////////////////
//DATALISTSAVEDFILTER / DATALISTCOLUMNVIEW
if (currentSchema < 7)
{
LogUpdateMessage(log);
await ExecQueryAsync("CREATE TABLE adatalistsavedfilter (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, userid BIGINT NOT NULL, name TEXT NOT NULL, public BOOL NOT NULL, "
+ "defaultfilter BOOL NOT NULL, listkey VARCHAR(255) NOT NULL, filter TEXT)");
await ExecQueryAsync("CREATE TABLE adatalistcolumnview (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, userid BIGINT NOT NULL, "
+ "listkey VARCHAR(255) NOT NULL, columns TEXT, sort 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);
//SERVICERATE
await ExecQueryAsync("CREATE TABLE aservicerate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"accountnumber TEXT, unit TEXT, cost DECIMAL(19,4) NOT NULL default 0, charge DECIMAL(19,4) NOT NULL default 0)");
//TRAVELRATE
await ExecQueryAsync("CREATE TABLE atravelrate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"accountnumber TEXT, unit TEXT, cost DECIMAL(19,4) NOT NULL default 0, charge DECIMAL(19,4) NOT NULL default 0)");
//TAXCODE
await ExecQueryAsync("CREATE TABLE ataxcode (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"taxa DECIMAL(19,4) NOT NULL default 0, taxb DECIMAL(19,4) NOT NULL default 0, taxontax BOOL NOT NULL default false)");
//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) )");
//REMINDER
await ExecQueryAsync("CREATE TABLE areminder (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"startdate TIMESTAMP NOT NULL, stopdate TIMESTAMP NOT NULL, userid BIGINT NOT NULL REFERENCES auser(id), color VARCHAR(12) NOT NULL default '#ffffff')");
await ExecQueryAsync("CREATE INDEX idx_areminder_userid ON areminder (userid);");
await ExecQueryAsync("CREATE INDEX idx_areminder_startdate ON areminder (startdate);");
await ExecQueryAsync("CREATE INDEX idx_areminder_stopdate ON areminder (stopdate);");
//REVIEW
await ExecQueryAsync("CREATE TABLE areview (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"duedate TIMESTAMP NOT NULL, completeddate TIMESTAMP NULL, completionnotes TEXT, userid BIGINT NOT NULL REFERENCES auser(id), " +
"assignedbyuserid BIGINT NOT NULL REFERENCES auser(id), objecttype INTEGER NOT NULL, objectid BIGINT NOT NULL)");
await ExecQueryAsync("CREATE INDEX idx_areview_objectid_objecttype ON areview (objectid, objecttype );");
await ExecQueryAsync("CREATE INDEX idx_areview_userid ON areview (userid);");
await ExecQueryAsync("CREATE INDEX idx_areview_duedate ON areview (duedate);");
await ExecQueryAsync("CREATE INDEX idx_areview_completeddate ON areview (completeddate);");
//SERVICE BANK
//Note: I'm allowing negative balances so this code differs slightly from the example it was drawn from https://dba.stackexchange.com/a/19368
await ExecQueryAsync("CREATE TABLE aservicebank (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, " +
"entrydate TIMESTAMP NOT NULL, lastentrydate TIMESTAMP NULL, objecttype INTEGER NOT NULL, objectid BIGINT NOT NULL, sourcetype INTEGER NOT NULL, sourceid BIGINT NOT NULL, " +
"incidents DECIMAL(19,4) NOT NULL, incidentsbalance DECIMAL(19,4) NOT NULL, lastincidentsbalance DECIMAL(19,4) NULL, " +
"currency DECIMAL(19,4) NOT NULL, currencybalance DECIMAL(19,4) NOT NULL, lastcurrencybalance DECIMAL(19,4) NULL, " +
"hours DECIMAL(19,4) NOT NULL, hoursbalance DECIMAL(19,4) NOT NULL, lasthoursbalance DECIMAL(19,4) NULL, " +
"CONSTRAINT unq_servicebank UNIQUE (entrydate, objectid, objecttype, incidentsbalance, hoursbalance, currencybalance), " +
"CONSTRAINT unq_servicebank_previous_values UNIQUE (lastentrydate, objectid, objecttype, lastincidentsbalance, lasthoursbalance, lastcurrencybalance), " +
"CONSTRAINT fk_servicebank_self FOREIGN KEY (lastentrydate, objectid, objecttype, lastincidentsbalance, lasthoursbalance, lastcurrencybalance) REFERENCES aservicebank(entrydate, objectid, objecttype, incidentsbalance, hoursbalance, currencybalance), " +
"CONSTRAINT chk_servicebank_valid_incidentbalance CHECK(incidentsbalance = COALESCE(lastincidentsbalance, 0) + incidents), " +
"CONSTRAINT chk_servicebank_valid_currencybalance CHECK(currencybalance = COALESCE(lastcurrencybalance, 0) + currency), " +
"CONSTRAINT chk_servicebank_valid_hoursbalance CHECK(hoursbalance = COALESCE(lasthoursbalance, 0) + hours), " +
"CONSTRAINT chk_servicebank_valid_dates_sequence CHECK(lastentrydate < entrydate), " +
"CONSTRAINT chk_servicebank_valid_previous_columns CHECK((lastentrydate IS NULL AND lastincidentsbalance IS NULL AND lastcurrencybalance IS NULL AND lasthoursbalance IS NULL) OR (lastentrydate IS NOT NULL AND lastincidentsbalance IS NOT NULL AND lastcurrencybalance IS NOT NULL AND lasthoursbalance IS NOT NULL)) " +
" )");
await ExecQueryAsync("CREATE INDEX idx_aservicebank_objectid_objecttype ON aservicebank (objectid, objecttype );");
//CUSTOMER
await ExecQueryAsync("CREATE TABLE acustomer (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"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("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 )");
//CONTRACT
await ExecQueryAsync("CREATE TABLE acontract (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
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 NOT NULL, " +
"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("ALTER TABLE acustomer ADD column headofficeid BIGINT NULL REFERENCES aheadoffice");
await ExecQueryAsync("ALTER TABLE auser ADD FOREIGN KEY (headofficeid) REFERENCES aheadoffice(id)");
//VENDOR
await ExecQueryAsync("CREATE TABLE avendor (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"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("ALTER TABLE auser ADD FOREIGN KEY (vendorid) REFERENCES avendor(id)");
//PART
await ExecQueryAsync("CREATE TABLE apart (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"partnumber TEXT NOT NULL UNIQUE, manufacturerid BIGINT REFERENCES avendor, manufacturernumber TEXT, " +
"wholesalerid BIGINT REFERENCES avendor, wholesalernumber TEXT, alternativewholesalerid BIGINT REFERENCES avendor, alternativewholesalernumber TEXT, " +
"cost DECIMAL(19,4) NOT NULL, retail DECIMAL(19,4) NOT NULL, unitofmeasure TEXT, upc TEXT " +
" )");
//PARTWAREHOUSE
await ExecQueryAsync("CREATE TABLE apartwarehouse (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY)");
await ExecQueryAsync("INSERT INTO apartwarehouse(name, active) VALUES ('Default', true);");
//PARTSERIAL
await ExecQueryAsync("CREATE TABLE apartserial (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial TEXT NOT NULL, " +
"partid BIGINT NOT NULL REFERENCES apart ON DELETE CASCADE, CONSTRAINT unq_partserialpart UNIQUE (partid, serial) )");//ensure not duplicate partid/serial combo
//PARTASSEMBLY
await ExecQueryAsync("CREATE TABLE apartassembly (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//PARTASSEMBLYITEM
await ExecQueryAsync("CREATE TABLE apartassemblyitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, partassemblyid BIGINT NOT NULL REFERENCES apartassembly ON DELETE CASCADE, " +
"partid BIGINT NOT NULL REFERENCES apart ON DELETE CASCADE, quantity DECIMAL(19,4) NOT NULL default 1, " +
"CONSTRAINT unq_partassemblypart UNIQUE (partid, partassemblyid) " +//ensure no duplicate parts in the same assembly
")");
// await ExecQueryAsync("CREATE INDEX idx_apartassemblyitem_partid ON apartassemblyitem(partid)");
// await ExecQueryAsync("CREATE INDEX idx_apartassemblyitem_partassemblyid ON apartassemblyitem(partassemblyid)");
//PART INVENTORY
await ExecQueryAsync("CREATE TABLE apartinventory (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, description TEXT NULL, " +
"entrydate TIMESTAMP NOT NULL, lastentrydate TIMESTAMP NULL, partid BIGINT NOT NULL REFERENCES apart, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse, " +
"sourcetype INTEGER, sourceid BIGINT, " +
"quantity DECIMAL(19,4) NOT NULL, balance DECIMAL(19,4) NOT NULL, lastbalance DECIMAL(19,4) NULL, " +
"CONSTRAINT unq_partinventory UNIQUE (sourceid, sourcetype, entrydate, balance), " +
"CONSTRAINT unq_partinventory_previous_values UNIQUE (sourceid, sourcetype, lastentrydate, lastbalance), " +
"CONSTRAINT fk_partinventory_self FOREIGN KEY (sourceid, sourcetype, lastentrydate, lastbalance) REFERENCES apartinventory(sourceid, sourcetype, entrydate, balance), " +
"CONSTRAINT chk_partinventory_valid_balance CHECK(balance >= 0 AND (balance = COALESCE(lastbalance, 0) + quantity)), " +
"CONSTRAINT chk_partinventory_valid_dates_sequence CHECK(lastentrydate < entrydate), " +
"CONSTRAINT chk_partinventory_valid_previous_columns CHECK((lastentrydate IS NULL AND lastbalance IS NULL) OR (lastentrydate IS NOT NULL AND lastbalance IS NOT NULL)), " +
"CONSTRAINT chk_partinventory_valid_source CHECK((sourcetype IS NULL AND sourceid IS NULL) OR (sourcetype IS NOT NULL AND sourceid IS NOT NULL)) " +
" )");
//PART INVENTORY VIEW
await ExecQueryAsync("CREATE VIEW vpartinventorynow AS WITH T AS (SELECT *, ROW_NUMBER() OVER(PARTITION BY partid, partwarehouseid ORDER BY entrydate DESC) AS rn FROM apartinventory) SELECT * FROM T WHERE rn = 1");
//MIGRATE_OUTSTANDING: index(s) to support inventory ops
//recheck this again once have full inventory in place and run some manual queries taken from inventory methods and issued by ef core
//see what if any index tuning will help with a huge db of realistic data doing most common ops
//await ExecQueryAsync("CREATE INDEX idx_PartInventory_SourceId_SourceType ON apartinventory (sourceid, sourcetype);");
//PARTSTOCKLEVEL
await ExecQueryAsync("CREATE TABLE apartstocklevel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse ON DELETE CASCADE, " +
"partid BIGINT NOT NULL REFERENCES apart ON DELETE CASCADE, minimumquantity DECIMAL(19,4) NOT NULL default 1, " +
"CONSTRAINT unq_partstocklevel_part_warehouse UNIQUE (partid, partwarehouseid) " +//ensure no duplicates
")");
//PROJECT
await ExecQueryAsync("CREATE TABLE aproject (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"datestarted TIMESTAMP NULL, datecompleted TIMESTAMP NULL, projectoverseerid BIGINT NULL REFERENCES auser(id), accountnumber TEXT)");
//PURCHASEORDER
//Note don't forget to update name fetcher stored procedure when change this to serial from name
await ExecQueryAsync("CREATE TABLE apurchaseorder (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial BIGINT generated by default as identity NOT NULL, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//UNITMODEL
await ExecQueryAsync("CREATE TABLE aunitmodel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NULL, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"number TEXT NOT NULL, vendorid BIGINT NULL REFERENCES avendor(id), upc TEXT NULL, lifetimewarranty BOOL NOT NULL, introduceddate TIMESTAMP NULL, " +
"discontinued BOOL NOT NULL, discontinueddate TIMESTAMP NULL, warrantylength INTEGER NULL, warrantyterms TEXT NULL, CONSTRAINT UNQ_UnitModelNumberVendorId UNIQUE (number, vendorid) " +
")");
//UNIT
await ExecQueryAsync("CREATE TABLE aunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"serial TEXT NOT NULL, customerid BIGINT NOT NULL REFERENCES acustomer(id), parentunitid BIGINT NULL REFERENCES aunit(id), " +
"unitmodelid BIGINT NULL REFERENCES aunitmodel(id), unithasownaddress BOOL, boughthere BOOL, purchasedfromvendorid BIGINT NULL REFERENCES avendor(id), " +
"receipt TEXT NULL, purchaseddate TIMESTAMP NULL, description TEXT NULL, replacedbyunitid BIGINT NULL REFERENCES aunit(id), " +
"overridemodelwarranty BOOL, warrantylength INTEGER NULL, warrantyterms TEXT NULL, usesbanking BOOL, metered BOOL, lifetimewarranty BOOL, " +
"text1 TEXT NULL, text2 TEXT NULL, text3 TEXT NULL, text4 TEXT NULL, address TEXT NULL, city TEXT NULL, region TEXT NULL, country TEXT NULL, latitude DECIMAL(8,6) NULL, longitude DECIMAL(9,6) NULL, " +
"CONSTRAINT unq_unitserialmodelid UNIQUE (serial, unitmodelid) " +
" )");
//LOANUNIT
await ExecQueryAsync("CREATE TABLE aloanunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"serial TEXT, unitid BIGINT NULL REFERENCES aunit(id), defaultrate INTEGER NOT NULL, " +
"ratehour DECIMAL(19,4) NOT NULL, ratehalfday DECIMAL(19,4) NOT NULL, rateday DECIMAL(19,4) NOT NULL, rateweek DECIMAL(19,4) NOT NULL, ratemonth DECIMAL(19,4) NOT NULL, rateyear DECIMAL(19,4) NOT NULL " +
")");
//----------
//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 NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
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 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 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 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("ALTER TABLE aloanunit ADD column workorderitemloanid BIGINT NULL REFERENCES aworkorderitemloan");
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 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 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 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 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 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)");
//----------
//WORKORDERTEMPLATE
await ExecQueryAsync("CREATE TABLE aworkordertemplate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
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 NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//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 NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//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 NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//QUOTETEMPLATE
await ExecQueryAsync("CREATE TABLE aquotetemplate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//QUOTETEMPLATEITEM
await ExecQueryAsync("CREATE TABLE aquotetemplateitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//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 NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//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 NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//PMTEMPLATE
await ExecQueryAsync("CREATE TABLE apmtemplate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//PMTEMPLATEITEM
await ExecQueryAsync("CREATE TABLE apmtemplateitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY )");
//CUSTOMERSERVICEREQUEST
await ExecQueryAsync("CREATE TABLE acustomerservicerequest (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, " +
"notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " +
"daterequested TIMESTAMP NOT NULL, customerid BIGINT NOT NULL REFERENCES acustomer(id), unitid BIGINT REFERENCES aunit(id), workorderitemid BIGINT REFERENCES aworkorderitem(id), " +
"requestedbyuserid BIGINT NOT NULL REFERENCES auser(id), customerreferencenumber TEXT, status INTEGER NOT NULL, priority INTEGER NOT NULL " +
")");
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), eventdate TIMESTAMP NOT NULL, message TEXT)");
//these fields were in here but seem to not be required so commented out for now, see notifyevent model for deets but
//basically remove this comment once certain don't need these fields (close to release or after)
//idvalue BIGINT NOT NULL, decvalue DECIMAL(19,4) NOT NULL,
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 NOT NULL, " +
"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
}