|
@@ -0,0 +1,167 @@
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+CREATE OR REPLACE FUNCTION public.getrandomsample(p_table text, p_count bigint) RETURNS TABLE(ordinal integer, category text, translation character varying, reference text)
|
|
|
+ LANGUAGE plpgsql
|
|
|
+ AS $$
|
|
|
+DECLARE
|
|
|
+ v_estimate bigint;
|
|
|
+ v_percentage double precision;
|
|
|
+ v_table_id int;
|
|
|
+BEGIN
|
|
|
+SELECT num INTO v_table_id FROM (VALUES
|
|
|
+ ('c_name', 10), ('c_z_kingdom', 15), ('c_a_kingdom', 20),
|
|
|
+ ('c_will', 25), ('c_bread', 30), ('c_because', 35),
|
|
|
+ ('c_forgive',40), ('c_debtors', 45), ('c_tempt', 50),
|
|
|
+ ('c_deliver', 60), ('c_glory', 70)
|
|
|
+
|
|
|
+) AS q(name, num)
|
|
|
+WHERE name = p_table;
|
|
|
+SELECT pg_class.reltuples INTO v_estimate FROM pg_class WHERE pg_class.relname = p_table;
|
|
|
+SELECT 1000::double precision / v_estimate INTO v_percentage;
|
|
|
+RETURN QUERY EXECUTE 'SELECT '|| v_table_id ||' AS ordinal,
|
|
|
+ '''|| REPLACE(p_table, 'c_', '') ||''' AS category, translation, reference
|
|
|
+FROM ' || p_table || ' TABLESAMPLE bernoulli ('|| v_percentage ||')
|
|
|
+LIMIT ' || p_count;
|
|
|
+END
|
|
|
+$$;
|
|
|
+
|
|
|
+
|
|
|
+ALTER FUNCTION public.getrandomsample(p_table text, p_count bigint) OWNER TO pgdb;
|
|
|
+
|
|
|
+-
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+CREATE OR REPLACE VIEW public.pg_random_view AS
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_name'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_bread'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_debtors'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_because'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_tempt'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_deliver'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_glory'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_will'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_a_kingdom'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+UNION
|
|
|
+ SELECT getrandomsample.ordinal,
|
|
|
+ getrandomsample.category,
|
|
|
+ getrandomsample.translation,
|
|
|
+ getrandomsample.reference,
|
|
|
+ public.gettext(getrandomsample.translation, (getrandomsample.reference)::character varying) AS txt
|
|
|
+ FROM public.getrandomsample('c_z_kingdom'::text, (1)::bigint) getrandomsample(ordinal, category, translation, reference)
|
|
|
+ ORDER BY 1;
|
|
|
+
|
|
|
+ALTER TABLE public.pg_random_view OWNER TO pgdb;
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+CREATE OR REPLACE VIEW public.pg_random_view_default_if_null AS
|
|
|
+ SELECT subq.category,
|
|
|
+ CASE
|
|
|
+ WHEN (subq.txt IS NULL) THEN public.getdefaulttranslation()
|
|
|
+ ELSE subq.translation
|
|
|
+ END AS translation,
|
|
|
+ subq.reference,
|
|
|
+ CASE
|
|
|
+ WHEN (subq.txt IS NULL) THEN public.getdefaulttext((subq.reference)::character varying)
|
|
|
+ ELSE subq.txt
|
|
|
+ END AS txt
|
|
|
+ FROM public.pg_random_view subq;
|
|
|
+
|
|
|
+ALTER TABLE public.pg_random_view_default_if_null OWNER TO pgdb;
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+CREATE OR REPLACE VIEW public.pg_view AS
|
|
|
+ SELECT reference.translation,
|
|
|
+ reference.reference,
|
|
|
+ public.gettext(reference.translation, (reference.reference)::character varying) AS txt
|
|
|
+ FROM public.reference;
|
|
|
+
|
|
|
+ALTER TABLE public.pg_view OWNER TO pgdb;
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+CREATE OR REPLACE VIEW public.pg_view_default_if_null AS
|
|
|
+ SELECT
|
|
|
+ CASE
|
|
|
+ WHEN (subq.txt IS NULL) THEN public.getdefaulttranslation()
|
|
|
+ ELSE subq.translation
|
|
|
+ END AS translation,
|
|
|
+ subq.reference,
|
|
|
+ CASE
|
|
|
+ WHEN (subq.txt IS NULL) THEN public.getdefaulttext((subq.reference)::character varying)
|
|
|
+ ELSE subq.txt
|
|
|
+ END AS txt
|
|
|
+ FROM ( SELECT reference.translation,
|
|
|
+ reference.reference,
|
|
|
+ public.gettext(reference.translation, (reference.reference)::character varying) AS txt
|
|
|
+ FROM public.reference) subq;
|
|
|
+
|
|
|
+ALTER TABLE public.pg_view_default_if_null OWNER TO pgdb;
|
|
|
+
|
|
|
+
|