Skip to content

Commit c9ee35b

Browse files
committed
Add verse_dictionary SQL function for lexical lookup
Enable clients to query dictionary entries (topic, word, meaning, parse, and forms) for each word in a verse by tokenizing Greek text with greek_to_betacode and parsing XML definitions. Grant web_anon SELECT and EXECUTE rights on dictionary tables and the new function.
1 parent 67a8e22 commit c9ee35b

File tree

2 files changed

+73
-0
lines changed

2 files changed

+73
-0
lines changed

sql/12_functions.sql

Lines changed: 71 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -631,3 +631,74 @@ BEGIN
631631
RETURN result;
632632
END;
633633
$BODY$;
634+
635+
-- retrieves dictionary entries for words in a given verse
636+
DROP FUNCTION IF EXISTS public.verse_dictionary(text);
637+
CREATE OR REPLACE FUNCTION public.verse_dictionary(p_verse_id text)
638+
RETURNS TABLE(topic text, word text, meaning text, parse text, forms text[])
639+
LANGUAGE 'sql'
640+
COST 100
641+
STABLE PARALLEL UNSAFE
642+
ROWS 1000
643+
AS $BODY$
644+
WITH words AS (
645+
SELECT DISTINCT
646+
unnest(
647+
string_to_array(
648+
greek_to_betacode(public.raw_text(v.text)),
649+
' '
650+
)
651+
) AS word
652+
FROM public._all_verses v
653+
WHERE v.id = p_verse_id
654+
),
655+
dict AS (
656+
SELECT
657+
d.topic,
658+
xmlparse(content '<root>' || d.definition || '</root>') AS x
659+
FROM public._all_dictionary_entries d
660+
JOIN words w
661+
ON w.word = d.topic
662+
),
663+
extracted AS (
664+
SELECT
665+
d.topic,
666+
667+
-- dt/a text from first <dl>
668+
trim((xpath('/root/dl[1]/dt/a/text()', x))[1]::text) AS word,
669+
670+
-- meaning
671+
trim(
672+
array_to_string(
673+
xpath('//span[@class="meaning"]//text()', x),
674+
' '
675+
)
676+
) AS meaning,
677+
678+
-- main parse
679+
trim(
680+
(xpath('/root/dl[1]//span[@class="parse"][1]/text()', x))[1]::text
681+
) AS parse,
682+
683+
-- raw Greek forms (array of text)
684+
xpath(
685+
'/root/dl[1]//li/a[starts-with(@href, ''S:'')]/text()',
686+
x
687+
)::text[] AS forms_raw
688+
689+
FROM dict d
690+
)
691+
SELECT
692+
topic,
693+
word,
694+
meaning,
695+
parse,
696+
COALESCE(
697+
(
698+
SELECT array_agg(greek_to_betacode(f))
699+
FROM unnest(forms_raw) f
700+
),
701+
'{}'
702+
) AS forms
703+
FROM extracted;
704+
$BODY$;

sql/13_postgrest.sql

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -13,6 +13,7 @@ GRANT SELECT ON public._all_sources TO web_anon;
1313
GRANT SELECT ON public._all_books TO web_anon;
1414
GRANT SELECT ON public._all_verses TO web_anon;
1515
GRANT SELECT ON public._all_commentaries TO web_anon;
16+
GRANT SELECT ON public._all_dictionary_entries TO web_anon;
1617
GRANT SELECT ON public._cross_references TO web_anon;
1718
GRANT SELECT ON public._rendered_stories TO web_anon;
1819
GRANT EXECUTE ON FUNCTION public.fetch_commentaries(text) TO web_anon;
@@ -22,3 +23,4 @@ GRANT EXECUTE ON FUNCTION public.fetch_verse_with_metadata(text) TO web_anon;
2223
GRANT EXECUTE ON FUNCTION public.fetch_verses_by_address(text, text, boolean) TO web_anon;
2324
GRANT EXECUTE ON FUNCTION public.parse_address(text) TO web_anon;
2425
GRANT EXECUTE ON FUNCTION public.search_verses(text) TO web_anon;
26+
GRANT EXECUTE ON FUNCTION public.verse_dictionary(text) TO web_anon;

0 commit comments

Comments
 (0)