1
0
Fork 0
mirror of https://github.com/perlbot/perlbuut synced 2025-06-07 10:45:40 -04:00

Test query made

This commit is contained in:
Ryan Voots 2020-09-06 11:39:53 -07:00
parent 5ec0f1d231
commit 1adff774d8
3 changed files with 53 additions and 0 deletions

1
.gitignore vendored
View file

@ -12,3 +12,4 @@ modules.lst
jail.ext4
var/asn.db
langs/
*.swp

27
factoidtest.sql Normal file
View file

@ -0,0 +1,27 @@
WITH RECURSIVE factoid_lookup_order (depth, namespace, server, alias_namespace, alias_server, parent_namespace, parent_server, recursive) AS (
SELECT 0 AS depth, namespace, server, alias_namespace, alias_server, parent_namespace, parent_server, recursive
FROM factoid_config
WHERE namespace = '#perlbot' AND server = 'freenode.net' -- PLACEHOLDER TARGET
UNION ALL
SELECT p.depth+1 AS depth, m.namespace, m.server, m.alias_namespace, m.alias_server, m.parent_namespace, m.parent_server, m.recursive
FROM factoid_config m
INNER JOIN factoid_lookup_order p
ON m.namespace = p.parent_namespace AND m.server = p.parent_server AND p.recursive
),
get_latest_factoid (depth, factoid_id, subject, copula, predicate, author, modified_time, compose_macro, protected, original_subject, deleted, server, namespace) AS (
SELECT DISTINCT ON(lo.depth) lo.depth, factoid_id, subject, copula, predicate, author, modified_time, compose_macro, protected, original_subject, f.deleted, f.server, f.namespace
FROM factoid f
INNER JOIN factoid_lookup_order lo
ON COALESCE(f.server, '') = COALESCE(lo.alias_server, lo.server)
AND COALESCE(f.namespace, '') = COALESCE(lo.alias_namespace, lo.namespace)
WHERE original_subject = 'hi' -- PLACEHOLDER TARGET
ORDER BY depth ASC, factoid_id DESC
)
SELECT * FROM get_latest_factoid WHERE NOT deleted ORDER BY depth ASC, factoid_id DESC LIMIT 1;
-- SELECT factoid_id, subject, copula, predicate, author, modified_time, compose_macro, protected, original_subject
-- FROM factoid
-- WHERE original_subject = ?
-- ORDER BY factoid_id DESC

View file

@ -6,6 +6,7 @@ ALTER TABLE public.factoid ALTER COLUMN original_subject TYPE text;
ALTER TABLE public.factoid ALTER COLUMN subject TYPE text;
ALTER TABLE public.factoid ALTER COLUMN copula TYPE text;
ALTER TABLE public.factoid ALTER COLUMN author TYPE text;
ALTER TABLE public.factoid ADD COLUMN deleted boolean DEFAULT false;
ALTER TABLE public.factoid ADD COLUMN namespace text;
ALTER TABLE public.factoid ADD COLUMN server text;
@ -14,5 +15,29 @@ UPDATE public.factoid SET namespace=NULL WHERE namespace = '';
UPDATE public.factoid SET server=NULL WHERE server = '';
UPDATE public.factoid SET original_subject=split_part(original_subject, E'\034', 4), subject=split_part(subject, E'\034', 4) WHERE namespace IS NOT NULL and server IS NOT NULL;
DROP TABLE IF EXISTS public.factoid_namespace_config;
DROP TABLE IF EXISTS public.factoid_config;
CREATE TABLE public.factoid_config (
server text NOT NULL,
namespace text NOT NULL,
-- this lets me set the explicit name used in the rest of the database
alias_server text,
alias_namespace text,
-- this lets me set the explicit name for the parent namespace, this only refers to the server+namespace values, not the alias_* they set
parent_server text NOT NULL DEFAULT '',
parent_namespace text NOT NULL DEFAULT '',
-- Should we do the recursive lookup into the parent_*, this is needed because NULL is a valid value for parent_*
recursive boolean DEFAULT false,
command_prefix text,
CONSTRAINT unique_config UNIQUE (server, namespace)
);
INSERT INTO public.factoid_config (server, namespace, alias_server, alias_namespace, recursive, command_prefix)
VALUES ('freenode.net', '#perlbot', 'freenode.net', '#perlbot', true, NULL),
('', '', '', '', false, NULL), -- the parent of all
('freenode.net', '#regex', 'freenode.net', '#regex', false, '!'),
('freenode.net', '#regexen', 'freenode.net', '#regex', false, '!');
COMMIT;