557 lines
30 KiB
C#
557 lines
30 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 = 11;
|
|
|
|
internal const long EXPECTED_COLUMN_COUNT = 277;
|
|
internal const long EXPECTED_INDEX_COUNT = 124;
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
/////////////////////////////////////////////////////////////////
|
|
|
|
|
|
/*
|
|
|
|
MAXIMUM POSTGRES OBJECT NAME LENGTH: 63 CHARACTERS
|
|
|
|
HOW TO INDEX
|
|
|
|
AyaNova does a lot of name fetching so any tables that contain a lot of columns in addition to the name will benefit from a compound index on (id,name)
|
|
|
|
Other indexes should be created with care and after a huge load and integration test periodically look for unused indexes and see how they are performing
|
|
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
|
|
|
|
*/
|
|
|
|
static int startingSchema = -1;
|
|
public static int currentSchema = -1;
|
|
|
|
|
|
|
|
//check and update schema
|
|
public static async Task CheckAndUpdateAsync(AyContext context, ILogger logger)
|
|
{
|
|
ct = context;
|
|
log = logger;
|
|
|
|
//Check if ayschemaversion table exists
|
|
bool aySchemaVersionExists = false;
|
|
|
|
using (var command = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
command.CommandText = "SELECT * FROM information_schema.tables WHERE table_name = 'aschemaversion'";
|
|
await ct.Database.OpenConnectionAsync();
|
|
using (var result = await command.ExecuteReaderAsync())
|
|
{
|
|
if (result.HasRows)
|
|
{
|
|
aySchemaVersionExists = true;
|
|
}
|
|
await ct.Database.CloseConnectionAsync();
|
|
}
|
|
}
|
|
|
|
|
|
//Create schema table (v1)
|
|
if (!aySchemaVersionExists)
|
|
{
|
|
log.LogDebug("aschemaversion table not found, creating now");
|
|
//nope, no schema table, add it now and set to v1
|
|
using (var cm = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
await ct.Database.OpenConnectionAsync();
|
|
cm.CommandText = "CREATE TABLE aschemaversion (schema INTEGER NOT NULL);";
|
|
await cm.ExecuteNonQueryAsync();
|
|
|
|
cm.CommandText = "insert into aschemaversion (schema) values (1);";
|
|
await cm.ExecuteNonQueryAsync();
|
|
|
|
await ct.Database.CloseConnectionAsync();
|
|
startingSchema = 1;
|
|
currentSchema = 1;
|
|
}
|
|
}
|
|
else
|
|
{
|
|
//get current schema level
|
|
using (var cm = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
log.LogDebug("Fetching current schema version");
|
|
cm.CommandText = "SELECT schema FROM aschemaversion;";
|
|
await ct.Database.OpenConnectionAsync();
|
|
using (var result = await cm.ExecuteReaderAsync())
|
|
{
|
|
if (result.HasRows)
|
|
{
|
|
await result.ReadAsync();
|
|
currentSchema = startingSchema = result.GetInt32(0);
|
|
await ct.Database.CloseConnectionAsync();
|
|
log.LogDebug("AyaNova schema version is " + currentSchema.ToString());
|
|
}
|
|
else
|
|
{
|
|
await ct.Database.CloseConnectionAsync();
|
|
throw new System.Exception("AyaNova->AySchema->CheckAndUpdate: Error reading schema version");
|
|
}
|
|
}
|
|
}
|
|
}
|
|
|
|
//Bail early no update?
|
|
if (currentSchema == DESIRED_SCHEMA_LEVEL)
|
|
{
|
|
log.LogDebug("Current schema is at required schema version " + currentSchema.ToString());
|
|
return;
|
|
}
|
|
|
|
log.LogInformation("AyaNova database needs to be updated from schema version {0} to version {1}", currentSchema, DESIRED_SCHEMA_LEVEL);
|
|
|
|
//************* SCHEMA UPDATES ******************
|
|
|
|
//////////////////////////////////////////////////
|
|
// FOUNDATIONAL TABLES
|
|
//
|
|
if (currentSchema < 2)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//create global biz settings table
|
|
await ExecQueryAsync("CREATE TABLE aglobalbizsettings (id integer NOT NULL PRIMARY KEY, " +
|
|
"searchcasesensitiveonly bool default false)");
|
|
|
|
//create aevent biz event log table
|
|
await ExecQueryAsync("CREATE TABLE aevent (id BIGSERIAL PRIMARY KEY, created timestamp not null, userid bigint not null," +
|
|
"ayid bigint not null, aytype integer not null, ayevent integer not null, textra varchar(255))");
|
|
//INDEX: Most selective first as there is more unique ID's than unique types
|
|
await ExecQueryAsync("CREATE INDEX aevent_typeid_idx ON aevent (ayid, aytype);");
|
|
await ExecQueryAsync("CREATE INDEX aevent_userid_idx ON aevent (userid);");
|
|
|
|
|
|
//SEARCH TABLES
|
|
await ExecQueryAsync("CREATE TABLE asearchdictionary (id BIGSERIAL PRIMARY KEY, word varchar(255) not null)");
|
|
//Search dictionary words must be unique
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX asearchdictionary_word_idx ON asearchdictionary (word);");
|
|
await ExecQueryAsync("CREATE TABLE asearchkey (id BIGSERIAL PRIMARY KEY, wordid bigint not null REFERENCES asearchdictionary (id), objectid bigint not null, objecttype integer not null)");
|
|
//todo: I think there is a missing index here, need to look at the search query section again as it was changed several times from the original schema creation
|
|
|
|
//create translation text tables
|
|
await ExecQueryAsync("CREATE TABLE atranslation (id BIGSERIAL PRIMARY KEY, name varchar(255) not null, stock bool, cjkindex bool default false)");
|
|
//LOOKAT: I don't think this is doing anything:
|
|
//exec("CREATE UNIQUE INDEX atranslation_name_idx ON atranslation (name)");
|
|
await ExecQueryAsync("CREATE TABLE atranslationitem (id BIGSERIAL PRIMARY KEY, translationid bigint not null REFERENCES atranslation (id), key text not null, display text not null)");
|
|
await ExecQueryAsync("CREATE INDEX atranslationitem_translationid_key_display_idx ON atranslationitem (translationid,key, display)");
|
|
|
|
//Load the default TRANSLATIONS
|
|
await AyaNova.Biz.PrimeData.PrimeTranslations();
|
|
|
|
|
|
//Add user table
|
|
await ExecQueryAsync("CREATE TABLE auser (id BIGSERIAL PRIMARY KEY, active bool not null, name varchar(255) not null unique, " +
|
|
"login text not null, password text not null, salt text not null, roles integer not null, " +
|
|
"dlkey text, dlkeyexpire timestamp, usertype integer not null, employeenumber varchar(255), notes text, customerid bigint, " +
|
|
"headofficeid bigint, subvendorid bigint, wiki text null, customfields text, tags varchar(255) ARRAY)");
|
|
|
|
//Index for name fetching
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX auser_name_id_idx ON auser (id, name);");
|
|
|
|
//Add user options table
|
|
await ExecQueryAsync("CREATE TABLE auseroptions (id BIGSERIAL PRIMARY KEY, " +
|
|
"userid bigint not null, translationid bigint not null REFERENCES atranslation (id), languageoverride text, timezoneoverride text, currencyname text, hour12 bool not null, emailaddress text, uicolor varchar(12) not null default '#000000')");
|
|
|
|
|
|
//Prime the db with the default MANAGER account
|
|
await AyaNova.Biz.PrimeData.PrimeManagerAccount(ct);
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//LICENSE table
|
|
if (currentSchema < 3)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//Add user table
|
|
await ExecQueryAsync("CREATE TABLE alicense (id BIGSERIAL PRIMARY KEY, dbid uuid, key text not null)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//WIDGET table for development testing
|
|
if (currentSchema < 4)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//Add widget table
|
|
//id, text, longtext, boolean, currency,
|
|
await ExecQueryAsync("CREATE TABLE awidget (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, serial bigint not null," +
|
|
"startdate timestamp, enddate timestamp, dollaramount decimal(19,5), active bool, usertype int4, count integer," +
|
|
"notes text, userid bigint null, wiki text null, customfields text, tags varchar(255) ARRAY)");
|
|
|
|
//TEST TEST TEST ONLY FOR DEVELOPMENT TESTING TO ENSURE UNIQUENESS
|
|
//exec("CREATE UNIQUE INDEX awidget_serial_idx ON awidget (serial);");
|
|
|
|
|
|
//Compound index for name fetching
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX awidget_name_id_idx ON awidget (id, name);");
|
|
|
|
//Index for tags
|
|
await ExecQueryAsync("CREATE INDEX awidget_tags ON AWIDGET using GIN(tags)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// FileAttachment table
|
|
if (currentSchema < 5)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE afileattachment (id BIGSERIAL PRIMARY KEY, " +
|
|
"attachtoobjectid bigint not null, attachtoobjecttype integer not null, " +
|
|
"storedfilename text not null, displayfilename text not null, contenttype text, lastmodified timestamp not null, notes text)");
|
|
|
|
//index required for ops that need to check if file already in db (delete, count refs etc)
|
|
//LOOKAT: isn't this useless without the ID as well or is that not fetched?
|
|
await ExecQueryAsync("CREATE INDEX afileattachment_storedfilename_idx ON afileattachment (storedfilename);");
|
|
|
|
//index for the common issue of checking if an object has an attachment and retrieving them
|
|
//note always query (where clause) in this same order for best performance
|
|
await ExecQueryAsync("CREATE INDEX afileattachment_typeid_idx ON afileattachment (attachtoobjectid, attachtoobjecttype );");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// OPS LRO tables
|
|
if (currentSchema < 6)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE aopsjob (gid uuid PRIMARY KEY, name text not null, created timestamp not null, exclusive bool not null, " +
|
|
"startafter timestamp not null, jobtype integer not null, objectid bigint null, objecttype integer null, jobstatus integer not null, jobinfo text null)");
|
|
await ExecQueryAsync("CREATE TABLE aopsjoblog (gid uuid PRIMARY KEY, jobid uuid not null REFERENCES aopsjob (gid), created timestamp not null, statustext text not null)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//DATAFILTER / DATALISTTEMPLATE tables
|
|
if (currentSchema < 7)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE adatalistview (id BIGSERIAL PRIMARY KEY, userId bigint not null, name varchar(255) not null unique, public bool not null," +
|
|
"listkey varchar(255) not null, listview text)");
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// TAGS repository
|
|
if (currentSchema < 8)
|
|
{
|
|
LogUpdateMessage(log);
|
|
await ExecQueryAsync("CREATE TABLE atag (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, refcount bigint not null)");
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//FORMCUSTOM table
|
|
if (currentSchema < 9)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE aformcustom (id BIGSERIAL PRIMARY KEY, " +
|
|
"formkey varchar(255) not null, template text, UNIQUE(formkey))");
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//PICKLISTTEMPLATE table
|
|
if (currentSchema < 10)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE apicklisttemplate (id integer NOT NULL PRIMARY KEY, " +
|
|
"template text)");
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//MULTIPLE BIZ OBJECT tables
|
|
if (currentSchema < 11)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//CUSTOMER
|
|
await ExecQueryAsync("CREATE TABLE acustomer (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX acustomer_name_id_idx ON acustomer (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX acustomer_tags ON acustomer using GIN(tags)");
|
|
|
|
//CONTRACT
|
|
await ExecQueryAsync("CREATE TABLE acontract (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX acontract_name_id_idx ON acontract (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX acontract_tags ON acontract using GIN(tags)");
|
|
|
|
//HEADOFFICE
|
|
await ExecQueryAsync("CREATE TABLE aheadoffice (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aheadoffice_name_id_idx ON aheadoffice (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aheadoffice_tags ON aheadoffice using GIN(tags)");
|
|
|
|
//LOANUNIT
|
|
await ExecQueryAsync("CREATE TABLE aloanunit (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aloanunit_name_id_idx ON aloanunit (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aloanunit_tags ON aloanunit using GIN(tags)");
|
|
|
|
//PART
|
|
await ExecQueryAsync("CREATE TABLE apart (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apart_name_id_idx ON apart (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apart_tags ON apart using GIN(tags)");
|
|
|
|
//PROJECT
|
|
await ExecQueryAsync("CREATE TABLE aproject (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aproject_name_id_idx ON aproject (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aproject_tags ON aproject using GIN(tags)");
|
|
|
|
//PURCHASEORDER
|
|
await ExecQueryAsync("CREATE TABLE apurchaseorder (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apurchaseorder_name_id_idx ON apurchaseorder (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apurchaseorder_tags ON apurchaseorder using GIN(tags)");
|
|
|
|
//UNIT
|
|
await ExecQueryAsync("CREATE TABLE aunit (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aunit_name_id_idx ON aunit (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aunit_tags ON aunit using GIN(tags)");
|
|
|
|
//UNITMODEL
|
|
await ExecQueryAsync("CREATE TABLE aunitmodel (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aunitmodel_name_id_idx ON aunitmodel (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aunitmodel_tags ON aunitmodel using GIN(tags)");
|
|
|
|
//VENDOR
|
|
await ExecQueryAsync("CREATE TABLE avendor (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX avendor_name_id_idx ON avendor (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX avendor_tags ON avendor using GIN(tags)");
|
|
|
|
//----------
|
|
//WORKORDER
|
|
await ExecQueryAsync("CREATE TABLE aworkorder (id BIGSERIAL PRIMARY KEY, serial bigint not null, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE INDEX aworkorder_serial_id_idx ON aworkorder (id, serial);");//is this necessary or fruitful?
|
|
await ExecQueryAsync("CREATE INDEX aworkorder_tags ON aworkorder using GIN(tags)");
|
|
|
|
//WORKORDERITEM
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitem (id BIGSERIAL PRIMARY KEY, workorderid bigint not null REFERENCES aworkorder (id), name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitem_name_id_idx ON aworkorderitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitem_tags ON aworkorderitem using GIN(tags)");
|
|
|
|
//WORKORDERITEMPART
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitempart (id BIGSERIAL PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitempart_name_id_idx ON aworkorderitempart (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitempart_tags ON aworkorderitempart using GIN(tags)");
|
|
|
|
//WORKORDERITEMLABOR
|
|
await ExecQueryAsync("CREATE TABLE aworkorderitemlabor (id BIGSERIAL PRIMARY KEY, workorderitemid bigint not null REFERENCES aworkorderitem (id), name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aworkorderitemlabor_name_id_idx ON aworkorderitemlabor (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkorderitemlabor_tags ON aworkorderitemlabor using GIN(tags)");
|
|
//----------
|
|
|
|
|
|
//WORKORDERTEMPLATE
|
|
await ExecQueryAsync("CREATE TABLE aworkordertemplate (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aworkordertemplate_name_id_idx ON aworkordertemplate (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkordertemplate_tags ON aworkordertemplate using GIN(tags)");
|
|
|
|
//WORKORDERTEMPLATEITEM
|
|
await ExecQueryAsync("CREATE TABLE aworkordertemplateitem (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aworkordertemplateitem_name_id_idx ON aworkordertemplateitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aworkordertemplateitem_tags ON aworkordertemplateitem using GIN(tags)");
|
|
|
|
//QUOTE
|
|
await ExecQueryAsync("CREATE TABLE aquote (id BIGSERIAL PRIMARY KEY, serial bigint not null, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aquote_serial_id_idx ON aquote (id, serial);");//is this necessary or fruitful?
|
|
await ExecQueryAsync("CREATE INDEX aquote_tags ON aquote using GIN(tags)");
|
|
|
|
//QUOTEITEM
|
|
await ExecQueryAsync("CREATE TABLE aquoteitem (id BIGSERIAL PRIMARY KEY, quoteid bigint not null REFERENCES aquote (id), name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aquoteitem_name_id_idx ON aquoteitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aquoteitem_tags ON aquoteitem using GIN(tags)");
|
|
|
|
//QUOTETEMPLATE
|
|
await ExecQueryAsync("CREATE TABLE aquotetemplate (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aquotetemplate_name_id_idx ON aquotetemplate (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aquotetemplate_tags ON aquotetemplate using GIN(tags)");
|
|
|
|
//QUOTETEMPLATEITEM
|
|
await ExecQueryAsync("CREATE TABLE aquotetemplateitem (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX aquotetemplateitem_name_id_idx ON aquotetemplateitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX aquotetemplateitem_tags ON aquotetemplateitem using GIN(tags)");
|
|
|
|
//PM
|
|
await ExecQueryAsync("CREATE TABLE apm (id BIGSERIAL PRIMARY KEY, serial bigint not null, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apm_serial_id_idx ON apm (id, serial);");//is this necessary or fruitful?
|
|
await ExecQueryAsync("CREATE INDEX apm_tags ON apm using GIN(tags)");
|
|
|
|
//PMITEM
|
|
await ExecQueryAsync("CREATE TABLE apmitem (id BIGSERIAL PRIMARY KEY, pmid bigint not null REFERENCES apm (id), name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apmitem_name_id_idx ON apmitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apmitem_tags ON apmitem using GIN(tags)");
|
|
|
|
//PMTEMPLATE
|
|
await ExecQueryAsync("CREATE TABLE apmtemplate (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apmtemplate_name_id_idx ON apmtemplate (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apmtemplate_tags ON apmtemplate using GIN(tags)");
|
|
|
|
//PMTEMPLATEITEM
|
|
await ExecQueryAsync("CREATE TABLE apmtemplateitem (id BIGSERIAL PRIMARY KEY, name varchar(255) not null unique, active bool, " +
|
|
"notes text NULL, wiki text null, customfields text NULL, tags varchar(255) ARRAY NULL)");
|
|
await ExecQueryAsync("CREATE UNIQUE INDEX apmtemplateitem_name_id_idx ON apmtemplateitem (id, name);");
|
|
await ExecQueryAsync("CREATE INDEX apmtemplateitem_tags ON apmtemplateitem using GIN(tags)");
|
|
|
|
|
|
await SetSchemaLevelAsync(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
// //////////////////////////////////////////////////
|
|
// // WikiPage table
|
|
// if (currentSchema < 11)
|
|
// {
|
|
// LogUpdateMessage(log);
|
|
|
|
// await ExecQueryAsync("CREATE TABLE awikipage (id BIGSERIAL PRIMARY KEY, " +
|
|
// "objectid bigint not null, objecttype integer not null, " +
|
|
// "content text)");
|
|
|
|
// //INDEX: Most selective first as there is more unique ID's than unique types
|
|
// //to take advantage of this always query with where objectid=xx and objecttype=yy order
|
|
// await ExecQueryAsync("CREATE INDEX awikipage_typeid_idx ON awikipage (objectid, objecttype );");
|
|
|
|
// await SetSchemaLevelAsync(++currentSchema);
|
|
// }
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
//#########################################
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
//////////////////////////////////////////////////
|
|
// FUTURE
|
|
// if (currentSchema < 10)
|
|
// {
|
|
// LogUpdateMessage(log);
|
|
|
|
// setSchemaLevel(++currentSchema);
|
|
// }
|
|
|
|
|
|
//MAKE SURE THE DESIRED SCHEMA WAS SET PROPERLY
|
|
if (currentSchema > DESIRED_SCHEMA_LEVEL)
|
|
throw new ArgumentOutOfRangeException("AySchema::DesiredSchemaLevel WASN'T SET PROPERLY");
|
|
|
|
|
|
|
|
log.LogInformation("Finished updating database schema to version {0}", currentSchema);
|
|
//*************************************************************************************
|
|
|
|
|
|
|
|
}//eofunction
|
|
|
|
|
|
|
|
private static async Task SetSchemaLevelAsync(int nCurrentSchema)
|
|
{
|
|
await ExecQueryAsync("UPDATE aschemaversion SET schema=" + nCurrentSchema.ToString());
|
|
}
|
|
|
|
//execute command query
|
|
private static async Task ExecQueryAsync(string q)
|
|
{
|
|
using (var cm = ct.Database.GetDbConnection().CreateCommand())
|
|
{
|
|
await ct.Database.OpenConnectionAsync();
|
|
cm.CommandText = q;
|
|
await cm.ExecuteNonQueryAsync();
|
|
await ct.Database.CloseConnectionAsync();
|
|
}
|
|
}
|
|
|
|
|
|
private static void LogUpdateMessage(ILogger log)
|
|
{
|
|
log.LogDebug($"Updating database to schema version {currentSchema + 1}");
|
|
}
|
|
|
|
|
|
//eoclass
|
|
}
|
|
//eons
|
|
} |