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::EmptyBizDataFromDatabaseForSeedingOrImportingAsync WHEN NEW TABLES ADDED!!!! private const int DESIRED_SCHEMA_LEVEL = 19; internal const long EXPECTED_COLUMN_COUNT = 1389; internal const long EXPECTED_INDEX_COUNT = 160; internal const long EXPECTED_CHECK_CONSTRAINTS = 561; internal const long EXPECTED_FOREIGN_KEY_CONSTRAINTS = 204; internal const long EXPECTED_VIEWS = 11; internal const long EXPECTED_ROUTINES = 2; //!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImportingAsync WHEN NEW TABLES ADDED!!!! ///////////////////////////////////////// C1389:I160:CC561:FC204:V11:R2 /* MAXIMUM POSTGRES OBJECT NAME LENGTH: 63 CHARACTERS DECIMALS: =-=-=-=-- DECIMAL(PRECISION,SCALE) DECIMAL([MAXIMUM DIGITS TOTAL],[DIGITS TO THE RIGHT OF DECIMAL POINT]) (left digits max is precision minus scale) CURRENCY: DECIMAL(38,18) (to support potential of cryptocurrencies) largest Etherium value fits in this (36bytes) TAX/PERCENTAGES/PDF PAGE SCALE: DECIMAL(10,5) largest tax I could find would fit in this, (was 8,5 but Joyce had an item that was 8000% so changed to allow up to 10000%) Taxes are in face value not fractional value, i.e. "7" not .07 in db Inventory/incidents/service rate quantity etc general numbers (19,5) Latitude/longitude 9,6 //DATA TYPES .net to postgres map //http://www.npgsql.org/doc/types/basic.html //if need to query a bit field: https://www.ehfeng.com/querying-bitfield-with-sql/ 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 (v0) 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 (0,'{AyaNova.Util.Hasher.GenerateSalt()}');";//NOTE: this is where the dbid comes from originally await cm.ExecuteNonQueryAsync(); await ct.Database.CloseConnectionAsync(); startingSchema = 0; currentSchema = 0; } } 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 ****************** bool PrimeEmptyDB = false; ////////////////////////////////////////////////// // v8 initial release TABLES // if (currentSchema < 1) { LogUpdateMessage(log); PrimeEmptyDB = true; //create global biz settings table await ExecQueryAsync("CREATE TABLE aglobalbizsettings (id INTEGER NOT NULL PRIMARY KEY, " + "webaddress TEXT, phone1 TEXT, phone2 TEXT, emailaddress TEXT, postaddress TEXT, postcity TEXT, postregion TEXT, postcountry TEXT, postcode TEXT, " + "address TEXT, city TEXT, region TEXT, country TEXT, latitude DECIMAL(9,6), longitude DECIMAL(9,6), " + "filtercasesensitive BOOL DEFAULT FALSE, " + "useinventory BOOL DEFAULT TRUE, " + "allowscheduleconflicts BOOL DEFAULT TRUE, " + "workordercompletebyage INTERVAL NOT NULL DEFAULT '00:00:00', " + "workordertraveldefaultminutes INTEGER NOT NULL DEFAULT 0, " + "worklaborscheduledefaultminutes INTEGER NOT NULL DEFAULT 0, " + "signaturetitle TEXT, " + "signatureheader TEXT, " + "signaturefooter TEXT, " + "customerservicerequestinfotext TEXT, " + "customerallowcsr BOOL DEFAULT FALSE, customerallowcsrintags VARCHAR(255) ARRAY, " + "customerallowcreateunit BOOL DEFAULT FALSE, customerallowcreateunitintags VARCHAR(255) ARRAY, " + "customerallowviewwo BOOL DEFAULT FALSE, customerallowviewwointags VARCHAR(255) ARRAY, " + "customerworkorderreport1tags VARCHAR(255) ARRAY, customerworkorderreport2tags VARCHAR(255) ARRAY, " + "customerworkorderreport3tags VARCHAR(255) ARRAY, customerworkorderreport4tags VARCHAR(255) ARRAY, customerworkorderreport5tags VARCHAR(255) ARRAY, " + "customerallowwowiki BOOL DEFAULT FALSE, customerallowwowikiintags VARCHAR(255) ARRAY, " + "customerallowwoattachments BOOL DEFAULT FALSE, customerallowwoattachmentsintags VARCHAR(255) ARRAY, " + "customerallowusersettings BOOL DEFAULT FALSE, customerallowusersettingsintags VARCHAR(255) ARRAY, " + "customerallownotifyserviceimminent BOOL DEFAULT FALSE, customerallownotifyserviceimminentintags VARCHAR(255) ARRAY, " + "customerallownotifycsraccepted BOOL DEFAULT FALSE, customerallownotifycsracceptedintags VARCHAR(255) ARRAY, " + "customerallownotifycsrrejected BOOL DEFAULT FALSE, customerallownotifycsrrejectedintags VARCHAR(255) ARRAY, " + "customerallownotifywocreated BOOL DEFAULT FALSE, customerallownotifywocreatedintags VARCHAR(255) ARRAY, " + "customerallownotifywocompleted BOOL DEFAULT FALSE, customerallownotifywocompletedintags VARCHAR(255) ARRAY" + ")"); //create global ops BACKUP settings table await ExecQueryAsync("CREATE TABLE aglobalopsbackupsettings (id INTEGER NOT NULL PRIMARY KEY, active BOOL NOT NULL, " + "backuptime TIMESTAMPTZ, 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 TIMESTAMPTZ 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_aType 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 TIMESTAMPTZ NOT NULL, allocated BIGINT,workingset BIGINT,privatebytes BIGINT,cpu double precision)"); //One day metrics await ExecQueryAsync("CREATE TABLE ametricdd (t TIMESTAMPTZ 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, atype 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 atype=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, atype );"); //This is what is needed during Searching //search does a lot of hits on searchkey looking for the wordid and optionally atype //In testing this did not pan out, in fact it was much faster to search both with and without a atype specified to simply have an index on wordid // await ExecQueryAsync("CREATE INDEX asearchkey_wordid_otype_idx ON asearchkey (wordid, atype);"); 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, ayatype 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 ayatype=0 THEN RAISE EXCEPTION 'Bad object type --> %', ayatype; END IF; IF cleanfirst=true THEN delete from asearchkey where objectid=ayobjectid and atype=ayatype; 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,atype) values(wordid,ayobjectid,ayatype); ELSE insert into asearchkey (wordid,objectid,atype) values(wordid,ayobjectid,ayatype); END IF; END LOOP; END; $BODY$; "); //Original Name fetcher function, superseded by later updates await ExecQueryAsync(@" CREATE OR REPLACE FUNCTION PUBLIC.AYGETNAME(IN AYOBJECTID BIGINT, IN AYATYPE INTEGER,TRANSLATIONID integer) RETURNS TEXT AS $BODY$ DECLARE aytable TEXT DEFAULT ''; aynamecolumn TEXT DEFAULT 'name'; aytkey TEXT DEFAULT 'no'; returnstr TEXT DEFAULT ''; BEGIN case ayatype when 0 then aytkey= 'NoType'; when 1 then aytkey= 'Global'; when 2 then return 'FormUserOptions'; when 3 then aytable = 'auser'; when 4 then aytkey= 'ServerState'; when 5 then aytkey= 'License'; when 6 then aytkey= 'LogFile'; when 7 then aytkey= 'PickListTemplate'; when 8 then aytable = 'acustomer'; when 9 then aytkey= 'ServerJob'; when 10 then aytable = 'acontract'; when 11 then aytkey= 'TrialSeeder'; when 12 then aytkey= 'ServerMetrics'; when 13 then aytable = 'atranslation'; when 14 then aytkey= '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'; when 21 then aytable = 'apm'; aynamecolumn ='serial'; when 22 then aytkey= 'PMItem'; when 23 then aytkey= 'WorkOrderItemExpense'; when 24 then aytkey= 'WorkOrderItemLabor'; when 25 then aytable = 'aproject'; when 26 then aytable = 'apurchaseorder'; aynamecolumn = 'serial'; when 27 then aytable = 'aquote'; aynamecolumn = 'serial'; when 28 then aytkey= 'QuoteItem'; when 29 then aytkey= 'WorkOrderItemLoan'; when 30 then aytkey= 'WorkOrderItemPart'; when 31 then aytable = 'aunit'; aynamecolumn = 'serial'; when 32 then aytable = 'aunitmodel'; aynamecolumn = 'name'; when 33 then aytable = 'avendor'; when 34 then aytable = 'aworkorder'; aynamecolumn = 'serial'; when 35 then aytkey= 'WorkOrderItem'; when 36 then aytkey= 'WorkOrderItemExpense'; when 37 then aytkey= 'WorkOrderItemLabor'; when 38 then aytkey= 'WorkOrderItemLoan'; when 39 then aytkey= 'WorkOrderItemPart'; when 40 then aytkey= 'WorkOrderItemPartRequest'; when 41 then aytkey= 'WorkOrderItemScheduledUser'; when 42 then aytkey= 'WorkOrderItemTask'; when 43 then aytkey= 'WorkOrderItemTravel'; when 44 then aytkey= 'WorkOrderItemUnit'; when 45 then aytkey= 'WorkOrderItemScheduledUser'; when 46 then aytkey= 'WorkOrderItemTask'; when 47 then aytkey= 'GlobalOps'; when 48 then aytkey= 'BizMetrics'; when 49 then aytkey= 'Backup'; when 50 then aytable = 'ainappnotification'; when 51 then aytkey= 'NotifySubscription'; when 52 then aytable = 'areminder'; when 53 then aytkey= 'UnitMeterReading'; when 54 then aytable = 'acustomerservicerequest'; when 56 then aytkey= 'OpsNotificationSettings'; when 57 then aytable = 'areport'; when 58 then aytkey= '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); when 71 then aytable = 'aworkorderstatus'; when 72 then aytable = 'ataskgroup'; when 73 then aytkey= 'WorkOrderItemOutsideService'; when 74 then aytable = 'aworkorderitempriority'; when 75 then aytable = 'aworkorderitemstatus'; when 76 then aytkey= 'WorkOrderItemTravel'; when 77 then aytkey= 'QuoteItemUnit'; when 78 then aytable = 'aquotestatus'; when 79 then aytkey= 'WorkOrderItemOutsideService'; when 80 then aytkey= 'WorkOrderItemExpense'; when 81 then aytkey= 'WorkOrderItemLabor'; when 82 then aytkey= 'WorkOrderItemLoan'; when 83 then aytkey= 'WorkOrderItemPart'; when 84 then aytkey= 'CustomerNotifySubscription'; when 85 then aytkey= 'WorkOrderItemScheduledUser'; when 86 then aytkey= 'WorkOrderItemTask'; when 87 then aytkey= 'WorkOrderItemTravel'; when 88 then aytkey= 'WorkOrderItemUnit'; when 89 then aytkey= 'WorkOrderItemOutsideService'; when 90 then aytkey= 'PartInventoryDataList'; else RETURN returnstr; end case; IF aytkey='no' then EXECUTE format('SELECT %I FROM %I WHERE id = %L', aynamecolumn, aytable, ayobjectid) INTO returnstr; else EXECUTE format('select display from atranslationitem where translationid=%L and key=%L', TRANSLATIONID, aytkey) INTO returnstr; END if; 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, baselanguage 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)"); //a lot of queries for subsets of translations await ExecQueryAsync("CREATE INDEX idx_atranslationitem_key ON atranslationitem (key)"); //Load the default TRANSLATIONS await AyaNova.Biz.PrimeData.PrimeTranslations(); //Add user table //!!WARNING: changes here need to be reflected in dbutil::EmptyBizDataFromDatabaseForSeedingOrImportingAsync auser_backup await ExecQueryAsync("CREATE TABLE auser (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, active BOOL NOT NULL, name TEXT NOT NULL UNIQUE, " + "lastlogin TIMESTAMPTZ, login TEXT NOT NULL UNIQUE, password TEXT NOT NULL, salt TEXT NOT NULL, roles INTEGER NOT NULL, currentauthtoken TEXT, " + "dlkey TEXT, dlkeyexpire TIMESTAMPTZ, totpsecret TEXT, temptoken TEXT, twofactorenabled BOOL, passwordresetcode TEXT, passwordresetcodeexpire TIMESTAMPTZ, 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 //!!WARNING: changes here need to be reflected in dbutil::EmptyBizDataFromDatabaseForSeedingOrImportingAsync auseroptions_backup await ExecQueryAsync("CREATE TABLE auseroptions (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " + "userid BIGINT NOT NULL UNIQUE REFERENCES auser (id) ON DELETE CASCADE, 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, mapurltemplate TEXT, uicolor VARCHAR(12) NOT NULL default '#ffffff')"); // //Prime the db with the default SuperUser account // await AyaNova.Biz.PrimeData.PrimeSuperUserAccount(ct); //Add user table await ExecQueryAsync("CREATE TABLE alicense (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, licenseagree BOOL NOT NULL, dbid TEXT, key TEXT NOT NULL)"); await ExecQueryAsync("CREATE TABLE afileattachment (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " + "attachtoobjectid BIGINT NOT NULL, attachtoatype INTEGER NOT NULL, attachedbyuserid BIGINT NOT NULL REFERENCES auser (id), " + "storedfilename TEXT NOT NULL, displayfilename TEXT NOT NULL, contenttype TEXT, lastmodified TIMESTAMPTZ 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_attachtoatype ON afileattachment (attachtoobjectid, attachtoatype );"); await ExecQueryAsync("CREATE TABLE aopsjob (gid uuid PRIMARY KEY, name TEXT NOT NULL, created TIMESTAMPTZ NOT NULL, exclusive BOOL NOT NULL, " + "startafter TIMESTAMPTZ NOT NULL, jobtype INTEGER NOT NULL, subtype INTEGER, objectid BIGINT, atype INTEGER, jobstatus INTEGER NOT NULL, jobinfo TEXT)"); await ExecQueryAsync("CREATE TABLE aopsjoblog (gid uuid PRIMARY KEY, jobid uuid NOT NULL, created TIMESTAMPTZ NOT NULL, statustext TEXT NOT NULL)"); 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 ExecQueryAsync("CREATE TABLE atag (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, refcount BIGINT NOT NULL)"); await ExecQueryAsync("CREATE TABLE aformuseroptions (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " + "userid BIGINT NOT NULL REFERENCES auser ON DELETE CASCADE, formkey VARCHAR(255) NOT NULL, options TEXT NOT NULL)"); await ExecQueryAsync("CREATE TABLE aformcustom (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " + "formkey VARCHAR(255) NOT NULL, template TEXT, UNIQUE(formkey))"); await ExecQueryAsync("CREATE TABLE apicklisttemplate (id INTEGER NOT NULL PRIMARY KEY, " + "template TEXT)"); //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, contractonly BOOL NOT NULL, cost DECIMAL(38,18) NOT NULL default 0, charge DECIMAL(38,18) 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, contractonly BOOL NOT NULL, cost DECIMAL(38,18) NOT NULL default 0, charge DECIMAL(38,18) 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, " + "taxapct DECIMAL(10,5) NOT NULL default 0, taxbpct DECIMAL(10,5) NOT NULL default 0, taxontax BOOL NOT NULL default false)"); //Global tax code defaults await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD column taxpartpurchaseid BIGINT REFERENCES ataxcode, " + "ADD column taxpartsaleid BIGINT REFERENCES ataxcode, ADD column taxratesaleid BIGINT REFERENCES ataxcode"); //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 TIMESTAMPTZ 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 TIMESTAMPTZ NOT NULL, stopdate TIMESTAMPTZ NOT NULL, userid BIGINT NOT NULL REFERENCES auser(id) ON DELETE CASCADE, 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, " + "reviewdate TIMESTAMPTZ NOT NULL, completeddate TIMESTAMPTZ NULL, completionnotes TEXT, userid BIGINT NOT NULL REFERENCES auser(id) ON DELETE CASCADE, " + "assignedbyuserid BIGINT NOT NULL REFERENCES auser(id), atype INTEGER NOT NULL, objectid BIGINT NOT NULL)"); await ExecQueryAsync("CREATE INDEX idx_areview_objectid_atype ON areview (objectid, atype );"); await ExecQueryAsync("CREATE INDEX idx_areview_userid ON areview (userid);"); await ExecQueryAsync("CREATE INDEX idx_areview_reviewdate ON areview (reviewdate);"); 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 TIMESTAMPTZ NOT NULL, lastentrydate TIMESTAMPTZ NULL, atype INTEGER NOT NULL, objectid BIGINT NOT NULL, sourcetype INTEGER NOT NULL, sourceid BIGINT NOT NULL, " // + "incidents DECIMAL(19,5) NOT NULL, incidentsbalance DECIMAL(19,5) NOT NULL, lastincidentsbalance DECIMAL(19,5) NULL, " // + "currency DECIMAL(38,18) NOT NULL, currencybalance DECIMAL(38,18) NOT NULL, lastcurrencybalance DECIMAL(38,18) NULL, " // + "hours DECIMAL(19,5) NOT NULL, hoursbalance DECIMAL(19,5) NOT NULL, lasthoursbalance DECIMAL(19,5) NULL, " // + "CONSTRAINT unq_servicebank UNIQUE (entrydate, objectid, atype, incidentsbalance, hoursbalance, currencybalance), " // + "CONSTRAINT unq_servicebank_previous_values UNIQUE (lastentrydate, objectid, atype, lastincidentsbalance, lasthoursbalance, lastcurrencybalance), " // + "CONSTRAINT fk_servicebank_self FOREIGN KEY (lastentrydate, objectid, atype, lastincidentsbalance, lasthoursbalance, lastcurrencybalance) REFERENCES aservicebank(entrydate, objectid, atype, 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_atype ON aservicebank (objectid, atype );"); //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, " + "responsetime INTERVAL NOT NULL, contractserviceratesonly BOOL NOT NULL, contracttravelratesonly BOOL NOT NULL, partsoverridepct DECIMAL(10,5) NOT NULL, partsoverridetype INTEGER NOT NULL, " + "serviceratesoverridepct DECIMAL(10,5) NOT NULL, serviceratesoverridetype INTEGER NOT NULL, travelratesoverridepct DECIMAL(10,5) NOT NULL, travelratesoverridetype INTEGER NOT NULL, " + "alertnotes text " + ")"); //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, alertnotes TEXT, billheadoffice BOOL, technotes TEXT, accountnumber TEXT, contractexpires TIMESTAMPTZ 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(9,6), longitude DECIMAL(9,6), " + "CONSTRAINT chk_contract_valid CHECK((contractid IS NULL) OR (contractid IS NOT NULL AND contractexpires IS NOT NULL)) " + ")"); 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 TIMESTAMPTZ NOT NULL, notes TEXT, tags VARCHAR(255) ARRAY )"); //CONTRACTSERVICERATE await ExecQueryAsync("CREATE TABLE acontractservicerate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, contractid BIGINT NOT NULL REFERENCES acontract ON DELETE CASCADE, " + "servicerateid BIGINT NOT NULL REFERENCES aservicerate " + ")"); //CONTRACTTRAVELERATE await ExecQueryAsync("CREATE TABLE acontracttravelrate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, contractid BIGINT NOT NULL REFERENCES acontract ON DELETE CASCADE, " + "travelrateid BIGINT NOT NULL REFERENCES atravelrate " + ")"); //CONTRACTPARTOVERRIDE await ExecQueryAsync("CREATE TABLE acontractpartoverride (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, contractid BIGINT NOT NULL REFERENCES acontract ON DELETE CASCADE, " + " overridepct DECIMAL(10,5) NOT NULL, overridetype INTEGER NOT NULL CONSTRAINT chk_overridetype_valid CHECK (overridetype > 0 AND overridetype < 3), tags VARCHAR(255) ARRAY)"); //CONTRACTSERVICERATEOVERRIDE await ExecQueryAsync("CREATE TABLE acontractservicerateoverride (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, contractid BIGINT NOT NULL REFERENCES acontract ON DELETE CASCADE, " + " overridepct DECIMAL(10,5) NOT NULL, overridetype INTEGER NOT NULL CONSTRAINT chk_overridetype_valid CHECK (overridetype > 0 AND overridetype < 3), tags VARCHAR(255) ARRAY)"); //CONTRACTTRAVELRATEOVERRIDE await ExecQueryAsync("CREATE TABLE acontracttravelrateoverride (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, contractid BIGINT NOT NULL REFERENCES acontract ON DELETE CASCADE, " + " overridepct DECIMAL(10,5) NOT NULL, overridetype INTEGER NOT NULL CONSTRAINT chk_overridetype_valid CHECK (overridetype > 0 AND overridetype < 3), tags VARCHAR(255) ARRAY)"); //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, contractexpires TIMESTAMPTZ 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(9,6), longitude DECIMAL(9,6), " + "CONSTRAINT chk_contract_valid CHECK((contractid IS NULL) OR (contractid IS NOT NULL AND contractexpires IS NOT NULL)) " + " )"); 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, alertnotes 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(9,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 NOT NULL UNIQUE, active BOOL NOT NULL, " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " + "description TEXT, manufacturerid BIGINT REFERENCES avendor, manufacturernumber TEXT, " + "wholesalerid BIGINT REFERENCES avendor, wholesalernumber TEXT, alternativewholesalerid BIGINT REFERENCES avendor, alternativewholesalernumber TEXT, " + "cost DECIMAL(38,18) NOT NULL, retail DECIMAL(38,18) 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, tags) 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,5) NOT NULL default 1, " + "CONSTRAINT unq_partassemblypart UNIQUE (partid, partassemblyid) " + ")"); // 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 NOT NULL, " + "entrydate TIMESTAMPTZ NOT NULL, lastentrydate TIMESTAMPTZ NULL, partid BIGINT NOT NULL REFERENCES apart, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse, " + "sourcetype INTEGER, sourceid BIGINT, " + "quantity DECIMAL(19,5) NOT NULL, balance DECIMAL(19,5) NOT NULL, lastbalance DECIMAL(19,5) NULL, " + "CONSTRAINT unq_partinventory UNIQUE (partid, partwarehouseid, entrydate, balance), " + "CONSTRAINT unq_partinventory_previous_values UNIQUE (partid, partwarehouseid, lastentrydate, lastbalance), " + "CONSTRAINT fk_partinventory_self FOREIGN KEY (partid, partwarehouseid, lastentrydate, lastbalance) REFERENCES apartinventory(partid, partwarehouseid, 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"); //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,5) 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 TIMESTAMPTZ NULL, datecompleted TIMESTAMPTZ NULL, projectoverseerid BIGINT NULL REFERENCES auser(id), accountnumber TEXT)"); //PURCHASEORDER await ExecQueryAsync("CREATE TABLE apurchaseorder (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial BIGINT GENERATED BY DEFAULT AS IDENTITY NOT NULL, " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " + "vendormemo TEXT, dropshiptocustomerid BIGINT REFERENCES acustomer, referencenumber TEXT, vendorid BIGINT NOT NULL REFERENCES avendor, " + "ordereddate TIMESTAMPTZ, expectedreceivedate TIMESTAMPTZ, status integer CONSTRAINT chk_status_valid CHECK (status > 0 AND status < 7), "//"a check constraint is satisfied if the check expression evaluates to true or the null value" + "projectid BIGINT REFERENCES aproject, text1 TEXT, text2 TEXT " + " )"); //PURCHASEORDERITEM await ExecQueryAsync("CREATE TABLE apurchaseorderitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, purchaseorderid BIGINT NOT NULL REFERENCES apurchaseorder ON DELETE CASCADE, " + "partid BIGINT NOT NULL REFERENCES apart, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse, quantityordered DECIMAL(19,5) NOT NULL default 0, " + "quantityreceived DECIMAL(19,5) NOT NULL default 0, purchaseordercost DECIMAL(38,18) NOT NULL default 0, receivedcost DECIMAL(38,18) NOT NULL default 0, " + "receiveddate TIMESTAMPTZ, partrequestedbyid BIGINT REFERENCES auser, purchasetaxcodeid BIGINT REFERENCES ataxcode, vendorpartnumber TEXT, serials TEXT " + ")"); //UNITMODEL await ExecQueryAsync("CREATE TABLE aunitmodel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, active BOOL NOT NULL, " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, " + "vendorid BIGINT NULL REFERENCES avendor(id), upc TEXT NULL, lifetimewarranty BOOL NOT NULL, introduceddate TIMESTAMPTZ NULL, " + "discontinued BOOL NOT NULL, discontinueddate TIMESTAMPTZ NULL, warrantylength INTEGER NULL, warrantyterms TEXT NULL " + ")"); //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 TIMESTAMPTZ NULL, description TEXT NULL, replacedbyunitid BIGINT NULL REFERENCES aunit(id), " + "overridemodelwarranty BOOL, warrantylength INTEGER NULL, warrantyterms TEXT NULL, contractid BIGINT NULL REFERENCES acontract, " + "contractexpires TIMESTAMPTZ NULL, 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(9,6) NULL, longitude DECIMAL(9,6) NULL, " + "CONSTRAINT unq_unitserialmodelid UNIQUE (serial, unitmodelid), " + "CONSTRAINT chk_contract_valid CHECK((contractid IS NULL) OR (contractid IS NOT NULL AND contractexpires IS NOT NULL)) " + " )"); //indexes to speed up deletion await ExecQueryAsync("CREATE INDEX idx_aunit_parentunitid ON aunit(parentunitid ASC NULLS LAST)"); await ExecQueryAsync("CREATE INDEX idx_aunit_replacedbyunitid ON aunit(replacedbyunitid ASC NULLS LAST)"); //indexes to speed up creation (validation) await ExecQueryAsync("CREATE INDEX idx_aunit_serial ON aunit(serial)"); //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, " + "ratehourcost DECIMAL(38,18) NOT NULL DEFAULT 0, ratehalfdaycost DECIMAL(38,18) NOT NULL DEFAULT 0, ratedaycost DECIMAL(38,18) NOT NULL DEFAULT 0, rateweekcost DECIMAL(38,18) NOT NULL DEFAULT 0, ratemonthcost DECIMAL(38,18) NOT NULL DEFAULT 0, rateyearcost DECIMAL(38,18) NOT NULL DEFAULT 0, " + "ratehour DECIMAL(38,18) NOT NULL, ratehalfday DECIMAL(38,18) NOT NULL, rateday DECIMAL(38,18) NOT NULL, rateweek DECIMAL(38,18) NOT NULL, ratemonth DECIMAL(38,18) NOT NULL, rateyear DECIMAL(38,18) NOT NULL " + ")"); //---------- /* ██╗ ██╗ ██████╗ ██████╗ ██╗ ██╗ ██████╗ ██████╗ ██████╗ ███████╗██████╗ ██║ ██║██╔═══██╗██╔══██╗██║ ██╔╝ ██╔═══██╗██╔══██╗██╔══██╗██╔════╝██╔══██╗ ██║ █╗ ██║██║ ██║██████╔╝█████╔╝█████╗██║ ██║██████╔╝██║ ██║█████╗ ██████╔╝ ██║███╗██║██║ ██║██╔══██╗██╔═██╗╚════╝██║ ██║██╔══██╗██║ ██║██╔══╝ ██╔══██╗ ╚███╔███╔╝╚██████╔╝██║ ██║██║ ██╗ ╚██████╔╝██║ ██║██████╔╝███████╗██║ ██║ ╚══╝╚══╝ ╚═════╝ ╚═╝ ╚═╝╚═╝ ╚═╝ ╚═════╝ ╚═╝ ╚═╝╚═════╝ ╚══════╝╚═╝ ╚═╝ */ //TASKGROUP await ExecQueryAsync("CREATE TABLE ataskgroup (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, notes TEXT)"); //TASKGROUPITEM await ExecQueryAsync("CREATE TABLE ataskgroupitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, taskgroupid BIGINT NOT NULL REFERENCES ataskgroup ON DELETE CASCADE, " + "sequence INTEGER DEFAULT 0, task TEXT)"); //WORKORDER STATUS await ExecQueryAsync("CREATE TABLE aworkorderstatus (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " + "notes TEXT, color VARCHAR(12) NOT NULL default '#000000', selectroles INTEGER NOT NULL, removeroles INTEGER NOT NULL, completed BOOL NOT NULL, locked BOOL NOT NULL)"); //WORKORDERITEM STATUS await ExecQueryAsync("CREATE TABLE aworkorderitemstatus (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " + "notes TEXT, color VARCHAR(12) NOT NULL default '#000000')"); //WORKORDERITEM PRIORITY await ExecQueryAsync("CREATE TABLE aworkorderitempriority (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " + "color VARCHAR(12) NOT NULL default '#000000')"); //WORKORDER await ExecQueryAsync("CREATE TABLE aworkorder (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial BIGINT GENERATED BY DEFAULT AS IDENTITY NOT NULL, " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, customerid BIGINT NOT NULL REFERENCES acustomer (id), " + "projectid BIGINT REFERENCES aproject, laststatusid BIGINT REFERENCES aworkorderstatus(id), contractid BIGINT NULL, internalreferencenumber text, " + "customerreferencenumber text, customercontactname text, createddate TIMESTAMPTZ NOT NULL, " + "servicedate TIMESTAMPTZ, completebydate TIMESTAMPTZ, invoicenumber TEXT, customersignature TEXT, customersignaturename TEXT, customersignaturecaptured TIMESTAMPTZ, " + "techsignature TEXT, techsignaturename TEXT, techsignaturecaptured TIMESTAMPTZ, durationtocompleted INTERVAL NOT NULL, onsite BOOL NOT NULL, " + "postaddress TEXT, postcity TEXT, postregion TEXT, postcountry TEXT, postcode TEXT, address TEXT, city TEXT, region TEXT, country TEXT, latitude DECIMAL(9,6), longitude DECIMAL(9,6) " + ")");//note deliberately not referencing contract here as it's not tied to it, just needs to keep track of it in case user selects alternate then triggers recalc //This index is *critical* for performance on customer list fetching last workorder id in lateral join await ExecQueryAsync("CREATE INDEX idx_aworkorder_customerid ON aworkorder (customerid)"); await ExecQueryAsync("CREATE TABLE aworkorderstate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderid BIGINT NOT NULL REFERENCES aworkorder (id), " + "workorderstatusid BIGINT NOT NULL REFERENCES aworkorderstatus (id), created TIMESTAMPTZ NOT NULL, userid BIGINT NOT NULL REFERENCES auser (id)" + ")"); //WORKORDERITEM 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, technotes TEXT, workorderitemstatusid BIGINT REFERENCES aworkorderitemstatus (id), " + " workorderitempriorityid BIGINT REFERENCES aworkorderitempriority (id), requestdate TIMESTAMPTZ, warrantyservice BOOL NOT NULL, sequence INTEGER" + ")"); //WORKORDERITEM EXPENSE await ExecQueryAsync("CREATE TABLE aworkorderitemexpense (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "description TEXT, name TEXT, totalcost DECIMAL(38,18) NOT NULL default 0, chargeamount DECIMAL(38,18) NOT NULL default 0, taxpaid DECIMAL(38,18) NOT NULL default 0, " + "chargetaxcodeid BIGINT REFERENCES ataxcode, reimburseuser BOOL NOT NULL, userid BIGINT REFERENCES auser, chargetocustomer BOOL NOT NULL " + ")"); //WORKORDERITEM LABOR await ExecQueryAsync("CREATE TABLE aworkorderitemlabor (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "userid BIGINT REFERENCES auser, servicestartdate TIMESTAMPTZ, servicestopdate TIMESTAMPTZ, servicerateid BIGINT REFERENCES aservicerate, servicedetails text, " + "serviceratequantity DECIMAL(19,5) NOT NULL default 0, nochargequantity DECIMAL(19,5) NOT NULL default 0, " + "taxcodesaleid BIGINT REFERENCES ataxcode, priceoverride DECIMAL(38,18) " + ")"); //WORKORDERITEM LOAN await ExecQueryAsync("CREATE TABLE aworkorderitemloan (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "notes TEXT, outdate TIMESTAMPTZ, duedate TIMESTAMPTZ, returndate TIMESTAMPTZ,cost DECIMAL(38,18) NOT NULL default 0, listprice DECIMAL(38,18) NOT NULL default 0, priceoverride DECIMAL(38,18), " + "taxcodeid BIGINT REFERENCES ataxcode, loanunitid BIGINT NOT NULL REFERENCES aloanunit, quantity DECIMAL(19,5) NOT NULL default 0, rate INTEGER NOT NULL" + ")"); await ExecQueryAsync("ALTER TABLE aloanunit ADD column workorderitemloanid BIGINT NULL REFERENCES aworkorderitemloan"); //WORKORDERITEM PART await ExecQueryAsync("CREATE TABLE aworkorderitempart (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "description TEXT, serials TEXT, partid BIGINT NOT NULL REFERENCES apart, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse, quantity DECIMAL(19,5) NOT NULL default 0, " + "suggestedquantity DECIMAL(19,5) NOT NULL default 0, cost DECIMAL(38,18) NOT NULL default 0, listprice DECIMAL(38,18) NOT NULL default 0, taxpartsaleid BIGINT REFERENCES ataxcode, priceoverride DECIMAL(38,18) " + ")"); //WORKORDERITEM PART REQUEST await ExecQueryAsync("CREATE TABLE aworkorderitempartrequest (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "partid BIGINT NOT NULL REFERENCES apart, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse, quantity DECIMAL(19,5) NOT NULL default 0, received DECIMAL(19,5) NOT NULL default 0, " + "requestdate TIMESTAMPTZ NOT NULL, requestedbyuserid BIGINT NULL REFERENCES auser, purchaseorderitemid BIGINT NULL REFERENCES apurchaseorderitem ON DELETE SET NULL" + ")"); //WORKORDERITEM SCHEDULED USER await ExecQueryAsync("CREATE TABLE aworkorderitemscheduleduser (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "userid BIGINT REFERENCES auser, startdate TIMESTAMPTZ, stopdate TIMESTAMPTZ, servicerateid BIGINT REFERENCES aservicerate, " + "estimatedquantity DECIMAL(19,5) NOT NULL default 0" + ")"); //indexes to speed up scheduling queries await ExecQueryAsync("CREATE INDEX idx_aworkorderitemscheduleduser_userid ON aworkorderitemscheduleduser (userid)"); await ExecQueryAsync("CREATE INDEX idx_aworkorderitemscheduleduser_startdate ON aworkorderitemscheduleduser (startdate)"); await ExecQueryAsync("CREATE INDEX idx_aworkorderitemscheduleduser_stopdate ON aworkorderitemscheduleduser (stopdate)"); //WORKORDERITEM TASK await ExecQueryAsync("CREATE TABLE aworkorderitemtask (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "sequence INTEGER NOT NULL DEFAULT 0, task text NOT NULL, status INTEGER NOT NULL DEFAULT 1, completedbyuserid BIGINT REFERENCES auser, completeddate TIMESTAMPTZ" + ")"); //WORKORDERITEM TRAVEL await ExecQueryAsync("CREATE TABLE aworkorderitemtravel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "userid BIGINT REFERENCES auser, travelstartdate TIMESTAMPTZ, travelstopdate TIMESTAMPTZ, travelrateid BIGINT REFERENCES atravelrate, traveldetails text, " + "travelratequantity DECIMAL(19,5) NOT NULL default 0, nochargequantity DECIMAL(19,5) NOT NULL default 0, " + "taxcodesaleid BIGINT REFERENCES ataxcode, distance DECIMAL(19,5) NOT NULL default 0, priceoverride DECIMAL(38,18) " + ")"); //WORKORDERITEM UNIT await ExecQueryAsync("CREATE TABLE aworkorderitemunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, unitid BIGINT NOT NULL REFERENCES aunit" + ")"); //This index is *critical* for performance on Unit list fetching last workorder id in lateral join await ExecQueryAsync("CREATE INDEX idx_aworkorderitemunit_unitidid ON aworkorderitemunit (unitid)"); //WORKORDERITEM OUTSIDE SERVICE await ExecQueryAsync("CREATE TABLE aworkorderitemoutsideservice (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, workorderitemid BIGINT NOT NULL REFERENCES aworkorderitem (id), " + "notes TEXT, unitid BIGINT NOT NULL REFERENCES aunit, vendorsenttoid BIGINT REFERENCES avendor, vendorsentviaid BIGINT REFERENCES avendor, rmanumber text, trackingnumber text, " + "taxcodeid BIGINT REFERENCES ataxcode, repaircost DECIMAL(38,18) NOT NULL default 0, repairprice DECIMAL(38,18) NOT NULL default 0, shippingcost DECIMAL(38,18) NOT NULL default 0, shippingprice DECIMAL(38,18) NOT NULL default 0, " + "SentDate TIMESTAMPTZ, etadate TIMESTAMPTZ, returndate TIMESTAMPTZ" + ")"); //POITEM LINK await ExecQueryAsync("ALTER TABLE apurchaseorderitem ADD column workorderitempartrequestid BIGINT REFERENCES aworkorderitempartrequest ON DELETE SET NULL"); //VPARTSONORDERCOMMITTED await ExecQueryAsync("CREATE VIEW vpartsonordercommitted AS SELECT partid, partwarehouseid, SUM((COALESCE(apurchaseorderitem.quantityordered,0)-COALESCE(apurchaseorderitem.quantityreceived,0))) AS quantityonordercommitted " + "FROM apurchaseorderitem WHERE workorderitempartrequestid IS NOT NULL AND (COALESCE(apurchaseorderitem.quantityordered,0)-COALESCE(apurchaseorderitem.quantityreceived,0)) > 0 GROUP BY partid, partwarehouseid"); //VPARTSONORDERUNCOMMITTED await ExecQueryAsync("CREATE VIEW vpartsonorderuncommitted AS SELECT partid, partwarehouseid, SUM((COALESCE(apurchaseorderitem.quantityordered,0)-COALESCE(apurchaseorderitem.quantityreceived,0))) AS quantityonorder " + "FROM apurchaseorderitem WHERE workorderitempartrequestid IS NULL AND (COALESCE(apurchaseorderitem.quantityordered,0)-COALESCE(apurchaseorderitem.quantityreceived,0)) > 0 GROUP BY partid, partwarehouseid"); //VPARTSONORDER await ExecQueryAsync("CREATE VIEW vpartsonorder AS SELECT partid, partwarehouseid, SUM((COALESCE(apurchaseorderitem.quantityordered,0)-COALESCE(apurchaseorderitem.quantityreceived,0))) AS quantityonorder " + "FROM apurchaseorderitem WHERE (COALESCE(apurchaseorderitem.quantityordered,0)-COALESCE(apurchaseorderitem.quantityreceived,0)) > 0 GROUP BY partid, partwarehouseid"); //VIEWRESTOCKREQUIRED (used by PO indirectly through a keyless model in dbset) await ExecQueryAsync("CREATE VIEW viewrestockrequired AS SELECT apart.id AS partid, apartwarehouse.id AS partwarehouseid, apart.name as partname, apart.description as partdescription, apartwarehouse.name AS displaywarehouse, " + "amanufacturer.id AS manufacturerid, amanufacturer.name AS displaymanufacturer, awholesaler.id AS wholesalerid, awholesaler.name AS displaywholesaler, " + "aalternativewholesaler.id AS alternativewholesalerid, aalternativewholesaler.name AS displayalternativewholesaler," + "apartstocklevel.minimumquantity, vpartinventorynow.balance, COALESCE(vpartsonorderuncommitted.quantityonorder,0) AS onorderquantity, " + "apartstocklevel.minimumquantity - (COALESCE(vpartinventorynow.balance, 0) + COALESCE(vpartsonorderuncommitted.quantityonorder, 0)) AS requiredquantity " + "FROM vpartinventorynow " + "LEFT JOIN apart ON vpartinventorynow.partid=apart.id LEFT JOIN apartwarehouse ON vpartinventorynow.partwarehouseid = apartwarehouse.id " + "LEFT JOIN avendor AS amanufacturer ON (apart.manufacturerid = amanufacturer.id) left join avendor AS awholesaler ON (apart.wholesalerid = awholesaler.id)" + "LEFT JOIN avendor AS aalternativewholesaler ON (apart.alternativewholesalerid = aalternativewholesaler.id)" + "LEFT JOIN apartstocklevel ON vpartinventorynow.partid=apartstocklevel.partid AND vpartinventorynow.partwarehouseid=apartstocklevel.partwarehouseid " + "LEFT JOIN vpartsonorderuncommitted ON vpartinventorynow.partid=vpartsonorderuncommitted.partid AND vpartinventorynow.partwarehouseid=vpartsonorderuncommitted.partwarehouseid " + "WHERE apartstocklevel.minimumquantity IS NOT NULL AND (apartstocklevel.minimumquantity - (COALESCE(vpartinventorynow.balance, 0) + COALESCE(vpartsonorderuncommitted.quantityonorder, 0))) >0 " + "ORDER BY requiredquantity DESC"); //VIEWPARTINVENTORYLIST await ExecQueryAsync( "CREATE VIEW viewpartinventorylist AS select apart.id as partid, apart.name as partname, apart.description as partdescription, apart.active as partactive, apart.cost as partcost, apart.retail as partretail," + "apart.tags as parttags, apartwarehouse.id as partwarehouseid, apartwarehouse.name as partwarehousename, awholesaler.name as wholesalername, awholesaler.id as wholesalerid, " + "aaltwholesaler.id as altwholesalerid, aaltwholesaler.name as altwholesalername, vpartinventorynow.balance as onhandqty,COALESCE(vpartsonorder.quantityonorder,0) as onorderqty, " + "COALESCE(vpartsonordercommitted.quantityonordercommitted,0) as onordercommittedqty,COALESCE(apartstocklevel.minimumquantity,0) as restockminqty, " + "GREATEST( COALESCE(apartstocklevel.minimumquantity, 0) - (COALESCE(vpartinventorynow.balance, 0) + COALESCE(vpartsonorder.quantityonorder, 0) - COALESCE(vpartsonordercommitted.quantityonordercommitted, 0)) ,0) AS reorderqty," + "vpartinventorynow.id as partinventoryid, vpartinventorynow.description as partinventorydescription " + "FROM vpartinventorynow LEFT JOIN vpartsonordercommitted ON " + "vpartinventorynow.partid = vpartsonordercommitted.partid AND vpartinventorynow.partwarehouseid = vpartsonordercommitted.partwarehouseid " + "LEFT JOIN vpartsonorder ON vpartinventorynow.partid = vpartsonorder.partid AND vpartinventorynow.partwarehouseid = vpartsonorder.partwarehouseid " + "LEFT JOIN apart ON (vpartinventorynow.partid = apart.id) LEFT JOIN apartwarehouse ON (vpartinventorynow.partwarehouseid = apartwarehouse.id) " + "left join avendor AS awholesaler on (apart.wholesalerid = awholesaler.id) left join avendor AS aaltwholesaler on (apart.alternativewholesalerid = aaltwholesaler.id) " + "left join apartstocklevel on (apartstocklevel.partid = apart.id AND apartstocklevel.partwarehouseid = vpartinventorynow.partwarehouseid);"); //VIEWUNFULFILLEDPARTREQUESTLIST await ExecQueryAsync("CREATE VIEW viewunfulfilledpartrequestlist AS SELECT AWORKORDERITEMPARTREQUEST.ID AS REQUESTID, PARTID, PARTWAREHOUSEID, QUANTITY, AWORKORDER.SERIAL, " + "APART.DESCRIPTION AS PARTDESCRIPTION, APART.NAME AS PARTNAME, APARTWAREHOUSE.NAME AS PARTWAREHOUSENAME, AWHOLESALER.NAME AS WHOLESALERNAME, " + "AWORKORDERITEMPARTREQUEST.REQUESTEDBYUSERID AS REQUESTEDBYUSERID, AUSER.NAME AS REQUESTEDBYUSERNAME, " + "AWHOLESALER.ID AS WHOLESALERID, AALTWHOLESALER.ID AS ALTWHOLESALERID, AALTWHOLESALER.NAME AS ALTWHOLESALERNAME FROM AWORKORDERITEMPARTREQUEST " + "LEFT JOIN AWORKORDERITEM ON AWORKORDERITEM.ID = AWORKORDERITEMPARTREQUEST.WORKORDERITEMID LEFT JOIN AWORKORDER ON AWORKORDERITEM.WORKORDERID = AWORKORDER.ID " + "LEFT JOIN AWORKORDERSTATUS ON AWORKORDER.LASTSTATUSID = AWORKORDERSTATUS.ID LEFT JOIN APART ON AWORKORDERITEMPARTREQUEST.PARTID = APART.ID " + "LEFT JOIN AUSER ON AWORKORDERITEMPARTREQUEST.REQUESTEDBYUSERID = AUSER.ID " + "LEFT JOIN APARTWAREHOUSE ON AWORKORDERITEMPARTREQUEST.PARTWAREHOUSEID = APARTWAREHOUSE.ID LEFT JOIN AVENDOR AS AWHOLESALER ON (APART.WHOLESALERID = AWHOLESALER.ID) " + "LEFT JOIN AVENDOR AS AALTWHOLESALER ON (APART.ALTERNATIVEWHOLESALERID = AALTWHOLESALER.ID) WHERE AWORKORDERITEMPARTREQUEST.PURCHASEORDERITEMID IS NULL AND " + "(AWORKORDER.LASTSTATUSID IS NULL OR AWORKORDERSTATUS.COMPLETED = FALSE) ORDER BY AWORKORDERITEMPARTREQUEST.ID;"); //VIEWPARTINVENTORYREQUESTLIST (note: twinned with pareventoryrequestdatalist, this drives reporting for that datalist which is not reportable directly) await ExecQueryAsync("CREATE VIEW VIEWPARTINVENTORYREQUESTLIST AS SELECT AWORKORDERITEMPARTREQUEST.ID AS REQUESTID, APART.ID AS PARTID, APARTWAREHOUSE.ID AS PARTWAREHOUSEID, QUANTITY, " + "APART.DESCRIPTION AS PARTDESCRIPTION, APART.NAME AS PARTNAME, APARTWAREHOUSE.NAME AS PARTWAREHOUSENAME, AWHOLESALER.NAME AS WHOLESALERNAME, " + "AWORKORDER.SERIAL AS WOSERIAL, AWORKORDERITEMPARTREQUEST.REQUESTDATE, AWORKORDERITEMPARTREQUEST.REQUESTEDBYUSERID AS REQUESTEDBYUSERID, AUSER.NAME AS REQUESTEDBYUSERNAME, " + "AWHOLESALER.ID AS WHOLESALERID, AALTWHOLESALER.ID AS ALTWHOLESALERID, AALTWHOLESALER.NAME AS ALTWHOLESALERNAME, " + "APARTMANU.NAME AS MANUFACTURERNAME, APARTMANU.ID AS MANUFACTURERID, APART.UPC AS PARTUPC, APURCHASEORDER.ID AS PURCHASEORDERID, APURCHASEORDER.SERIAL AS PURCHASEORDERSERIAL, " + "APURCHASEORDER.EXPECTEDRECEIVEDATE AS EXPECTEDRECEIVEDATE, APURCHASEORDER.ORDEREDDATE AS ORDEREDDATE, AWORKORDERITEMPARTREQUEST.RECEIVED AS PARTREQUESTRECEIVED, APOVENDOR.NAME AS PURCHASEORDERVENDOR, " + "APART.MANUFACTURERNUMBER, ACUSTOMER.NAME AS CUSTOMERNAME, ACUSTOMER.ID AS CUSTOMERID, AWORKORDER.LASTSTATUSID AS WOSTATUSID, AWORKORDERSTATUS.COLOR AS STATUSCOLOR, AWORKORDERSTATUS.NAME AS STATUSNAME " + "FROM AWORKORDERITEMPARTREQUEST " + "LEFT JOIN AWORKORDERITEM ON AWORKORDERITEM.ID = AWORKORDERITEMPARTREQUEST.WORKORDERITEMID " + "LEFT JOIN AWORKORDER ON AWORKORDERITEM.WORKORDERID = AWORKORDER.ID " + "LEFT JOIN ACUSTOMER ON AWORKORDER.CUSTOMERID=ACUSTOMER.ID " + "LEFT JOIN APURCHASEORDERITEM ON AWORKORDERITEMPARTREQUEST.PURCHASEORDERITEMID=APURCHASEORDERITEM.ID " + "LEFT JOIN APURCHASEORDER ON APURCHASEORDERITEM.PURCHASEORDERID=APURCHASEORDER.ID " + "LEFT JOIN AWORKORDERSTATUS ON AWORKORDER.LASTSTATUSID = AWORKORDERSTATUS.ID " + "LEFT JOIN APART ON AWORKORDERITEMPARTREQUEST.PARTID = APART.ID " + "LEFT JOIN AUSER ON AWORKORDERITEMPARTREQUEST.REQUESTEDBYUSERID = AUSER.ID " + "LEFT JOIN APARTWAREHOUSE ON AWORKORDERITEMPARTREQUEST.PARTWAREHOUSEID = APARTWAREHOUSE.ID " + "LEFT JOIN AVENDOR AS AWHOLESALER ON APART.WHOLESALERID = AWHOLESALER.ID " + "LEFT JOIN AVENDOR AS AALTWHOLESALER ON APART.ALTERNATIVEWHOLESALERID = AALTWHOLESALER.ID " + "LEFT JOIN AVENDOR AS APOVENDOR ON APURCHASEORDER.VENDORID = APOVENDOR.ID " + "LEFT JOIN AVENDOR AS APARTMANU ON APART.MANUFACTURERID = APARTMANU.ID;"); //---------- /* ██████╗ ██╗ ██╗ ██████╗ ████████╗███████╗ ██╔═══██╗██║ ██║██╔═══██╗╚══██╔══╝██╔════╝ ██║ ██║██║ ██║██║ ██║ ██║ █████╗ ██║▄▄ ██║██║ ██║██║ ██║ ██║ ██╔══╝ ╚██████╔╝╚██████╔╝╚██████╔╝ ██║ ███████╗ ╚══▀▀═╝ ╚═════╝ ╚═════╝ ╚═╝ ╚══════╝ */ //QUOTE STATUS await ExecQueryAsync("CREATE TABLE aquotestatus (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " + "notes TEXT, color VARCHAR(12) NOT NULL default '#000000', selectroles INTEGER NOT NULL, removeroles INTEGER NOT NULL, completed BOOL NOT NULL, locked BOOL NOT NULL)"); //QUOTE await ExecQueryAsync("CREATE TABLE aquote (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial BIGINT GENERATED BY DEFAULT AS IDENTITY NOT NULL, " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, customerid BIGINT NOT NULL REFERENCES acustomer (id), " + "projectid BIGINT REFERENCES aproject, laststatusid BIGINT REFERENCES aquotestatus(id), contractid BIGINT NULL, internalreferencenumber text, " + "customerreferencenumber text, customercontactname text, createddate TIMESTAMPTZ NOT NULL, " + "preparedbyid BIGINT REFERENCES auser(id), introduction TEXT, requested TIMESTAMPTZ, validuntil TIMESTAMPTZ, submitted TIMESTAMPTZ, approved TIMESTAMPTZ, onsite BOOL NOT NULL, " + "postaddress TEXT, postcity TEXT, postregion TEXT, postcountry TEXT, postcode TEXT, address TEXT, city TEXT, region TEXT, country TEXT, latitude DECIMAL(9,6), longitude DECIMAL(9,6) " + ")"); await ExecQueryAsync("CREATE TABLE aquotestate (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteid BIGINT NOT NULL REFERENCES aquote (id), " + "quotestatusid BIGINT NOT NULL REFERENCES aquotestatus (id), created TIMESTAMPTZ NOT NULL, userid BIGINT NOT NULL REFERENCES auser (id)" + ")"); //QUOTEITEM await ExecQueryAsync("CREATE TABLE aquoteitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteid BIGINT NOT NULL REFERENCES aquote (id), " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, technotes TEXT, workorderitemstatusid BIGINT REFERENCES aworkorderitemstatus (id), " + " workorderitempriorityid BIGINT REFERENCES aworkorderitempriority (id), requestdate TIMESTAMPTZ, warrantyservice BOOL NOT NULL, sequence INTEGER" + ")"); //QUOTEITEM EXPENSE await ExecQueryAsync("CREATE TABLE aquoteitemexpense (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "description TEXT, name TEXT, totalcost DECIMAL(38,18) NOT NULL default 0, chargeamount DECIMAL(38,18) NOT NULL default 0, taxpaid DECIMAL(38,18) NOT NULL default 0, " + "chargetaxcodeid BIGINT REFERENCES ataxcode, reimburseuser BOOL NOT NULL, userid BIGINT REFERENCES auser, chargetocustomer BOOL NOT NULL " + ")"); //QUOTEITEM LABOR await ExecQueryAsync("CREATE TABLE aquoteitemlabor (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "userid BIGINT REFERENCES auser, servicestartdate TIMESTAMPTZ, servicestopdate TIMESTAMPTZ, servicerateid BIGINT REFERENCES aservicerate, servicedetails text, " + "serviceratequantity DECIMAL(19,5) NOT NULL default 0, nochargequantity DECIMAL(19,5) NOT NULL default 0, " + "taxcodesaleid BIGINT REFERENCES ataxcode, priceoverride DECIMAL(38,18) " + ")"); //QUOTEITEM LOAN await ExecQueryAsync("CREATE TABLE aquoteitemloan (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "notes TEXT, outdate TIMESTAMPTZ, duedate TIMESTAMPTZ, returndate TIMESTAMPTZ,cost DECIMAL(38,18) NOT NULL default 0, listprice DECIMAL(38,18) NOT NULL default 0, priceoverride DECIMAL(38,18), " + "taxcodeid BIGINT REFERENCES ataxcode, loanunitid BIGINT NOT NULL REFERENCES aloanunit, quantity DECIMAL(19,5) NOT NULL default 0, rate INTEGER NOT NULL" + ")"); //QUOTEITEM PART await ExecQueryAsync("CREATE TABLE aquoteitempart (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "description TEXT, serials TEXT, partid BIGINT NOT NULL REFERENCES apart, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse, quantity DECIMAL(19,5) NOT NULL default 0, " + "cost DECIMAL(38,18) NOT NULL default 0, listprice DECIMAL(38,18) NOT NULL default 0, taxpartsaleid BIGINT REFERENCES ataxcode, priceoverride DECIMAL(38,18) " + ")"); //QUOTEITEM SCHEDULED USER await ExecQueryAsync("CREATE TABLE aquoteitemscheduleduser (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "userid BIGINT REFERENCES auser, startdate TIMESTAMPTZ, stopdate TIMESTAMPTZ, servicerateid BIGINT REFERENCES aservicerate, " + "estimatedquantity DECIMAL(19,5) NOT NULL default 0" + ")"); //QUOTEITEM TASK await ExecQueryAsync("CREATE TABLE aquoteitemtask (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "sequence INTEGER NOT NULL DEFAULT 0, task text NOT NULL, status INTEGER NOT NULL DEFAULT 1, completedbyuserid BIGINT REFERENCES auser, completeddate TIMESTAMPTZ" + ")"); //QUOTEITEM TRAVEL await ExecQueryAsync("CREATE TABLE aquoteitemtravel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "userid BIGINT REFERENCES auser, travelstartdate TIMESTAMPTZ, travelstopdate TIMESTAMPTZ, travelrateid BIGINT REFERENCES atravelrate, traveldetails text, " + "travelratequantity DECIMAL(19,5) NOT NULL default 0, nochargequantity DECIMAL(19,5) NOT NULL default 0, " + "taxcodesaleid BIGINT REFERENCES ataxcode, distance DECIMAL(19,5) NOT NULL default 0, priceoverride DECIMAL(38,18) " + ")"); //QUOTEITEM UNIT await ExecQueryAsync("CREATE TABLE aquoteitemunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, unitid BIGINT NOT NULL REFERENCES aunit" + ")"); //QUOTEITEM OUTSIDE SERVICE await ExecQueryAsync("CREATE TABLE aquoteitemoutsideservice (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, quoteitemid BIGINT NOT NULL REFERENCES aquoteitem (id), " + "notes TEXT, unitid BIGINT NOT NULL REFERENCES aunit, vendorsenttoid BIGINT REFERENCES avendor, vendorsentviaid BIGINT REFERENCES avendor, rmanumber text, trackingnumber text, " + "taxcodeid BIGINT REFERENCES ataxcode, repaircost DECIMAL(38,18) NOT NULL default 0, repairprice DECIMAL(38,18) NOT NULL default 0, shippingcost DECIMAL(38,18) NOT NULL default 0, shippingprice DECIMAL(38,18) NOT NULL default 0, " + "SentDate TIMESTAMPTZ, etadate TIMESTAMPTZ, returndate TIMESTAMPTZ" + ")"); /////////////////////////////////////////////////////////////////////////////////////// /* ██████╗ ███╗ ███╗ ██╔══██╗████╗ ████║ ██████╔╝██╔████╔██║ ██╔═══╝ ██║╚██╔╝██║ ██║ ██║ ╚═╝ ██║ ╚═╝ ╚═╝ ╚═╝ */ //PM await ExecQueryAsync("CREATE TABLE apm (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, serial BIGINT GENERATED BY DEFAULT AS IDENTITY NOT NULL, " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, customerid BIGINT NOT NULL REFERENCES acustomer (id), " + "projectid BIGINT REFERENCES aproject, contractid BIGINT NULL, internalreferencenumber text, " + "customerreferencenumber text, customercontactname text, createddate TIMESTAMPTZ NOT NULL, onsite BOOL NOT NULL, " + "stopgeneratingdate TIMESTAMPTZ, nextservicedate TIMESTAMPTZ NOT NULL, generatedate TIMESTAMPTZ NOT NULL, excludedaysofweek INTEGER NOT NULL," + "active BOOL NOT NULL, repeatunit INTEGER NOT NULL, generatebeforeunit INTEGER NOT NULL, repeatinterval INTEGER NOT NULL, " + "generatebeforeinterval INTEGER NOT NULL, copywiki BOOL NOT NULL, copyattachments BOOL NOT NULL, " + "postaddress TEXT, postcity TEXT, postregion TEXT, postcountry TEXT, postcode TEXT, address TEXT, city TEXT, region TEXT, country TEXT, latitude DECIMAL(9,6), longitude DECIMAL(9,6) " + ")"); //PMITEM await ExecQueryAsync("CREATE TABLE apmitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmid BIGINT NOT NULL REFERENCES apm (id), " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, technotes TEXT, workorderitemstatusid BIGINT REFERENCES aworkorderitemstatus (id), " + " workorderitempriorityid BIGINT REFERENCES aworkorderitempriority (id), requestdate TIMESTAMPTZ, warrantyservice BOOL NOT NULL, sequence INTEGER" + ")"); //PMITEM EXPENSE await ExecQueryAsync("CREATE TABLE apmitemexpense (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "description TEXT, name TEXT, totalcost DECIMAL(38,18) NOT NULL default 0, chargeamount DECIMAL(38,18) NOT NULL default 0, taxpaid DECIMAL(38,18) NOT NULL default 0, " + "chargetaxcodeid BIGINT REFERENCES ataxcode, reimburseuser BOOL NOT NULL, userid BIGINT REFERENCES auser, chargetocustomer BOOL NOT NULL " + ")"); //PMITEM LABOR await ExecQueryAsync("CREATE TABLE apmitemlabor (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "userid BIGINT REFERENCES auser, servicestartdate TIMESTAMPTZ, servicestopdate TIMESTAMPTZ, servicerateid BIGINT REFERENCES aservicerate, servicedetails text, " + "serviceratequantity DECIMAL(19,5) NOT NULL default 0, nochargequantity DECIMAL(19,5) NOT NULL default 0, " + "taxcodesaleid BIGINT REFERENCES ataxcode, priceoverride DECIMAL(38,18) " + ")"); //PMITEM LOAN await ExecQueryAsync("CREATE TABLE apmitemloan (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "notes TEXT, outdate TIMESTAMPTZ, duedate TIMESTAMPTZ, returndate TIMESTAMPTZ,cost DECIMAL(38,18) NOT NULL default 0, listprice DECIMAL(38,18) NOT NULL default 0, priceoverride DECIMAL(38,18), " + "taxcodeid BIGINT REFERENCES ataxcode, loanunitid BIGINT NOT NULL REFERENCES aloanunit, quantity DECIMAL(19,5) NOT NULL default 0, rate INTEGER NOT NULL" + ")"); //PMITEM PART await ExecQueryAsync("CREATE TABLE apmitempart (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "description TEXT, serials TEXT, partid BIGINT NOT NULL REFERENCES apart, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse, quantity DECIMAL(19,5) NOT NULL default 0, " + "cost DECIMAL(38,18) NOT NULL default 0, listprice DECIMAL(38,18) NOT NULL default 0, taxpartsaleid BIGINT REFERENCES ataxcode, priceoverride DECIMAL(38,18) " + ")"); //PMITEM SCHEDULED USER await ExecQueryAsync("CREATE TABLE apmitemscheduleduser (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "userid BIGINT REFERENCES auser, startdate TIMESTAMPTZ, stopdate TIMESTAMPTZ, servicerateid BIGINT REFERENCES aservicerate, " + "estimatedquantity DECIMAL(19,5) NOT NULL default 0" + ")"); //PMITEM TASK await ExecQueryAsync("CREATE TABLE apmitemtask (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "sequence INTEGER NOT NULL DEFAULT 0, task text NOT NULL, status INTEGER NOT NULL DEFAULT 1, completedbyuserid BIGINT REFERENCES auser, completeddate TIMESTAMPTZ" + ")"); //PMITEM TRAVEL await ExecQueryAsync("CREATE TABLE apmitemtravel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "userid BIGINT REFERENCES auser, travelstartdate TIMESTAMPTZ, travelstopdate TIMESTAMPTZ, travelrateid BIGINT REFERENCES atravelrate, traveldetails text, " + "travelratequantity DECIMAL(19,5) NOT NULL default 0, nochargequantity DECIMAL(19,5) NOT NULL default 0, " + "taxcodesaleid BIGINT REFERENCES ataxcode, distance DECIMAL(19,5) NOT NULL default 0, priceoverride DECIMAL(38,18) " + ")"); //PMITEM UNIT await ExecQueryAsync("CREATE TABLE apmitemunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, unitid BIGINT NOT NULL REFERENCES aunit" + ")"); //PMITEM OUTSIDE SERVICE await ExecQueryAsync("CREATE TABLE apmitemoutsideservice (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, pmitemid BIGINT NOT NULL REFERENCES apmitem (id), " + "notes TEXT, unitid BIGINT NOT NULL REFERENCES aunit, vendorsenttoid BIGINT REFERENCES avendor, vendorsentviaid BIGINT REFERENCES avendor, rmanumber text, trackingnumber text, " + "taxcodeid BIGINT REFERENCES ataxcode, repaircost DECIMAL(38,18) NOT NULL default 0, repairprice DECIMAL(38,18) NOT NULL default 0, shippingcost DECIMAL(38,18) NOT NULL default 0, shippingprice DECIMAL(38,18) NOT NULL default 0, " + "SentDate TIMESTAMPTZ, etadate TIMESTAMPTZ, returndate TIMESTAMPTZ" + ")"); //########################################################################################################### /////////////////////////////////////////////////////////////////////////////////////////////////////////////// //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 TIMESTAMPTZ 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 " + ")"); //WORKORDER "FROM" LINKS await ExecQueryAsync("ALTER TABLE aworkorder ADD column fromquoteid BIGINT REFERENCES aquote (id), ADD column frompmid BIGINT REFERENCES apm (id)"); await ExecQueryAsync("ALTER TABLE aworkorderitem ADD column fromcsrid BIGINT REFERENCES acustomerservicerequest (id)"); //VIEWWORKORDER - adds AGE expression column for datalist queries //do *not* use the postgre AGE function, it's not intended for code use: https://github.com/npgsql/efcore.pg/issues/2157 // await ExecQueryAsync("CREATE VIEW viewworkorder AS select aworkorder.*, AGE(timezone('UTC', now()), aworkorder.createddate) as expwoage from aworkorder"); await ExecQueryAsync("CREATE VIEW viewworkorder AS select aworkorder.*, now() - aworkorder.createddate as expwoage from aworkorder"); //NOTIFICATION await ExecQueryAsync("CREATE TABLE anotifysubscription (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " + "userid BIGINT NOT NULL REFERENCES auser (id) ON DELETE CASCADE, ayatype INTEGER NOT NULL, eventtype INTEGER NOT NULL, advancenotice INTERVAL NOT NULL, " + "idvalue BIGINT NOT NULL, decvalue DECIMAL(38,18) NOT NULL, agevalue INTERVAL NOT NULL, deliverymethod INTEGER NOT NULL, " + "deliveryaddress TEXT, linkreportid BIGINT, tags VARCHAR(255) ARRAY)"); await ExecQueryAsync("CREATE TABLE anotifyevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created TIMESTAMPTZ 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) ON DELETE CASCADE, eventdate TIMESTAMPTZ NOT NULL, decvalue DECIMAL(38,18) NULL, message TEXT)"); await ExecQueryAsync("CREATE TABLE ainappnotification (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, userid BIGINT NOT NULL REFERENCES auser (id) ON DELETE CASCADE, " + "created TIMESTAMPTZ NOT NULL, ayatype INTEGER NOT NULL, objectid BIGINT NOT NULL, name TEXT NOT NULL, agevalue INTERVAL, eventtype INTEGER NOT NULL, " + "decvalue DECIMAL(38,18) 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 TIMESTAMPTZ NOT NULL, " + "objectid BIGINT NOT NULL, notifysubscriptionid BIGINT NOT NULL, fail BOOL NOT NULL, error TEXT)"); //CUSTOMER "proxy" NOTIFICATION await ExecQueryAsync("CREATE TABLE acustomernotifysubscription (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, " + "translationid BIGINT NOT NULL REFERENCES atranslation (id) NOT NULL, languageoverride TEXT NOT NULL, timezoneoverride TEXT NOT NULL, " + "currencyname TEXT NOT NULL, hour12 BOOL NOT NULL, " + "customertags VARCHAR(255) ARRAY, ayatype INTEGER NOT NULL, eventtype INTEGER NOT NULL, advancenotice INTERVAL NOT NULL, " + "idvalue BIGINT NOT NULL, decvalue DECIMAL(38,18) NOT NULL, agevalue INTERVAL NOT NULL, " + "linkreportid BIGINT, template TEXT NOT NULL, subject TEXT NOT NULL, tags VARCHAR(255) ARRAY)"); await ExecQueryAsync("CREATE TABLE acustomernotifyevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created TIMESTAMPTZ NOT NULL, " + "ayatype INTEGER NOT NULL, objectid BIGINT NOT NULL, name TEXT NOT NULL, eventtype INTEGER NOT NULL, customernotifysubscriptionid BIGINT NOT NULL REFERENCES acustomernotifysubscription(id) ON DELETE CASCADE, " + "customerid BIGINT NOT NULL REFERENCES acustomer (id) ON DELETE CASCADE, eventdate TIMESTAMPTZ NOT NULL, decvalue DECIMAL(38,18) NULL)"); await ExecQueryAsync("CREATE TABLE acustomernotifydeliverylog (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, processed TIMESTAMPTZ NOT NULL, " + "objectid BIGINT NOT NULL, customernotifysubscriptionid BIGINT NOT NULL, fail BOOL NOT NULL, error TEXT)"); //UNITMETERREADING await ExecQueryAsync("CREATE TABLE aunitmeterreading (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, meterdate TIMESTAMPTZ NOT NULL, notes TEXT, " + "meter BIGINT NOT NULL, unitid BIGINT NOT NULL REFERENCES aunit(id) ON DELETE CASCADE, workorderitemunitid BIGINT REFERENCES aworkorderitemunit(id) ON DELETE SET NULL)"); //LOGO 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)"); //REPORTS await ExecQueryAsync("CREATE TABLE areport (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, active BOOL NOT NULL, " + "notes TEXT, roles INTEGER NOT NULL, atype INTEGER NOT NULL, includewoitemdescendants BOOL, 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(10,5), UNIQUE(name,atype))"); //Global customer default workorder report default await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD column customerdefaultworkorderreportid BIGINT REFERENCES areport(id) "); await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD column customertagworkorderreport1id BIGINT REFERENCES areport(id) "); await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD column customertagworkorderreport2id BIGINT REFERENCES areport(id) "); await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD column customertagworkorderreport3id BIGINT REFERENCES areport(id) "); await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD column customertagworkorderreport4id BIGINT REFERENCES areport(id) "); await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD column customertagworkorderreport5id BIGINT REFERENCES areport(id) "); //Load the stock REPORT TEMPLATES await AyaNova.Biz.PrimeData.PrimeReportTemplates(); //DASHBOARD 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); //PART DATA LIST VIEW //required to include serials from partserials table await ExecQueryAsync("CREATE OR REPLACE VIEW viewpartsdatalist AS SELECT APART.*, AMAN.NAME AS MANNAME, AMAN.ID AS MANID, AWHOLE.NAME AS WHOLENAME,AWHOLE.ID AS WHOLEID, " + "AALTWHOLE.NAME AS ALTWHOLENAME, AALTWHOLE.ID AS ALTWHOLEID, (SELECT ARRAY_TO_STRING(ARRAY_AGG(serial),', ') FROM APARTSERIAL WHERE PARTID = APART.ID GROUP BY PARTID) AS PARTSERIALS " + "FROM APART LEFT JOIN AVENDOR AS AMAN ON (APART.MANUFACTURERID = AMAN.ID) LEFT JOIN AVENDOR AS AWHOLE ON (APART.WHOLESALERID = AWHOLE.ID) LEFT JOIN AVENDOR AS AALTWHOLE ON (APART.ALTERNATIVEWHOLESALERID = AALTWHOLE.ID)"); //SCHEDULE VIEWS //WORKORDERS await ExecQueryAsync("CREATE VIEW VIEWSCHEDULEWORKORDER AS SELECT " + "AWORKORDERITEMSCHEDULEDUSER.ID AS WOITEMSCHEDUSERID, " + "AWORKORDERITEMSCHEDULEDUSER.USERID AS SCHEDUSERID, " + "AWORKORDERITEMSCHEDULEDUSER.STARTDATE, " + "AWORKORDERITEMSCHEDULEDUSER.STOPDATE, " + "AWORKORDER.SERIAL, ACUSTOMER.NAME AS CUSTOMERNAME, " + "AWORKORDERSTATUS.COLOR AS WORKORDERSTATUSCOLOR, " + "AWORKORDERSTATUS.COMPLETED AS WORKORDERSTATUSCOMPLETED, " + "AWORKORDERSTATUS.LOCKED AS WORKORDERSTATUSLOCKED, " + "AWORKORDERITEMSTATUS.COLOR AS WORKORDERITEMSTATUSCOLOR, " + "AWORKORDERITEMPRIORITY.COLOR AS WORKORDERITEMPRIORITYCOLOR " + "FROM AWORKORDERITEMSCHEDULEDUSER " + "LEFT JOIN AWORKORDERITEM ON AWORKORDERITEMSCHEDULEDUSER.WORKORDERITEMID = AWORKORDERITEM.ID " + "LEFT JOIN AWORKORDER ON AWORKORDERITEM.WORKORDERID = AWORKORDER.ID " + "LEFT JOIN ACUSTOMER ON AWORKORDER.CUSTOMERID = ACUSTOMER.ID " + "LEFT JOIN AWORKORDERSTATUS ON AWORKORDER.LASTSTATUSID = AWORKORDERSTATUS.ID " + "LEFT JOIN AWORKORDERITEMSTATUS ON AWORKORDERITEM.WORKORDERITEMSTATUSID = AWORKORDERITEMSTATUS.ID " + "LEFT JOIN AWORKORDERITEMPRIORITY ON AWORKORDERITEM.WORKORDERITEMPRIORITYID = AWORKORDERITEMPRIORITY.ID"); } ////////////////////////////////////////////////// // // Beta .2 new translation keys for import feature // if (currentSchema < 2) { LogUpdateMessage(log); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ImportNewRecords', 'Import new records' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'UpdateExistingRecords', 'Update existing records' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AdminImportUpdateWarning', 'Warning: you are about to permanently change multiple objects.\r\nAre you sure?' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'FileToImport', 'File to import' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProcessCompleted', 'Process completed' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ImportNewRecords', 'Importar nuevos registros' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'UpdateExistingRecords', 'Actualizar registros existentes' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AdminImportUpdateWarning', 'Advertencia: está a punto de cambiar varios objetos de forma permanente.\r\n¿Está seguro?' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'FileToImport', 'Archivo a importar' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProcessCompleted', 'Proceso completado' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ImportNewRecords', 'Importer de nouveaux enregistrements' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'UpdateExistingRecords', 'Mettre à jour les enregistrements existants' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AdminImportUpdateWarning', 'Avertissement: vous êtes sur le point de modifier définitivement plusieurs objets.\r\nÊtes-vous sûr?' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'FileToImport', 'Fichier à importer' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProcessCompleted', 'Processus terminé' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ImportNewRecords', 'Importieren Sie neue Datensätze' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'UpdateExistingRecords', 'Aktualisieren Sie vorhandene Datensätze' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AdminImportUpdateWarning', 'Warnung: Sie sind dabei, mehrere Objekte dauerhaft zu ändern.\r\nSind Sie sicher?' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'FileToImport', 'Zu importierende Datei' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProcessCompleted', 'Prozess abgeschlossen' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } //////////////////////////////////////////////// // rc 1 remove default rate from loan unit // if (currentSchema < 3) { LogUpdateMessage(log); await ExecQueryAsync("DELETE FROM atranslationitem where key = 'LoanUnitDefaultRate'"); await ExecQueryAsync("ALTER TABLE aloanunit DROP COLUMN defaultrate;"); await SetSchemaLevelAsync(++currentSchema); } //////////////////////////////////////////////// // rc 2 integration objects for QBI etc // if (currentSchema < 4) { LogUpdateMessage(log); //INTEGRATION await ExecQueryAsync("CREATE TABLE aintegration (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, integrationappid uuid NOT NULL UNIQUE, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, " + "integrationdata TEXT )"); //INTEGRATIONITEM await ExecQueryAsync("CREATE TABLE aintegrationitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, integrationid BIGINT NOT NULL REFERENCES aintegration ON DELETE CASCADE, " + "atype INTEGER NOT NULL, objectid BIGINT NOT NULL, integrationitemid TEXT NOT NULL, integrationitemname TEXT, lastsync TIMESTAMPTZ, integrationitemdata TEXT " + ")"); //INTEGRATIONLOG await ExecQueryAsync("CREATE TABLE aintegrationlog (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, integrationid BIGINT NOT NULL REFERENCES aintegration ON DELETE CASCADE, created TIMESTAMPTZ NOT NULL, statustext TEXT NOT NULL)"); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationList', 'Integrated applications' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Integration', 'Integrated application' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationName', 'Name' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationList', 'Aplicaciones integradas' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Integration', 'Aplicación integrada' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationName', 'Nombre' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationList', 'Applications intégrées' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Integration', 'Application intégrée' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationName', 'Nom' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationList', 'Integrierte Anwendungen' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Integration', 'Integrierte Anwendung' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationName', 'Name' FROM atranslation t where t.baselanguage = 'de'"); //UPDATED NAME FETCHER FOR INTEGRATION await ExecQueryAsync(@" CREATE OR REPLACE FUNCTION PUBLIC.AYGETNAME(IN AYOBJECTID BIGINT, IN AYATYPE INTEGER,TRANSLATIONID integer) RETURNS TEXT AS $BODY$ DECLARE aytable TEXT DEFAULT ''; aynamecolumn TEXT DEFAULT 'name'; aytkey TEXT DEFAULT 'no'; returnstr TEXT DEFAULT ''; BEGIN case ayatype when 0 then aytkey= 'NoType'; when 1 then aytkey= 'Global'; when 2 then return 'FormUserOptions'; when 3 then aytable = 'auser'; when 4 then aytkey= 'ServerState'; when 5 then aytkey= 'License'; when 6 then aytkey= 'LogFile'; when 7 then aytkey= 'PickListTemplate'; when 8 then aytable = 'acustomer'; when 9 then aytkey= 'ServerJob'; when 10 then aytable = 'acontract'; when 11 then aytkey= 'TrialSeeder'; when 12 then aytkey= 'ServerMetrics'; when 13 then aytable = 'atranslation'; when 14 then aytkey= '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'; when 21 then aytable = 'apm'; aynamecolumn ='serial'; when 22 then aytkey= 'PMItem'; when 23 then aytkey= 'WorkOrderItemExpense'; when 24 then aytkey= 'WorkOrderItemLabor'; when 25 then aytable = 'aproject'; when 26 then aytable = 'apurchaseorder'; aynamecolumn = 'serial'; when 27 then aytable = 'aquote'; aynamecolumn = 'serial'; when 28 then aytkey= 'QuoteItem'; when 29 then aytkey= 'WorkOrderItemLoan'; when 30 then aytkey= 'WorkOrderItemPart'; when 31 then aytable = 'aunit'; aynamecolumn = 'serial'; when 32 then aytable = 'aunitmodel'; aynamecolumn = 'name'; when 33 then aytable = 'avendor'; when 34 then aytable = 'aworkorder'; aynamecolumn = 'serial'; when 35 then aytkey= 'WorkOrderItem'; when 36 then aytkey= 'WorkOrderItemExpense'; when 37 then aytkey= 'WorkOrderItemLabor'; when 38 then aytkey= 'WorkOrderItemLoan'; when 39 then aytkey= 'WorkOrderItemPart'; when 40 then aytkey= 'WorkOrderItemPartRequest'; when 41 then aytkey= 'WorkOrderItemScheduledUser'; when 42 then aytkey= 'WorkOrderItemTask'; when 43 then aytkey= 'WorkOrderItemTravel'; when 44 then aytkey= 'WorkOrderItemUnit'; when 45 then aytkey= 'WorkOrderItemScheduledUser'; when 46 then aytkey= 'WorkOrderItemTask'; when 47 then aytkey= 'GlobalOps'; when 48 then aytkey= 'BizMetrics'; when 49 then aytkey= 'Backup'; when 50 then aytable = 'ainappnotification'; when 51 then aytkey= 'NotifySubscription'; when 52 then aytable = 'areminder'; when 53 then aytkey= 'UnitMeterReading'; when 54 then aytable = 'acustomerservicerequest'; when 56 then aytkey= 'OpsNotificationSettings'; when 57 then aytable = 'areport'; when 58 then aytkey= '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); when 71 then aytable = 'aworkorderstatus'; when 72 then aytable = 'ataskgroup'; when 73 then aytkey= 'WorkOrderItemOutsideService'; when 74 then aytable = 'aworkorderitempriority'; when 75 then aytable = 'aworkorderitemstatus'; when 76 then aytkey= 'WorkOrderItemTravel'; when 77 then aytkey= 'QuoteItemUnit'; when 78 then aytable = 'aquotestatus'; when 79 then aytkey= 'WorkOrderItemOutsideService'; when 80 then aytkey= 'WorkOrderItemExpense'; when 81 then aytkey= 'WorkOrderItemLabor'; when 82 then aytkey= 'WorkOrderItemLoan'; when 83 then aytkey= 'WorkOrderItemPart'; when 84 then aytkey= 'CustomerNotifySubscription'; when 85 then aytkey= 'WorkOrderItemScheduledUser'; when 86 then aytkey= 'WorkOrderItemTask'; when 87 then aytkey= 'WorkOrderItemTravel'; when 88 then aytkey= 'WorkOrderItemUnit'; when 89 then aytkey= 'WorkOrderItemOutsideService'; when 90 then aytkey= 'PartInventoryDataList'; when 91 then return 'PartInventoryRequestDataList synthetic unnamed object'; when 92 then aytable = 'aintegration'; else RETURN returnstr; end case; IF aytkey='no' then EXECUTE format('SELECT %I FROM %I WHERE id = %L', aynamecolumn, aytable, ayobjectid) INTO returnstr; else EXECUTE format('select display from atranslationitem where translationid=%L and key=%L', TRANSLATIONID, aytkey) INTO returnstr; END if; RETURN returnstr; END; $BODY$ LANGUAGE PLPGSQL STABLE"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // 8.0.7 Subscription license trans keys // if (currentSchema < 5) { LogUpdateMessage(log); //LicenseType, LicenseTypeSubscription, LicenseTypePerpetual //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseType', 'License type' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseTypeSubscription', 'Subscription' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseTypePerpetual', 'Perpetual' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseType', 'Tipo de licencia' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseTypeSubscription', 'Suscripción' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseTypePerpetual', 'Perpetuo' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseType', 'Type de licence' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseTypeSubscription', 'Abonnement' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseTypePerpetual', 'Perpétuel' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseType', 'Lizenz-Typ' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseTypeSubscription', 'Abonnement' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseTypePerpetual', 'Ewig' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // 8.0.7 additions for customer contact licensing (allowlogin) // if (currentSchema < 6) { LogUpdateMessage(log); //!!WARNING: changes TO AUSER need to be reflected in dbutil::EmptyBizDataFromDatabaseForSeedingOrImportingAsync auser_backup await ExecQueryAsync("ALTER TABLE auser ADD column allowlogin BOOL"); await ExecQueryAsync("UPDATE auser SET allowlogin=true WHERE active=true"); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AllowLogin', 'Allow login' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AllowLogin', 'Permitir acceso' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AllowLogin', 'Autoriser la connexion' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AllowLogin', 'Login erlauben' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // 8.0.7 additions for license related display // if (currentSchema < 7) { LogUpdateMessage(log); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveTechUserCount', 'Active scheduleable Users' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveCustomerContactUserCount', 'Active Customer Contact login Users' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveInternalUserCount', 'Active internal Users' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveTechUserCount', 'Técnico de horario activo Usuarios' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveCustomerContactUserCount', 'Usuarios de inicio de sesión de contacto de cliente activo' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveInternalUserCount', 'Usuarios internos activos' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveTechUserCount', 'Utilisateurs planifiables actifs' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveCustomerContactUserCount', 'Utilisateurs de connexion de contact client actifs' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveInternalUserCount', 'Utilisateurs internes actifs' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveTechUserCount', 'Aktive planbare Benutzer' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveCustomerContactUserCount', 'Aktive Kundenkontakt-Login-Benutzer' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ActiveInternalUserCount', 'Aktive interne Benutzer' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // 8.0.14 additions for job feedback // if (currentSchema < 8) { LogUpdateMessage(log); await ExecQueryAsync("ALTER TABLE aopsjob ADD column progress TEXT"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4237 // if (currentSchema < 9) { LogUpdateMessage(log); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewWorkOrder', 'New work order' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewWorkOrder', 'nueva orden de trabajo' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewWorkOrder', 'Nouvel ordre de travail' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewWorkOrder', 'Neuer Arbeitsauftrag' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4239 // if (currentSchema < 10) { LogUpdateMessage(log); await ExecQueryAsync(@" CREATE OR REPLACE VIEW public.viewpartinventorylist AS SELECT apart.id AS partid, apart.name AS partname, apart.description AS partdescription, apart.active AS partactive, apart.cost AS partcost, apart.retail AS partretail, apart.tags AS parttags, apartwarehouse.id AS partwarehouseid, apartwarehouse.name AS partwarehousename, awholesaler.name AS wholesalername, awholesaler.id AS wholesalerid, aaltwholesaler.id AS altwholesalerid, aaltwholesaler.name AS altwholesalername, vpartinventorynow.balance AS onhandqty, COALESCE(vpartsonorder.quantityonorder, 0::numeric) AS onorderqty, COALESCE(vpartsonordercommitted.quantityonordercommitted, 0::numeric) AS onordercommittedqty, COALESCE(apartstocklevel.minimumquantity, 0::numeric) AS restockminqty, GREATEST(COALESCE(apartstocklevel.minimumquantity, 0::numeric) - (COALESCE(vpartinventorynow.balance, 0::numeric) + COALESCE(vpartsonorder.quantityonorder, 0::numeric) - COALESCE(vpartsonordercommitted.quantityonordercommitted, 0::numeric)), 0::numeric) AS reorderqty, vpartinventorynow.id AS partinventoryid, vpartinventorynow.description AS partinventorydescription, amanufacturer.name AS manufacturername, amanufacturer.id AS manufacturerid FROM vpartinventorynow LEFT JOIN vpartsonordercommitted ON vpartinventorynow.partid = vpartsonordercommitted.partid AND vpartinventorynow.partwarehouseid = vpartsonordercommitted.partwarehouseid LEFT JOIN vpartsonorder ON vpartinventorynow.partid = vpartsonorder.partid AND vpartinventorynow.partwarehouseid = vpartsonorder.partwarehouseid LEFT JOIN apart ON vpartinventorynow.partid = apart.id LEFT JOIN apartwarehouse ON vpartinventorynow.partwarehouseid = apartwarehouse.id LEFT JOIN avendor awholesaler ON apart.wholesalerid = awholesaler.id LEFT JOIN avendor aaltwholesaler ON apart.alternativewholesalerid = aaltwholesaler.id LEFT JOIN avendor amanufacturer ON apart.manufacturerid = amanufacturer.id LEFT JOIN apartstocklevel ON apartstocklevel.partid = apart.id AND apartstocklevel.partwarehouseid = vpartinventorynow.partwarehouseid; "); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4242 // if (currentSchema < 11) { LogUpdateMessage(log); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewCustomer', 'New customer' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewCustomer', 'Nuevo cliente' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewCustomer', 'Nouveau client' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewCustomer', 'Neukunde' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4173 // if (currentSchema < 12) { LogUpdateMessage(log); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NotifyEventDirectSMTPMessage', 'On request SMTP' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NotifyEventDirectSMTPMessage', 'Bajo petición SMTP' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NotifyEventDirectSMTPMessage', 'SMTP demandé' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NotifyEventDirectSMTPMessage', 'Auf Anfrage SMTP' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4322 User name uniqueness constraint problematic // if (currentSchema < 13) { LogUpdateMessage(log); await ExecQueryAsync("ALTER TABLE auser DROP CONSTRAINT auser_name_key;"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4341 // if (currentSchema < 14) { LogUpdateMessage(log); await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD COLUMN addresspostal TEXT;"); await ExecQueryAsync("ALTER TABLE acustomer ADD COLUMN addresspostal TEXT;"); await ExecQueryAsync("ALTER TABLE aheadoffice ADD COLUMN addresspostal TEXT;"); await ExecQueryAsync("ALTER TABLE avendor ADD COLUMN addresspostal TEXT;"); await ExecQueryAsync("ALTER TABLE aunit ADD COLUMN addresspostal TEXT;"); await ExecQueryAsync("ALTER TABLE aworkorder ADD COLUMN addresspostal TEXT;"); await ExecQueryAsync("ALTER TABLE aquote ADD COLUMN addresspostal TEXT;"); await ExecQueryAsync("ALTER TABLE apm ADD COLUMN addresspostal TEXT;"); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AddressPostal', 'Postal / ZIP code' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AddressPostal', 'Código postal' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AddressPostal', 'Code postal' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AddressPostal', 'Postleitzahl' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4341 missing bit // if (currentSchema < 15) { LogUpdateMessage(log); //Note: for future reference PostgreSQL can't handle replacing a view with different columns so it must be dropped explicitly first then created again //replace view error cannot change name of view column await ExecQueryAsync("DROP VIEW viewworkorder"); await ExecQueryAsync("CREATE VIEW viewworkorder AS SELECT aworkorder.*, now() - aworkorder.createddate AS expwoage FROM aworkorder"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4503 // if (currentSchema < 16) { LogUpdateMessage(log); //seriously, how does one get this far into a big business application and not have a Save as yet? //inconceivable! //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SaveAs', 'Save as' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SaveAs', 'Guardar como' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SaveAs', 'Enregistrer sous' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SaveAs', 'Speichern unter' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4491 // if (currentSchema < 17) { LogUpdateMessage(log); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ServerUpdateAvailable', 'New version available' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ServerUpdateAvailable', 'Nueva versión disponible' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ServerUpdateAvailable', 'Nouvelle version disponible' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ServerUpdateAvailable', 'Neue Version verfügbar' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4522 // if (currentSchema < 18) { LogUpdateMessage(log); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseExpirationDays', 'Days before license expires' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseExpirationDays', 'Días antes de que caduque la licencia' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseExpirationDays', 'Jours avant l''expiration de la licence' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseExpirationDays', 'Tage vor Ablauf der Lizenz' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } ////////////////////////////////////////////////// // // case 4173 // if (currentSchema < 19) { LogUpdateMessage(log); //english translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'BatchDirectSMTP', 'Batch email job' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SendEmail', 'Send email' FROM atranslation t where t.baselanguage = 'en'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'EmailMultipleObjectsWarning', 'Warning: you are about to send an email to multiple objects.\r\nAre you sure?' FROM atranslation t where t.baselanguage = 'en'"); //spanish translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'BatchDirectSMTP', 'Trabajo de correo electrónico por lotes' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SendEmail', 'Enviar correo electrónico' FROM atranslation t where t.baselanguage = 'es'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'EmailMultipleObjectsWarning', 'Advertencia: está a punto de enviar un correo electrónico a varios objetos.\r\n¿Está seguro?' FROM atranslation t where t.baselanguage = 'es'"); //french translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'BatchDirectSMTP', 'Tâche d''e-mail par lots' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SendEmail', 'Envoyer un e-mail' FROM atranslation t where t.baselanguage = 'fr'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'EmailMultipleObjectsWarning', 'Avertissement : vous êtes sur le point d''envoyer un e-mail à plusieurs objets.\r\nÊtes-vous sûr?' FROM atranslation t where t.baselanguage = 'fr'"); //german translations await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'BatchDirectSMTP', 'Batch-E-Mail-Job' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SendEmail', 'E-Mail senden' FROM atranslation t where t.baselanguage = 'de'"); await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'EmailMultipleObjectsWarning', 'Warnung: Sie sind im Begriff, eine E-Mail an mehrere Objekte zu senden.\r\nSind Sie sicher?' FROM atranslation t where t.baselanguage = 'de'"); await SetSchemaLevelAsync(++currentSchema); } //######################################### //!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!! ////////////////////////////////////////////////// // FUTURE // if (currentSchema < xx) // { // LogUpdateMessage(log); // exec queries here to do updates // await SetSchemaLevelAsync(++currentSchema); // } /*AdminImportUpdateWarning INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'mytestkey', 'mytestdisplay' FROM atranslation t where t.baselanguage = 'en' */ //Handle newer schema than expected (user ran a new version then downgraded ayanova) if (currentSchema > DESIRED_SCHEMA_LEVEL) throw new ArgumentOutOfRangeException($"DB Schema error: the database has a newer schema version {currentSchema} than this version of AyaNova expects {DESIRED_SCHEMA_LEVEL}\nThis version of AyaNova is older than a previous version that was used with this database and is not compatible with the new database format.\nUpgrade AyaNova or restore a backup of the database from before the newer version of AyaNova was used."); log.LogInformation("Completed updating database schema to version {0}", currentSchema); //************************************************************************************* if (PrimeEmptyDB) { // //Load the default TRANSLATIONS // await AyaNova.Biz.PrimeData.PrimeTranslations(); //Prime the db with the default SuperUser account await AyaNova.Biz.PrimeData.PrimeSuperUserAccount(ct); } }//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 }