From 3528ddbb7de36c64d94e23d2e39f172f81bcb988 Mon Sep 17 00:00:00 2001
From: Lars Johansson <lars.johansson@ess.eu>
Date: Wed, 23 Feb 2022 20:46:18 +0100
Subject: [PATCH] Added database scripts. old and new, for verification
 purposes

---
 docs/verification/V1__Initial.sql             | 378 ++++++++
 .../verification/V2__Commit_Msg_to_Device.sql |   1 +
 .../verification/V3__Notification_CC_List.sql |   6 +
 docs/verification/script_notes.txt            | 815 ++++++++++++++++++
 4 files changed, 1200 insertions(+)
 create mode 100644 docs/verification/V1__Initial.sql
 create mode 100644 docs/verification/V2__Commit_Msg_to_Device.sql
 create mode 100644 docs/verification/V3__Notification_CC_List.sql
 create mode 100644 docs/verification/script_notes.txt

diff --git a/docs/verification/V1__Initial.sql b/docs/verification/V1__Initial.sql
new file mode 100644
index 00000000..cb960e1f
--- /dev/null
+++ b/docs/verification/V1__Initial.sql
@@ -0,0 +1,378 @@
+SET statement_timeout = 0;
+SET client_encoding = 'UTF8';
+SET standard_conforming_strings = on;
+SET check_function_bodies = false;
+SET client_min_messages = warning;
+SET search_path = public, pg_catalog;
+SET default_tablespace = '';
+SET default_with_oids = false;
+
+--
+-- Name: appinfo; Type: TABLE; Schema: public; Owner: -; Tablespace:
+--
+
+CREATE TABLE appinfo (
+    id bigint NOT NULL,
+    version integer,
+    schemaversion integer NOT NULL
+);
+
+
+--
+-- Name: appinfo_id_seq; Type: SEQUENCE; Schema: public; Owner: -
+--
+
+CREATE SEQUENCE appinfo_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+
+--
+-- Name: appinfo_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
+--
+
+ALTER SEQUENCE appinfo_id_seq OWNED BY appinfo.id;
+
+
+--
+-- Name: device; Type: TABLE; Schema: public; Owner: -; Tablespace:
+--
+
+CREATE TABLE device (
+    id bigint NOT NULL,
+    version integer,
+    uuid character varying(255)
+);
+
+
+--
+-- Name: device_id_seq; Type: SEQUENCE; Schema: public; Owner: -
+--
+
+CREATE SEQUENCE device_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+
+--
+-- Name: device_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
+--
+
+ALTER SEQUENCE device_id_seq OWNED BY device.id;
+
+
+--
+-- Name: devicerevision; Type: TABLE; Schema: public; Owner: -; Tablespace:
+--
+
+CREATE TABLE devicerevision (
+    id bigint NOT NULL,
+    version integer,
+    additionalinfo character varying(255),
+    conventionname character varying(255),
+    conventionnameeqclass character varying(255),
+    deleted boolean NOT NULL,
+    instanceindex character varying(255),
+    requestdate timestamp without time zone,
+    device_id bigint,
+    devicetype_id bigint,
+    requestedby_id bigint,
+    section_id bigint
+);
+
+
+--
+-- Name: devicerevision_id_seq; Type: SEQUENCE; Schema: public; Owner: -
+--
+
+CREATE SEQUENCE devicerevision_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+
+--
+-- Name: devicerevision_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
+--
+
+ALTER SEQUENCE devicerevision_id_seq OWNED BY devicerevision.id;
+
+
+--
+-- Name: namepart; Type: TABLE; Schema: public; Owner: -; Tablespace:
+--
+
+CREATE TABLE namepart (
+    id bigint NOT NULL,
+    version integer,
+    nameparttype character varying(255),
+    uuid character varying(255)
+);
+
+
+--
+-- Name: namepart_id_seq; Type: SEQUENCE; Schema: public; Owner: -
+--
+
+CREATE SEQUENCE namepart_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+
+--
+-- Name: namepart_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
+--
+
+ALTER SEQUENCE namepart_id_seq OWNED BY namepart.id;
+
+
+--
+-- Name: namepartrevision; Type: TABLE; Schema: public; Owner: -; Tablespace:
+--
+
+CREATE TABLE namepartrevision (
+    id bigint NOT NULL,
+    version integer,
+    deleted boolean NOT NULL,
+    description character varying(255),
+    mnemonic character varying(255),
+    mnemoniceqclass character varying(255),
+    name character varying(255),
+    processdate timestamp without time zone,
+    processorcomment character varying(255),
+    requestdate timestamp without time zone,
+    requestercomment character varying(255),
+    status character varying(255),
+    namepart_id bigint,
+    parent_id bigint,
+    processedby_id bigint,
+    requestedby_id bigint
+);
+
+
+--
+-- Name: namepartrevision_id_seq; Type: SEQUENCE; Schema: public; Owner: -
+--
+
+CREATE SEQUENCE namepartrevision_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+
+--
+-- Name: namepartrevision_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
+--
+
+ALTER SEQUENCE namepartrevision_id_seq OWNED BY namepartrevision.id;
+
+
+--
+-- Name: useraccount; Type: TABLE; Schema: public; Owner: -; Tablespace:
+--
+
+CREATE TABLE useraccount (
+    id bigint NOT NULL,
+    version integer,
+    role character varying(255),
+    username character varying(255)
+);
+
+
+--
+-- Name: useraccount_id_seq; Type: SEQUENCE; Schema: public; Owner: -
+--
+
+CREATE SEQUENCE useraccount_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+
+--
+-- Name: useraccount_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
+--
+
+ALTER SEQUENCE useraccount_id_seq OWNED BY useraccount.id;
+
+
+--
+-- Name: id; Type: DEFAULT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY appinfo ALTER COLUMN id SET DEFAULT nextval('appinfo_id_seq'::regclass);
+
+
+--
+-- Name: id; Type: DEFAULT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY device ALTER COLUMN id SET DEFAULT nextval('device_id_seq'::regclass);
+
+
+--
+-- Name: id; Type: DEFAULT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY devicerevision ALTER COLUMN id SET DEFAULT nextval('devicerevision_id_seq'::regclass);
+
+
+--
+-- Name: id; Type: DEFAULT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY namepart ALTER COLUMN id SET DEFAULT nextval('namepart_id_seq'::regclass);
+
+
+--
+-- Name: id; Type: DEFAULT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY namepartrevision ALTER COLUMN id SET DEFAULT nextval('namepartrevision_id_seq'::regclass);
+
+
+--
+-- Name: id; Type: DEFAULT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY useraccount ALTER COLUMN id SET DEFAULT nextval('useraccount_id_seq'::regclass);
+
+
+--
+-- Name: appinfo_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace:
+--
+
+ALTER TABLE ONLY appinfo
+    ADD CONSTRAINT appinfo_pkey PRIMARY KEY (id);
+
+
+--
+-- Name: device_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace:
+--
+
+ALTER TABLE ONLY device
+    ADD CONSTRAINT device_pkey PRIMARY KEY (id);
+
+
+--
+-- Name: devicerevision_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace:
+--
+
+ALTER TABLE ONLY devicerevision
+    ADD CONSTRAINT devicerevision_pkey PRIMARY KEY (id);
+
+
+--
+-- Name: namepart_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace:
+--
+
+ALTER TABLE ONLY namepart
+    ADD CONSTRAINT namepart_pkey PRIMARY KEY (id);
+
+
+--
+-- Name: namepartrevision_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace:
+--
+
+ALTER TABLE ONLY namepartrevision
+    ADD CONSTRAINT namepartrevision_pkey PRIMARY KEY (id);
+
+
+--
+-- Name: useraccount_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace:
+--
+
+ALTER TABLE ONLY useraccount
+    ADD CONSTRAINT useraccount_pkey PRIMARY KEY (id);
+
+
+--
+-- Name: fk_3f26vetemhujfdm9q74ecr2u5; Type: FK CONSTRAINT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY namepartrevision
+    ADD CONSTRAINT fk_3f26vetemhujfdm9q74ecr2u5 FOREIGN KEY (namepart_id) REFERENCES namepart(id);
+
+
+--
+-- Name: fk_4ucnoos7kd8s1gaqbpwm1xptq; Type: FK CONSTRAINT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY devicerevision
+    ADD CONSTRAINT fk_4ucnoos7kd8s1gaqbpwm1xptq FOREIGN KEY (requestedby_id) REFERENCES useraccount(id);
+
+
+--
+-- Name: fk_9vomfk9x1jow27ifx6xc62c5x; Type: FK CONSTRAINT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY namepartrevision
+    ADD CONSTRAINT fk_9vomfk9x1jow27ifx6xc62c5x FOREIGN KEY (processedby_id) REFERENCES useraccount(id);
+
+
+--
+-- Name: fk_9xs5oy86lf0j8ukpjokjipeke; Type: FK CONSTRAINT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY namepartrevision
+    ADD CONSTRAINT fk_9xs5oy86lf0j8ukpjokjipeke FOREIGN KEY (requestedby_id) REFERENCES useraccount(id);
+
+
+--
+-- Name: fk_d3ocbsb4tl4ttnusn98khq148; Type: FK CONSTRAINT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY devicerevision
+    ADD CONSTRAINT fk_d3ocbsb4tl4ttnusn98khq148 FOREIGN KEY (devicetype_id) REFERENCES namepart(id);
+
+
+--
+-- Name: fk_l7kklb4mxixjs27nsso6shone; Type: FK CONSTRAINT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY devicerevision
+    ADD CONSTRAINT fk_l7kklb4mxixjs27nsso6shone FOREIGN KEY (section_id) REFERENCES namepart(id);
+
+
+--
+-- Name: fk_l9r1givkfaiol5or2lnr324xp; Type: FK CONSTRAINT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY devicerevision
+    ADD CONSTRAINT fk_l9r1givkfaiol5or2lnr324xp FOREIGN KEY (device_id) REFERENCES device(id);
+
+
+--
+-- Name: fk_lufxqy46l9eiq55d445rbukag; Type: FK CONSTRAINT; Schema: public; Owner: -
+--
+
+ALTER TABLE ONLY namepartrevision
+    ADD CONSTRAINT fk_lufxqy46l9eiq55d445rbukag FOREIGN KEY (parent_id) REFERENCES namepart(id);
+
+
+--
+-- Name: public; Type: ACL; Schema: -; Owner: -
+--
+
+REVOKE ALL ON SCHEMA public FROM PUBLIC;
+REVOKE ALL ON SCHEMA public FROM postgres;
+GRANT ALL ON SCHEMA public TO postgres;
+GRANT ALL ON SCHEMA public TO PUBLIC;
+
+
+INSERT INTO appinfo (version, schemaversion) VALUES (1,1);
diff --git a/docs/verification/V2__Commit_Msg_to_Device.sql b/docs/verification/V2__Commit_Msg_to_Device.sql
new file mode 100644
index 00000000..acbe8e16
--- /dev/null
+++ b/docs/verification/V2__Commit_Msg_to_Device.sql
@@ -0,0 +1 @@
+ALTER TABLE devicerevision ADD processorcomment varchar(255) NULL;
diff --git a/docs/verification/V3__Notification_CC_List.sql b/docs/verification/V3__Notification_CC_List.sql
new file mode 100644
index 00000000..f694a061
--- /dev/null
+++ b/docs/verification/V3__Notification_CC_List.sql
@@ -0,0 +1,6 @@
+CREATE TABLE user_notification (
+	id bigserial NOT NULL,
+	notification_type varchar(32) NOT NULL,
+	user_login_name varchar(32) NOT NULL,
+	CONSTRAINT user_notification_pk PRIMARY KEY (id)
+);
\ No newline at end of file
diff --git a/docs/verification/script_notes.txt b/docs/verification/script_notes.txt
new file mode 100644
index 00000000..3110a96b
--- /dev/null
+++ b/docs/verification/script_notes.txt
@@ -0,0 +1,815 @@
+-- --------------------------------------------------------------------------------
+-- About
+--     migration script
+--     postgresql 9.6.7
+-- Content
+--     structures
+--     name
+--     data structures level 1
+--     data structures level 2
+--     data structures level 3
+--     data name level 1
+--     data name level 2
+--     data name level 3
+--     index
+--     latest
+--     foreign key
+--     index
+--     sequence
+--     primary key
+--     function
+-- Note
+--     order of items is important
+-- --------------------------------------------------------------------------------
+
+-- --------------------------------------------------------------------------------
+-- structures
+-- --------------------------------------------------------------------------------
+CREATE TABLE systemgroup (
+    id bigint NOT NULL,
+    version integer,
+    uuid character varying(255),
+    name character varying(255),
+    mnemonic character varying(255),
+    mnemonic_equivalence character varying(255),
+    description character varying(255),
+    status character varying(255),
+    latest boolean NOT NULL,
+    deleted boolean NOT NULL,
+    requested timestamp without time zone,
+    requested_by character varying(255),
+    requested_comment character varying(255),
+    processed timestamp without time zone,
+    processed_by character varying(255),
+    processed_comment character varying(255)
+);
+CREATE TABLE system (
+    id bigint NOT NULL,
+    version integer,
+    uuid character varying(255),
+    parent_uuid character varying(255),
+    name character varying(255),
+    mnemonic character varying(255),
+    mnemonic_equivalence character varying(255),
+    description character varying(255),
+    status character varying(255),
+    latest boolean NOT NULL,
+    deleted boolean NOT NULL,
+    requested timestamp without time zone,
+    requested_by character varying(255),
+    requested_comment character varying(255),
+    processed timestamp without time zone,
+    processed_by character varying(255),
+    processed_comment character varying(255)
+);
+
+CREATE TABLE subsystem (
+    id bigint NOT NULL,
+    version integer,
+    uuid character varying(255),
+    parent_uuid character varying(255),
+    name character varying(255),
+    mnemonic character varying(255),
+    mnemonic_equivalence character varying(255),
+    description character varying(255),
+    status character varying(255),
+    latest boolean NOT NULL,
+    deleted boolean NOT NULL,
+    requested timestamp without time zone,
+    requested_by character varying(255),
+    requested_comment character varying(255),
+    processed timestamp without time zone,
+    processed_by character varying(255),
+    processed_comment character varying(255)
+);
+-- --------------------------------------------------------------------------------
+CREATE TABLE discipline (
+    id bigint NOT NULL,
+    version integer,
+    uuid character varying(255),
+    name character varying(255),
+    mnemonic character varying(255),
+    mnemonic_equivalence character varying(255),
+    description character varying(255),
+    status character varying(255),
+    latest boolean NOT NULL,
+    deleted boolean NOT NULL,
+    requested timestamp without time zone,
+    requested_by character varying(255),
+    requested_comment character varying(255),
+    processed timestamp without time zone,
+    processed_by character varying(255),
+    processed_comment character varying(255)
+);
+
+CREATE TABLE devicegroup (
+    id bigint NOT NULL,
+    version integer,
+    uuid character varying(255),
+    parent_uuid character varying(255),
+    name character varying(255),
+    mnemonic character varying(255),
+    mnemonic_equivalence character varying(255),
+    description character varying(255),
+    status character varying(255),
+    latest boolean NOT NULL,
+    deleted boolean NOT NULL,
+    requested timestamp without time zone,
+    requested_by character varying(255),
+    requested_comment character varying(255),
+    processed timestamp without time zone,
+    processed_by character varying(255),
+    processed_comment character varying(255)
+);
+
+CREATE TABLE devicetype (
+    id bigint NOT NULL,
+    version integer,
+    uuid character varying(255),
+    parent_uuid character varying(255),
+    name character varying(255),
+    mnemonic character varying(255),
+    mnemonic_equivalence character varying(255),
+    description character varying(255),
+    status character varying(255),
+    latest boolean NOT NULL,
+    deleted boolean NOT NULL,
+    requested timestamp without time zone,
+    requested_by character varying(255),
+    requested_comment character varying(255),
+    processed timestamp without time zone,
+    processed_by character varying(255),
+    processed_comment character varying(255)
+);
+
+-- --------------------------------------------------------------------------------
+-- name
+-- --------------------------------------------------------------------------------
+CREATE TABLE name (
+    id bigint NOT NULL,
+    version integer,
+    uuid character varying(255),
+    systemgroup_uuid character varying(255),
+    system_uuid character varying(255),
+    subsystem_uuid character varying(255),
+    devicetype_uuid character varying(255),
+    instance_index character varying(255),
+    convention_name character varying(255),
+    convention_name_equivalence character varying(255),
+    description character varying(255),
+    status character varying(255),
+    latest boolean NOT NULL,
+    deleted boolean NOT NULL,
+    requested timestamp without time zone,
+    requested_by character varying(255),
+    requested_comment character varying(255),
+    processed timestamp without time zone,
+    processed_by character varying(255),
+    processed_comment character varying(255)
+);
+
+-- --------------------------------------------------------------------------------
+-- data structures level 1
+-- --------------------------------------------------------------------------------
+insert into systemgroup (
+    id,
+    version,
+    uuid,
+    name,
+    mnemonic,
+    mnemonic_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select npr1.id, npr1."version", np1.uuid, npr1."name", npr1.mnemonic, npr1.mnemoniceqclass, npr1.description, npr1.status, false, npr1.deleted,
+npr1.requestdate, ua_r.username as requestedBy, npr1.requestercomment, npr1.processdate, ua_p.username as processedBy, npr1.processorcomment
+from namepartrevision npr1
+inner join namepart np1 on npr1.namepart_id = np1.id
+left join useraccount ua_r on npr1.requestedby_id = ua_r.id
+left join useraccount ua_p on npr1.processedby_id = ua_p.id
+where np1.nameparttype = 'SECTION' and npr1.parent_id is null;
+
+insert into discipline (
+    id,
+    version,
+    uuid,
+    name,
+    mnemonic,
+    mnemonic_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select npr1.id, npr1."version", np1.uuid, npr1."name", npr1.mnemonic, npr1.mnemoniceqclass, npr1.description, npr1.status, false, npr1.deleted,
+npr1.requestdate, ua_r.username as requestedBy, npr1.requestercomment, npr1.processdate, ua_p.username as processedBy, npr1.processorcomment
+from namepartrevision npr1
+inner join namepart np1 on npr1.namepart_id = np1.id
+left join useraccount ua_r on npr1.requestedby_id = ua_r.id
+left join useraccount ua_p on npr1.processedby_id = ua_p.id
+where np1.nameparttype = 'DEVICE_TYPE' and npr1.parent_id is null;
+
+-- --------------------------------------------------------------------------------
+-- data structures level 2
+-- --------------------------------------------------------------------------------
+insert into system (
+    id,
+    version,
+    uuid,
+    parent_uuid,
+    name,
+    mnemonic,
+    mnemonic_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select npr2.id, npr2."version", np2.uuid, np22.uuid,
+npr2."name", npr2.mnemonic, npr2.mnemoniceqclass, npr2.description,
+npr2.status, false, npr2.deleted, npr2.requestdate, ua_r.username as requestedBy, npr2.requestercomment, npr2.processdate, ua_p.username as processedBy, npr2.processorcomment
+from namepartrevision npr2
+inner join namepart np2  on npr2.namepart_id = np2.id
+inner join namepart np22 on npr2.parent_id   = np22.id
+left join useraccount ua_r on npr2.requestedby_id = ua_r.id
+left join useraccount ua_p on npr2.processedby_id = ua_p.id
+where np2.nameparttype = 'SECTION' and npr2.parent_id in
+(select npr1.namepart_id from namepartrevision npr1, namepart np1 where npr1.namepart_id = np1.id and np1.nameparttype = 'SECTION' and npr1.parent_id is null);
+
+insert into devicegroup (
+    id,
+    version,
+    uuid,
+    parent_uuid,
+    name,
+    mnemonic,
+    mnemonic_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select npr2.id, npr2."version", np2.uuid, np22.uuid,
+npr2."name", npr2.mnemonic, npr2.mnemoniceqclass, npr2.description,
+npr2.status, false, npr2.deleted, npr2.requestdate, ua_r.username as requestedBy, npr2.requestercomment, npr2.processdate, ua_p.username as processedBy, npr2.processorcomment
+from namepartrevision npr2
+inner join namepart np2  on npr2.namepart_id = np2.id
+inner join namepart np22 on npr2.parent_id   = np22.id
+left join useraccount ua_r on npr2.requestedby_id = ua_r.id
+left join useraccount ua_p on npr2.processedby_id = ua_p.id
+where np2.nameparttype = 'DEVICE_TYPE' and npr2.parent_id in
+(select npr1.namepart_id from namepartrevision npr1, namepart np1 where npr1.namepart_id = np1.id and np1.nameparttype = 'DEVICE_TYPE' and npr1.parent_id is null);
+
+-- --------------------------------------------------------------------------------
+-- data structures level 3
+-- --------------------------------------------------------------------------------
+insert into subsystem (
+    id,
+    version,
+    uuid,
+    parent_uuid,
+    name,
+    mnemonic,
+    mnemonic_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select npr3.id, npr3."version", np3.uuid, np32.uuid,
+npr3."name", npr3.mnemonic, npr3.mnemoniceqclass, npr3.description,
+npr3.status, false, npr3.deleted, npr3.requestdate, ua_r.username as requestedBy, npr3.requestercomment, npr3.processdate, ua_p.username as processedBy, npr3.processorcomment
+from namepartrevision npr3
+inner join namepart np3  on npr3.namepart_id = np3.id
+inner join namepart np32 on npr3.parent_id   = np32.id
+left join useraccount ua_r on npr3.requestedby_id = ua_r.id
+left join useraccount ua_p on npr3.processedby_id = ua_p.id
+where np3.nameparttype = 'SECTION' and npr3.parent_id in
+(
+select npr2.namepart_id from namepartrevision npr2, namepart np2 where npr2.namepart_id = np2.id and np2.nameparttype = 'SECTION' and npr2.parent_id in
+(select npr1.namepart_id from namepartrevision npr1, namepart np1 where npr1.namepart_id = np1.id and np1.nameparttype = 'SECTION' and npr1.parent_id is null)
+);
+
+insert into devicetype (
+    id,
+    version,
+    uuid,
+    parent_uuid,
+    name,
+    mnemonic,
+    mnemonic_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select npr3.id, npr3."version", np3.uuid, np32.uuid,
+npr3."name", npr3.mnemonic, npr3.mnemoniceqclass, npr3.description,
+npr3.status, false, npr3.deleted, npr3.requestdate, ua_r.username as requestedBy, npr3.requestercomment, npr3.processdate, ua_p.username as processedBy, npr3.processorcomment
+from namepartrevision npr3
+inner join namepart np3  on npr3.namepart_id = np3.id
+inner join namepart np32 on npr3.parent_id   = np32.id
+left join useraccount ua_r on npr3.requestedby_id = ua_r.id
+left join useraccount ua_p on npr3.processedby_id = ua_p.id
+where np3.nameparttype = 'DEVICE_TYPE' and npr3.parent_id in
+(
+select npr2.namepart_id from namepartrevision npr2, namepart np2 where npr2.namepart_id = np2.id and np2.nameparttype = 'DEVICE_TYPE' and npr2.parent_id in
+(select npr1.namepart_id from namepartrevision npr1, namepart np1 where npr1.namepart_id = np1.id and np1.nameparttype = 'DEVICE_TYPE' and npr1.parent_id is null)
+);
+
+-- --------------------------------------------------------------------------------
+-- data name level 1
+-- --------------------------------------------------------------------------------
+insert into name (
+    id,
+    version,
+    uuid,
+    systemgroup_uuid,
+    system_uuid,
+    subsystem_uuid,
+    devicetype_uuid,
+    instance_index,
+    convention_name,
+    convention_name_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select dr.id, dr.version, d.uuid,
+np_s.uuid,
+null,
+null,
+np_d.uuid,
+dr.instanceindex, dr.conventionname, dr.conventionnameeqclass, dr.additionalinfo, null, false, dr.deleted,
+dr.requestdate, ua_r.username as requestedBy, null, null, null, dr.processorComment
+from devicerevision dr
+inner join device d on dr.device_id = d.id
+inner join namepart np_s on dr.section_id    = np_s.id
+left outer join namepart np_d on dr.devicetype_id = np_d.id
+left join useraccount ua_r on dr.requestedby_id = ua_r.id
+where dr.section_id in
+(
+select np.id from namepart np, namepartrevision npr where np.id = npr.namepart_id and npr.parent_id is null
+);
+-- --------------------------------------------------------------------------------
+-- data name level 2
+-- --------------------------------------------------------------------------------
+insert into name (
+    id,
+    version,
+    uuid,
+    systemgroup_uuid,
+    system_uuid,
+    subsystem_uuid,
+    devicetype_uuid,
+    instance_index,
+    convention_name,
+    convention_name_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select dr.id, dr.version, d.uuid,
+null,
+np_s.uuid,
+null,
+np_d.uuid,
+dr.instanceindex, dr.conventionname, dr.conventionnameeqclass, dr.additionalinfo, null, false, dr.deleted,
+dr.requestdate, ua_r.username as requestedBy, null, null, null, dr.processorComment
+from devicerevision dr
+inner join device d on dr.device_id = d.id
+inner join namepart np_s on dr.section_id    = np_s.id
+left outer join namepart np_d on dr.devicetype_id = np_d.id
+left join useraccount ua_r on dr.requestedby_id = ua_r.id
+where dr.section_id in
+(
+select np.id from namepart np, namepartrevision npr where np.id = npr.namepart_id and npr.parent_id in
+    (
+    select np2.id from namepart np2, namepartrevision npr2 where np2.id = npr2.namepart_id and npr2.parent_id is null
+    )
+);
+
+-- --------------------------------------------------------------------------------
+-- data name level 3
+-- --------------------------------------------------------------------------------
+insert into name (
+    id,
+    version,
+    uuid,
+    systemgroup_uuid,
+    system_uuid,
+    subsystem_uuid,
+    devicetype_uuid,
+    instance_index,
+    convention_name,
+    convention_name_equivalence,
+    description,
+    status,
+    latest,
+    deleted,
+    requested,
+    requested_by,
+    requested_comment,
+    processed,
+    processed_by,
+    processed_comment
+)
+select dr.id, dr.version, d.uuid,
+null,
+null,
+np_s.uuid,
+np_d.uuid,
+dr.instanceindex, dr.conventionname, dr.conventionnameeqclass, dr.additionalinfo, null, false, dr.deleted,
+dr.requestdate, ua_r.username as requestedBy, null, null, null, dr.processorComment
+from devicerevision dr
+inner join device d on dr.device_id = d.id
+inner join namepart np_s on dr.section_id    = np_s.id
+left outer join namepart np_d on dr.devicetype_id = np_d.id
+left join useraccount ua_r on dr.requestedby_id = ua_r.id
+where dr.section_id in
+(
+select np.id from namepart np, namepartrevision npr where np.id = npr.namepart_id and npr.parent_id in
+    (
+    select np2.id from namepart np2, namepartrevision npr2 where np2.id = npr2.namepart_id and npr2.parent_id in
+        (
+        select np3.id from namepart np3, namepartrevision npr3 where np3.id = npr3.namepart_id and npr3.parent_id is null
+        )
+    )
+);
+
+-- --------------------------------------------------------------------------------
+-- index
+-- --------------------------------------------------------------------------------
+CREATE INDEX systemgroup_id_idx ON public.systemgroup (id);
+CREATE INDEX systemgroup_uuid_idx ON public.systemgroup (uuid);
+CREATE INDEX systemgroup_mnemonic_idx ON public.systemgroup (mnemonic);
+CREATE INDEX systemgroup_status_idx ON public.systemgroup (status);
+CREATE INDEX systemgroup_deleted_idx ON public.systemgroup (deleted);
+
+CREATE INDEX system_id_idx ON public.system (id);
+CREATE INDEX system_uuid_idx ON public.system (uuid);
+CREATE INDEX system_parent_uuid_idx ON public.system (parent_uuid);
+CREATE INDEX system_mnemonic_idx ON public.system (mnemonic);
+CREATE INDEX system_status_idx ON public.system (status);
+CREATE INDEX system_deleted_idx ON public.system (deleted);
+
+CREATE INDEX subsystem_id_idx ON public.subsystem (id);
+CREATE INDEX subsystem_uuid_idx ON public.subsystem (uuid);
+CREATE INDEX subsystem_parent_uuid_idx ON public.subsystem (parent_uuid);
+CREATE INDEX subsystem_mnemonic_idx ON public.subsystem (mnemonic);
+CREATE INDEX subsystem_status_idx ON public.subsystem (status);
+CREATE INDEX subsystem_deleted_idx ON public.subsystem (deleted);
+
+CREATE INDEX discipline_id_idx ON public.discipline (id);
+CREATE INDEX discipline_uuid_idx ON public.discipline (uuid);
+CREATE INDEX discipline_mnemonic_idx ON public.discipline (mnemonic);
+CREATE INDEX discipline_status_idx ON public.discipline (status);
+CREATE INDEX discipline_deleted_idx ON public.discipline (deleted);
+
+CREATE INDEX devicegroup_id_idx ON public.devicegroup (id);
+CREATE INDEX devicegroup_uuid_idx ON public.devicegroup (uuid);
+CREATE INDEX devicegroup_parent_uuid_idx ON public.devicegroup (parent_uuid);
+CREATE INDEX devicegroup_mnemonic_idx ON public.devicegroup (mnemonic);
+CREATE INDEX devicegroup_status_idx ON public.devicegroup (status);
+CREATE INDEX devicegroup_deleted_idx ON public.devicegroup (deleted);
+
+CREATE INDEX devicetype_id_idx ON public.devicetype (id);
+CREATE INDEX devicetype_uuid_idx ON public.devicetype (uuid);
+CREATE INDEX devicetype_parent_uuid_idx ON public.devicetype (parent_uuid);
+CREATE INDEX devicetype_mnemonic_idx ON public.devicetype (mnemonic);
+CREATE INDEX devicetype_status_idx ON public.devicetype (status);
+CREATE INDEX devicetype_deleted_idx ON public.devicetype (deleted);
+
+CREATE INDEX name_uuid_idx ON public.name (uuid);
+
+-- --------------------------------------------------------------------------------
+-- latest
+-- --------------------------------------------------------------------------------
+update systemgroup sg set latest = true where sg.id = (
+  select max(sg2.id) from systemgroup sg2 where sg2.uuid = sg.uuid and sg2.status = 'APPROVED'
+);
+update system sys set latest = true where sys.id = (
+  select max(sys2.id) from system sys2 where sys2.uuid = sys.uuid and sys2.status = 'APPROVED'
+);
+update subsystem sub set latest = true where sub.id = (
+  select max(sub2.id) from subsystem sub2 where sub2.uuid = sub.uuid and sub2.status = 'APPROVED'
+);
+
+update discipline di set latest = true where di.id = (
+  select max(di2.id) from discipline di2 where di2.uuid = di.uuid and di2.status = 'APPROVED'
+);
+update devicegroup dg set latest = true where dg.id = (
+  select max(dg2.id) from devicegroup dg2 where dg2.uuid = dg.uuid and dg2.status = 'APPROVED'
+);
+update devicetype dt set latest = true where dt.id = (
+  select max(dt2.id) from devicetype dt2 where dt2.uuid = dt.uuid and dt2.status = 'APPROVED'
+);
+
+update name en set latest = true where en.id = (
+  select max(en2.id) from name en2 where en2.uuid = en.uuid
+);
+
+-- --------------------------------------------------------------------------------
+-- foreign key
+-- --------------------------------------------------------------------------------
+
+-- --------------------------------------------------------------------------------
+-- index
+-- --------------------------------------------------------------------------------
+CREATE INDEX name_id_idx ON public.name (id);
+CREATE INDEX name_namepartrevision_systemgroup_uuid_idx ON public.name (systemgroup_uuid);
+CREATE INDEX name_namepartrevision_system_uuid_idx ON public.name (system_uuid);
+CREATE INDEX name_namepartrevision_subsystem_uuid_idx ON public.name (subsystem_uuid);
+CREATE INDEX name_namepartrevision_devicetype_uuid_idx ON public.name (devicetype_uuid);
+CREATE INDEX name_convention_name_idx ON public.name (convention_name);
+CREATE INDEX name_status_idx ON public.name (status);
+CREATE INDEX name_deleted_idx ON public.name (deleted);
+
+CREATE INDEX systemgroup_latest_idx ON public.systemgroup (latest);
+CREATE INDEX system_latest_idx ON public.system (latest);
+CREATE INDEX subsystem_latest_idx ON public.subsystem (latest);
+
+CREATE INDEX discipline_latest_idx ON public.discipline (latest);
+CREATE INDEX devicegroup_latest_idx ON public.devicegroup (latest);
+CREATE INDEX devicetype_latest_idx ON public.devicetype (latest);
+
+CREATE INDEX name_latest_idx ON public.name (latest);
+
+-- --------------------------------------------------------------------------------
+-- sequence
+-- --------------------------------------------------------------------------------
+CREATE SEQUENCE systemgroup_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+CREATE SEQUENCE system_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+CREATE SEQUENCE subsystem_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+CREATE SEQUENCE discipline_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+CREATE SEQUENCE devicegroup_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+CREATE SEQUENCE devicetype_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+CREATE SEQUENCE name_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+SELECT setval('systemgroup_id_seq', (select max(id) from systemgroup));
+SELECT setval('system_id_seq', (select max(id) from "system"));
+SELECT setval('subsystem_id_seq', (select max(id) from "subsystem"));
+SELECT setval('discipline_id_seq', (select max(id) from discipline));
+SELECT setval('devicegroup_id_seq', (select max(id) from devicegroup));
+SELECT setval('devicetype_id_seq', (select max(id) from devicetype));
+SELECT setval('name_id_seq', (select max(id) from "name"));
+
+ALTER SEQUENCE systemgroup_id_seq OWNED BY systemgroup.id;
+ALTER SEQUENCE system_id_seq OWNED BY system.id;
+ALTER SEQUENCE subsystem_id_seq OWNED BY subsystem.id;
+ALTER SEQUENCE discipline_id_seq OWNED BY discipline.id;
+ALTER SEQUENCE devicegroup_id_seq OWNED BY devicegroup.id;
+ALTER SEQUENCE devicetype_id_seq OWNED BY devicetype.id;
+ALTER SEQUENCE name_id_seq OWNED BY name.id;
+
+ALTER TABLE ONLY systemgroup ALTER COLUMN id SET DEFAULT nextval('systemgroup_id_seq'::regclass);
+ALTER TABLE ONLY system ALTER COLUMN id SET DEFAULT nextval('system_id_seq'::regclass);
+ALTER TABLE ONLY subsystem ALTER COLUMN id SET DEFAULT nextval('subsystem_id_seq'::regclass);
+ALTER TABLE ONLY discipline ALTER COLUMN id SET DEFAULT nextval('discipline_id_seq'::regclass);
+ALTER TABLE ONLY devicegroup ALTER COLUMN id SET DEFAULT nextval('devicegroup_id_seq'::regclass);
+ALTER TABLE ONLY devicetype ALTER COLUMN id SET DEFAULT nextval('devicetype_id_seq'::regclass);
+ALTER TABLE ONLY name ALTER COLUMN id SET DEFAULT nextval('name_id_seq'::regclass);
+
+-- --------------------------------------------------------------------------------
+-- primary key
+-- --------------------------------------------------------------------------------
+ALTER TABLE public.systemgroup ADD CONSTRAINT systemgroup_pk PRIMARY KEY (id);
+ALTER TABLE public.system ADD CONSTRAINT system_pk PRIMARY KEY (id);
+ALTER TABLE public.subsystem ADD CONSTRAINT subsystem_pk PRIMARY KEY (id);
+
+ALTER TABLE public.discipline ADD CONSTRAINT discipline_pk PRIMARY KEY (id);
+ALTER TABLE public.devicegroup ADD CONSTRAINT devicegroup_pk PRIMARY KEY (id);
+ALTER TABLE public.devicetype ADD CONSTRAINT devicetype_pk PRIMARY KEY (id);
+
+ALTER TABLE public.name ADD CONSTRAINT name_pk PRIMARY KEY (id);
+-- --------------------------------------------------------------------------------
+
+-- --------------------------------------------------------------------------------
+-- function
+-- --------------------------------------------------------------------------------
+CREATE OR REPLACE FUNCTION get_mnemonic_path_system_structure(convention_name text)
+    RETURNS text
+    LANGUAGE plpgsql
+AS
+$$
+DECLARE
+    pos int;
+BEGIN
+    pos = strpos(convention_name, ':');
+    IF pos > 0  THEN
+        RETURN substr(convention_name, 1, pos-1);
+    END IF;
+    RETURN convention_name;
+END;
+$$;
+
+CREATE OR REPLACE FUNCTION get_mnemonic_path_device_structure(convention_name text)
+    RETURNS text
+    LANGUAGE plpgsql
+AS
+$$
+DECLARE
+    pos int;
+    mnemonic_path text;
+    nbr_delimiters int;
+BEGIN
+    pos = strpos(convention_name, ':');
+    IF pos > 0  THEN
+        mnemonic_path = substr(convention_name, pos+1);
+        nbr_delimiters = array_length(string_to_array(mnemonic_path, '-'), 1) - 1;
+        IF nbr_delimiters = 2 then
+            mnemonic_path = reverse(mnemonic_path);
+            mnemonic_path = substr(mnemonic_path, strpos(mnemonic_path, '-')+1);
+            RETURN reverse(mnemonic_path);
+        ELSIF nbr_delimiters = 1 then
+            return mnemonic_path;
+        ELSE
+            RETURN null;
+        END IF;
+    END IF;
+    RETURN null;
+END;
+$$;
+
+CREATE OR REPLACE FUNCTION get_mnemonic_path_system(system_uuid text)
+    RETURNS text
+    LANGUAGE plpgsql
+AS
+$$
+DECLARE
+    system_mnemonic text;
+    systemgroup_uuid text;
+    systemgroup_mnemonic text;
+BEGIN
+    select parent_uuid, mnemonic into systemgroup_uuid, system_mnemonic from "system" where uuid = system_uuid and latest = true;
+    select mnemonic into systemgroup_mnemonic from systemgroup where uuid = systemgroup_uuid and latest = true;
+
+    if systemgroup_mnemonic is not null and system_mnemonic is not null then
+        return concat(systemgroup_mnemonic, '-', system_mnemonic);
+    elsif system_mnemonic is not null then
+        return system_mnemonic;
+    else
+        return null;
+    end if;
+END;
+$$;
+
+CREATE OR REPLACE FUNCTION get_mnemonic_path_subsystem(subsystem_uuid text)
+    RETURNS text
+    LANGUAGE plpgsql
+AS
+$$
+DECLARE
+    subsystem_mnemonic text;
+    system_uuid text;
+    system_mnemonic text;
+    systemgroup_uuid text;
+    systemgroup_mnemonic text;
+BEGIN
+    select parent_uuid, mnemonic into system_uuid, subsystem_mnemonic from subsystem where uuid = subsystem_uuid and latest = true;
+    select parent_uuid, mnemonic into systemgroup_uuid, system_mnemonic from "system" where uuid = system_uuid and latest = true;
+    select mnemonic into systemgroup_mnemonic from systemgroup where uuid = systemgroup_uuid and latest = true;
+
+    if systemgroup_mnemonic is not null and system_mnemonic is not null and subsystem_mnemonic is not null then
+        return concat(systemgroup_mnemonic, '-', system_mnemonic, '-', subsystem_mnemonic);
+    elsif system_mnemonic is not null and subsystem_mnemonic is not null then
+        return concat(system_mnemonic, '-', subsystem_mnemonic);
+    elsif subsystem_mnemonic is not null then
+        return subsystem_mnemonic;
+    else
+        return null;
+    end if;
+END;
+$$;
+
+CREATE OR REPLACE FUNCTION get_mnemonic_path_devicegroup(devicegroup_uuid text)
+    RETURNS text
+    LANGUAGE plpgsql
+AS
+$$
+DECLARE
+    discipline_uuid text;
+    discipline_mnemonic text;
+BEGIN
+    select parent_uuid into discipline_uuid from devicegroup where uuid = devicegroup_uuid and latest = true;
+    select mnemonic into discipline_mnemonic from discipline where uuid = discipline_uuid and latest = true;
+
+    if discipline_mnemonic is not null then
+        return discipline_mnemonic;
+    else
+        return null;
+    end if;
+END;
+$$;
+
+CREATE OR REPLACE FUNCTION get_mnemonic_path_devicetype(devicetype_uuid text)
+    RETURNS text
+    LANGUAGE plpgsql
+AS
+$$
+DECLARE
+    devicetype_mnemonic text;
+    devicegroup_uuid text;
+    discipline_uuid text;
+    discipline_mnemonic text;
+BEGIN
+    select parent_uuid, mnemonic into devicegroup_uuid, devicetype_mnemonic from devicetype where uuid = devicetype_uuid and latest = true;
+    select parent_uuid, mnemonic into discipline_uuid from devicegroup where uuid = devicegroup_uuid and latest = true;
+    select mnemonic into discipline_mnemonic from discipline where uuid = discipline_uuid and latest = true;
+
+    if discipline_mnemonic is not null and devicetype_mnemonic is not null then
+        return concat(discipline_mnemonic, '-', devicetype_mnemonic);
+    elsif devicetype_mnemonic is not null then
+        return devicetype_mnemonic;
+    else
+        return null;
+    end if;
+END;
+$$;
\ No newline at end of file
-- 
GitLab