v3 of indexing test
This commit is contained in:
@@ -12,16 +12,9 @@ todo: Search indexing performance improvement and exception avoidance (Search.cs
|
||||
stored procedure?
|
||||
https://www.postgresqltutorial.com/plpgsql-loop-statements/
|
||||
-------
|
||||
-- PROCEDURE: public.pdoindex(text[], bigint, integer, boolean)
|
||||
|
||||
-- DROP PROCEDURE public.pdoindex(text[], bigint, integer, boolean);
|
||||
|
||||
CREATE OR REPLACE PROCEDURE public.aydosearchindex(
|
||||
wordlist text[],
|
||||
ayobjectid bigint,
|
||||
ayobjecttype integer)
|
||||
LANGUAGE 'plpgsql'
|
||||
|
||||
CREATE OR REPLACE PROCEDURE public.aydosearchindex(wordlist text[], ayobjectid bigint, ayobjecttype integer, cleanfirst boolean)
|
||||
LANGUAGE 'plpgsql'
|
||||
|
||||
AS $BODY$DECLARE
|
||||
s text;
|
||||
wordid bigint;
|
||||
@@ -35,12 +28,24 @@ BEGIN
|
||||
END IF;
|
||||
|
||||
|
||||
delete from asearchkey where objectid=ayobjectid and objecttype=ayobjecttype;
|
||||
IF cleanfirst=true THEN
|
||||
delete from asearchkey where objectid=ayobjectid and objecttype=ayobjecttype;
|
||||
END IF;
|
||||
|
||||
FOREACH s IN ARRAY wordlist
|
||||
FOREACH s IN ARRAY wordlist
|
||||
LOOP
|
||||
insert into asearchdictionary (word) values(s) on conflict (word) do update set word=excluded.word returning id into wordid;
|
||||
insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
||||
raise info 'processing word %',s;
|
||||
SELECT id INTO wordid FROM asearchdictionary WHERE word = s;
|
||||
raise info 'initial select found that word id is %', wordid;
|
||||
IF wordid = NULL THEN
|
||||
raise info 'since wordid was null inserting %...', wordid;
|
||||
insert into asearchdictionary (word) values(s) on conflict (word) do update set word=excluded.word returning id into wordid;
|
||||
raise info 'After insert new word returned word id %, inserting into searchkey', wordid;
|
||||
insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
||||
ELSE
|
||||
raise info 'since we have initial word id from select inserting into search key the Word id %', wordid;
|
||||
insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$BODY$;
|
||||
|
||||
@@ -752,8 +752,11 @@ namespace AyaNova.Biz
|
||||
// 2020-05-20 18:17:47.9889|INFO|Seeder|Seeding completed successfully
|
||||
|
||||
|
||||
//v3 - remove the automatic delete and try fetch first only then insert
|
||||
|
||||
|
||||
//call stored procedure
|
||||
var SomeValue = await ServiceProviderProvider.DBContext.Database.ExecuteSqlInterpolatedAsync($"call aydosearchindex({KeyWordList},{p.ObjectId},{p.ObjectType})");
|
||||
var SomeValue = await ServiceProviderProvider.DBContext.Database.ExecuteSqlInterpolatedAsync($"call aydosearchindex({KeyWordList},{p.ObjectId},{p.ObjectType},{!newRecord})");
|
||||
return;
|
||||
|
||||
|
||||
|
||||
@@ -173,35 +173,39 @@ namespace AyaNova.Util
|
||||
await ExecQueryAsync("CREATE INDEX asearchkey_wordid_otype_idx ON asearchkey (wordid, objecttype);");
|
||||
|
||||
//Search indexing stored procedure
|
||||
await ExecQueryAsync(@"CREATE OR REPLACE PROCEDURE public.aydosearchindex(
|
||||
wordlist text[],
|
||||
ayobjectid bigint,
|
||||
ayobjecttype integer)
|
||||
LANGUAGE 'plpgsql'
|
||||
|
||||
AS $BODY$DECLARE
|
||||
s text;
|
||||
wordid bigint;
|
||||
BEGIN
|
||||
IF ayobjectid=0 THEN
|
||||
RAISE EXCEPTION 'Bad object id --> %', ayobjectid;
|
||||
END IF;
|
||||
////v1
|
||||
// await ExecQueryAsync(@"CREATE OR REPLACE PROCEDURE public.aydosearchindex(
|
||||
// wordlist text[],
|
||||
// ayobjectid bigint,
|
||||
// ayobjecttype integer)
|
||||
// LANGUAGE 'plpgsql'
|
||||
|
||||
// AS $BODY$DECLARE
|
||||
// s text;
|
||||
// wordid bigint;
|
||||
// BEGIN
|
||||
// IF ayobjectid=0 THEN
|
||||
// RAISE EXCEPTION 'Bad object id --> %', ayobjectid;
|
||||
// END IF;
|
||||
|
||||
IF ayobjecttype=0 THEN
|
||||
RAISE EXCEPTION 'Bad object type --> %', ayobjecttype;
|
||||
END IF;
|
||||
// IF ayobjecttype=0 THEN
|
||||
// RAISE EXCEPTION 'Bad object type --> %', ayobjecttype;
|
||||
// END IF;
|
||||
|
||||
|
||||
delete from asearchkey where objectid=ayobjectid and objecttype=ayobjecttype;
|
||||
// delete from asearchkey where objectid=ayobjectid and objecttype=ayobjecttype;
|
||||
|
||||
FOREACH s IN ARRAY wordlist
|
||||
LOOP
|
||||
insert into asearchdictionary (word) values(s) on conflict (word) do update set word=excluded.word returning id into wordid;
|
||||
insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
||||
END LOOP;
|
||||
END;
|
||||
$BODY$;");
|
||||
// FOREACH s IN ARRAY wordlist
|
||||
// LOOP
|
||||
// insert into asearchdictionary (word) values(s) on conflict (word) do update set word=excluded.word returning id into wordid;
|
||||
// insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
||||
// END LOOP;
|
||||
// END;
|
||||
// $BODY$;");
|
||||
|
||||
|
||||
//v2
|
||||
// await ExecQueryAsync(@"CREATE OR REPLACE PROCEDURE public.aydosearchindex(
|
||||
// wordlist text[],
|
||||
// ayobjectid bigint,
|
||||
@@ -232,6 +236,51 @@ $BODY$;");
|
||||
// END;
|
||||
// $BODY$;");
|
||||
|
||||
//v3
|
||||
await ExecQueryAsync(@"
|
||||
CREATE OR REPLACE PROCEDURE public.aydosearchindex(
|
||||
wordlist text[],
|
||||
ayobjectid bigint,
|
||||
ayobjecttype 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 ayobjecttype=0 THEN
|
||||
RAISE EXCEPTION 'Bad object type --> %', ayobjecttype;
|
||||
END IF;
|
||||
|
||||
|
||||
IF cleanfirst=true THEN
|
||||
delete from asearchkey where objectid=ayobjectid and objecttype=ayobjecttype;
|
||||
END IF;
|
||||
|
||||
FOREACH s IN ARRAY wordlist
|
||||
LOOP
|
||||
--raise info 'processing word %',s;
|
||||
SELECT id INTO wordid FROM asearchdictionary WHERE word = s;
|
||||
--raise info 'initial select found that word id is %', wordid;
|
||||
IF wordid IS NULL THEN
|
||||
--raise info 'since wordid was null inserting %...', wordid;
|
||||
insert into asearchdictionary (word) values(s) on conflict (word) do update set word=excluded.word returning id into wordid;
|
||||
--raise info 'After insert new word returned word id %, inserting into searchkey', wordid;
|
||||
insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
||||
ELSE
|
||||
--raise info 'since we have initial word id from select inserting into search key the Word id %', wordid;
|
||||
insert into asearchkey (wordid,objectid,objecttype) values(wordid,ayobjectid,ayobjecttype);
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$BODY$;
|
||||
");
|
||||
|
||||
//create translation text tables
|
||||
await ExecQueryAsync("CREATE TABLE atranslation (id BIGINT GENERATED ALWAYS AS IDENTITY PRIMARY KEY, name varchar(255) not null, stock bool, cjkindex bool default false)");
|
||||
//LOOKAT: I don't think this is doing anything:
|
||||
|
||||
Reference in New Issue
Block a user