|
|
|
|
@@ -23,12 +23,26 @@ namespace AyaNova.Util
|
|
|
|
|
private const int DESIRED_SCHEMA_LEVEL = 9;
|
|
|
|
|
|
|
|
|
|
internal const long EXPECTED_COLUMN_COUNT = 99;
|
|
|
|
|
internal const long EXPECTED_INDEX_COUNT = 22;
|
|
|
|
|
internal const long EXPECTED_INDEX_COUNT = 23;
|
|
|
|
|
|
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::PrepareDatabaseForSeeding 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
|
|
|
|
|
|
|
|
|
|
*/
|
|
|
|
|
|
|
|
|
|
static int startingSchema = -1;
|
|
|
|
|
public static int currentSchema = -1;
|
|
|
|
|
|
|
|
|
|
@@ -125,37 +139,30 @@ namespace AyaNova.Util
|
|
|
|
|
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
|
|
|
|
|
|
|
|
|
|
//SEARCH TABLES
|
|
|
|
|
exec("CREATE TABLE asearchdictionary (id BIGSERIAL PRIMARY KEY, word varchar(255) not null)");
|
|
|
|
|
exec("CREATE UNIQUE INDEX searchdictword_idx ON asearchdictionary (word);");
|
|
|
|
|
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, 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 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)");
|
|
|
|
|
exec("CREATE INDEX localeitemlid_key_idx ON alocaleitem (localeid,key)");
|
|
|
|
|
exec("CREATE INDEX alocaleitem_localeid_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)");
|
|
|
|
|
|
|
|
|
|
//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, ownerid bigint not null, " +
|
|
|
|
|
"userid bigint not null, timezoneoffset decimal(19,5) not null default 0, emailaddress text, uicolor int not null default 0)");
|
|
|
|
|
@@ -192,9 +199,8 @@ namespace AyaNova.Util
|
|
|
|
|
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)");
|
|
|
|
|
|
|
|
|
|
//PERF TESTING INDEX ############################
|
|
|
|
|
//Weirdly, it's always slower when it uses the index?? memory issue maybe?
|
|
|
|
|
exec("CREATE UNIQUE INDEX widget_idx_name_id ON public.awidget USING btree (id, name COLLATE pg_catalog.\"default\") TABLESPACE pg_default;");
|
|
|
|
|
//Compound index for name fetching
|
|
|
|
|
exec("CREATE UNIQUE INDEX awidget_name_id_idx ON awidget (id, name);");
|
|
|
|
|
|
|
|
|
|
setSchemaLevel(++currentSchema);
|
|
|
|
|
}
|
|
|
|
|
@@ -211,7 +217,8 @@ namespace AyaNova.Util
|
|
|
|
|
"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);");
|
|
|
|
|
//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);
|
|
|
|
|
}
|
|
|
|
|
@@ -224,7 +231,10 @@ namespace AyaNova.Util
|
|
|
|
|
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);");
|
|
|
|
|
|
|
|
|
|
//LOOKAT: isn't this useless without the ID? Need to see if it's being used after unit testing
|
|
|
|
|
exec("CREATE UNIQUE INDEX atag_name_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)");
|
|
|
|
|
|
|
|
|
|
@@ -253,6 +263,7 @@ namespace AyaNova.Util
|
|
|
|
|
//////////////////////////////////////////////////
|
|
|
|
|
//LICENSE table new columns
|
|
|
|
|
//LOOKAT: DO I need this anymore???
|
|
|
|
|
//answer: no because it relates to ops stuff in other tables and logging, not to the license itself (except maybe dbid?)
|
|
|
|
|
if (currentSchema < 8)
|
|
|
|
|
{
|
|
|
|
|
LogUpdateMessage(log);
|
|
|
|
|
|