using System; using System.Text; 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 = 9; internal const long EXPECTED_COLUMN_COUNT = 99; internal const long EXPECTED_INDEX_COUNT = 26; //!!!!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 void CheckAndUpdate(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'"; ct.Database.OpenConnection(); using (var result = command.ExecuteReader()) { if (result.HasRows) { aySchemaVersionExists = true; } ct.Database.CloseConnection(); } } //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()) { ct.Database.OpenConnection(); cm.CommandText = "CREATE TABLE aschemaversion (schema INTEGER NOT NULL);"; cm.ExecuteNonQuery(); cm.CommandText = "insert into aschemaversion (schema) values (1);"; cm.ExecuteNonQuery(); ct.Database.CloseConnection(); 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;"; ct.Database.OpenConnection(); using (var result = cm.ExecuteReader()) { if (result.HasRows) { result.Read(); currentSchema = startingSchema = result.GetInt32(0); ct.Database.CloseConnection(); log.LogDebug("AyaNova schema version is " + currentSchema.ToString()); } else { ct.Database.CloseConnection(); 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 aevent biz event log table exec("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))"); //SEARCH TABLES exec("CREATE TABLE asearchdictionary (id BIGSERIAL PRIMARY KEY, word varchar(255) not null)"); //Search dictionary words must be unique exec("CREATE UNIQUE INDEX asearchdictionary_word_idx ON asearchdictionary (word);"); exec("CREATE TABLE asearchkey (id BIGSERIAL PRIMARY KEY, wordid bigint not null REFERENCES asearchdictionary (id), objectid bigint not null, objecttype integer not null, inname bool not null)"); //create locale text tables exec("CREATE TABLE alocale (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 alocale_name_idx ON alocale (name)"); exec("CREATE TABLE alocaleitem (id BIGSERIAL PRIMARY KEY, localeid bigint not null REFERENCES alocale (id), key text not null, display text not null)"); //LOOKAT: this is for what exactly?? // exec("CREATE INDEX alocaleitem_localeid_key_idx ON alocaleitem (localeid,key)"); //This seems more appropriate exec("CREATE INDEX alocaleitem_localeid_key_display_idx ON alocaleitem (localeid,key, display)"); //Load the default LOCALES AyaNova.Biz.PrimeData.PrimeLocales(); //Add user table exec("CREATE TABLE auser (id BIGSERIAL PRIMARY KEY, active bool not null, name varchar(255) not null, " + "login text not null, password text not null, salt text not null, roles integer not null, localeid bigint not null REFERENCES alocale (id), " + "dlkey text, dlkeyexpire timestamp, usertype integer not null, employeenumber varchar(255), notes text, customerid bigint, " + "headofficeid bigint, subvendorid bigint, customfields text, tags varchar(255) ARRAY)"); //Index for name fetching exec("CREATE UNIQUE INDEX auser_name_id_idx ON auser (id, name);"); //Add user options table exec("CREATE TABLE auseroptions (id BIGSERIAL PRIMARY KEY, " + "userid bigint not null, timezoneoffset decimal(19,5) not null default 0, emailaddress text, uicolor int not null default 0)"); //Prime the db with the default MANAGER account AyaNova.Biz.PrimeData.PrimeManagerAccount(ct); setSchemaLevel(++currentSchema); } ////////////////////////////////////////////////// //LICENSE table if (currentSchema < 3) { LogUpdateMessage(log); //Add user table exec("CREATE TABLE alicense (id BIGSERIAL PRIMARY KEY, dbid uuid, key text not null)"); setSchemaLevel(++currentSchema); } ////////////////////////////////////////////////// //WIDGET table for development testing if (currentSchema < 4) { LogUpdateMessage(log); //Add widget table //id, text, longtext, boolean, currency, exec("CREATE TABLE awidget (id BIGSERIAL PRIMARY KEY, name varchar(255) not null, serial bigint not null," + "startdate timestamp, enddate timestamp, dollaramount decimal(19,5), active bool, roles int4, count integer," + "notes text, userid bigint 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 exec("CREATE UNIQUE INDEX awidget_name_id_idx ON awidget (id, name);"); //Index for tags exec("CREATE INDEX awidget_tags ON AWIDGET using GIN(tags)"); setSchemaLevel(++currentSchema); } ////////////////////////////////////////////////// // FileAttachment table if (currentSchema < 5) { LogUpdateMessage(log); exec("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, 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? exec("CREATE INDEX afileattachment_storedfilename_idx ON afileattachment (storedfilename);"); setSchemaLevel(++currentSchema); } ////////////////////////////////////////////////// // OPS LRO tables if (currentSchema < 6) { LogUpdateMessage(log); exec("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)"); exec("CREATE TABLE aopsjoblog (gid uuid PRIMARY KEY, jobid uuid not null REFERENCES aopsjob (gid), created timestamp not null, statustext text not null)"); setSchemaLevel(++currentSchema); } ////////////////////////////////////////////////// //DATAFILTER / DATALISTTEMPLATE tables if (currentSchema < 7) { LogUpdateMessage(log); exec("CREATE TABLE adatalistfilter (id BIGSERIAL PRIMARY KEY, userId bigint not null, name varchar(255) not null, public bool not null," + "listkey varchar(255) not null, filter text, sort text, UNIQUE(name))"); exec("CREATE TABLE adatalisttemplate (id BIGSERIAL PRIMARY KEY, datalistkey text not null, template text, UNIQUE(datalistkey))"); setSchemaLevel(++currentSchema); } ////////////////////////////////////////////////// // TAGS repository if (currentSchema < 8) { LogUpdateMessage(log); exec("CREATE TABLE atag (id BIGSERIAL PRIMARY KEY, name varchar(255) not null, refcount bigint not null, UNIQUE(name))"); setSchemaLevel(++currentSchema); } ////////////////////////////////////////////////// //FORMCUSTOM table if (currentSchema < 9) { LogUpdateMessage(log); exec("CREATE TABLE aformcustom (id BIGSERIAL PRIMARY KEY, " + "formkey varchar(255) not null, template text, UNIQUE(formkey))"); setSchemaLevel(++currentSchema); } //MAKE SURE THE DESIRED SCHEMA WAS SET PROPERLY if (currentSchema > DESIRED_SCHEMA_LEVEL) throw new ArgumentOutOfRangeException("AySchema::DesiredSchemaLevel WASN'T SET PROPERLY"); //######################################### //!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!! ////////////////////////////////////////////////// // FUTURE // if (currentSchema < 10) // { // LogUpdateMessage(log); // setSchemaLevel(++currentSchema); // } log.LogInformation("Finished updating database schema to version {0}", currentSchema); //************************************************************************************* }//eofunction private static void setSchemaLevel(int nCurrentSchema) { exec("UPDATE aschemaversion SET schema=" + nCurrentSchema.ToString()); } //execute command query private static void exec(string q) { using (var cm = ct.Database.GetDbConnection().CreateCommand()) { ct.Database.OpenConnection(); cm.CommandText = q; cm.ExecuteNonQuery(); ct.Database.CloseConnection(); } } private static void LogUpdateMessage(ILogger log) { log.LogDebug($"Updating database to schema version {currentSchema + 1}"); } //eoclass } //eons }