1364 lines
106 KiB
C#
1364 lines
106 KiB
C#
using System;
|
|
using System.Threading.Tasks;
|
|
using Microsoft.Extensions.Logging;
|
|
using Microsoft.EntityFrameworkCore;
|
|
using Sockeye.Models;
|
|
|
|
namespace Sockeye.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::EmptyBizDataFromDatabaseForSeedingOrImportingAsync WHEN NEW TABLES ADDED!!!!
|
|
private const int DESIRED_SCHEMA_LEVEL = 16;
|
|
|
|
internal const long EXPECTED_COLUMN_COUNT = 495;
|
|
internal const long EXPECTED_INDEX_COUNT = 71;
|
|
internal const long EXPECTED_CHECK_CONSTRAINTS = 236;
|
|
internal const long EXPECTED_FOREIGN_KEY_CONSTRAINTS = 32;
|
|
internal const long EXPECTED_VIEWS = 0;
|
|
internal const long EXPECTED_ROUTINES = 2;
|
|
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImportingAsync WHEN NEW TABLES ADDED!!!!
|
|
|
|
///////////////////////////////////////// (C495:I71:CC236:FC32:V0: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(10,5) largest tax I could find would fit in this, (was 8,5 but Joyce had an item that was 8000% so changed to allow up to 10000%)
|
|
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,'{Sockeye.Util.Hasher.GenerateSalt()}');";//NOTE: this is where the dbid comes from originally
|
|
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("Sockeye schema version is " + currentSchema.ToString());
|
|
}
|
|
else
|
|
{
|
|
await ct.Database.CloseConnectionAsync();
|
|
throw new System.Exception("Sockeye->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("Sockeye database needs to be updated from schema version {0} to version {1}", currentSchema, DESIRED_SCHEMA_LEVEL);
|
|
|
|
//************* SCHEMA UPDATES ******************
|
|
bool PrimeEmptyDB = false;
|
|
//////////////////////////////////////////////////
|
|
// v8 initial release TABLES
|
|
//
|
|
if (currentSchema < 1)
|
|
{
|
|
LogUpdateMessage(log);
|
|
PrimeEmptyDB = true;
|
|
//create global biz settings table
|
|
await ExecQueryAsync("CREATE TABLE aglobalbizsettings (id INTEGER NOT NULL PRIMARY KEY, "
|
|
+ "webaddress TEXT, phone1 TEXT, phone2 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), "
|
|
+ "filtercasesensitive BOOL DEFAULT FALSE, "
|
|
+ "customerallowusersettings BOOL DEFAULT FALSE, customerallowusersettingsintags 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 TIMESTAMPTZ, 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, sockeyeserverurl TEXT)");
|
|
|
|
//create aevent biz event log table
|
|
await ExecQueryAsync("CREATE TABLE aevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created TIMESTAMPTZ NOT NULL, userid BIGINT NOT NULL,"
|
|
+ "sockid BIGINT NOT NULL, socktype INTEGER NOT NULL, sockevent 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_sockid_sockType ON aevent (sockid, socktype);");
|
|
|
|
//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 TIMESTAMPTZ NOT NULL, allocated BIGINT,workingset BIGINT,privatebytes BIGINT,cpu double precision)");
|
|
//One day metrics
|
|
await ExecQueryAsync("CREATE TABLE ametricdd (t TIMESTAMPTZ 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, sockType 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 sockType=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, sockType );");
|
|
|
|
//This is what is needed during Searching
|
|
//search does a lot of hits on searchkey looking for the wordid and optionally sockType
|
|
//In testing this did not pan out, in fact it was much faster to search both with and without a sockType specified to simply have an index on wordid
|
|
// await ExecQueryAsync("CREATE INDEX asearchkey_wordid_otype_idx ON asearchkey (wordid, sockType);");
|
|
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,
|
|
socktype 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 socktype=0 THEN
|
|
RAISE EXCEPTION 'Bad object type --> %', socktype;
|
|
END IF;
|
|
|
|
IF cleanfirst=true THEN
|
|
delete from asearchkey where objectid=ayobjectid and sockType=socktype;
|
|
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,sockType) values(wordid,ayobjectid,socktype);
|
|
ELSE
|
|
insert into asearchkey (wordid,objectid,sockType) values(wordid,ayobjectid,socktype);
|
|
END IF;
|
|
END LOOP;
|
|
END;
|
|
$BODY$;
|
|
");
|
|
|
|
|
|
//Original Name fetcher function, superseded by later updates
|
|
await ExecQueryAsync(@"
|
|
CREATE OR REPLACE FUNCTION PUBLIC.AYGETNAME(IN AYOBJECTID BIGINT, IN AYATYPE INTEGER,TRANSLATIONID integer) RETURNS TEXT AS $BODY$
|
|
DECLARE
|
|
aytable TEXT DEFAULT '';
|
|
aynamecolumn TEXT DEFAULT 'name';
|
|
aytkey TEXT DEFAULT 'no';
|
|
returnstr TEXT DEFAULT '';
|
|
BEGIN
|
|
case socktype
|
|
when 0 then aytkey= 'NoType';
|
|
when 1 then aytkey= 'Global';
|
|
when 2 then return 'FormUserOptions';
|
|
when 3 then aytable = 'auser';
|
|
when 4 then aytkey= 'ServerState';
|
|
when 5 then aytkey= 'License';
|
|
when 6 then aytkey= 'LogFile';
|
|
when 7 then aytkey= 'PickListTemplate';
|
|
when 8 then aytable = 'acustomer';
|
|
when 9 then aytkey= 'ServerJob';
|
|
when 12 then aytkey= 'ServerMetrics';
|
|
when 13 then aytable = 'atranslation';
|
|
when 14 then aytkey= 'UserOptions';
|
|
when 15 then aytable = 'aheadoffice';
|
|
when 17 then aytable = 'afileattachment'; aynamecolumn ='displayfilename';
|
|
when 18 then aytable = 'adatalistsavedfilter';
|
|
when 19 then aytable = 'aformcustom'; aynamecolumn = 'formkey';
|
|
when 47 then aytkey= 'GlobalOps';
|
|
when 48 then aytkey= 'BizMetrics';
|
|
when 49 then aytkey= 'Backup';
|
|
when 50 then aytable = 'ainappnotification';
|
|
when 51 then aytkey= 'NotifySubscription';
|
|
when 52 then aytable = 'areminder';
|
|
when 56 then aytkey= 'OpsNotificationSettings';
|
|
when 57 then aytable = 'areport';
|
|
when 58 then aytkey= 'DashBoardView';
|
|
when 59 then aytable = 'acustomernote'; aynamecolumn = 'notedate';
|
|
when 60 then aytable = 'amemo';
|
|
when 61 then aytable = 'areview';
|
|
when 68 then return format('DataListColumnView %L', ayobjectid);
|
|
when 84 then aytkey= 'CustomerNotifySubscription';
|
|
else
|
|
RETURN returnstr;
|
|
end case;
|
|
|
|
IF aytkey='no' then
|
|
EXECUTE format('SELECT %I FROM %I WHERE id = %L', aynamecolumn, aytable, ayobjectid) INTO returnstr;
|
|
else
|
|
EXECUTE format('select display from atranslationitem where translationid=%L and key=%L', TRANSLATIONID, aytkey) INTO returnstr;
|
|
END if;
|
|
RETURN returnstr;
|
|
END;
|
|
$BODY$ LANGUAGE PLPGSQL STABLE");
|
|
|
|
//Usage: select created, textra, AYGETNAME(aevent.ayid, aevent.socktype) 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, baselanguage TEXT NOT NULL, 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)");
|
|
//a lot of queries for subsets of translations
|
|
await ExecQueryAsync("CREATE INDEX idx_atranslationitem_key ON atranslationitem (key)");
|
|
|
|
|
|
//Load the default TRANSLATIONS
|
|
await Sockeye.Biz.PrimeData.PrimeTranslations();
|
|
|
|
|
|
//Add user table
|
|
//!!WARNING: changes here need to be reflected in dbutil::EmptyBizDataFromDatabaseForSeedingOrImportingAsync auser_backup
|
|
await ExecQueryAsync("CREATE TABLE auser (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, active BOOL NOT NULL, name TEXT NOT NULL, "
|
|
+ "lastlogin TIMESTAMPTZ, login TEXT NOT NULL UNIQUE, password TEXT NOT NULL, salt TEXT NOT NULL, roles INTEGER NOT NULL, currentauthtoken TEXT, "
|
|
+ "dlkey TEXT, dlkeyexpire TIMESTAMPTZ, totpsecret TEXT, temptoken TEXT, twofactorenabled BOOL, passwordresetcode TEXT, passwordresetcodeexpire TIMESTAMPTZ, 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
|
|
//!!WARNING: changes here need to be reflected in dbutil::EmptyBizDataFromDatabaseForSeedingOrImportingAsync auseroptions_backup
|
|
await ExecQueryAsync("CREATE TABLE auseroptions (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, "
|
|
+ "userid BIGINT NOT NULL UNIQUE REFERENCES auser (id) ON DELETE CASCADE, 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, mapurltemplate TEXT, uicolor VARCHAR(12) NOT NULL default '#ffffff')");
|
|
|
|
|
|
// //Prime the db with the default SuperUser account
|
|
// await Sockeye.Biz.PrimeData.PrimeSuperUserAccount(ct);
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE afileattachment (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, "
|
|
+ "attachtoobjectid BIGINT NOT NULL, attachtosockType INTEGER NOT NULL, attachedbyuserid BIGINT NOT NULL REFERENCES auser (id), "
|
|
+ "storedfilename TEXT NOT NULL, displayfilename TEXT NOT NULL, contenttype TEXT, lastmodified TIMESTAMPTZ 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_attachtosockType ON afileattachment (attachtoobjectid, attachtosockType );");
|
|
|
|
await ExecQueryAsync("CREATE TABLE aopsjob (gid uuid PRIMARY KEY, name TEXT NOT NULL, created TIMESTAMPTZ NOT NULL, exclusive BOOL NOT NULL, "
|
|
+ "startafter TIMESTAMPTZ NOT NULL, jobtype INTEGER NOT NULL, subtype INTEGER, objectid BIGINT, sockType INTEGER, jobstatus INTEGER NOT NULL, jobinfo TEXT)");
|
|
await ExecQueryAsync("CREATE TABLE aopsjoblog (gid uuid PRIMARY KEY, jobid uuid NOT NULL, created TIMESTAMPTZ 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 aformuseroptions (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, "
|
|
+ "userid BIGINT NOT NULL REFERENCES auser ON DELETE CASCADE, formkey VARCHAR(255) NOT NULL, options TEXT 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)");
|
|
|
|
|
|
//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 TIMESTAMPTZ 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 TIMESTAMPTZ NOT NULL, stopdate TIMESTAMPTZ NOT NULL, userid BIGINT NOT NULL REFERENCES auser(id) ON DELETE CASCADE, 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, "
|
|
+ "reviewdate TIMESTAMPTZ NOT NULL, completeddate TIMESTAMPTZ NULL, completionnotes TEXT, userid BIGINT NOT NULL REFERENCES auser(id) ON DELETE CASCADE, "
|
|
+ "assignedbyuserid BIGINT NOT NULL REFERENCES auser(id), sockType INTEGER NOT NULL, objectid BIGINT NOT NULL)");
|
|
|
|
await ExecQueryAsync("CREATE INDEX idx_areview_objectid_sockType ON areview (objectid, sockType );");
|
|
await ExecQueryAsync("CREATE INDEX idx_areview_userid ON areview (userid);");
|
|
await ExecQueryAsync("CREATE INDEX idx_areview_reviewdate ON areview (reviewdate);");
|
|
await ExecQueryAsync("CREATE INDEX idx_areview_completeddate ON areview (completeddate);");
|
|
|
|
|
|
|
|
//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, alertnotes TEXT, billheadoffice BOOL, technotes TEXT, accountnumber 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 (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 TIMESTAMPTZ NOT NULL, notes TEXT, 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, "
|
|
+ "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 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, alertnotes 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))");
|
|
|
|
|
|
//NOTIFICATION
|
|
await ExecQueryAsync("CREATE TABLE anotifysubscription (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, "
|
|
+ "userid BIGINT NOT NULL REFERENCES auser (id) ON DELETE CASCADE, socktype 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, tags VARCHAR(255) ARRAY)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE anotifyevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created TIMESTAMPTZ NOT NULL, "
|
|
+ "socktype 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) ON DELETE CASCADE, eventdate TIMESTAMPTZ NOT NULL, decvalue DECIMAL(38,18) NULL, message TEXT)");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE ainappnotification (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, userid BIGINT NOT NULL REFERENCES auser (id) ON DELETE CASCADE, "
|
|
+ "created TIMESTAMPTZ NOT NULL, socktype 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 TIMESTAMPTZ NOT NULL, "
|
|
+ "objectid BIGINT NOT NULL, notifysubscriptionid BIGINT NOT NULL, fail BOOL NOT NULL, error TEXT)");
|
|
|
|
|
|
//CUSTOMER "proxy" NOTIFICATION
|
|
await ExecQueryAsync("CREATE TABLE acustomernotifysubscription (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, "
|
|
+ "translationid BIGINT NOT NULL REFERENCES atranslation (id) NOT NULL, languageoverride TEXT NOT NULL, timezoneoverride TEXT NOT NULL, "
|
|
+ "currencyname TEXT NOT NULL, hour12 BOOL NOT NULL, "
|
|
+ "customertags VARCHAR(255) ARRAY, socktype 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, "
|
|
+ "linkreportid BIGINT, template TEXT NOT NULL, subject TEXT NOT NULL, tags VARCHAR(255) ARRAY)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE acustomernotifyevent (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created TIMESTAMPTZ NOT NULL, "
|
|
+ "socktype INTEGER NOT NULL, objectid BIGINT NOT NULL, name TEXT NOT NULL, eventtype INTEGER NOT NULL, customernotifysubscriptionid BIGINT NOT NULL REFERENCES acustomernotifysubscription(id) ON DELETE CASCADE, "
|
|
+ "customerid BIGINT NOT NULL REFERENCES acustomer (id) ON DELETE CASCADE, eventdate TIMESTAMPTZ NOT NULL, decvalue DECIMAL(38,18) NULL)");
|
|
|
|
await ExecQueryAsync("CREATE TABLE acustomernotifydeliverylog (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, processed TIMESTAMPTZ NOT NULL, "
|
|
+ "objectid BIGINT NOT NULL, customernotifysubscriptionid BIGINT 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, active BOOL NOT NULL, "
|
|
+ "notes TEXT, roles INTEGER NOT NULL, sockType 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(10,5), UNIQUE(name,sockType))");
|
|
|
|
|
|
//Load the stock REPORT TEMPLATES
|
|
await Sockeye.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);
|
|
|
|
|
|
|
|
|
|
}
|
|
|
|
//////////////////////////////////////////////////
|
|
//
|
|
// Beta .2 new translation keys for import feature
|
|
//
|
|
if (currentSchema < 2)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ImportNewRecords', 'Import new records' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'UpdateExistingRecords', 'Update existing records' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AdminImportUpdateWarning', 'Warning: you are about to permanently change multiple objects.\r\nAre you sure?' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'FileToImport', 'File to import' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProcessCompleted', 'Process completed' FROM atranslation t where t.baselanguage = 'en'");
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ImportNewRecords', 'Importar nuevos registros' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'UpdateExistingRecords', 'Actualizar registros existentes' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AdminImportUpdateWarning', 'Advertencia: está a punto de cambiar varios objetos de forma permanente.\r\n¿Está seguro?' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'FileToImport', 'Archivo a importar' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProcessCompleted', 'Proceso completado' FROM atranslation t where t.baselanguage = 'es'");
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ImportNewRecords', 'Importer de nouveaux enregistrements' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'UpdateExistingRecords', 'Mettre à jour les enregistrements existants' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AdminImportUpdateWarning', 'Avertissement: vous êtes sur le point de modifier définitivement plusieurs objets.\r\nÊtes-vous sûr?' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'FileToImport', 'Fichier à importer' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProcessCompleted', 'Processus terminé' FROM atranslation t where t.baselanguage = 'fr'");
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ImportNewRecords', 'Importieren Sie neue Datensätze' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'UpdateExistingRecords', 'Aktualisieren Sie vorhandene Datensätze' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AdminImportUpdateWarning', 'Warnung: Sie sind dabei, mehrere Objekte dauerhaft zu ändern.\r\nSind Sie sicher?' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'FileToImport', 'Zu importierende Datei' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProcessCompleted', 'Prozess abgeschlossen' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
await SetSchemaLevelAsync(2);
|
|
}
|
|
|
|
|
|
////////////////////////////////////////////////
|
|
// rc 1 remove default rate from loan unit
|
|
//
|
|
if (currentSchema < 3)
|
|
{
|
|
LogUpdateMessage(log);
|
|
await ExecQueryAsync("DELETE FROM atranslationitem where key = 'LoanUnitDefaultRate'");
|
|
|
|
await SetSchemaLevelAsync(3);
|
|
}
|
|
|
|
////////////////////////////////////////////////
|
|
// rc 2 integration objects for QBI etc
|
|
//
|
|
if (currentSchema < 4)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//INTEGRATION
|
|
await ExecQueryAsync("CREATE TABLE aintegration (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, integrationappid uuid NOT NULL UNIQUE, name TEXT NOT NULL UNIQUE, active BOOL NOT NULL, "
|
|
+ "integrationdata TEXT )");
|
|
|
|
//INTEGRATIONITEM
|
|
await ExecQueryAsync("CREATE TABLE aintegrationitem (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, integrationid BIGINT NOT NULL REFERENCES aintegration ON DELETE CASCADE, "
|
|
+ "sockType INTEGER NOT NULL, objectid BIGINT NOT NULL, integrationitemid TEXT NOT NULL, integrationitemname TEXT, lastsync TIMESTAMPTZ, integrationitemdata TEXT "
|
|
+ ")");
|
|
|
|
//INTEGRATIONLOG
|
|
await ExecQueryAsync("CREATE TABLE aintegrationlog (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, integrationid BIGINT NOT NULL REFERENCES aintegration ON DELETE CASCADE, created TIMESTAMPTZ NOT NULL, statustext TEXT NOT NULL)");
|
|
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationList', 'Integrated applications' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Integration', 'Integrated application' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationName', 'Name' FROM atranslation t where t.baselanguage = 'en'");
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationList', 'Aplicaciones integradas' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Integration', 'Aplicación integrada' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationName', 'Nombre' FROM atranslation t where t.baselanguage = 'es'");
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationList', 'Applications intégrées' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Integration', 'Application intégrée' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationName', 'Nom' FROM atranslation t where t.baselanguage = 'fr'");
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationList', 'Integrierte Anwendungen' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Integration', 'Integrierte Anwendung' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'IntegrationName', 'Name' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
|
|
//UPDATED NAME FETCHER FOR INTEGRATION
|
|
await ExecQueryAsync(@"
|
|
CREATE OR REPLACE FUNCTION PUBLIC.AYGETNAME(IN AYOBJECTID BIGINT, IN AYATYPE INTEGER,TRANSLATIONID integer) RETURNS TEXT AS $BODY$
|
|
DECLARE
|
|
aytable TEXT DEFAULT '';
|
|
aynamecolumn TEXT DEFAULT 'name';
|
|
aytkey TEXT DEFAULT 'no';
|
|
returnstr TEXT DEFAULT '';
|
|
BEGIN
|
|
case socktype
|
|
when 0 then aytkey= 'NoType';
|
|
when 1 then aytkey= 'Global';
|
|
when 2 then return 'FormUserOptions';
|
|
when 3 then aytable = 'auser';
|
|
when 4 then aytkey= 'ServerState';
|
|
when 6 then aytkey= 'LogFile';
|
|
when 7 then aytkey= 'PickListTemplate';
|
|
when 8 then aytable = 'acustomer';
|
|
when 9 then aytkey= 'ServerJob';
|
|
when 12 then aytkey= 'ServerMetrics';
|
|
when 13 then aytable = 'atranslation';
|
|
when 14 then aytkey= 'UserOptions';
|
|
when 15 then aytable = 'aheadoffice';
|
|
when 17 then aytable = 'afileattachment'; aynamecolumn ='displayfilename';
|
|
when 18 then aytable = 'adatalistsavedfilter';
|
|
when 19 then aytable = 'aformcustom'; aynamecolumn = 'formkey';
|
|
when 33 then aytable = 'avendor';
|
|
when 47 then aytkey= 'GlobalOps';
|
|
when 48 then aytkey= 'BizMetrics';
|
|
when 49 then aytkey= 'Backup';
|
|
when 50 then aytable = 'ainappnotification';
|
|
when 51 then aytkey= 'NotifySubscription';
|
|
when 52 then aytable = 'areminder';
|
|
when 56 then aytkey= 'OpsNotificationSettings';
|
|
when 57 then aytable = 'areport';
|
|
when 58 then aytkey= 'DashBoardView';
|
|
when 59 then aytable = 'acustomernote'; aynamecolumn = 'notedate';
|
|
when 60 then aytable = 'amemo';
|
|
when 61 then aytable = 'areview';
|
|
when 68 then return format('DataListColumnView %L', ayobjectid);
|
|
when 84 then aytkey= 'CustomerNotifySubscription';
|
|
when 92 then aytable = 'aintegration';
|
|
when 93 then aytable = 'alicense';
|
|
when 94 then aytable = 'atriallicenserequest';
|
|
when 95 then aytable = 'asubscriptionserver';
|
|
when 96 then aytable = 'apurchase';
|
|
when 97 then aytable = 'aproduct';
|
|
when 98 then aytable = 'agzcase';
|
|
|
|
else
|
|
RETURN returnstr;
|
|
end case;
|
|
|
|
IF aytkey='no' then
|
|
EXECUTE format('SELECT %I FROM %I WHERE id = %L', aynamecolumn, aytable, ayobjectid) INTO returnstr;
|
|
else
|
|
EXECUTE format('select display from atranslationitem where translationid=%L and key=%L', TRANSLATIONID, aytkey) INTO returnstr;
|
|
END if;
|
|
RETURN returnstr;
|
|
END;
|
|
$BODY$ LANGUAGE PLPGSQL STABLE");
|
|
|
|
await SetSchemaLevelAsync(4);
|
|
}
|
|
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//
|
|
// 8.0.7 additions for customer contact licensing (allowlogin)
|
|
//
|
|
if (currentSchema < 6)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//!!WARNING: changes TO AUSER need to be reflected in dbutil::EmptyBizDataFromDatabaseForSeedingOrImportingAsync auser_backup
|
|
await ExecQueryAsync("ALTER TABLE auser ADD column allowlogin BOOL");
|
|
await ExecQueryAsync("UPDATE auser SET allowlogin=true WHERE active=true");
|
|
|
|
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AllowLogin', 'Allow login' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AllowLogin', 'Permitir acceso' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AllowLogin', 'Autoriser la connexion' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AllowLogin', 'Login erlauben' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
currentSchema = 6;
|
|
await SetSchemaLevelAsync(currentSchema);
|
|
|
|
}
|
|
|
|
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//
|
|
// 8.0.14 additions for job feedback
|
|
//
|
|
if (currentSchema < 8)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("ALTER TABLE aopsjob ADD column progress TEXT");
|
|
|
|
currentSchema = 8;
|
|
await SetSchemaLevelAsync(currentSchema);
|
|
|
|
}
|
|
|
|
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//
|
|
// case 4242
|
|
//
|
|
if (currentSchema < 11)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewCustomer', 'New customer' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewCustomer', 'Nuevo cliente' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewCustomer', 'Nouveau client' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NewCustomer', 'Neukunde' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
currentSchema = 11;
|
|
await SetSchemaLevelAsync(currentSchema);
|
|
}
|
|
|
|
//////////////////////////////////////////////////
|
|
//
|
|
// case 4173
|
|
//
|
|
if (currentSchema < 12)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NotifyEventDirectSMTPMessage', 'On request SMTP' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NotifyEventDirectSMTPMessage', 'Bajo petición SMTP' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NotifyEventDirectSMTPMessage', 'SMTP demandé' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'NotifyEventDirectSMTPMessage', 'Auf Anfrage SMTP' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
currentSchema = 12;
|
|
await SetSchemaLevelAsync(currentSchema);
|
|
}
|
|
|
|
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//
|
|
// case 4341
|
|
//
|
|
if (currentSchema < 14)
|
|
{
|
|
LogUpdateMessage(log);
|
|
await ExecQueryAsync("ALTER TABLE aglobalbizsettings ADD COLUMN addresspostal TEXT;");
|
|
await ExecQueryAsync("ALTER TABLE acustomer ADD COLUMN addresspostal TEXT;");
|
|
await ExecQueryAsync("ALTER TABLE aheadoffice ADD COLUMN addresspostal TEXT;");
|
|
await ExecQueryAsync("ALTER TABLE avendor ADD COLUMN addresspostal TEXT;");
|
|
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AddressPostal', 'Postal / ZIP code' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AddressPostal', 'Código postal' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AddressPostal', 'Code postal' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'AddressPostal', 'Postleitzahl' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
currentSchema = 14;
|
|
await SetSchemaLevelAsync(currentSchema);
|
|
|
|
}
|
|
|
|
|
|
//////////////////////////////////////////////////
|
|
//
|
|
// "In the tree, part of the tree"
|
|
//
|
|
if (currentSchema < 16)
|
|
{
|
|
LogUpdateMessage(log);
|
|
|
|
await ExecQueryAsync("CREATE TABLE alicense (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, created TIMESTAMPTZ NOT NULL, "
|
|
+ "customerid BIGINT NOT NULL REFERENCES acustomer(id), regto TEXT NOT NULL, key TEXT NOT NULL, fetchcode TEXT, fetchemail TEXT, "
|
|
+ "fetchedon TIMESTAMPTZ, dbid TEXT, licenseexpire TIMESTAMPTZ, maintenanceexpire TIMESTAMPTZ NOT NULL, "
|
|
+ "wiki TEXT, tags VARCHAR(255) ARRAY )");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE atriallicenserequest (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, dbid TEXT NOT NULL, companyname TEXT NOT NULL, "
|
|
+ "contactname TEXT NOT NULL, email TEXT NOT NULL, emailconfirmcode TEXT NOT NULL, emailvalidated BOOL DEFAULT false, "
|
|
+ "requested TIMESTAMPTZ NOT NULL, processed TIMESTAMPTZ, status INTEGER NOT NULL DEFAULT 0, rejectreason TEXT, key TEXT, "
|
|
+ "fetchedon TIMESTAMPTZ, perpetual BOOL DEFAULT false NOT NULL )");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE asubscriptionserver (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, active BOOL NOT NULL DEFAULT true, created TIMESTAMPTZ NOT NULL, "
|
|
+ "name TEXT NOT NULL, notes TEXT, datacenter TEXT NOT NULL, timezone TEXT NOT NULL, dbid TEXT, lastupdated TIMESTAMPTZ, subscriptionexpire TIMESTAMPTZ NOT NULL, "
|
|
+ "trial BOOL NOT NULL DEFAULT true, trialcontact TEXT, trialemail TEXT, trialcompany TEXT, operatingsystem TEXT, customersubdomain TEXT, "
|
|
+ "wiki TEXT, tags VARCHAR(255) ARRAY, customerid BIGINT REFERENCES acustomer(id) )");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE aproduct (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name TEXT NOT NULL, active BOOL NOT NULL DEFAULT true, "
|
|
+ "vendorid BIGINT NOT NULL REFERENCES avendor(id), licenseinterval INTERVAL, maintinterval INTERVAL, vendorcode TEXT NOT NULL, ourcode TEXT NOT NULL, "
|
|
+ "wiki TEXT, tags VARCHAR(255) ARRAY )");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE apurchase (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, customerid BIGINT NOT NULL REFERENCES acustomer(id) ON DELETE CASCADE, "
|
|
+ "vendorid BIGINT NOT NULL REFERENCES avendor(id), productid BIGINT NOT NULL REFERENCES aproduct(id), salesordernumber TEXT, "
|
|
+ "purchasedate TIMESTAMPTZ NOT NULL, expiredate TIMESTAMPTZ, canceldate TIMESTAMPTZ, couponcode text, notes text, "
|
|
+ "renewnoticesent BOOL NOT NULL DEFAULT false, quantity INTEGER NOT NULL DEFAULT 1, "
|
|
+ "vendordata TEXT, processeddate TIMESTAMPTZ, "
|
|
+ "wiki TEXT, tags VARCHAR(255) ARRAY )");
|
|
|
|
|
|
await ExecQueryAsync("CREATE TABLE agzcase (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, caseid BIGINT GENERATED BY DEFAULT AS IDENTITY NOT NULL, "
|
|
+ "created TIMESTAMPTZ NOT NULL, closed TIMESTAMPTZ, name TEXT NOT NULL, notes TEXT, "
|
|
+ "wiki TEXT, tags VARCHAR(255) ARRAY )");
|
|
|
|
|
|
|
|
|
|
|
|
//**************** TRANSLATIONS **********************
|
|
#region LICENSE
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseList', 'Licenses' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseRegTo', 'Registered to' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseKey', 'License key' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchCode', 'Fetch code' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchEmail', 'Fetch email' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchedOn', 'Fetched date' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseDBID', 'DBID' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseMaintenanceExpire', 'Maintenance expire to' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseList', 'Licenses' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseRegTo', 'Registered to' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseKey', 'License key' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchCode', 'Fetch code' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchEmail', 'Fetch email' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchedOn', 'Fetched date' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseDBID', 'DBID' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseMaintenanceExpire', 'Maintenance expire to' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseList', 'Licenses' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseRegTo', 'Registered to' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseKey', 'License key' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchCode', 'Fetch code' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchEmail', 'Fetch email' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchedOn', 'Fetched date' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseDBID', 'DBID' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseMaintenanceExpire', 'Maintenance expire to' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseList', 'Licenses' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseRegTo', 'Registered to' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseKey', 'License key' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchCode', 'Fetch code' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchEmail', 'Fetch email' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseFetchedOn', 'Fetched date' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseDBID', 'DBID' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'LicenseMaintenanceExpire', 'Maintenance expire to' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
#endregion license
|
|
|
|
#region TRIALLICENSEREQEUEST
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequest', 'Trial license request' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestList', 'Trial license requests' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestCompanyName', 'Company' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestContactName', 'Contact' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestEmail', 'Email address' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestEmailValidated', 'Email validated' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestRequested', 'Requested' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestProcessed', 'Processed' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestStatus', 'Status' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestRejectReason', 'Reject reason' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestFetchedOn', 'Fetched' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestPerpetual', 'Perpetual' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequest', 'Trial license request' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestList', 'Trial license requests' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestCompanyName', 'Company' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestContactName', 'Contact' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestEmail', 'Email address' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestEmailValidated', 'Email validated' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestRequested', 'Requested' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestProcessed', 'Processed' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestStatus', 'Status' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestRejectReason', 'Reject reason' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestFetchedOn', 'Fetched' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestPerpetual', 'Perpetual' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequest', 'Trial license request' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestList', 'Trial license requests' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestCompanyName', 'Company' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestContactName', 'Contact' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestEmail', 'Email address' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestEmailValidated', 'Email validated' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestRequested', 'Requested' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestProcessed', 'Processed' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestStatus', 'Status' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestRejectReason', 'Reject reason' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestFetchedOn', 'Fetched' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestPerpetual', 'Perpetual' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequest', 'Trial license request' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestList', 'Trial license requests' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestCompanyName', 'Company' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestContactName', 'Contact' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestEmail', 'Email address' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestEmailValidated', 'Email validated' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestRequested', 'Requested' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestProcessed', 'Processed' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestStatus', 'Status' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestRejectReason', 'Reject reason' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestFetchedOn', 'Fetched' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'TrialLicenseRequestPerpetual', 'Perpetual' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
|
|
#endregion triallicenserequest
|
|
|
|
#region SUBSCRIPTIONSERVER
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubscriptionServer', 'Subscription server' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubscriptionServerList', 'Subscription servers' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerName', 'Name' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerNotes', 'Notes' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerDatacenter', 'Data center' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTimeZone', 'Time zone' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerLastUpdated', 'Last updated' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerSubExpire', 'Subscription expires' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialContact', 'Trial contact' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialEmail', 'TrialEmail' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrial', 'Trial' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialCompany', 'Trial company' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerOperatingSystem', 'OS' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerCustomerDomain', 'Customer subdomain' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubscriptionServer', 'Subscription server' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubscriptionServerList', 'Subscription servers' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerName', 'Name' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerNotes', 'Notes' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerDatacenter', 'Data center' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTimeZone', 'Time zone' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerLastUpdated', 'Last updated' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerSubExpire', 'Subscription expires' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialContact', 'Trial contact' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialEmail', 'TrialEmail' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrial', 'Trial' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialCompany', 'Trial company' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerOperatingSystem', 'OS' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerCustomerDomain', 'Customer subdomain' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubscriptionServer', 'Subscription server' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubscriptionServerList', 'Subscription servers' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerName', 'Name' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerNotes', 'Notes' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerDatacenter', 'Data center' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTimeZone', 'Time zone' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerLastUpdated', 'Last updated' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerSubExpire', 'Subscription expires' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialContact', 'Trial contact' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialEmail', 'TrialEmail' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrial', 'Trial' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialCompany', 'Trial company' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerOperatingSystem', 'OS' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerCustomerDomain', 'Customer subdomain' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubscriptionServer', 'Subscription server' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubscriptionServerList', 'Subscription servers' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerName', 'Name' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerNotes', 'Notes' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerDatacenter', 'Data center' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTimeZone', 'Time zone' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerLastUpdated', 'Last updated' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerSubExpire', 'Subscription expires' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialContact', 'Trial contact' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialEmail', 'TrialEmail' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrial', 'Trial' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerTrialCompany', 'Trial company' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerOperatingSystem', 'OS' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'SubServerCustomerDomain', 'Customer subdomain' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
#endregion subscriptionserver
|
|
|
|
#region PRODUCT
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Product', 'Product' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductList', 'Products' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductName', 'Name' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductLicenseInterval', 'License period' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductMaintInterval', 'Maintenance period' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductVendorCode', 'Vendor code' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductOurCode', 'Our code' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Product', 'Product' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductList', 'Products' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductName', 'Name' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductLicenseInterval', 'License period' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductMaintInterval', 'Maintenance period' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductVendorCode', 'Vendor code' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductOurCode', 'Our code' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Product', 'Product' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductList', 'Products' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductName', 'Name' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductLicenseInterval', 'License period' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductMaintInterval', 'Maintenance period' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductVendorCode', 'Vendor code' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductOurCode', 'Our code' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Product', 'Product' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductList', 'Products' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductName', 'Name' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductLicenseInterval', 'License period' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductMaintInterval', 'Maintenance period' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductVendorCode', 'Vendor code' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'ProductOurCode', 'Our code' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
#endregion product
|
|
|
|
#region PURCHASE
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Purchase', 'Purchase' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseList', 'Purchases' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseSalesOrderNumber', 'Sales order #' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseDate', 'Date' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseExpireDate', 'Expires' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseCancelDate', 'Cancelled' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseCouponCode', 'Coupon' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseNotes', 'Notes' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseRenewNoticeSent', 'Renew notice sent' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseQuantity', 'Quantity' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseVendorData', 'Vendor data' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseProcessedDate', 'Processed' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Purchase', 'Purchase' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseList', 'Purchases' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseSalesOrderNumber', 'Sales order #' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseDate', 'Date' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseExpireDate', 'Expires' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseCancelDate', 'Cancelled' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseCouponCode', 'Coupon' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseNotes', 'Notes' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseRenewNoticeSent', 'Renew notice sent' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseQuantity', 'Quantity' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseVendorData', 'Vendor data' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseProcessedDate', 'Processed' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Purchase', 'Purchase' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseList', 'Purchases' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseSalesOrderNumber', 'Sales order #' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseDate', 'Date' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseExpireDate', 'Expires' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseCancelDate', 'Cancelled' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseCouponCode', 'Coupon' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseNotes', 'Notes' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseRenewNoticeSent', 'Renew notice sent' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseQuantity', 'Quantity' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseVendorData', 'Vendor data' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseProcessedDate', 'Processed' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'Purchase', 'Purchase' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseList', 'Purchases' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseSalesOrderNumber', 'Sales order #' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseDate', 'Date' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseExpireDate', 'Expires' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseCancelDate', 'Cancelled' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseCouponCode', 'Coupon' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseNotes', 'Notes' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseRenewNoticeSent', 'Renew notice sent' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseQuantity', 'Quantity' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseVendorData', 'Vendor data' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'PurchaseProcessedDate', 'Processed' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
#endregion purchase
|
|
|
|
#region GZCASE
|
|
//english translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCase', 'Case' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseList', 'Cases' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseId', 'Case #' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseClosed', 'Closed' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseName', 'Summary' FROM atranslation t where t.baselanguage = 'en'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseNotes', 'Details' FROM atranslation t where t.baselanguage = 'en'");
|
|
|
|
//spanish translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCase', 'Case' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseList', 'Cases' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseId', 'Case #' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseClosed', 'Closed' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseName', 'Summary' FROM atranslation t where t.baselanguage = 'es'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseNotes', 'Details' FROM atranslation t where t.baselanguage = 'es'");
|
|
|
|
//french translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCase', 'Case' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseList', 'Cases' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseId', 'Case #' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseClosed', 'Closed' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseName', 'Summary' FROM atranslation t where t.baselanguage = 'fr'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseNotes', 'Details' FROM atranslation t where t.baselanguage = 'fr'");
|
|
|
|
|
|
//german translations
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCase', 'Case' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseList', 'Cases' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseId', 'Case #' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseClosed', 'Closed' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseName', 'Summary' FROM atranslation t where t.baselanguage = 'de'");
|
|
await ExecQueryAsync("INSERT INTO atranslationitem(translationid,key,display) SELECT t.id, 'GZCaseNotes', 'Details' FROM atranslation t where t.baselanguage = 'de'");
|
|
|
|
#endregion gzcase
|
|
|
|
currentSchema = 16;
|
|
await SetSchemaLevelAsync(currentSchema);
|
|
|
|
}
|
|
|
|
|
|
/*
|
|
|
|
|
|
[KEY
|
|
{
|
|
"AyaNovaLicenseKey": {
|
|
"SchemaVersion": "7",
|
|
"Id": "1670002683",
|
|
"Created": "2022-12-02T09:38:03.5126283-08:00",
|
|
"Sub": "true",
|
|
"RegisteredTo": "CompCare Compressed Air Ltd",
|
|
"EmailAddress": "m.knowles@compcare-air.co.uk",
|
|
"FetchCode": "slAERKGVtq",
|
|
"Source": "5246494432",
|
|
"InstallableUntil": "2023-12-02T09:38:03.5125736-08:00",
|
|
"TotalScheduleableUsers": "10",
|
|
"Expires": "2023-12-02T00:00:00",
|
|
"RequestedTrial": "False",
|
|
"Plugins": {
|
|
"Plugin": [
|
|
{
|
|
"Item": "ExportToXls",
|
|
"SubscriptionExpires": "2023-12-02T00:00:00"
|
|
},
|
|
{
|
|
"Item": "RI - Responsive Interface",
|
|
"SubscriptionExpires": "2023-12-02T00:00:00"
|
|
}
|
|
]
|
|
}
|
|
}
|
|
}
|
|
KEY]
|
|
[SIGNATURE
|
|
c6duLfqPW0Cp7vnQ+6CON3rAUWtL8dVpUhoxb6SBXgin6FsYErYLGY5VNkOWGBrsZ04/VXqqkayCBmZuKS6TwD8ki636bZU0VlGituuSdnR3oUcXyNWubc8FXIo8pmZtigTw904uXnVdhSImV0rhNt9EHyprBqgFVq5j0QMePsJmu9tucqwSxVEcWOWAE7j6735AVQua3pyqVtT+j/qSzPSgaxojBG2OHlS/8qMFaKxVQVJ7uFyU5rzQ2CA2CDfusyTit3Bii7Xewm5AhMjxRCbLOp16wWbz5iIC3XZ37hR0+klN6NYvkipVLsL6f2Knf0TFUnt6oF0FwL3M7aSl+w==
|
|
SIGNATURE]
|
|
|
|
|
|
[KEY
|
|
{
|
|
"Key": {
|
|
"LicenseFormat": "8",
|
|
"Id": "1669501889",
|
|
"RegisteredTo": "Vicom Australia",
|
|
"DBID": "mZaliiy+/TsHF9rcMpIGWO20Q5FhPD1ZdnWO2cMKMW8=",
|
|
"Perpetual": true,
|
|
"LicenseExpiration": "5555-01-01T00:00:00",
|
|
"MaintenanceExpiration": "2023-11-25T00:00:00",
|
|
"Features": [
|
|
{
|
|
"Name": "ActiveInternalUsers",
|
|
"Count": 3
|
|
}
|
|
]
|
|
}
|
|
}
|
|
KEY]
|
|
[SIGNATURE
|
|
O4kbtlVvQnHusjYXw3ppdhfkuPV7J7tHys33OYkcSl/KXgIqMhNMwU8TfTt5zsYElMLT0UKPmCoUlBIFmbayHx46xT17qHGm0j4C7HH1FmEefxOrNPtOa7k2AJ4fJvZESZGAIVboOHA2EAATV8WIyTOXAtG2JhHWIN/NVjMK0SlFs+0wkdsmx+8BQ9oZvz19w3I9bnt6kBwIogMTV4NBHk0637TmgGiNMZAXP8g4n/FaMQEXjVXGK05iLMf0jz4HohLSFvx1tpbg65pQ8lJtrdSgiFAvl09WgkpKpFakXuO/xP6HcnkzLIFitB8VCiOzj81YtQ81jldUiig2QYf+IQ==
|
|
SIGNATURE]
|
|
|
|
*/
|
|
|
|
|
|
|
|
//#########################################
|
|
//!!!!WARNING: BE SURE TO UPDATE THE DbUtil::EmptyBizDataFromDatabaseForSeedingOrImporting WHEN NEW TABLES ADDED!!!!
|
|
|
|
//////////////////////////////////////////////////
|
|
// FUTURE
|
|
// if (currentSchema < xx)
|
|
// {
|
|
// LogUpdateMessage(log);
|
|
// exec queries here to do updates
|
|
// currentSchema=xx;
|
|
// await SetSchemaLevelAsync(currentSchema);
|
|
// }
|
|
|
|
/*AdminImportUpdateWarning
|
|
INSERT INTO atranslationitem(translationid,key,display)
|
|
SELECT t.id, 'mytestkey', 'mytestdisplay'
|
|
FROM atranslation t
|
|
where t.baselanguage = 'en'
|
|
*/
|
|
|
|
//Handle newer schema than expected (user ran a new version then downgraded ayanova)
|
|
if (currentSchema > DESIRED_SCHEMA_LEVEL)
|
|
throw new ArgumentOutOfRangeException($"DB Schema error: the database has a newer schema version {currentSchema} than this version of Sockeye expects {DESIRED_SCHEMA_LEVEL}\nThis version of Sockeye is older than a previous version that was used with this database and is not compatible with the new database format.\nUpgrade Sockeye or restore a backup of the database from before the newer version of Sockeye was used.");
|
|
|
|
|
|
|
|
log.LogInformation("Completed updating database schema to version {0}", currentSchema);
|
|
//*************************************************************************************
|
|
|
|
if (PrimeEmptyDB)
|
|
{
|
|
|
|
// //Load the default TRANSLATIONS
|
|
// await Sockeye.Biz.PrimeData.PrimeTranslations();
|
|
|
|
//Prime the db with the default SuperUser account
|
|
await Sockeye.Biz.PrimeData.PrimeSuperUserAccount(ct);
|
|
}
|
|
|
|
}//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
|
|
} |