Prechádzať zdrojové kódy

Merge branch 'add-schema-sql' of gogsadmin/prayer-generator into master

gogsadmin 1 rok pred
rodič
commit
c15d5c3b8a

+ 310 - 0
Readme.md

@@ -0,0 +1,310 @@
+```
+Given a postgresql database created as ``pgdb``
+And a postgresql user created as ``pgdb``
+And pljava extension installed
+```
+
+Ensure at least one SWORD module installed
+===
+
+See https://crosswire.org/ and specifically https://crosswire.org/sword/index.jsp.
+
+### On Debian system, the KJV can be installed as follows
+```
+sudo apt-get install sword-text-kjv
+```
+
+### Or install xiphos and download the modules from there
+```
+sudo apt-get install xiphos
+```
+NOTE: You may need to place the modules in the postgresql directory and with correct permissions.
+
+### As privileged user
+```
+# sudo su
+mkdir -p /var/lib/postgresql/.sword/mods.d
+chown postgres:postgres /var/lib/postgresql/.sword
+chmod 0755 /var/lib/postgresql/.sword
+cp ~/.sword/mods.d/* /var/lib/postgresql/.sword/mods.d
+chown -R postgres:postgres /var/lib/postgresql/.sword/mods.d
+chmod -R 0644 /var/lib/postgresql/.sword/mods.d
+```
+
+Ensure java policy allows JSword to function
+===
+
+Need to tweak the default policy shipped with PlJava to allow JSword to search for module directory.
+
+### As privileged user
+```
+mv /etc/postgresql-common/pljava.policy{,.bak}
+cat <<'EOF' > /etc/postgresql-common/pljava.policy
+//
+// Security policy for PL/Java. These grants are intended to add to those
+// contained in the java.policy file of the standard Java installation.
+//
+
+
+//
+// This grant is unconditional. It adds these properties to the standard Java
+// list of system properties that any code may read.
+//
+grant {
+	// "standard" properties that can be read by anyone, by analogy to the
+	// ones so treated in Java itself.
+	//
+	permission java.util.PropertyPermission
+		"org.postgresql.version", "read";
+	permission java.util.PropertyPermission
+		"org.postgresql.pljava.version", "read";
+	permission java.util.PropertyPermission
+		"org.postgresql.pljava.native.version", "read";
+
+	permission java.util.PropertyPermission
+		"org.postgresql.pljava.udt.byteorder.*", "read";
+
+	permission java.util.PropertyPermission
+		"org.postgresql.server.encoding", "read";
+
+	// PostgreSQL allows SELECT current_database() or SHOW cluster_name anyway.
+	//
+	permission java.util.PropertyPermission
+		"org.postgresql.database", "read";
+	permission java.util.PropertyPermission
+		"org.postgresql.cluster", "read";
+
+	// SQL/JRT specifies this property.
+	//
+	permission java.util.PropertyPermission
+		"sqlj.defaultconnection", "read";
+
+	// This property is read in the innards of Java 9 and 10, but they forgot
+	// to add a permission for it. Not needed for Java 11 and later.
+	//
+	permission java.util.PropertyPermission
+		"jdk.lang.ref.disableClearBeforeEnqueue", "read";
+
+	// Something similar happened in Java 14 (not yet fixed in 15).
+	//
+	permission java.util.PropertyPermission
+		"java.util.concurrent.ForkJoinPool.common.maximumSpares", "read";
+};
+
+
+//
+// This grant is specific to the internal implementation of PL/Java itself,
+// which needs these permissions for its own operations.
+//
+// Historically, PL/Java has been able to read any file on the server filesystem
+// when a file: URL is passed to sqlj.install_jar or sqlj.replace_jar. Such a
+// broad grant is not necessary, and can be narrowed below if desired.
+//
+grant codebase "${org.postgresql.pljava.codesource}" {
+	permission java.lang.RuntimePermission
+		"charsetProvider";
+	permission java.lang.RuntimePermission
+		"createClassLoader";
+	permission java.lang.RuntimePermission
+		"getProtectionDomain";
+	permission java.net.NetPermission
+		"specifyStreamHandler";
+	permission java.util.logging.LoggingPermission
+		"control";
+	permission java.security.SecurityPermission
+		"createAccessControlContext";
+
+	// This gives the PL/Java implementation code permission to read
+	// any file, which it only exercises on behalf of sqlj.install_jar()
+	// or sqlj.replace_jar() when called with a file: URL.
+	//
+	// There would be nothing wrong with restricting this permission to
+	// a specific directory, if all jar files to be loaded will be found there,
+	// or replacing it with a URLPermission if they will be hosted on a remote
+	// server, etc.
+	//
+	permission java.io.FilePermission
+		"<<ALL FILES>>", "read";
+};
+
+
+//
+// This grant defines the mapping onto Java of PostgreSQL's "trusted language"
+// category. When PL/Java executes a function whose SQL declaration names
+// a language that was declared WITH the TRUSTED keyword, it will have these
+// permissions, if any (in addition to whatever others might be granted to all
+// code, or to its specific jar, etc.).
+//
+grant principal org.postgresql.pljava.PLPrincipal$Sandboxed * {
+	permission java.lang.RuntimePermission
+		"createClassLoader";
+        permission java.lang.RuntimePermission
+                "getClassLoader";
+        permission java.util.PropertyPermission
+        	"user.home", "read";
+        permission java.util.PropertyPermission
+        	"sword.home", "read";
+        permission java.util.PropertyPermission
+        	"jsword.home", "read";
+	permission java.io.FilePermission
+		"/usr/share/sword", "read";
+	permission java.io.FilePermission
+		"/usr/share/sword/-", "read";
+	permission java.io.FilePermission
+		"/usr/share/sword/mods.d", "read,write";
+	permission java.io.FilePermission
+		"/usr/share/sword/mods.d/-", "read,write";
+	permission java.io.FilePermission
+		"/var/lib/postgresql", "read";
+	permission java.io.FilePermission
+		"/var/lib/postgresql/.jsword", "read";
+	permission java.io.FilePermission
+		"/var/lib/postgresql/.jsword/-", "read";
+	permission java.io.FilePermission
+		"/var/lib/postgresql/.sword", "read";
+	permission java.io.FilePermission
+		"/var/lib/postgresql/.sword/-", "read";
+	permission java.io.FilePermission
+		"/var/lib/postgresql/.sword/mods.d", "read,write";
+	permission java.io.FilePermission
+		"/var/lib/postgresql/.sword/mods.d/-", "read,write";
+	permission java.io.FilePermission
+		"./sword.conf", "read";
+	permission java.io.FilePermission
+		"./mods.d", "read";
+	permission java.io.FilePermission
+		"../library/mods.d", "read";
+	permission java.io.FilePermission
+		"/etc/sword.conf", "read";
+	permission java.io.FilePermission
+		"/usr/local/etc/sword.conf", "read";
+	//permission java.io.FilePermission
+	//	"<<ALL FILES>>", "read";
+};
+
+
+//
+// This grant defines the mapping onto Java of PostgreSQL's "untrusted language"
+// category. When PL/Java executes a function whose SQL declaration names
+// a language that was declared WITHOUT the TRUSTED keyword, it will have these
+// permissions (in addition to whatever others might be granted to all code, or
+// to its specific jar, etc.).
+//
+grant principal org.postgresql.pljava.PLPrincipal$Unsandboxed * {
+	// Java does not circumvent operating system access controls; this grant
+	// will still be limited to what the OS allows a PostgreSQL backend process
+	// to do.
+	permission java.io.FilePermission
+		"<<ALL FILES>>", "read,readlink,write,delete";
+};
+
+
+//
+// This grant applies to a specific PL/Java sandboxed language named java_tzset
+// (if such a language exists) and grants functions created in that language
+// permission to adjust the time zone. There is an example method in the
+// org.postgresql.pljava.example.annotation.PreJSR310 class, which needs to
+// temporarily adjust the time zone for a test. That example also uses
+// sqlj.alias_java_language to create the java_tzset "language" when deployed,
+// and DROP LANGUAGE to remove it when undeployed.
+//
+grant principal org.postgresql.pljava.PLPrincipal$Sandboxed "java_tzset" {
+	permission java.util.PropertyPermission "user.timezone", "write";
+};
+EOF
+```
+
+Create the sqlj schema
+===
+
+Creates a schema for pljava extension to use.
+
+Imports the dependencies for jsword and pljava-jsword.
+
+Authorizes ``pgdb`` user to access the pljava-jsword functions.
+
+### As postgres user
+
+NOTE: java jar file location hard-coded to /home/pi/bin in create-pljava-jsword
+
+```
+# sudo su postgres
+psql -d pgdb -1 < ./init-privileged.sql
+```
+
+Test everything is working
+===
+
+Sanity check the pljava-jsword is working.
+
+Script should exit with zero exit code. Non-zero exit code indicates failure.
+
+NOTE: requires the KJV SWORD module to be installed.
+
+### As unprivileged user
+```
+./test-pljava-jsword.sh
+```
+
+Create the pgdb schema
+===
+
+Creates the tables, functions, triggers, and views that form the core of the app.
+
+### As unprivileged user
+```
+psql -d pgdb -1 < ./init.sql
+```
+
+Add the data
+===
+
+Inserts all the data from the CSV files.
+
+### As unprivileged user
+```
+psql -d pgdb -1 < ./import-data.sql
+```
+
+Check the default module is installed
+===
+
+A default module is required as fallback if the specified translation is unavailable.
+
+The default translation can be determined with a pljava-jsword stored procedure call.
+
+### As unprivileged user
+```
+psql -d pgdb -c 'SELECT * FROM getdefaulttranslation();'
+```
+
+Generate prayer
+===
+
+Generates a table of scriptures.
+
+One scripture for each of the sections of the model prayer outlined in Matthew 6:9-13 and Luke 11:2-4.
+
+Each scripture is randomly selected from the pool of scriptures in each section.
+
+### As unprivileged user
+```
+psql -d pgdb -c 'SELECT * FROM pg_random_view_default_if_null;'
+```
+
+### Example output
+```
+ category  | translation |         reference         |                                                                                                                                                                                                                            txt                                                                                                                                                                                                           
+-----------+-------------+---------------------------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ name      | KJV         | 1 Corinthians 15:23       | But every man in his own order: Christ the firstfruits; afterward they that are Christ’s at his coming.
+ z_kingdom | KJV         | 1 John 4:3                | And every spirit that confesseth not that Jesus Christ is come in the flesh is not of God: and this is that spirit of antichrist, whereof ye have heard that it should come; and even now already is it in the world.
+ a_kingdom | KJV         | Revelation of John 20:1-3 | And I saw an angel come down from heaven, having the key of the bottomless pit and a great chain in his hand. And he laid hold on the dragon, that old serpent, which is the Devil, and Satan, and bound him a thousand years, And cast him into the bottomless pit, and shut him up, and set a seal upon him, that he should deceive the nations no more, till the thousand years should be fulfilled: and after that he must be loosed a little season.
+ will      | MKJV        | John 11:40                | Jesus answered her, Did I not say to you that if you would believe you would see the glory of God?
+ bread     | KJV         | 1 John 5:14               | And this is the confidence that we have in him, that, if we ask any thing according to his will, he heareth us:
+ because   | MKJV        | Matthew 6:33              | But seek first the kingdom of God and His righteousness; and all these things shall be added to you.
+ debtors   | KJV         | 1 Corinthians 6:9-10      | Know ye not that the unrighteous shall not inherit the kingdom of God? Be not deceived: neither fornicators, nor idolaters, nor adulterers, nor effeminate, nor abusers of themselves with mankind, Nor thieves, nor covetous, nor drunkards, nor revilers, nor extortioners, shall inherit the kingdom of God.
+ tempt     | ESV         | Deuteronomy 6:6-8         | And these words that I command you today shall be on your heart. You shall teach them diligently to your children, and shall talk of them when you sit in your house, and when you walk by the way, and when you lie down, and when you rise. You shall bind them as a sign on your hand, and they shall be as frontlets between your eyes.
+ deliver   | MKJV        | Luke 21:36                | Watch therefore, praying in every season that you may be counted worthy to escape all these things which shall occur, and to stand before the Son of man.
+ glory     | ESV         | Psalms 150:6              | Let everything that has breath praise the Lord! Praise the Lord!
+(10 rows)
+```

+ 300 - 45
create-categories.sql

@@ -1,59 +1,314 @@
-CREATE TABLE IF NOT EXISTS public.c_will
-(
-    -- Inherited from table public.reference: translation character varying(12) COLLATE pg_catalog."default" NOT NULL,
-    -- Inherited from table public.reference: reference text COLLATE pg_catalog."default" NOT NULL,
-    CONSTRAINT c_will_pkey PRIMARY KEY (translation, reference)
+--
+-- Name: normalize_on_insert(); Type: FUNCTION; Schema: public; Owner: pgdb
+--
+
+CREATE OR REPLACE FUNCTION public.normalize_on_insert() RETURNS trigger
+    LANGUAGE plpgsql
+    AS $$
+    BEGIN        
+        NEW.reference = normalizeverse(NEW.reference);
+        RETURN NEW;
+    END;
+$$;
+
+
+ALTER FUNCTION public.normalize_on_insert() OWNER TO pgdb;
+
+--
+-- Name: reference; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.reference (
+    translation character varying(12) NOT NULL,
+    reference text NOT NULL
+);
+
+ALTER TABLE public.reference OWNER TO pgdb;
+
+--
+-- Name: reference reference_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.reference
+    DROP CONSTRAINT IF EXISTS reference_pkey;
+ALTER TABLE ONLY public.reference
+    ADD CONSTRAINT reference_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: reference reference_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
+
+DROP TRIGGER IF EXISTS reference_normalize_on_insert_trigger ON public.reference;
+CREATE TRIGGER reference_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.reference FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_a_kingdom; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_a_kingdom (
+)
+INHERITS (public.reference);
+
+ALTER TABLE public.c_a_kingdom OWNER TO pgdb;
+
+--
+-- Name: c_a_kingdom c_a_kingdom_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_a_kingdom
+    DROP CONSTRAINT IF EXISTS c_a_kingdom_pkey;
+ALTER TABLE ONLY public.c_a_kingdom
+    ADD CONSTRAINT c_a_kingdom_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: c_a_kingdom c_a_kingdom_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
+
+DROP TRIGGER IF EXISTS c_a_kingdom_normalize_on_insert_trigger ON public.c_a_kingdom;
+CREATE TRIGGER c_a_kingdom_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_a_kingdom FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_because; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_because (
+)
+INHERITS (public.reference);
+
+ALTER TABLE public.c_because OWNER TO pgdb;
+
+--
+-- Name: c_because c_because_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_because
+    DROP CONSTRAINT IF EXISTS c_because_pkey;
+ALTER TABLE ONLY public.c_because
+    ADD CONSTRAINT c_because_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: c_because c_because_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
+
+DROP TRIGGER IF EXISTS c_because_normalize_on_insert_trigger ON public.c_because;
+CREATE TRIGGER c_because_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_because FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_bread; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_bread (
+)
+INHERITS (public.reference);
+
+ALTER TABLE public.c_bread OWNER TO pgdb;
+
+--
+-- Name: c_bread c_bread_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_bread
+    DROP CONSTRAINT IF EXISTS c_bread_pkey;
+ALTER TABLE ONLY public.c_bread
+    ADD CONSTRAINT c_bread_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: c_bread c_bread_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
+
+DROP TRIGGER IF EXISTS c_bread_normalize_on_insert_trigger ON public.c_bread;
+CREATE TRIGGER c_bread_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_bread FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_debtors; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_debtors (
+)
+INHERITS (public.reference);
+
+ALTER TABLE public.c_debtors OWNER TO pgdb;
+
+--
+-- Name: c_debtors c_debtors_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_debtors
+    DROP CONSTRAINT IF EXISTS c_debtors_pkey;
+ALTER TABLE ONLY public.c_debtors
+    ADD CONSTRAINT c_debtors_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: c_debtors c_debtors_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
+
+DROP TRIGGER IF EXISTS c_debtors_normalize_on_insert_trigger ON public.c_debtors;
+CREATE TRIGGER c_debtors_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_debtors FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_deliver; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_deliver (
+)
+INHERITS (public.reference);
+
+ALTER TABLE public.c_deliver OWNER TO pgdb;
+
+--
+-- Name: c_deliver c_deliver_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_deliver
+    DROP CONSTRAINT IF EXISTS c_deliver_pkey;
+ALTER TABLE ONLY public.c_deliver
+    ADD CONSTRAINT c_deliver_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: c_deliver c_deliver_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
+
+DROP TRIGGER IF EXISTS c_deliver_normalize_on_insert_trigger ON public.c_deliver;
+CREATE TRIGGER c_deliver_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_deliver FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_glory; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_glory (
+)
+INHERITS (public.reference);
+
+ALTER TABLE public.c_glory OWNER TO pgdb;
+
+--
+-- Name: c_glory c_glory_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_glory
+    DROP CONSTRAINT IF EXISTS c_glory_pkey;
+ALTER TABLE ONLY public.c_glory
+    ADD CONSTRAINT c_glory_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: c_glory c_glory_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
+
+DROP TRIGGER IF EXISTS c_glory_normalize_on_insert_trigger ON public.c_glory;
+CREATE TRIGGER c_glory_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_glory FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_name; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_name (
 )
-    INHERITS (public.reference)
-TABLESPACE pg_default;
+INHERITS (public.reference);
+
+ALTER TABLE public.c_name OWNER TO pgdb;
+
+--
+-- Name: c_name c_name_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_name
+    DROP CONSTRAINT IF EXISTS c_name_pkey;
+ALTER TABLE ONLY public.c_name
+    ADD CONSTRAINT c_name_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: c_name c_name_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
+
+DROP TRIGGER IF EXISTS c_name_normalize_on_insert_trigger ON public.c_name;
+CREATE TRIGGER c_name_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_name FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_tempt; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_tempt (
+)
+INHERITS (public.reference);
+
+ALTER TABLE public.c_tempt OWNER TO pgdb;
 
-ALTER TABLE IF EXISTS public.c_will
-    OWNER to pgdb;
+--
+-- Name: c_tempt c_tempt_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
 
-GRANT ALL ON TABLE public.c_will TO pgdb;
+ALTER TABLE ONLY public.c_tempt
+    DROP CONSTRAINT IF EXISTS c_tempt_pkey;
+ALTER TABLE ONLY public.c_tempt
+    ADD CONSTRAINT c_tempt_pkey PRIMARY KEY (translation, reference);
 
-CREATE TRIGGER c_will_normalize_on_insert_trigger
-    BEFORE INSERT OR UPDATE 
-    ON public.c_will
-    FOR EACH ROW
-    EXECUTE FUNCTION public.normalize_on_insert();
+--
+-- Name: c_tempt c_tempt_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
 
-CREATE TABLE IF NOT EXISTS public.c_a_kingdom
-(
-    -- Inherited from table public.reference: translation character varying(12) COLLATE pg_catalog."default" NOT NULL,
-    -- Inherited from table public.reference: reference text COLLATE pg_catalog."default" NOT NULL,
-    CONSTRAINT c_a_kingdom_pkey PRIMARY KEY (translation, reference)
+DROP TRIGGER IF EXISTS c_tempt_normalize_on_insert_trigger ON public.c_tempt;
+CREATE TRIGGER c_tempt_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_tempt FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
+
+
+--
+-- Name: c_will; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_will (
 )
-    INHERITS (public.reference)
-TABLESPACE pg_default;
+INHERITS (public.reference);
+
+ALTER TABLE public.c_will OWNER TO pgdb;
+
+--
+-- Name: c_will c_will_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_will
+    DROP CONSTRAINT IF EXISTS c_will_pkey;
+ALTER TABLE ONLY public.c_will
+    ADD CONSTRAINT c_will_pkey PRIMARY KEY (translation, reference);
 
-ALTER TABLE IF EXISTS public.c_a_kingdom
-    OWNER to pgdb;
+--
+-- Name: c_will c_will_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
 
-GRANT ALL ON TABLE public.c_a_kingdom TO pgdb;
+DROP TRIGGER IF EXISTS c_will_normalize_on_insert_trigger ON public.c_will;
+CREATE TRIGGER c_will_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_will FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
 
-CREATE TRIGGER c_a_kingdom_normalize_on_insert_trigger
-    BEFORE INSERT OR UPDATE 
-    ON public.c_a_kingdom
-    FOR EACH ROW
-    EXECUTE FUNCTION public.normalize_on_insert();
 
-CREATE TABLE IF NOT EXISTS public.c_z_kingdom
-(
-    -- Inherited from table public.reference: translation character varying(12) COLLATE pg_catalog."default" NOT NULL,
-    -- Inherited from table public.reference: reference text COLLATE pg_catalog."default" NOT NULL,
-    CONSTRAINT c_z_kingdom_pkey PRIMARY KEY (translation, reference)
+--
+-- Name: c_z_kingdom; Type: TABLE; Schema: public; Owner: pgdb
+--
+
+CREATE TABLE IF NOT EXISTS public.c_z_kingdom (
 )
-    INHERITS (public.reference)
-TABLESPACE pg_default;
+INHERITS (public.reference);
+
+ALTER TABLE public.c_z_kingdom OWNER TO pgdb;
+
+--
+-- Name: c_z_kingdom c_z_kingdom_pkey; Type: CONSTRAINT; Schema: public; Owner: pgdb
+--
+
+ALTER TABLE ONLY public.c_z_kingdom
+    DROP CONSTRAINT IF EXISTS c_z_kingdom_pkey;
+ALTER TABLE ONLY public.c_z_kingdom
+    ADD CONSTRAINT c_z_kingdom_pkey PRIMARY KEY (translation, reference);
+
+--
+-- Name: c_z_kingdom c_z_kingdom_normalize_on_insert_trigger; Type: TRIGGER; Schema: public; Owner: pgdb
+--
 
-ALTER TABLE IF EXISTS public.c_z_kingdom
-    OWNER to pgdb;
+DROP TRIGGER IF EXISTS c_z_kingdom_normalize_on_insert_trigger ON public.c_z_kingdom;
+CREATE TRIGGER c_z_kingdom_normalize_on_insert_trigger BEFORE INSERT OR UPDATE ON public.c_z_kingdom FOR EACH ROW EXECUTE FUNCTION public.normalize_on_insert();
 
-GRANT ALL ON TABLE public.c_z_kingdom TO pgdb;
 
-CREATE TRIGGER c_z_kingdom_normalize_on_insert_trigger
-    BEFORE INSERT OR UPDATE 
-    ON public.c_z_kingdom
-    FOR EACH ROW
-    EXECUTE FUNCTION public.normalize_on_insert();

+ 55 - 0
create-jsword-functions.sql

@@ -0,0 +1,55 @@
+--
+-- Name: getdefaulttext(character varying); Type: FUNCTION; Schema: public; Owner: postgres
+--
+
+CREATE OR REPLACE FUNCTION public.getdefaulttext(reference character varying) RETURNS character varying
+    LANGUAGE java IMMUTABLE STRICT
+    AS $$java.lang.String=one.shandan.PlJavaJSword.getDefaultText(java.lang.String)$$;
+
+ALTER FUNCTION public.getdefaulttext(reference character varying) OWNER TO pgdb;
+
+
+--
+-- Name: getdefaulttranslation(); Type: FUNCTION; Schema: public; Owner: postgres
+--
+
+CREATE OR REPLACE FUNCTION public.getdefaulttranslation() RETURNS character varying
+    LANGUAGE java IMMUTABLE
+    AS $$java.lang.String=one.shandan.PlJavaJSword.getDefaultTranslation()$$;
+
+ALTER FUNCTION public.getdefaulttranslation() OWNER TO pgdb;
+
+
+--
+-- Name: gettext(character varying, character varying); Type: FUNCTION; Schema: public; Owner: postgres
+--
+
+CREATE OR REPLACE FUNCTION public.gettext(translation character varying, reference character varying) RETURNS character varying
+    LANGUAGE java IMMUTABLE STRICT
+    AS $$java.lang.String=one.shandan.PlJavaJSword.getText(java.lang.String,java.lang.String)$$;
+
+ALTER FUNCTION public.gettext(translation character varying, reference character varying) OWNER TO pgdb;
+
+
+--
+-- Name: isvalidverse(character varying); Type: FUNCTION; Schema: public; Owner: postgres
+--
+
+CREATE OR REPLACE FUNCTION public.isvalidverse(reference character varying) RETURNS boolean
+    LANGUAGE java IMMUTABLE STRICT
+    AS $$java.lang.Boolean=one.shandan.PlJavaJSword.isValidVerse(java.lang.String)$$;
+
+ALTER FUNCTION public.isvalidverse(reference character varying) OWNER TO pgdb;
+
+
+--
+-- Name: normalizeverse(character varying); Type: FUNCTION; Schema: public; Owner: postgres
+--
+
+CREATE OR REPLACE FUNCTION public.normalizeverse(reference character varying) RETURNS character varying
+    LANGUAGE java IMMUTABLE STRICT
+    AS $$java.lang.String=one.shandan.PlJavaJSword.normalizeVerse(java.lang.String)$$;
+
+ALTER FUNCTION public.normalizeverse(reference character varying) OWNER TO pgdb;
+
+

+ 11 - 0
create-pljava-jsword.sql

@@ -0,0 +1,11 @@
+SELECT sqlj.remove_jar ('pljava_jsword', 'false');
+\i drop-jsword-functions.sql
+SELECT sqlj.remove_jar ('jsword', 'true');
+SELECT sqlj.remove_jar ('jdom2', 'true');
+SELECT sqlj.remove_jar ('slf4j_logger', 'true');
+SELECT * FROM sqlj.install_jar('file:///home/pi/bin/slf4j-api-1.7.36.jar', 'slf4j_logger', 'false');
+SELECT * FROM sqlj.install_jar('file:///home/pi/bin/jdom2-2.0.6.1.jar', 'jdom2', 'false');
+SELECT * FROM sqlj.install_jar('file:///home/pi/bin/jsword-2.1-SNAPSHOT.jar', 'jsword', 'false');
+SELECT sqlj.set_classpath('public', 'slf4j_logger:jsword:jdom2');
+SELECT * FROM sqlj.install_jar('file:///home/pi/bin/pljava-jsword-0.1.2-SNAPSHOT.jar', 'pljava_jsword', 'true');
+SELECT sqlj.set_classpath('public', 'slf4j_logger:jsword:jdom2:pljava_jsword');

+ 27 - 0
create-pljava-schema.sql

@@ -0,0 +1,27 @@
+--
+-- Name: sqlj; Type: SCHEMA; Schema: -; Owner: pgdb
+--
+
+CREATE SCHEMA IF NOT EXISTS sqlj;
+
+
+ALTER SCHEMA sqlj OWNER TO pgdb;
+
+--
+-- Name: pljava; Type: EXTENSION; Schema: -; Owner: -
+--
+
+CREATE EXTENSION IF NOT EXISTS pljava WITH SCHEMA sqlj;
+
+
+--
+-- Name: EXTENSION pljava; Type: COMMENT; Schema: -; Owner: 
+--
+
+COMMENT ON EXTENSION pljava IS 'PL/Java procedural language (https://tada.github.io/pljava/)';
+
+GRANT USAGE ON LANGUAGE java TO pgdb;
+
+ALTER DATABASE pgdb SET pljava.libjvm_location TO '/usr/lib/jvm/java-11-openjdk-arm64/lib/server/libjvm.so';
+
+

+ 169 - 0
create-views.sql

@@ -0,0 +1,169 @@
+--
+-- Name: getrandomsample(text, bigint); Type: FUNCTION; Schema: public; Owner: pgdb
+--
+
+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;
+
+--
+-- Name: pg_random_view; Type: VIEW; Schema: public; Owner: pgdb
+--
+
+-- DROP VIEW IF EXISTS public.pg_random_view CASCADE;
+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;
+
+
+--
+-- Name: pg_random_view_default_if_null; Type: VIEW; Schema: public; Owner: pgdb
+--
+
+-- DROP VIEW IF EXISTS public.pg_random_view_default_if_null CASCADE;
+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;
+
+
+--
+-- Name: pg_view; Type: VIEW; Schema: public; Owner: 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;
+
+
+--
+-- Name: pg_view_default_if_null; Type: VIEW; Schema: public; Owner: 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;
+
+

+ 7 - 0
drop-jsword-functions.sql

@@ -0,0 +1,7 @@
+DROP FUNCTION IF EXISTS public.getdefaulttext(reference character varying) CASCADE;
+DROP FUNCTION IF EXISTS public.getdefaulttranslation() CASCADE;
+DROP FUNCTION IF EXISTS public.gettext(translation character varying, reference character varying) CASCADE;
+DROP FUNCTION IF EXISTS public.isvalidverse(reference character varying) CASCADE;
+DROP FUNCTION IF EXISTS public.normalizeverse(reference character varying) CASCADE;
+
+

+ 10 - 0
import-data.sql

@@ -0,0 +1,10 @@
+\copy c_a_kingdom(translation,reference) FROM './a_kingdom.csv' DELIMITER ',' CSV HEADER;
+\copy c_z_kingdom(reference,translation) FROM './z_kingdom.csv' DELIMITER ',' CSV HEADER;
+\copy c_bread(translation,reference) FROM './bread.csv' DELIMITER ',' CSV HEADER;
+\copy c_deliver(reference,translation) FROM './deliver.csv' DELIMITER '	' CSV HEADER;
+\copy c_name(translation,reference) FROM './name.csv' DELIMITER '	' CSV HEADER;
+\copy c_will(reference,translation) FROM './will.csv' DELIMITER '	' CSV HEADER;
+\copy c_because(reference,translation) FROM './because.csv' DELIMITER '	' CSV HEADER;
+\copy c_debtors(translation,reference) FROM './debtors.csv' DELIMITER ',' CSV HEADER;
+\copy c_glory(reference,translation) FROM './glory.csv' DELIMITER '	' CSV HEADER;
+\copy c_tempt(translation,reference) FROM './tempt.csv' DELIMITER ',' CSV HEADER;

+ 3 - 0
init-privileged.sql

@@ -0,0 +1,3 @@
+\i create-pljava-schema.sql
+\i create-pljava-jsword.sql
+\i create-jsword-functions.sql

+ 2 - 0
init.sql

@@ -0,0 +1,2 @@
+\i create-categories.sql
+\i create-views.sql

+ 6 - 0
test-pljava-jsword.sh

@@ -0,0 +1,6 @@
+#!/bin/bash
+output=$(psql -d pgdb -1 -t -A <<EOF
+SELECT * FROM getText('KJV', 'Gen 1:1');
+EOF
+)
+[ "${output}" == "In the beginning God created the heaven and the earth." ]