320 lines
13 KiB
C#
320 lines
13 KiB
C#
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::PrepareDatabaseForSeeding WHEN NEW TABLES ADDED!!!!
|
|
private const int DESIRED_SCHEMA_LEVEL = 9;
|
|
|
|
internal const long EXPECTED_COLUMN_COUNT = 99;
|
|
internal const long EXPECTED_INDEX_COUNT = 20;
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::PrepareDatabaseForSeeding WHEN NEW TABLES ADDED!!!!
|
|
|
|
/////////////////////////////////////////////////////////////////
|
|
|
|
|
|
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, ownerid bigint not null," +
|
|
"ayid bigint not null, aytype integer not null, ayevent integer not null, textra varchar(255))");
|
|
|
|
//LOOKAT: do I *really* need these or do they bloat unnecessarily? Need to test with big dataset
|
|
//index for quick searching
|
|
// exec("CREATE INDEX ayid_idx ON aevent (ayid);");
|
|
// exec("CREATE INDEX aytype_idx ON aevent (aytype);");
|
|
|
|
//Add the search key and dictionary tables
|
|
//TODO: Indexes determined through load testing and experimentation
|
|
//Too many indexes or unnecessary ones would be bad because this table is hit on every save / update of an object and would slow those ops
|
|
//too little is bad if search takes a dogs age to find anything
|
|
|
|
exec("CREATE TABLE asearchdictionary (id BIGSERIAL PRIMARY KEY, word varchar(255) not null)");
|
|
// exec("CREATE UNIQUE INDEX tagname_idx ON atag (name);");
|
|
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, ownerid bigint not null, name varchar(255) not null, stock bool, cjkindex bool default false)");
|
|
exec("CREATE UNIQUE INDEX localename_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)");
|
|
exec("CREATE INDEX localeitemlid_key_idx ON alocaleitem (localeid,key)");
|
|
|
|
//Load the default LOCALES
|
|
AyaNova.Biz.PrimeData.PrimeLocales(ct);
|
|
|
|
|
|
|
|
|
|
//Add user table
|
|
exec("CREATE TABLE auser (id BIGSERIAL PRIMARY KEY, ownerid bigint not null, 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, clientid bigint, headofficeid bigint, subvendorid bigint)");
|
|
|
|
//Add user options table
|
|
exec("CREATE TABLE auseroptions (id BIGSERIAL PRIMARY KEY, ownerid bigint not null, " +
|
|
"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, 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, ownerid bigint not null, name varchar(255) not null, " +
|
|
"startdate timestamp, enddate timestamp, dollaramount decimal(19,5), active bool, roles int4, notes text)");
|
|
|
|
setSchemaLevel(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// FileAttachment table
|
|
if (currentSchema < 5)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
exec("CREATE TABLE afileattachment (id BIGSERIAL PRIMARY KEY, ownerid bigint not null," +
|
|
"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)
|
|
exec("CREATE INDEX storedfilename_idx ON afileattachment (storedfilename);");
|
|
|
|
setSchemaLevel(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//TAG tables
|
|
if (currentSchema < 6)
|
|
{
|
|
LogUpdateMessage(log);
|
|
// LOOKAT: Should taggroupmap have an index that enforces no taggroup can have the same tag more than once? Same for objects being tagged?
|
|
exec("CREATE TABLE atag (id BIGSERIAL PRIMARY KEY, ownerid bigint not null, name varchar(255) not null)");
|
|
exec("CREATE UNIQUE INDEX tagname_idx ON atag (name);");
|
|
exec("CREATE TABLE atagmap (id BIGSERIAL PRIMARY KEY, ownerid bigint not null," +
|
|
"tagid bigint not null REFERENCES atag (id), tagtoobjectid bigint not null, tagtoobjecttype integer not null)");
|
|
|
|
//Taggroup
|
|
exec("CREATE TABLE ataggroup (id BIGSERIAL PRIMARY KEY, ownerid bigint not null, name varchar(255) not null)");
|
|
exec("CREATE TABLE ataggroupmap (id BIGSERIAL PRIMARY KEY, ownerid bigint not null, tagid bigint not null REFERENCES atag (id), taggroupid bigint not null)");
|
|
|
|
setSchemaLevel(++currentSchema);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// OPS LRO tables
|
|
if (currentSchema < 7)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
exec("CREATE TABLE aopsjob (gid uuid PRIMARY KEY, ownerid bigint not null, 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);
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//LICENSE table new columns
|
|
//LOOKAT: DO I need this anymore???
|
|
if (currentSchema < 8)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//Add license related stuff
|
|
exec("ALTER TABLE alicense ADD COLUMN dbid uuid");
|
|
exec("ALTER TABLE alicense ADD COLUMN LastFetchStatus integer");
|
|
exec("ALTER TABLE alicense ADD COLUMN LastFetchMessage text");
|
|
|
|
setSchemaLevel(++currentSchema);
|
|
}
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
// FUTURE
|
|
// if (currentSchema < 9)
|
|
// {
|
|
// LogUpdateMessage(log);
|
|
|
|
// setSchemaLevel(++currentSchema);
|
|
// }
|
|
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::PrepareDatabaseForSeeding WHEN NEW TABLES ADDED!!!!
|
|
|
|
|
|
|
|
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
|
|
} |