1211 lines
87 KiB
C#
1211 lines
87 KiB
C#
using System;
|
|
using System.Threading.Tasks;
|
|
using Microsoft.Extensions.Logging;
|
|
using Microsoft.EntityFrameworkCore;
|
|
using AyaNova.Models;
|
|
|
|
namespace AyaNova.Util
|
|
{
|
|
|
|
//Key generator controller
|
|
public static class AySchema
|
|
{
|
|
private static ILogger log;
|
|
private static AyContext ct;
|
|
|
|
|
|
|
|
|
|
/////////////////////////////////////////////////////////////////
|
|
/////////// CHANGE THIS ON NEW SCHEMA UPDATE ////////////////////
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
private const int DESIRED_SCHEMA_LEVEL = 1;
|
|
|
|
internal const long EXPECTED_COLUMN_COUNT = 1095;
|
|
internal const long EXPECTED_INDEX_COUNT = 137;
|
|
internal const long EXPECTED_CHECK_CONSTRAINTS = 460;
|
|
internal const long EXPECTED_FOREIGN_KEY_CONSTRAINTS = 156;
|
|
internal const long EXPECTED_VIEWS = 7;
|
|
internal const long EXPECTED_ROUTINES = 2;
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
///////////////////////////////////////////////////////////////// C1095:I137:CC460:FC156:V7: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(8,5) largest tax I could find would fit in this, that's 3 digits to left and 5 to right
|
|
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()}');";
|
|
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 ******************
|
|
|
|
//////////////////////////////////////////////////
|
|
// v8 initial release TABLES
|
|
//
|
|
if (currentSchema < 1)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//create global biz settings table
|
|
await ExecQueryAsync("CREATE TABLE aglobalbizsettings (id INTEGER NOT NULL PRIMARY KEY, "
|
|
+ "searchcasesensitiveonly BOOL DEFAULT FALSE, "
|
|
+ "useinventory BOOL DEFAULT TRUE, "
|
|
+ "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, "
|
|
|
|
+ "customerservicerequestinfohtml TEXT, "
|
|
+ "customerallowcsr BOOL DEFAULT FALSE, customerallowcsrintags VARCHAR(255) ARRAY, customerallowcsrouttags VARCHAR(255) ARRAY, "
|
|
+ "customerallowviewwo BOOL DEFAULT FALSE, customerallowviewwointags VARCHAR(255) ARRAY, customerallowviewwoouttags VARCHAR(255) ARRAY, "
|
|
+ "customerallowwowiki BOOL DEFAULT FALSE, customerallowwowikiintags VARCHAR(255) ARRAY, customerallowwowikiouttags VARCHAR(255) ARRAY, "
|
|
+ "customerallowusersettings BOOL DEFAULT FALSE, customerallowusersettingsintags VARCHAR(255) ARRAY, customerallowusersettingsouttags VARCHAR(255) ARRAY, "
|
|
+ "customerallownotifyserviceimminent BOOL DEFAULT FALSE, customerallownotifyserviceimminentintags VARCHAR(255) ARRAY, customerallownotifyserviceimminentouttags VARCHAR(255) ARRAY, "
|
|
+ "customerallownotifycsraccepted BOOL DEFAULT FALSE, customerallownotifycsracceptedintags VARCHAR(255) ARRAY, customerallownotifycsracceptedouttags VARCHAR(255) ARRAY, "
|
|
+ "customerallownotifycsrrejected BOOL DEFAULT FALSE, customerallownotifycsrrejectedintags VARCHAR(255) ARRAY, customerallownotifycsrrejectedouttags VARCHAR(255) ARRAY, "
|
|
+ "customerallownotifywocreated BOOL DEFAULT FALSE, customerallownotifywocreatedintags VARCHAR(255) ARRAY, customerallownotifywocreatedouttags VARCHAR(255) ARRAY, "
|
|
+ "customerallownotifywocompleted BOOL DEFAULT FALSE, customerallownotifywocompletedintags VARCHAR(255) ARRAY, customerallownotifywocompletedouttags 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 TIMESTAMP, backupsetstokeep int, backupattachments BOOL)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE aglobalopsnotificationsettings (id INTEGER NOT NULL PRIMARY KEY, smtpdeliveryactive BOOL NOT NULL, "
|
|
+ "smtpserveraddress TEXT, smtpaccount TEXT, smtppassword TEXT, connectionsecurity INTEGER NOT NULL default 0, smtpserverport INTEGER, notifyfromaddress TEXT, ayanovaserverurl TEXT)");
|
|
|
|
//create aevent biz event log table
|
|
await ExecQueryAsync("CREATE TABLE aevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created TIMESTAMP NOT NULL, userid BIGINT NOT NULL,"
|
|
+ "ayid BIGINT NOT NULL, ayatype INTEGER NOT NULL, ayevent INTEGER NOT NULL, textra VARCHAR(255))");
|
|
//INDEX: Most selective first as there is more UNIQUE ID's than UNIQUE types
|
|
await ExecQueryAsync("CREATE INDEX idx_aevent_ayid_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 TIMESTAMP NOT NULL, allocated BIGINT,workingset BIGINT,privatebytes BIGINT,cpu double precision)");
|
|
//One day metrics
|
|
await ExecQueryAsync("CREATE TABLE ametricdd (t TIMESTAMP NOT NULL, dbtotalsize BIGINT, attachmentfilesize BIGINT, attachmentfilecount BIGINT, attachmentfilesavailablespace BIGINT, utilityfilesize BIGINT, utilityfilecount BIGINT, utilityfilesavailablespace BIGINT)");
|
|
|
|
|
|
//SEARCH TABLES
|
|
await ExecQueryAsync("CREATE TABLE asearchdictionary (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, word VARCHAR(255) NOT NULL UNIQUE)");
|
|
//Must be UNIQUE and also this is hit a *lot* during searches and also indexing
|
|
//On actual testing this index is never used so for now removing it, perhaps it is a case of bad data but I tested with Huge dataset
|
|
//await ExecQueryAsync("CREATE UNIQUE INDEX asearchdictionary_word_idx ON asearchdictionary (word);");
|
|
|
|
//search key
|
|
await ExecQueryAsync("CREATE TABLE asearchkey (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, wordid BIGINT NOT NULL REFERENCES asearchdictionary (id), objectid BIGINT NOT NULL, 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$;
|
|
");
|
|
|
|
//Name fetcher function
|
|
//CoreBizObject ADD here
|
|
await ExecQueryAsync(@"
|
|
CREATE OR REPLACE FUNCTION PUBLIC.AYGETNAME(IN AYOBJECTID BIGINT, IN AYATYPE INTEGER) RETURNS TEXT AS $BODY$
|
|
DECLARE
|
|
aytable TEXT DEFAULT '';
|
|
aynamecolumn TEXT DEFAULT 'name';
|
|
returnstr TEXT DEFAULT '';
|
|
BEGIN
|
|
case ayatype
|
|
when 0 then return 'LT:NoType';
|
|
when 1 then return 'LT:Global';
|
|
when 2 then aytable = 'awidget';
|
|
when 3 then aytable = 'auser';
|
|
when 4 then return 'LT:ServerState';
|
|
when 5 then return 'LT:License';
|
|
when 6 then return 'LT:LogFile';
|
|
when 7 then return 'LT:PickListTemplate';
|
|
when 8 then aytable = 'acustomer';
|
|
when 9 then return 'LT:ServerJob';
|
|
when 10 then aytable = 'acontract';
|
|
when 11 then return 'LT:TrialSeeder';
|
|
when 12 then return 'LT:ServerMetrics';
|
|
when 13 then aytable = 'atranslation';
|
|
when 14 then return 'LT:UserOptions';
|
|
when 15 then aytable = 'aheadoffice';
|
|
when 16 then aytable = 'aloanunit';
|
|
when 17 then aytable = 'afileattachment'; aynamecolumn ='displayfilename';
|
|
when 18 then aytable = 'adatalistsavedfilter';
|
|
when 19 then aytable = 'aformcustom'; aynamecolumn = 'formkey';
|
|
when 20 then aytable = 'apart'; aynamecolumn ='partnumber';
|
|
when 21 then aytable = 'apm'; aynamecolumn ='serial';
|
|
when 22 then aytable = 'apmitem';
|
|
when 23 then return 'LT:WorkOrderItemExpense';
|
|
when 24 then return 'LT:WorkOrderItemLabor';
|
|
when 25 then aytable = 'aproject';
|
|
when 26 then aytable = 'apurchaseorder'; aynamecolumn = 'serial';
|
|
when 27 then aytable = 'aquote'; aynamecolumn = 'serial';
|
|
when 28 then return 'LT:WorkOrderItem';
|
|
when 29 then return 'LT:aworkorderitemloan';
|
|
when 30 then return 'LT:WorkOrderItemPart';
|
|
when 31 then aytable = 'aunit'; aynamecolumn = 'serial';
|
|
when 32 then aytable = 'aunitmodel'; aynamecolumn = 'number';
|
|
when 33 then aytable = 'avendor';
|
|
when 34 then aytable = 'aworkorder'; aynamecolumn = 'serial';
|
|
when 35 then return 'LT:WorkOrderItem';
|
|
when 36 then return 'LT:WorkOrderItemExpense';
|
|
when 37 then return 'LT:WorkOrderItemLabor';
|
|
when 38 then return 'LT:aworkorderitemloan';
|
|
when 39 then return 'LT:WorkOrderItemPart';
|
|
when 40 then return 'LT:WorkOrderItemPartRequest';
|
|
when 41 then return 'LT:WorkOrderItemScheduledUser';
|
|
when 42 then return 'LT:WorkOrderItemTask';
|
|
when 43 then return 'LT:WorkOrderItemTravel';
|
|
when 44 then return 'LT:WorkOrderItemUnit';
|
|
when 45 then return 'LT:WorkOrderItemScheduledUser';
|
|
when 46 then return 'LT:WorkOrderItemTask';
|
|
when 47 then return 'LT:GlobalOps';
|
|
when 48 then return 'LT:BizMetrics';
|
|
when 49 then return 'LT:Backup';
|
|
when 50 then aytable = 'anotification';
|
|
when 51 then return 'LT:NotifySubscription';
|
|
when 52 then aytable = 'areminder';
|
|
when 53 then return 'LT:UnitMeterReading';
|
|
when 54 then aytable = 'acustomerservicerequest';
|
|
when 56 then return 'LT:OpsNotificationSettings';
|
|
when 57 then aytable = 'areport';
|
|
when 58 then return 'LT:DashBoardView';
|
|
when 59 then aytable = 'acustomernote'; aynamecolumn = 'notedate';
|
|
when 60 then aytable = 'amemo';
|
|
when 61 then aytable = 'areview';
|
|
when 62 then aytable = 'aservicerate';
|
|
when 63 then aytable = 'atravelrate';
|
|
when 64 then aytable = 'ataxcode';
|
|
when 65 then aytable = 'apartassembly';
|
|
when 66 then aytable = 'apartwarehouse';
|
|
when 67 then aytable = 'apartinventory'; aynamecolumn='description';
|
|
when 68 then return format('DataListColumnView %L', ayobjectid);
|
|
when 71 then aytable = 'aworkorderstatus';
|
|
when 72 then aytable = 'aTaskGroup';
|
|
when 73 then return 'LT:WorkOrderItemOutsideService';
|
|
when 74 then aytable = 'aWorkOrderItemPriority';
|
|
when 75 then aytable = 'aWorkOrderItemStatus';
|
|
when 76 then return 'LT:WorkOrderItemTravel';
|
|
when 77 then return 'LT:WorkOrderItemUnit';
|
|
when 78 then aytable = 'aquotestatus';
|
|
when 79 then return 'LT:WorkOrderItemOutsideService';
|
|
|
|
else
|
|
RETURN returnstr;
|
|
end case;
|
|
EXECUTE format('SELECT %I FROM %I WHERE id = %L', aynamecolumn, aytable, ayobjectid) INTO returnstr;
|
|
RETURN returnstr;
|
|
END;
|
|
$BODY$ LANGUAGE PLPGSQL STABLE");
|
|
|
|
//Usage: select created, textra, AYGETNAME(aevent.ayid, aevent.ayatype) as name from aevent order by created
|
|
|
|
|
|
//create translation TEXT tables
|
|
await ExecQueryAsync("CREATE TABLE atranslation (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, stock BOOL, cjkindex BOOL default false)");
|
|
await ExecQueryAsync("CREATE TABLE atranslationitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, translationid BIGINT NOT NULL REFERENCES atranslation (id), key TEXT NOT NULL, display TEXT NOT NULL)");
|
|
|
|
|
|
//Load the default TRANSLATIONS
|
|
await AyaNova.Biz.PrimeData.PrimeTranslations();
|
|
|
|
|
|
//Add user table
|
|
await ExecQueryAsync("CREATE TABLE auser (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, active BOOL NOT NULL, name TEXT NOT NULL UNIQUE, "
|
|
+ "lastlogin TIMESTAMP, login TEXT NOT NULL UNIQUE, password TEXT NOT NULL, salt TEXT NOT NULL, roles INTEGER NOT NULL, currentauthtoken TEXT, "
|
|
+ "dlkey TEXT, dlkeyexpire TIMESTAMP, totpsecret TEXT, temptoken TEXT, twofactorenabled BOOL, passwordresetcode TEXT, passwordresetcodeexpire TIMESTAMP, usertype INTEGER NOT NULL, "
|
|
+ "employeenumber TEXT, notes TEXT, customerid BIGINT, "
|
|
+ "headofficeid BIGINT, vendorid BIGINT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY)");
|
|
|
|
|
|
//Add user options table
|
|
await ExecQueryAsync("CREATE TABLE auseroptions (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, "
|
|
+ "userid BIGINT NOT NULL UNIQUE REFERENCES auser (id), translationid BIGINT NOT NULL REFERENCES atranslation (id), languageoverride TEXT, timezoneoverride TEXT, "
|
|
+ "currencyname TEXT, hour12 BOOL NOT NULL, emailaddress TEXT, phone1 TEXT, phone2 TEXT, phone3 TEXT, uicolor VARCHAR(12) NOT NULL default '#000000', mapurltemplate TEXT)");
|
|
|
|
|
|
//Prime the db with the default SuperUser account
|
|
await AyaNova.Biz.PrimeData.PrimeSuperUserAccount(ct);
|
|
|
|
//Add user table
|
|
await ExecQueryAsync("CREATE TABLE alicense (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, dbid TEXT, key TEXT NOT NULL)");
|
|
|
|
//Add widget table
|
|
//id, TEXT, longtext, boolean, currency,
|
|
await ExecQueryAsync("CREATE TABLE awidget (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL UNIQUE, serial BIGINT GENERATED BY DEFAULT AS IDENTITY NOT NULL,"
|
|
+ "startdate TIMESTAMP, enddate TIMESTAMP, dollaramount DECIMAL(38,18), active BOOL NOT NULL, usertype int4, count INTEGER,"
|
|
+ "notes TEXT, userid BIGINT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE afileattachment (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, "
|
|
+ "attachtoobjectid BIGINT NOT NULL, attachtoatype INTEGER NOT NULL, "
|
|
+ "storedfilename TEXT NOT NULL, displayfilename TEXT NOT NULL, contenttype TEXT, lastmodified TIMESTAMP NOT NULL, notes TEXT, exists BOOL NOT NULL, size BIGINT NOT NULL)");
|
|
|
|
//index required for ops that need to check if file already in db (delete, count refs etc)
|
|
//LOOKAT: isn't this useless without the ID as well or is that not fetched?
|
|
await ExecQueryAsync("CREATE INDEX idx_afileattachment_storedfilename ON afileattachment (storedfilename);");
|
|
|
|
//index for the common issue of checking if an object has an attachment and retrieving them
|
|
//note always query (where clause) in this same order for best performance
|
|
await ExecQueryAsync("CREATE INDEX idx_afileattachment_attachtoobjectid_attachtoatype ON afileattachment (attachtoobjectid, attachtoatype );");
|
|
|
|
await ExecQueryAsync("CREATE TABLE aopsjob (gid uuid PRIMARY KEY, name TEXT NOT NULL, created TIMESTAMP NOT NULL, exclusive BOOL NOT NULL, "
|
|
+ "startafter TIMESTAMP NOT NULL, jobtype INTEGER NOT NULL, subtype INTEGER, objectid BIGINT, atype INTEGER, jobstatus INTEGER NOT NULL, jobinfo TEXT)");
|
|
await ExecQueryAsync("CREATE TABLE aopsjoblog (gid uuid PRIMARY KEY, jobid uuid NOT NULL, created TIMESTAMP NOT NULL, statustext TEXT NOT NULL)");
|
|
|
|
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 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(8,5) NOT NULL default 0, taxbpct DECIMAL(8,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 TIMESTAMP NOT NULL, viewed BOOL default false, replied BOOL default false, fromid BIGINT NOT NULL REFERENCES auser(id), toid BIGINT NOT NULL REFERENCES auser(id) )");
|
|
|
|
//REMINDER
|
|
await ExecQueryAsync("CREATE TABLE areminder (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, "
|
|
+ "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, "
|
|
+ "startdate TIMESTAMP NOT NULL, stopdate TIMESTAMP NOT NULL, userid BIGINT NOT NULL REFERENCES auser(id), color VARCHAR(12) NOT NULL default '#ffffff')");
|
|
|
|
await ExecQueryAsync("CREATE INDEX idx_areminder_userid ON areminder (userid);");
|
|
await ExecQueryAsync("CREATE INDEX idx_areminder_startdate ON areminder (startdate);");
|
|
await ExecQueryAsync("CREATE INDEX idx_areminder_stopdate ON areminder (stopdate);");
|
|
|
|
//REVIEW
|
|
await ExecQueryAsync("CREATE TABLE areview (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, "
|
|
+ "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, "
|
|
+ "duedate TIMESTAMP NOT NULL, completeddate TIMESTAMP NULL, completionnotes TEXT, userid BIGINT NOT NULL REFERENCES auser(id), "
|
|
+ "assignedbyuserid BIGINT NOT NULL REFERENCES auser(id), 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_duedate ON areview (duedate);");
|
|
await ExecQueryAsync("CREATE INDEX idx_areview_completeddate ON areview (completeddate);");
|
|
|
|
// //SERVICE BANK
|
|
// //Note: I'm allowing negative balances so this code differs slightly from the example it was drawn from https://dba.stackexchange.com/a/19368
|
|
// await ExecQueryAsync("CREATE TABLE aservicebank (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, "
|
|
// + "entrydate TIMESTAMP NOT NULL, lastentrydate TIMESTAMP NULL, 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(8,5) NOT NULL, partsoverridetype INTEGER NOT NULL, "
|
|
+ "serviceratesoverridepct DECIMAL(8,5) NOT NULL, serviceratesoverridetype INTEGER NOT NULL, travelratesoverridepct DECIMAL(8,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, popupnotes TEXT, billheadoffice BOOL, technotes TEXT, accountnumber TEXT, contractexpires TIMESTAMP NULL, contractid BIGINT NULL REFERENCES acontract(id), "
|
|
+ "phone1 TEXT, phone2 TEXT, phone3 TEXT, phone4 TEXT, phone5 TEXT, emailaddress TEXT, "
|
|
+ "postaddress TEXT, postcity TEXT, postregion TEXT, postcountry TEXT, postcode TEXT, address TEXT, city TEXT, region TEXT, country TEXT, latitude DECIMAL(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 TIMESTAMP 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(8,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(8,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(8,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 TIMESTAMP NULL, contractid BIGINT NULL REFERENCES acontract(id), "
|
|
+ "phone1 TEXT, phone2 TEXT, phone3 TEXT, phone4 TEXT, phone5 TEXT, emailaddress TEXT, "
|
|
+ "postaddress TEXT, postcity TEXT, postregion TEXT, postcountry TEXT, postcode TEXT, address TEXT, city TEXT, region TEXT, country TEXT, latitude DECIMAL(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, popupnotes TEXT, accountnumber TEXT, "
|
|
+ "contact TEXT, contactnotes TEXT, phone1 TEXT, phone2 TEXT, phone3 TEXT, phone4 TEXT, phone5 TEXT, emailaddress TEXT, "
|
|
+ "postaddress TEXT, postcity TEXT, postregion TEXT, postcountry TEXT, postcode TEXT, address TEXT, city TEXT, region TEXT, country TEXT, latitude DECIMAL(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, active BOOL NOT NULL, "
|
|
+ "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, "
|
|
+ "partnumber TEXT NOT NULL UNIQUE, manufacturerid BIGINT REFERENCES avendor, manufacturernumber TEXT, "
|
|
+ "wholesalerid BIGINT REFERENCES avendor, wholesalernumber TEXT, alternativewholesalerid BIGINT REFERENCES avendor, alternativewholesalernumber TEXT, "
|
|
+ "cost DECIMAL(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 TIMESTAMP NOT NULL, lastentrydate TIMESTAMP NULL, partid BIGINT NOT NULL REFERENCES apart, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse, "
|
|
+ "sourcetype INTEGER, sourceid BIGINT, "
|
|
+ "quantity DECIMAL(19,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");
|
|
|
|
//MIGRATE_OUTSTANDING: index(s) to support inventory ops
|
|
//recheck this again once have full inventory in place and run some manual queries taken from inventory methods and issued by ef core
|
|
//see what if any index tuning will help with a huge db of realistic data doing most common ops
|
|
//await ExecQueryAsync("CREATE INDEX idx_PartInventory_SourceId_SourceType ON apartinventory (sourceid, sourcetype);");
|
|
|
|
//PARTSTOCKLEVEL
|
|
await ExecQueryAsync("CREATE TABLE apartstocklevel (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, partwarehouseid BIGINT NOT NULL REFERENCES apartwarehouse ON DELETE CASCADE, "
|
|
+ "partid BIGINT NOT NULL REFERENCES apart ON DELETE CASCADE, minimumquantity DECIMAL(19,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 TIMESTAMP NULL, datecompleted TIMESTAMP 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 TIMESTAMP, expectedreceivedate TIMESTAMP, 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 TIMESTAMP, 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 NULL, active BOOL NOT NULL, "
|
|
+ "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, "
|
|
+ "number TEXT NOT NULL, vendorid BIGINT NULL REFERENCES avendor(id), upc TEXT NULL, lifetimewarranty BOOL NOT NULL, introduceddate TIMESTAMP NULL, "
|
|
+ "discontinued BOOL NOT NULL, discontinueddate TIMESTAMP NULL, warrantylength INTEGER NULL, warrantyterms TEXT NULL, CONSTRAINT UNQ_UnitModelNumberVendorId UNIQUE (number, vendorid) "
|
|
+ ")");
|
|
|
|
|
|
//UNIT
|
|
await ExecQueryAsync("CREATE TABLE aunit (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, active BOOL NOT NULL, "
|
|
+ "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, "
|
|
+ "serial TEXT NOT NULL, customerid BIGINT NOT NULL REFERENCES acustomer(id), parentunitid BIGINT NULL REFERENCES aunit(id), "
|
|
+ "unitmodelid BIGINT NULL REFERENCES aunitmodel(id), unithasownaddress BOOL, boughthere BOOL, purchasedfromvendorid BIGINT NULL REFERENCES avendor(id), "
|
|
+ "receipt TEXT NULL, purchaseddate TIMESTAMP NULL, description TEXT NULL, replacedbyunitid BIGINT NULL REFERENCES aunit(id), "
|
|
+ "overridemodelwarranty BOOL, warrantylength INTEGER NULL, warrantyterms TEXT NULL, contractid BIGINT NULL REFERENCES acontract, "
|
|
+ "contractexpires TIMESTAMP 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)) "
|
|
+ " )");
|
|
|
|
//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 TIMESTAMP NOT NULL, "
|
|
+ "servicedate TIMESTAMP, completebydate TIMESTAMP, invoicenumber TEXT, customersignature TEXT, customersignaturename TEXT, customersignaturecaptured TIMESTAMP, "
|
|
+ "techsignature TEXT, techsignaturename TEXT, techsignaturecaptured TIMESTAMP, 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
|
|
|
|
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 TIMESTAMP 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 TIMESTAMP, 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 TIMESTAMP, servicestopdate TIMESTAMP, 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 TIMESTAMP, duedate TIMESTAMP, returndate TIMESTAMP,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, "
|
|
+ "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, "
|
|
+ "purchaseorderitemid BIGINT NULL REFERENCES apurchaseorderitem"
|
|
+ ")");
|
|
|
|
//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 TIMESTAMP, stopdate TIMESTAMP, servicerateid BIGINT REFERENCES aservicerate, "
|
|
+ "estimatedquantity DECIMAL(19,5) NOT NULL default 0"
|
|
+ ")");
|
|
|
|
//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 TIMESTAMP"
|
|
+ ")");
|
|
|
|
//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 TIMESTAMP, travelstopdate TIMESTAMP, 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"
|
|
+ ")");
|
|
|
|
//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 TIMESTAMP, etadate TIMESTAMP, returndate TIMESTAMP"
|
|
+ ")");
|
|
|
|
//POITEM LINK
|
|
await ExecQueryAsync("ALTER TABLE apurchaseorderitem ADD column workorderitempartrequestid BIGINT REFERENCES aworkorderitempartrequest");
|
|
|
|
//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");
|
|
|
|
//VRESTOCKREQUIRED
|
|
await ExecQueryAsync("CREATE VIEW viewrestockrequired AS SELECT apart.id AS partid, apartwarehouse.id AS partwarehouseid, apart.partnumber, 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");
|
|
|
|
//VPARTINVENTORYLIST
|
|
await ExecQueryAsync("CREATE VIEW vpartinventorylist AS select vpartinventorynow.*, vpartsonordercommitted.quantityonordercommitted, vpartsonorder.quantityonorder from vpartinventorynow "
|
|
+ "left outer join vpartsonordercommitted on (vpartinventorynow.partid = vpartsonordercommitted.partid and vpartinventorynow.partwarehouseid = vpartsonordercommitted.partwarehouseid)"
|
|
+ "left outer join vpartsonorder on (vpartinventorynow.partid = vpartsonorder.partid and vpartinventorynow.partwarehouseid = vpartsonorder.partwarehouseid)");
|
|
|
|
|
|
//VIEWWORKORDER - adds AGE expression column for datalist queries
|
|
await ExecQueryAsync("CREATE VIEW viewworkorder AS select aworkorder.*, AGE(timezone('UTC', now()), aworkorder.createddate) as expwoage from aworkorder");
|
|
|
|
//----------
|
|
|
|
|
|
|
|
/*
|
|
██████╗ ██╗ ██╗ ██████╗ ████████╗███████╗
|
|
██╔═══██╗██║ ██║██╔═══██╗╚══██╔══╝██╔════╝
|
|
██║ ██║██║ ██║██║ ██║ ██║ █████╗
|
|
██║▄▄ ██║██║ ██║██║ ██║ ██║ ██╔══╝
|
|
╚██████╔╝╚██████╔╝╚██████╔╝ ██║ ███████╗
|
|
╚══▀▀═╝ ╚═════╝ ╚═════╝ ╚═╝ ╚══════╝
|
|
*/
|
|
|
|
//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 TIMESTAMP NOT NULL, "
|
|
+ "preparedbyid BIGINT REFERENCES auser(id), introduction TEXT, requested TIMESTAMP, validuntil TIMESTAMP, submitted TIMESTAMP, approved TIMESTAMP, 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 TIMESTAMP 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 TIMESTAMP, 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 TIMESTAMP, servicestopdate TIMESTAMP, 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 TIMESTAMP, duedate TIMESTAMP, returndate TIMESTAMP,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 TIMESTAMP, stopdate TIMESTAMP, 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 TIMESTAMP"
|
|
+ ")");
|
|
|
|
//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 TIMESTAMP, travelstopdate TIMESTAMP, 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 TIMESTAMP, etadate TIMESTAMP, returndate TIMESTAMP"
|
|
+ ")");
|
|
|
|
|
|
|
|
|
|
///////////////////////////////////////////////////////////////////////////////////////
|
|
|
|
//----------
|
|
|
|
|
|
|
|
/*
|
|
██████╗ ███╗ ███╗
|
|
██╔══██╗████╗ ████║
|
|
██████╔╝██╔████╔██║
|
|
██╔═══╝ ██║╚██╔╝██║
|
|
██║ ██║ ╚═╝ ██║
|
|
╚═╝ ╚═╝ ╚═╝
|
|
*/
|
|
|
|
|
|
//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, laststatusid BIGINT REFERENCES apmstatus(id), contractid BIGINT NULL, internalreferencenumber text, "
|
|
+ "customerreferencenumber text, customercontactname text, createddate TIMESTAMP NOT NULL, "
|
|
+ "preparedbyid BIGINT REFERENCES auser(id), introduction TEXT, requested TIMESTAMP, validuntil TIMESTAMP, submitted TIMESTAMP, approved TIMESTAMP, 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) "
|
|
+ ")");
|
|
|
|
|
|
//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 TIMESTAMP, 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 TIMESTAMP, servicestopdate TIMESTAMP, 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 TIMESTAMP, duedate TIMESTAMP, returndate TIMESTAMP,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 TIMESTAMP, stopdate TIMESTAMP, 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 TIMESTAMP"
|
|
+ ")");
|
|
|
|
//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 TIMESTAMP, travelstopdate TIMESTAMP, 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 TIMESTAMP, etadate TIMESTAMP, returndate TIMESTAMP"
|
|
+ ")");
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
//CUSTOMERSERVICEREQUEST
|
|
await ExecQueryAsync("CREATE TABLE acustomerservicerequest (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, "
|
|
+ "notes TEXT, wiki TEXT, customfields TEXT, tags VARCHAR(255) ARRAY, "
|
|
+ "daterequested TIMESTAMP NOT NULL, customerid BIGINT NOT NULL REFERENCES acustomer(id), unitid BIGINT REFERENCES aunit(id), workorderitemid BIGINT REFERENCES aworkorderitem(id), "
|
|
+ "requestedbyuserid BIGINT NOT NULL REFERENCES auser(id), customerreferencenumber TEXT, status INTEGER NOT NULL, priority INTEGER NOT NULL "
|
|
+ ")");
|
|
|
|
|
|
//WORKORDER "FROM" LINKS
|
|
await ExecQueryAsync("ALTER TABLE aworkorder ADD column fromquoteid BIGINT REFERENCES aquote (id), ADD column frompmid BIGINT REFERENCES apm (id), ADD column fromcsrid BIGINT REFERENCES acustomerservicerequest (id)");
|
|
|
|
|
|
//NOTIFICATION
|
|
await ExecQueryAsync("CREATE TABLE anotifysubscription (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, "
|
|
+ "userid BIGINT NOT NULL REFERENCES auser (id), ayatype INTEGER NOT NULL, eventtype INTEGER NOT NULL, advancenotice INTERVAL NOT NULL, "
|
|
+ "idvalue BIGINT NOT NULL, decvalue DECIMAL(38,18) NOT NULL, agevalue INTERVAL NOT NULL, deliverymethod INTEGER NOT NULL, "
|
|
+ "deliveryaddress TEXT, linkreportid BIGINT NOT NULL, tags VARCHAR(255) ARRAY)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE anotifyevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created TIMESTAMP NOT NULL, "
|
|
+ "ayatype INTEGER NOT NULL, objectid BIGINT NOT NULL, name TEXT NOT NULL, eventtype INTEGER NOT NULL, notifysubscriptionid BIGINT NOT NULL REFERENCES anotifysubscription(id) ON DELETE CASCADE, "
|
|
+ "userid BIGINT NOT NULL REFERENCES auser (id), eventdate TIMESTAMP NOT NULL, decvalue DECIMAL(38,18) NULL, message TEXT)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE anotification (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, userid BIGINT NOT NULL REFERENCES auser (id), "
|
|
+ "created TIMESTAMP NOT NULL, ayatype INTEGER NOT NULL, objectid BIGINT NOT NULL, name TEXT NOT NULL, 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 TIMESTAMP NOT NULL, "
|
|
+ "ayatype INTEGER NOT NULL, objectid BIGINT NOT NULL, eventtype INTEGER NOT NULL, notifysubscriptionid BIGINT NOT NULL, idvalue BIGINT NOT NULL, "
|
|
+ "decvalue DECIMAL(38,18) NOT NULL, userid BIGINT NOT NULL REFERENCES auser (id), deliverymethod INTEGER NOT NULL, fail BOOL NOT NULL, error TEXT)");
|
|
|
|
//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 UNIQUE, 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(8,5) )");
|
|
|
|
//Global customer default workorder report default
|
|
await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD column customerdefaultworkorderreportid 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);
|
|
}
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
|
|
|
|
|
|
//#########################################
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
//////////////////////////////////////////////////
|
|
// FUTURE
|
|
// if (currentSchema < xx)
|
|
// {
|
|
// LogUpdateMessage(log);
|
|
// exec queries here to do updates
|
|
// await SetSchemaLevelAsync(++currentSchema);
|
|
// }
|
|
|
|
|
|
//MAKE SURE THE DESIRED SCHEMA WAS SET PROPERLY
|
|
if (currentSchema > DESIRED_SCHEMA_LEVEL)
|
|
throw new ArgumentOutOfRangeException("AySchema::DesiredSchemaLevel WASN'T SET PROPERLY");
|
|
|
|
|
|
|
|
log.LogInformation("Completed updating database schema to version {0}", currentSchema);
|
|
//*************************************************************************************
|
|
|
|
|
|
|
|
}//eofunction
|
|
|
|
|
|
|
|
private static async Task SetSchemaLevelAsync(int nCurrentSchema)
|
|
{
|
|
await ExecQueryAsync("UPDATE aschemaversion SET schema=" + nCurrentSchema.ToString());
|
|
}
|
|
|
|
//execute command query
|
|
private static async Task ExecQueryAsync(string q)
|
|
{
|
|
using (var cm = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
await ct.Database.OpenConnectionAsync();
|
|
cm.CommandText = q;
|
|
await cm.ExecuteNonQueryAsync();
|
|
await ct.Database.CloseConnectionAsync();
|
|
}
|
|
}
|
|
|
|
|
|
private static void LogUpdateMessage(ILogger log)
|
|
{
|
|
log.LogDebug($"Updating database to schema version {currentSchema + 1}");
|
|
}
|
|
|
|
|
|
//eoclass
|
|
}
|
|
//eons
|
|
} |