diff --git a/devdocs/specs/core-performance.txt b/devdocs/specs/core-performance.txt new file mode 100644 index 00000000..21bdabe3 --- /dev/null +++ b/devdocs/specs/core-performance.txt @@ -0,0 +1,94 @@ +PERFORMANCE SPECS AND USEFUL INFO + +Useful queries to indicate how indexes are being used in postgresql + +This is a test query I used with widget and name fetching performance analysis: +explain analyze SELECT m.name +FROM awidget AS m +WHERE m.id = 12989 +LIMIT 1 + +//All index data collected by postgresql + +select * from pg_stat_user_indexes + + +Reveals Unused indices +=-=-=-=-=-=-=-=-=-=-=- + +SELECT + relid::regclass AS table, + indexrelid::regclass AS index, + pg_size_pretty(pg_relation_size(indexrelid::regclass)) AS index_size, + idx_tup_read, + idx_tup_fetch, + idx_scan +FROM + pg_stat_user_indexes + JOIN pg_index USING (indexrelid) +WHERE + idx_scan > 0 + AND indisunique IS FALSE + + +Shows info on all indices +=-=-=-=-=-=-=-=-=-=-=-=-=- +SELECT + t.tablename, + indexname, + c.reltuples AS num_rows, + pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size, + pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size, + CASE WHEN indisunique THEN 'Y' + ELSE 'N' + END AS UNIQUE, + idx_scan AS number_of_scans, + idx_tup_read AS tuples_read, + idx_tup_fetch AS tuples_fetched +FROM pg_tables t +LEFT OUTER JOIN pg_class c ON t.tablename=c.relname +LEFT OUTER JOIN + ( SELECT c.relname AS ctablename, ipg.relname AS indexname, x.indnatts AS number_of_columns, idx_scan, idx_tup_read, idx_tup_fetch, indexrelname, indisunique FROM pg_index x + JOIN pg_class c ON c.oid = x.indrelid + JOIN pg_class ipg ON ipg.oid = x.indexrelid + JOIN pg_stat_all_indexes psai ON x.indexrelid = psai.indexrelid ) + AS foo + ON t.tablename = foo.ctablename +WHERE t.schemaname='public' +ORDER BY 7,1,2; + + +Show performance of indices that are being used +=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-= +SELECT indexrelname,cast(idx_tup_read AS numeric) / idx_scan AS avg_tuples,idx_scan,idx_tup_read FROM pg_stat_user_indexes WHERE idx_scan > 0; + + + + +WORK IN PROGRESS: + +Search result list: + +//Before attempt to optimize name fetcher (unknown number of results) +//22548, 21187, 20462, 22336, 20094 - AVG = 21325 + +14244 results with index scan: 24141, 29549, 23366, 24085, 23335 AVG: 24895 = 1.7ms per result + +Removed index but kept data: +14244 results without index scan: 23391, 22623, 21428, 22607, 23106 ANOMALOUS, disregarding + +### 14244 results without index scan (after a restart of server): 24124, 21157, 21178, 21187, 21932 AVG: 21915 = 1.53 per result ##### + +14244 results without index scan (after a restart of server and using a fresh aycontext for each query): 32336, 31794...clearly much slower, abandoning this avenue +14244 results without index scan (after a restart of server and using asnotracking for each query): 24625, 21387, 21905, 22190 ... not a dramatic difference, keeping the notracking code in as it makes sense but need to look elsewhere +14244 results without index scan (after a restart of server and bypassing EF entirely with a direct query INITIAL NAIVE ATTEMPT): 13955, 13365, 13421, 13445, 13271 + + +### 14244 results without index scan (after a restart of server and bypassing EF entirely with a direct query OPTIMIZED TO REUSE CONNECTION): 12707, 12341, 12733, 12487, 12452 AVG: 12,544 = .88ms per result #### + +Now I'm going to try it with the index put back in and data regenerated +### 14244 results with index in place (after a restart of server and bypassing EF entirely with a direct query OPTIMIZED TO REUSE CONNECTION): 11229, 15480, 13763, 13051, 13178 AVG: 13,340 = .936 per result + +Now fresh test but without index being crated +### 14244 results with index in place (after a restart of server, and bypassing EF entirely with a direct query OPTIMIZED TO REUSE CONNECTION): 14270 results - 13176, 12688, 13179, 12994, 12272 AVG: 12,861 = .90 per result + diff --git a/devdocs/todo.txt b/devdocs/todo.txt index 6e9bca79..f0e42b07 100644 --- a/devdocs/todo.txt +++ b/devdocs/todo.txt @@ -27,7 +27,14 @@ Once that is done then can steam ahead on the biz objects but until I have the c IMMEDIATE ITEMS: ================ - +Current huge seeding takes around 15 minutes +Current unbounded search for "et*" in huge dataset takes avg 21 seconds to process +{ + "phrase": "et*", + "nameOnly": false, + "typeOnly": 0, + "maxResults": 0 +} - Search and search text indexing - https://gist.github.com/ruckus/5718112 @@ -35,22 +42,12 @@ IMMEDIATE ITEMS: - Can it be sped up with the huge dataset test (The actual slowness is directly related to namefetch so that's where I am concentrating effort) - - First up is to test generate data again and see if the name fetcher query uses the compound name/id index I added when data is generated freshly - - First add to ayschema these two indexes (2 in case one preferred over other or order issues) - - CREATE INDEX widget_idx_test_name_id2 - ON public.awidget USING btree - (name COLLATE pg_catalog."default", id) - TABLESPACE pg_default; - - CREATE UNIQUE INDEX widget_idx_name_id - ON public.awidget USING btree - (id, name COLLATE pg_catalog."default") - TABLESPACE pg_default; - - - - + - One final test *WITH* the index again just to confirm the earlier results, if it's confirmed slower then remove the index + but keep the code in place in case it becomes faster again with it later + - Re-run the integration tests for search performance and set a new benchmark minimum for that shit as it should be way faster now + - Change return object from a search to include a count of results plus the restricted list of results + - this way the Client can know there are tons more than just weren't shown so they can narrow their terms + - see if any other callers to name fetcher are in tight loops and could benefit from using the new Direct version - Update all the other routes to include search indexing (attachments, tags etc, anything with text in it) diff --git a/server/AyaNova/Startup.cs b/server/AyaNova/Startup.cs index 113523b7..935ce0e5 100644 --- a/server/AyaNova/Startup.cs +++ b/server/AyaNova/Startup.cs @@ -405,7 +405,7 @@ namespace AyaNova if (TESTING_REFRESH_DB) { AyaNova.Core.License.Fetch(apiServerState, dbContext, _log); - Util.Seeder.SeedDatabase(Util.Seeder.SeedLevel.SmallOneManShopTrialDataSet); + Util.Seeder.SeedDatabase(Util.Seeder.SeedLevel.HugeForLoadTest); } //TESTING #endif diff --git a/server/AyaNova/biz/BizObjectNameFetcher.cs b/server/AyaNova/biz/BizObjectNameFetcher.cs index 9bcab00d..bed72fa3 100644 --- a/server/AyaNova/biz/BizObjectNameFetcher.cs +++ b/server/AyaNova/biz/BizObjectNameFetcher.cs @@ -34,13 +34,35 @@ namespace AyaNova.Biz switch (aytype) { case AyaType.User: - return ct.User.Where(m => m.Id == id).Select(m => m.Name).FirstOrDefault(); + return ct.User.AsNoTracking().Where(m => m.Id == id).Select(m => m.Name).FirstOrDefault(); case AyaType.Widget: - return ct.Widget.Where(m => m.Id == id).Select(m => m.Name).FirstOrDefault(); + { + + using (var command = ct.Database.GetDbConnection().CreateCommand()) + { + command.CommandText = $"SELECT m.name FROM awidget AS m WHERE m.id = {id} LIMIT 1"; + ct.Database.OpenConnection(); + using (var dr = command.ExecuteReader()) + { + + // do something with result + return dr.Read() ? dr.GetString(0) : "UNKNOWN"; + } + } + + // var ret = ct.Widget + // .FromSql($"SELECT m.name FROM awidget AS m WHERE m.id = {id} LIMIT 1") + // .FirstOrDefault(); + // return ret.Name; + + + + // return ct.Widget.AsNoTracking().Where(m => m.Id == id).Select(m => m.Name).FirstOrDefault(); + } case AyaType.Tag: - return ct.Tag.Where(m => m.Id == id).Select(m => m.Name).FirstOrDefault(); + return ct.Tag.AsNoTracking().Where(m => m.Id == id).Select(m => m.Name).FirstOrDefault(); case AyaType.TagGroup: - return ct.TagGroup.Where(m => m.Id == id).Select(m => m.Name).FirstOrDefault(); + return ct.TagGroup.AsNoTracking().Where(m => m.Id == id).Select(m => m.Name).FirstOrDefault(); default: throw new System.NotSupportedException($"AyaNova.BLL.BizObjectNameFetcher::Name type {aytype.ToString()} is not supported"); diff --git a/server/AyaNova/biz/BizObjectNameFetcherDirect.cs b/server/AyaNova/biz/BizObjectNameFetcherDirect.cs new file mode 100644 index 00000000..9206e655 --- /dev/null +++ b/server/AyaNova/biz/BizObjectNameFetcherDirect.cs @@ -0,0 +1,76 @@ +using System.Linq; +using System.Threading.Tasks; +using Microsoft.EntityFrameworkCore; +using Microsoft.AspNetCore.Mvc; +using Microsoft.AspNetCore.JsonPatch; +using EnumsNET; +using AyaNova.Util; +using AyaNova.Api.ControllerHelpers; +using AyaNova.Biz; +using AyaNova.Models; + + +namespace AyaNova.Biz +{ + + /* + + using (var command = ct.Database.GetDbConnection().CreateCommand()) + { + command.CommandText = $"SELECT m.name FROM awidget AS m WHERE m.id = {id} LIMIT 1"; + ct.Database.OpenConnection(); + using (var dr = command.ExecuteReader()) + { + + // do something with result + return dr.Read() ? dr.GetString(0) : "UNKNOWN"; + } + } + */ + //Turn a type and ID into a displayable name + internal static class BizObjectNameFetcherDirect + { + + internal static string Name(AyaTypeId tid, System.Data.Common.DbCommand cmd) + { + return Name(tid.ObjectType, tid.ObjectId, cmd); + } + + + //Returns existance status of object type and id specified in database + internal static string Name(AyaType aytype, long id, System.Data.Common.DbCommand cmd) + { + string TABLE = string.Empty; + switch (aytype) + { + case AyaType.User: + TABLE = "auser"; + break; + case AyaType.Widget: + TABLE = "awidget"; + break; + case AyaType.Tag: + TABLE = "atag"; + break; + case AyaType.TagGroup: + TABLE = "ataggroup"; + break; + default: + throw new System.NotSupportedException($"AyaNova.BLL.BizObjectNameFetcher::Name type {aytype.ToString()} is not supported"); + } + cmd.CommandText = $"SELECT m.name FROM {TABLE} AS m WHERE m.id = {id} LIMIT 1"; + using (var dr = cmd.ExecuteReader()) + return dr.Read() ? dr.GetString(0) : "UNKNOWN"; + } + + + + + + ///////////////////////////////////////////////////////////////////// + + }//eoc + + +}//eons + diff --git a/server/AyaNova/biz/Search.cs b/server/AyaNova/biz/Search.cs index f1a31180..101c4544 100644 --- a/server/AyaNova/biz/Search.cs +++ b/server/AyaNova/biz/Search.cs @@ -340,18 +340,38 @@ namespace AyaNova.Biz watch.Start();//###################### PROFILING watch.Start();//###################### PROFILING - //Build the return list from the remaining matching objects list - //BUGBUG: THIS is what is taking all the time in the search FFS! - foreach (AyaTypeId i in OrderedMatchingObjects) + + + //EF CORE METHOD + // //Build the return list from the remaining matching objects list + // foreach (AyaTypeId i in OrderedMatchingObjects) + // { + // SearchResult SR = new SearchResult(); + // SR.Name = BizObjectNameFetcher.Name(i, ct);//THIS IS CAUSING ALL THE SLOWNESS IN RETURNING SEARCH RESULTS + // SR.Id = i.ObjectId; + // SR.Type = i.ObjectType; + // ResultList.Add(SR); + // } + + //TEST DIRECT METHOD ############## + using (var command = ct.Database.GetDbConnection().CreateCommand()) { - SearchResult SR = new SearchResult(); - //SR.Name = "BLAH"; - SR.Name = BizObjectNameFetcher.Name(i, ct);//THIS IS PROBABLY CAUSING ALL THE SLOWNESS - SR.Id = i.ObjectId; - SR.Type = i.ObjectType; - ResultList.Add(SR); + + ct.Database.OpenConnection(); + //Build the return list from the remaining matching objects list + foreach (AyaTypeId i in OrderedMatchingObjects) + { + SearchResult SR = new SearchResult(); + + SR.Name = BizObjectNameFetcherDirect.Name(i, command);//THIS IS CAUSING ALL THE SLOWNESS IN RETURNING SEARCH RESULTS + + SR.Id = i.ObjectId; + SR.Type = i.ObjectType; + ResultList.Add(SR); + } } + watch.Stop();//###################### PROFILING var TimeToBuildSearchResultReturnList = watch.ElapsedMilliseconds;//###################### PROFILING @@ -365,9 +385,6 @@ WHERE m.id = 12989 LIMIT 1 - - - "Limit (cost=0.29..8.30 rows=1 width=27) (actual time=0.079..0.080 rows=1 loops=1)" " -> Index Scan using awidget_pkey on awidget m (cost=0.29..8.30 rows=1 width=27) (actual time=0.077..0.077 rows=1 loops=1)" " Index Cond: (id = 12989)" @@ -379,49 +396,8 @@ LIMIT 1 select * from pg_stat_user_indexes -SELECT indexrelname,cast(idx_tup_read AS numeric) / idx_scan AS avg_tuples,idx_scan,idx_tup_read FROM pg_stat_user_indexes WHERE idx_scan > 0; -SELECT - t.tablename, - indexname, - c.reltuples AS num_rows, - pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size, - pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size, - CASE WHEN indisunique THEN 'Y' - ELSE 'N' - END AS UNIQUE, - idx_scan AS number_of_scans, - idx_tup_read AS tuples_read, - idx_tup_fetch AS tuples_fetched -FROM pg_tables t -LEFT OUTER JOIN pg_class c ON t.tablename=c.relname -LEFT OUTER JOIN - ( SELECT c.relname AS ctablename, ipg.relname AS indexname, x.indnatts AS number_of_columns, idx_scan, idx_tup_read, idx_tup_fetch, indexrelname, indisunique FROM pg_index x - JOIN pg_class c ON c.oid = x.indrelid - JOIN pg_class ipg ON ipg.oid = x.indexrelid - JOIN pg_stat_all_indexes psai ON x.indexrelid = psai.indexrelid ) - AS foo - ON t.tablename = foo.ctablename -WHERE t.schemaname='public' -ORDER BY 7,1,2; - - -Unused indexes? -SELECT - relid::regclass AS table, - indexrelid::regclass AS index, - pg_size_pretty(pg_relation_size(indexrelid::regclass)) AS index_size, - idx_tup_read, - idx_tup_fetch, - idx_scan -FROM - pg_stat_user_indexes - JOIN pg_index USING (indexrelid) -WHERE - idx_scan > 0 - AND indisunique IS FALSE - */ @@ -916,7 +892,7 @@ WHERE { //Filter out short words if we are breaking for indexing //but keep them if they are part of a wildcard search phrase - if (s.Length > MINWORDLENGTH || (KeepWildCards && s.Contains('%'))) + if (s.Length >= MINWORDLENGTH || (KeepWildCards && s.Contains('%'))) { //Add only non stopwords if (!LocaleSearchData.StopWords.Contains(s)) diff --git a/server/AyaNova/util/AySchema.cs b/server/AyaNova/util/AySchema.cs index 0abc4f41..7a99a05e 100644 --- a/server/AyaNova/util/AySchema.cs +++ b/server/AyaNova/util/AySchema.cs @@ -23,7 +23,7 @@ namespace AyaNova.Util private const int DESIRED_SCHEMA_LEVEL = 9; internal const long EXPECTED_COLUMN_COUNT = 99; - internal const long EXPECTED_INDEX_COUNT = 24; + internal const long EXPECTED_INDEX_COUNT = 22; //!!!!WARNING: BE SURE TO UPDATE THE DbUtil::PrepareDatabaseForSeeding WHEN NEW TABLES ADDED!!!! ///////////////////////////////////////////////////////////////// @@ -192,9 +192,9 @@ namespace AyaNova.Util exec("CREATE TABLE awidget (id BIGSERIAL PRIMARY KEY, ownerid bigint not null, name varchar(255) not null, " + "startdate timestamp, enddate timestamp, dollaramount decimal(19,5), active bool, roles int4, notes text)"); - //TESTING INDEXES ONLY ############################ - exec("CREATE INDEX widget_idx_test_name_id2 ON public.awidget USING btree (name COLLATE pg_catalog.\"default\", id) TABLESPACE pg_default;"); - exec("CREATE UNIQUE INDEX widget_idx_name_id ON public.awidget USING btree (id, name COLLATE pg_catalog.\"default\") TABLESPACE pg_default;"); + //PERF TESTING INDEX ############################ + //Weirdly, it's always slower when it uses the index?? memory issue maybe? + exec("CREATE UNIQUE INDEX widget_idx_name_id ON public.awidget USING btree (id, name COLLATE pg_catalog.\"default\") TABLESPACE pg_default;"); setSchemaLevel(++currentSchema); }