NSI system anatomy

This article is based on real events,
and all the problems in it are not imaginary. (C)


In the beginning, I would like to note that the article is not intended to show the invention of the bicycle, because many techniques have long existed in the culture of database development. However, to summarize, analyze the problems that they can solve and show how you can work with them. And there are enough problems despite the fact that the reference information (NSI) does not apply to business logic, but rather is in its service. The standard process of drawing another plate to store the directory very soon begins to grow with crutches or time-consuming alterations.

So, in my case, the same picture turned out to be - the system has been on the productive for more than ten years, was built on the same principle, if necessary, we draw and turn it on. Thus, several tables were created for storing various kinds of equipment. But then came the hour X, when it became necessary to add a couple more tables for new equipment and at the same time everyone (including old ones) should be included in a certain group. This means that links to different tables should be included in the crosstab between the group and all five types of equipment, that is, for each of its own fields with a constant on the corresponding table. And if one more is added, change the structure. And processing needs to be done depending on which fields are filled. So the first problem arises ,how to summarize different tables so that you can work with them equally and not change the structure if another one is added . A wonderful idea, we create a separate label that is designed to store the abstract concept of equipment with an indication of the type, and then the remaining labels refer to their parent by foreign key. On this joyful wave, we fill records from one into the created plate and try to make for the other too. But something went wrong, the primary key restriction worked, why would it? And to the fact that at the dawn of the turbulent youth of the system, each plate had its own sequences. Of course, over time this disgrace was corrected, but the old keys still remained. Moreover, they sprouted roots on foreign keys with other tables. We fix the second problem ,associated with end-to-end numbering of all directories .

The torment with the equipment tables did not end there. Because according to the latest requirements, the equipment has various characteristics, moreover, their number is variable, and one characteristic can have several values. So a third problem appears , namely, to be able to store a variable number of characteristics of a record .

It seems like they managed it, but the customer is on the alert, he always has something new ready. And then the demand comes - all the directories are historical (for example, the name of the product was one, and then it was renamed, and according to the documents for different dates you need to show the current name). The requirement itself is normal, you can’t say anything. And if there is someone else in the development department who is going through a trial period, then everything is covered in chocolate, you may not notice that this is a problem. However, everything goes as usual - with a complete breakdown, and then you still need to do this. We create plates duplicating the tables of the corresponding directories in order to store the chronology of changes in the directory there. But by creating these tables, we also create a fourth problem for ourselves ,Now in the code, depending on the date, one must refer to either the main table or the historical one .

Well, we are good fellows, we won this too))) Now, while drinking tea from your own mug, you begin to discuss with other colleagues about what they had to solve, and you understand that the list of problems is growing. The discussion raises the question of how to store versions of the same record. I want to make a reservation that the version is not something that fits into the table of historicity. In historicity, it is understandable, until such a date there was one name, and starting from this date, another becomes relevant. And in versioning, it is understood that the record was first saved with an error, and after a few hours it was understood and changed, and you need to know all the states of this record. Firstly, there should be crushing for a while, not just a day. And secondly, such traces are needed in the event of a showdown. For example, they filled in the price list, made a mistake, managed to sell the goods at such a price, and then corrected,but at the end of the day there was an unbalance. However, the decision for such situations bothered me personally, it was proposed to store all such changes in the table itself. I will not arrange holivar on how much is so right, but for me it has become clearthe fifth problem , namely the storage of record changes .

So, summarizing the above, we see five weighty rakes in front of us. Now our task is to determine a strategy that allows you to get around and not step on them.

How much can you step on the same rake, let's throw off and buy new ones


Starting to design a system from scratch, no one can predict the path of its development, and therefore can not say at what level it will be necessary to generalize, as in the described example with equipment. Therefore, it makes sense to immediately set an abstract entity that is distributed to all NSI tables. Thus, all directories will have a prototype in a single directory with the division into types.

CREATE TABLE nsi_type (
    nsi_type_id     NUMBER(10) NOT NULL,
    name            VARCHAR2(50) NOT NULL,
    descr           VARCHAR2(100),
    table_name      VARCHAR2(50) NOT NULL,
    CONSTRAINT nsi_type_pk PRIMARY KEY (nsi_type_id)
);

CREATE TABLE nsi (
    nsi_id      NUMBER(10) NOT NULL,
    nsi_type_id NUMBER(10) NOT NULL,
    descr       VARCHAR2(100),
    create_date DATE NOT NULL,
    modif_date  DATE NOT NULL,
    begin_date  DATE,
    CONSTRAINT nsi_nsi_type_fk FOREIGN KEY (nsi_type_id) REFERENCES nsi_type (nsi_type_id),
    CONSTRAINT nsi_uk UNIQUE(nsi_type_id, nsi_id)
);

CREATE SEQUENCE nsi_seq
  MINVALUE 1
  START WITH 1
  INCREMENT BY 1
  CACHE 20;

The nsi_type system table is populated as new directories are added. The nsi table stores keys and system fields. At the same time, we create our own sequence and thereby close the second problem .

We will also create a package containing the basic functionality for working with directories and will gradually fill it.

create or replace NONEDITIONABLE PACKAGE BODY pkg_nsi
IS

    /*      
    *  @param p_table_name VARCHAR2 -  
    *  @return nsi.nsi_type_id%TYPE -    nsi_type
    */
    FUNCTION get_type_id(p_table_name IN VARCHAR2) 
    RETURN nsi_type.nsi_type_id%TYPE
    AS
       v_type_id 	nsi_type.nsi_type_id%TYPE; 
    BEGIN
        SELECT nsi_type_id INTO v_type_id 
        FROM nsi_type
        WHERE TRIM(LOWER(table_name)) = TRIM(LOWER(p_table_name));

        RETURN v_type_id;
    END get_type_id;

    /*   id  nsi_seq
    *  @return nsi.nsi_id%TYPE - id  nsi_seq
    */
    FUNCTION get_nsi_id 
    RETURN nsi.nsi_id%TYPE
    AS
       v_id 	nsi.nsi_id%TYPE; 
    BEGIN    
        SELECT nsi_seq.NEXTVAL INTO v_id FROM DUAL;
        RETURN v_id;
    END get_nsi_id;

    /*      
    *  @param p_nsi_type_id nsi_type.nsi_type_id%TYPE -    nsi_type 
    *  @return nsi_type.table_name%TYPE -  
    */
    FUNCTION get_table_name(p_nsi_type_id IN nsi_type.nsi_type_id%TYPE) 
    RETURN nsi_type.table_name%TYPE
    AS
       v_table_name nsi_type.table_name%TYPE; 
    BEGIN
        SELECT table_name INTO v_table_name 
        FROM nsi_type
        WHERE nsi_type_id = p_nsi_type_id;

        RETURN v_table_name;
    END get_table_name;

    /*        nsi
    *  @param p_nsi_id nsi.nsi_id%TYPE -   
    *  @param p_nsi_type_id nsi_type.nsi_type_id%TYPE -   
    *  @return nsi.descr%TYPE - 
    */
    FUNCTION get_nsi_descr (
        p_nsi_id        IN nsi.nsi_id%TYPE,
        p_nsi_type_id   IN nsi.nsi_type_id%TYPE) 
    RETURN nsi.descr%TYPE
    AS
       v_nsi_descr  nsi.descr%TYPE; 
    BEGIN
        SELECT descr 
          INTO v_nsi_descr 
          FROM nsi
         WHERE nsi_id = p_nsi_id
           AND nsi_type_id = p_nsi_type_id;

        RETURN v_nsi_descr;
    END get_nsi_descr;
...
END pkg_nsi;

So far, auxiliary functions have been provided to provide the necessary infrastructure.

So the task is to create a directory of organizations, where, without it, any company contacts third-party organizations - these are suppliers, customers, and partners. Immediately add the corresponding type to the nsi_type table and define the nsi_organization table.

CREATE TABLE nsi_organization (
    nsi_id      NUMBER(10) NOT NULL,
    name        VARCHAR2(50) NOT NULL,
    full_name   VARCHAR2(100) NOT NULL,
    inn         VARCHAR2(12) NOT NULL,
    CONSTRAINT nsi_organization_pk PRIMARY KEY (nsi_id),
    CONSTRAINT nsi_organization_nsi_fk FOREIGN KEY (nsi_id) REFERENCES nsi (nsi_id)
);

INSERT INTO nsi_type (nsi_type_id, name, descr, table_name) 
VALUES (11, '', ' , , , ', 'nsi_organization');

Now, before it's too late, you need to remember about the rake with the number "five". If we start adding records to the created table of organizations, then this event needs to be fixed somewhere.

CREATE TABLE nsi_log (
    nsi_log_id        NUMBER(10) NOT NULL,
    nsi_id            NUMBER(10) NOT NULL,
    table_name        VARCHAR2(100),
    oper_num          NUMBER,
    descr             CLOB,
    create_date       DATE,
    CONSTRAINT nsi_log_pk PRIMARY KEY (nsi_log_id),
    CONSTRAINT nsi_log_oper_num_ch CHECK (oper_num IN (1, 2, 3, 4, 5, 6, 7))
);

COMMENT ON TABLE nsi_log IS '.  ';
COMMENT ON COLUMN nsi_log.nsi_log_id IS '';
COMMENT ON COLUMN nsi_log.nsi_id IS '';
COMMENT ON COLUMN nsi_log.table_name IS ' ';
COMMENT ON COLUMN nsi_log.oper_num IS '  (1 -  , 2 -  , 3 -  , 4 -  , 5 -  , 6 -  , 7 -   ).';
COMMENT ON COLUMN nsi_log.descr IS '';
COMMENT ON COLUMN nsi_log.create_date IS ' ';

And also a logging function has been added to the package.

    --  CHECK nsi_log_oper_num_ch
    NSI_LOG_OPERNUM_INSERT          NUMBER := 1;
    NSI_LOG_OPERNUM_UPDATE          NUMBER := 2;
    NSI_LOG_OPERNUM_DELETE          NUMBER := 3;
    NSI_LOG_OPERNUM_ATTR_INSERT     NUMBER := 4;
    NSI_LOG_OPERNUM_ATTR_UPDATE     NUMBER := 5;
    NSI_LOG_OPERNUM_ATTR_DELETE     NUMBER := 6;
    NSI_LOG_OPERNUM_HISTORY_PUSH    NUMBER := 7;

    /*    .
    *  @param p_nsi_id nsi.nsi_id%TYPE - 
    *  @param p_nsi_type_id nsi_type.nsi_type_id%TYPE -  
    *  @param p_oper_num NUMBER -  
    *  @param p_descr VARCHAR2 - 
    */
    PROCEDURE log_oper (
        p_nsi_id        IN nsi.nsi_id%TYPE,
        p_nsi_type_id   IN nsi_type.nsi_type_id%TYPE,
        p_oper_num      IN NUMBER,
        p_descr         IN VARCHAR2)
    AS
    BEGIN
        INSERT INTO nsi_log 
        (nsi_log_id, nsi_id, table_name, oper_num, descr, create_date)
        VALUES 
        (get_nsi_id(), p_nsi_id, get_table_name(p_nsi_type_id), p_oper_num, p_descr, Sysdate);
    END;

Thus, the fifth problem is resolved , now for any NSI record you can see what happened to it.

We are trying to add an organization there.

INSERT INTO nsi_organization (nsi_id, name, full_name, inn)
VALUES (1, ' "  "', '  "  "', '11223344');

Of course we run into the nsi_organization_nsi_fk constant. Therefore, all lookup tables should be equipped with the necessary refinement of triggers.

CREATE OR REPLACE TRIGGER nsi_organization_trg_insert 
BEFORE INSERT ON nsi_organization FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_organization');
    :NEW.nsi_id := pkg_nsi.get_nsi_id();

    INSERT INTO nsi (nsi_id, nsi_type_id, descr, create_date, modif_date, begin_date)
    VALUES (:NEW.nsi_id, v_type_id, :NEW.name, Trunc(Sysdate), Trunc(Sysdate), Trunc(Sysdate));
    
    v_log_descr := 'name = ''' || :NEW.name || ''', full_name = ''' || :NEW.full_name || ''', inn = ''' || :NEW.inn || ''' ';
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_INSERT, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_organization_trg_update 
BEFORE UPDATE ON nsi_organization FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_organization');

    UPDATE nsi
       SET modif_date = Trunc(Sysdate)
     WHERE nsi_id = :NEW.nsi_id
       AND nsi_type_id = v_type_id;
    
    v_log_descr := 'name = ''' || :NEW.name || ''', full_name = ''' || :NEW.full_name || ''', inn = ''' || :NEW.inn || ''' ';
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_UPDATE, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_organization_trg_delete 
AFTER DELETE ON nsi_organization FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_organization');

    DELETE FROM nsi
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;
    
    v_log_descr := 'name = ''' || :OLD.name || ''', full_name = ''' || :OLD.full_name || ''', inn = ''' || :OLD.inn || ''' ';
    pkg_nsi.log_oper (:OLD.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_DELETE, v_log_descr);
END;

And now adding the record will work without problems (no need to specify the key). At the same time, the first record will appear in the nsi table, and this event will also be recorded in the logging table.

INSERT INTO nsi_organization (name, full_name, inn)
VALUES (' "  "', '  "  "', '11223344');

But for now, you can notice only the additional costs of creating a table of some kind of directory, and not the advantage of a single approach. Then we recall the fourth problem - we need to store the historicity of the data in the tables of the directory, as well as retrieve the current state for a given date.

CREATE TABLE nsi_history (
    nsi_history_id  NUMBER(10) NOT NULL,
    nsi_id          NUMBER(10) NOT NULL,
    nsi_type_id     NUMBER(10) NOT NULL,
    version         NUMBER(10) NOT NULL,
    content         CLOB NOT NULL,
    note            VARCHAR2(100),
    begin_date      DATE NOT NULL,
    end_date        DATE NOT NULL,     
    CONSTRAINT nsi_history_pk PRIMARY KEY (nsi_history_id),
    CONSTRAINT nsi_history_nsi_type_fk FOREIGN KEY (nsi_type_id) REFERENCES nsi_type (nsi_type_id),
    CONSTRAINT nsi_history_nsi_fk FOREIGN KEY (nsi_id) REFERENCES nsi (nsi_id),
    CONSTRAINT nsi_history_content_json_chk CHECK (content IS JSON)
);

COMMENT ON TABLE nsi_history IS ' ';
COMMENT ON COLUMN nsi_history.nsi_history_id IS '';
COMMENT ON COLUMN nsi_history.nsi_id IS '';
COMMENT ON COLUMN nsi_history.nsi_type_id IS ' ';
COMMENT ON COLUMN nsi_history.version IS '';
COMMENT ON COLUMN nsi_history.content IS ' ';
COMMENT ON COLUMN nsi_history.note IS '';
COMMENT ON COLUMN nsi_history.begin_date IS '  ';
COMMENT ON COLUMN nsi_history.end_date IS '  ';

In the pkg_nsi package, we add the function of saving the record to the historical table. We will store the record in json format, so the package will also have the opportunity to get json for the transmitted request.

    /*     json
    *  @param p_query VARCHAR2 - 
    *  @return CLOB -  json
    */
    FUNCTION get_json(p_query IN VARCHAR2) 
    RETURN CLOB
    AS
      v_theCursor       integer default dbms_sql.open_cursor;
      v_columnValue     varchar2(4000);
      v_status          integer;
      v_descTbl         dbms_sql.desc_tab;
      v_colCnt          number;
      v_res             clob;
    BEGIN
        dbms_sql.parse(v_theCursor, p_query, dbms_sql.native);
        dbms_sql.describe_columns( v_theCursor, v_colCnt, v_descTbl);

        FOR i IN 1 .. v_colCnt LOOP
            dbms_sql.define_column(v_theCursor, i, v_columnValue, 4000);
        END LOOP;
      
        v_status := dbms_sql.execute(v_theCursor);
        WHILE ( dbms_sql.fetch_rows(v_theCursor) > 0 ) LOOP
            FOR i IN 1 .. v_colCnt LOOP
                dbms_sql.column_value( v_theCursor, i, v_columnValue );
                IF i > 1 THEN
                    v_res := v_res || ', ';
                END IF;
                v_res := v_res || '"' || v_descTbl(i).col_name || '" : "' || replace(v_columnValue, '"', '\"') || '"';
            END LOOP;
            
            --   ,     ,   
            --     
            EXIT;
        END LOOP;
        
        RETURN '{' || v_res || '}';
      
    exception
        when others then dbms_sql.close_cursor( v_theCursor ); RAISE;
    END get_json;

    /*       .
    *  @param p_nsi_id nsi.nsi_id%TYPE - 
    *  @param p_nsi_type_id nsi_type.nsi_type_id%TYPE -  
    *  @param p_end_date nsi_history.end_date%TYPE -     
    *  @param p_note nsi_history.note%TYPE -     
    */
    PROCEDURE nsi_history_push (
        p_nsi_id        IN nsi.nsi_id%TYPE,
        p_nsi_type_id   IN nsi_type.nsi_type_id%TYPE,
        p_end_date      IN nsi_history.end_date%TYPE,
        p_note          IN nsi_history.note%TYPE)
    AS
        v_table_name VARCHAR2(50);
        v_content CLOB;
        v_max_ver NUMBER;
        v_begin_date DATE;
    BEGIN
        IF (p_end_date IS NULL) THEN
            RAISE_APPLICATION_ERROR (NSI_ERROR_CODE, 
                '[nsi_history_push]     .'); 
        END IF;

        IF (Trunc(p_end_date) > Trunc(Sysdate) ) THEN
            RAISE_APPLICATION_ERROR (NSI_ERROR_CODE, 
                '[nsi_history_push]       .'); 
        END IF;
        
        SELECT begin_date INTO v_begin_date
          FROM nsi
         WHERE nsi_id = p_nsi_id
           AND nsi_type_id = p_nsi_type_id;

        IF (Trunc(p_end_date) < Trunc(v_begin_date) ) THEN
            RAISE_APPLICATION_ERROR (NSI_ERROR_CODE, 
                '[nsi_history_push]            .'); 
        END IF;
        
        v_table_name := get_table_name(p_nsi_type_id);
        v_content := get_json ('select * from ' || v_table_name || ' where nsi_id=' || p_nsi_id);
        
        SELECT MAX(version) INTO v_max_ver
          FROM nsi_history
         WHERE nsi_id = p_nsi_id
           AND nsi_type_id = p_nsi_type_id;
          
        IF (v_max_ver IS NULL) THEN
            v_max_ver := 0;
        END IF;

        v_max_ver := v_max_ver + 1;
        
        UPDATE nsi
           SET begin_date = Trunc(p_end_date) + 1
         WHERE nsi_id = p_nsi_id
           AND nsi_type_id = p_nsi_type_id;
           
        INSERT INTO nsi_history
        (nsi_history_id, nsi_id, nsi_type_id, version, content, note, begin_date, end_date)
        VALUES (get_nsi_id, p_nsi_id, p_nsi_type_id, v_max_ver, v_content, p_note, v_begin_date, Trunc(p_end_date));
        
        log_oper(p_nsi_id, p_nsi_type_id, NSI_LOG_OPERNUM_HISTORY_PUSH, v_content);
    END nsi_history_push; 

Thus, any directory can use this function to capture the current state in the history. Already good, at least something useful came from such a generalization))) To extract the current state of the directory, we add the corresponding pipeline function to the package. Directory entries will be returned in the type extended by system fields.

    --     nsi_organization     nsi
    TYPE nsi_organization_rec IS RECORD(
        nsi_id          nsi_organization.nsi_id%TYPE, 
        name            nsi_organization.name%TYPE,
        full_name       nsi_organization.full_name%TYPE,
        inn             nsi_organization.inn%TYPE,
        nsi_type_id     nsi.nsi_type_id%TYPE, 
        create_date     nsi.create_date%TYPE,
        modif_date      nsi.create_date%TYPE,
        version         nsi_history.version%TYPE,
        begin_date      nsi.begin_date%TYPE,
        end_date        nsi_history.end_date%TYPE
    );
    TYPE nsi_organization_list IS TABLE OF nsi_organization_rec;

    /*  ,    .
    *     ,    .
    *  @param p_date DATE - ,      
    *  @return nsi_organization_table -    nsi_organization_rec
    */
    FUNCTION nsi_organization_table(p_date IN DATE := null) 
    RETURN nsi_organization_list PIPELINED
    AS
        v_date date;
    BEGIN
        v_date := Trunc(Sysdate);
        IF p_date IS NOT NULL THEN
            v_date := Trunc(p_date);
        END IF;

        FOR rec IN (
            SELECT 
                o.nsi_id, o.name, o.full_name, o.inn,
                n.nsi_type_id, n.create_date, n.modif_date, 
                0 AS version, n.begin_date, to_date(null) AS end_date
            FROM 
                nsi_organization o INNER JOIN nsi n
                ON (o.nsi_id = n.nsi_id)
            WHERE 
                n.begin_date <= v_date
            UNION ALL
            SELECT 
                n.nsi_id, 
                json_value(h.content, '$.NAME') AS name, 
                json_value(h.content, '$.FULL_NAME') AS full_name,
                json_value(h.content, '$.INN') AS inn, 
                n.nsi_type_id, n.create_date, n.modif_date, 
                h.version, h.begin_date, h.end_date
            FROM 
                nsi_history h INNER JOIN nsi n
                ON (h.nsi_id = n.nsi_id AND h.nsi_type_id = n.nsi_type_id)
            WHERE 
                    h.begin_date <= v_date
                AND h.end_date >= v_date
        ) LOOP
            PIPE ROW (rec);
        END LOOP;
    END nsi_organization_table;

Applicable to our nsi_organization table.

select * from nsi where nsi_id=1;
---------------------------------------------------------------------------------------
"NSI_ID"	"NSI_TYPE_ID"	"DESCR"	"CREATE_DATE"	"MODIF_DATE"	"BEGIN_DATE"
1	1	" ""  """	11.03.20	11.03.20	11.03.20
---------------------------------------------------------------------------------------

begin
--       ,      
    pkg_nsi.nsi_history_push(202, 1, sysdate, ' ');
end;
select * from nsi_history;
---------------------------------------------------------------------------------------
"NSI_HISTORY_ID"	"NSI_ID"	"NSI_TYPE_ID"	"VERSION"	"CONTENT"	"NOTE"	"BEGIN_DATE"	"END_DATE"
205	1	1	1	"{""NSI_ID"" : ""1"", ""NAME"" : "" \""  \"""", ""FULL_NAME"" : ""  \""  \"""", ""INN"" : ""11223344""}"	" "	11.03.20	11.03.20
---------------------------------------------------------------------------------------

--      
--       ,         
select * from nsi where nsi_id=1;
---------------------------------------------------------------------------------------
"NSI_ID"	"NSI_TYPE_ID"	"DESCR"	"CREATE_DATE"	"MODIF_DATE"	"BEGIN_DATE"
1	1	" ""  """	11.03.20	11.03.20	12.03.20
---------------------------------------------------------------------------------------

--        
--     inn, version, begin_date, end_date
--       0
update nsi_organization set inn='99887766' where nsi_id=1;

select * from table(pkg_nsi.nsi_organization_table(sysdate));
---------------------------------------------------------------------------------------
"NSI_ID"	"NAME"	"FULL_NAME"	"INN"	"NSI_TYPE_ID"	"CREATE_DATE"	"MODIF_DATE"	"VERSION"	"BEGIN_DATE"	"END_DATE"
1	" ""  """	"  ""  """	"11223344"	1	11.03.20	11.03.20	1	11.03.20	11.03.20
---------------------------------------------------------------------------------------

select * from table(pkg_nsi.nsi_organization_table(sysdate+1));
---------------------------------------------------------------------------------------
"NSI_ID"	"NAME"	"FULL_NAME"	"INN"	"NSI_TYPE_ID"	"CREATE_DATE"	"MODIF_DATE"	"VERSION"	"BEGIN_DATE"	"END_DATE"
1	" ""  """	"  ""  """	"99887766"	1	11.03.20	11.03.20	0	12.03.20	
---------------------------------------------------------------------------------------

The nsi_organization_table function is very useful because it satisfies our requirements and finally takes problem four to the past .

Move on. Since we have such an advantage with the introduction of a unified approach for working with all directories, we will also use it to store additional information that can be assigned to any entry from any directory. Such a mechanism has long existed, called the EAV-pattern, and we are implementing it.

    --  CHECK nsi_attribute_type_ch
    NSI_ATTRIBUTE_TYPE_STRING   NUMBER := 1;
    NSI_ATTRIBUTE_TYPE_INT      NUMBER := 2;
    NSI_ATTRIBUTE_TYPE_DOUBLE   NUMBER := 3;
    NSI_ATTRIBUTE_TYPE_DATE     NUMBER := 4;

CREATE TABLE nsi_attribute_type (
    nsi_attribute_type_id   NUMBER(10) NOT NULL,
    value_type              NUMBER NOT NULL,
    descr                   VARCHAR2(100) NOT NULL,
    CONSTRAINT nsi_attribute_type_pk PRIMARY KEY (nsi_attribute_type_id),
    CONSTRAINT nsi_attribute_type_ch CHECK (value_type IN (1, 2, 3, 4)),
    CONSTRAINT nsi_attribute_type_fk FOREIGN KEY (nsi_attribute_type_id) REFERENCES nsi (nsi_id)
);

COMMENT ON TABLE nsi_attribute_type IS '.  ';
COMMENT ON COLUMN nsi_attribute_type.nsi_attribute_type_id IS '';
COMMENT ON COLUMN nsi_attribute_type.value_type IS '  (1 - , 2 - , 3 - , 4 - )';
COMMENT ON COLUMN nsi_attribute_type.descr IS '';

CREATE TABLE nsi_attribute (
    nsi_attribute_id        NUMBER(10) NOT NULL,
    nsi_attribute_type_id   NUMBER(10) NOT NULL,
    nsi_id                  NUMBER(10) NOT NULL,
    nsi_type_id             NUMBER(10) NOT NULL,
    value_1                 VARCHAR2(100),
    value_2_3               NUMBER,
    value_4                 DATE,
    begin_date              DATE,
    end_date                DATE,
    CONSTRAINT nsi_attribute_pk PRIMARY KEY (nsi_attribute_id),
    CONSTRAINT nsi_attribute_type_fk FOREIGN KEY (nsi_attribute_type_id) REFERENCES nsi_attribute_type (nsi_attribute_type_id),
    CONSTRAINT nsi_attribute_nsi_fk FOREIGN KEY (nsi_id, nsi_type_id) REFERENCES nsi (nsi_id, nsi_type_id)
);

COMMENT ON TABLE nsi_attribute IS '.  ';
COMMENT ON COLUMN nsi_attribute.nsi_attribute_id IS '';
COMMENT ON COLUMN nsi_attribute.nsi_attribute_type_id IS ' ';
COMMENT ON COLUMN nsi_attribute.nsi_id IS '';
COMMENT ON COLUMN nsi_attribute.nsi_type_id is ' ';
COMMENT ON COLUMN nsi_attribute.value_1 IS '  ';
COMMENT ON COLUMN nsi_attribute.value_2_3 IS '    ';
COMMENT ON COLUMN nsi_attribute.value_4 IS '  ';
COMMENT ON COLUMN nsi_attribute.begin_date IS '   ';
COMMENT ON COLUMN nsi_attribute.end_date IS '   ';

Very often, in the context of documents, proper names must be used in some case, so we will create a new table with individuals and, by analogy with organizations, add trigger processing and a type for selection.

CREATE TABLE nsi_person (
    nsi_id   NUMBER(10) NOT NULL,
    surname         VARCHAR2(30) NOT NULL,
    name            VARCHAR2(30) NOT NULL,
    patronymic      VARCHAR2(30) NOT NULL,
    birthday        DATE,
    CONSTRAINT nsi_person_pk PRIMARY KEY (nsi_id),
    CONSTRAINT nsi_person_nsi_fk FOREIGN KEY (nsi_id) REFERENCES nsi (nsi_id)
);

COMMENT ON TABLE nsi_person IS '.  ';
COMMENT ON COLUMN nsi_person.nsi_id IS '';
COMMENT ON COLUMN nsi_person.surname IS '';
COMMENT ON COLUMN nsi_person.name IS '';
COMMENT ON COLUMN nsi_person.patronymic IS '';
COMMENT ON COLUMN nsi_person.birthday IS ' ';

CREATE OR REPLACE TRIGGER nsi_person_trg_insert 
BEFORE INSERT ON nsi_person FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_person');
    :NEW.nsi_id := pkg_nsi.get_nsi_id();

    INSERT INTO nsi (nsi_id, nsi_type_id, descr, create_date, modif_date, begin_date)
    VALUES (:NEW.nsi_id, v_type_id, :NEW.name, Trunc(Sysdate), Trunc(Sysdate), Trunc(Sysdate));
    
    v_log_query := 'SELECT ''' || :NEW.surname || ''' AS surname, ''' || :NEW.name || ''' AS name, ''' || :NEW.patronymic || ''' AS patronymic, to_date(''' || :NEW.birthday || ''', ''dd.mm.yy'') AS birthday FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_INSERT, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_person_trg_update 
BEFORE UPDATE ON nsi_person FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_person');

    UPDATE nsi
       SET modif_date = Trunc(Sysdate)
     WHERE nsi_id = :NEW.nsi_id
       AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :NEW.surname || ''' AS surname, ''' || :NEW.name || ''' AS name, ''' || :NEW.patronymic || ''' AS patronymic, to_date(''' || :NEW.birthday || ''', ''dd.mm.yy'') AS birthday FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_UPDATE, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_person_trg_delete 
AFTER DELETE ON nsi_person FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_person');

    DELETE FROM nsi_history 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi_attribute 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :OLD.surname || ''' AS surname, ''' || :OLD.name || ''' AS name, ''' || :OLD.patronymic || ''' AS patronymic, to_date(''' || :OLD.birthday || ''', ''dd.mm.yy'') AS birthday FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:OLD.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_DELETE, v_log_descr);
END;

It remains to supplement the pkg_nsi package with the processing of this table.

--     nsi_person     nsi
    TYPE nsi_person_rec IS RECORD(
        nsi_id          nsi_person.nsi_id%TYPE, 
        surname         nsi_person.surname%TYPE,
        name            nsi_person.name%TYPE,
        patronymic      nsi_person.patronymic%TYPE,
        birthday        nsi_person.birthday%TYPE,
        nsi_type_id     nsi.nsi_type_id%TYPE, 
        create_date     nsi.create_date%TYPE,
        modif_date      nsi.create_date%TYPE,
        version         nsi_history.version%TYPE,
        begin_date      nsi.begin_date%TYPE,
        end_date        nsi_history.end_date%TYPE
    );
    TYPE nsi_person_list IS TABLE OF nsi_person_rec;

    /*  ,    .
    *     ,    .
    *  @param p_date DATE - ,      
    *  @return nsi_person_table -    nsi_person_rec
    */
    FUNCTION nsi_person_table(p_date IN DATE := null) 
    RETURN nsi_person_list PIPELINED
    AS
        v_date date;
    BEGIN
        v_date := Trunc(Sysdate);
        IF p_date IS NOT NULL THEN
            v_date := Trunc(p_date);
        END IF;

        FOR rec IN (
            SELECT 
                p.nsi_id, p.surname, p.name, p.patronymic, p.birthday, 
                n.nsi_type_id, n.create_date, n.modif_date, 
                0 AS version, n.begin_date, to_date(null) AS end_date
            FROM 
                nsi_person p INNER JOIN nsi n
                ON (p.nsi_id = n.nsi_id)
            WHERE 
                n.begin_date <= v_date
            UNION ALL
            SELECT 
                n.nsi_id, 
                json_value(h.content, '$.SURNAME') AS surname, 
                json_value(h.content, '$.NAME') AS name,
                json_value(h.content, '$.PATRONYMIC') AS patronymic,
                to_date(json_value(h.content, '$.BIRTHDAY')) AS birthday,
                n.nsi_type_id, n.create_date, n.modif_date, 
                h.version, h.begin_date, h.end_date
            FROM 
                nsi_history h INNER JOIN nsi n
                ON (h.nsi_id = n.nsi_id AND h.nsi_type_id = n.nsi_type_id)
            WHERE 
                    h.begin_date <= v_date
                AND h.end_date >= v_date
        ) LOOP
            PIPE ROW (rec);
        END LOOP;
    END nsi_person_table;

And add someone to this table.

INSERT INTO nsi_person
(surname, name, patronymic, birthday)
VALUES ('', '', '', to_date('22.12.70', 'dd.mm.yy'));

Create attributes for the most sought-after genitive case.

INSERT INTO nsi_attribute_type (nsi_attribute_type_id, value_type, descr) 
VALUES (1, 1, '  . ');
INSERT INTO nsi_attribute_type (nsi_attribute_type_id, value_type, descr) 
VALUES (2, 1, '  . ');
INSERT INTO nsi_attribute_type (nsi_attribute_type_id, value_type, descr) 
VALUES (3, 1, '  . ');

In the pkg_nsi package we add functions for working with directory attributes.

    /*   id      .
    *  @param p_nsi_attribute_type_id nsi_attribute_type.nsi_attribute_type_id%TYPE -  
    *  @param p_value_type nsi_attribute_type.value_type%TYPE -  
    *  @param p_descr nsi_attribute_type.descr%TYPE -  
    */
    PROCEDURE get_attribute_type (
        p_nsi_attribute_type_id IN nsi_attribute_type.nsi_attribute_type_id%TYPE,
        p_value_type            OUT nsi_attribute_type.value_type%TYPE,
        p_descr                 OUT nsi_attribute_type.descr%TYPE)
    AS
    BEGIN
        SELECT value_type, descr
          INTO p_value_type, p_descr
          FROM nsi_attribute_type
         WHERE nsi_attribute_type_id = p_nsi_attribute_type_id;
    END;


    /*   .
    *  @param p_nsi_attribute_type_id nsi_attribute.nsi_attribute_type_id%TYPE -  
    *  @param p_nsi_id nsi_attribute.nsi_id%TYPE - 
    *  @param p_nsi_type_id nsi_attribute.nsi_type_id%TYPE -  
    *  @param p_value_1 nsi_attribute.value_1%TYPE -   
    *  @param p_value_2_3 nsi_attribute.value_2_3%TYPE -   
    *  @param p_value_4 nsi_attribute.value_4%TYPE -   
    *  @param p_begin_date nsi_attribute.begin_date%TYPE -    
    *  @param p_end_date nsi_attribute.end_date%TYPE -    
    */
    PROCEDURE nsi_attribute_insert (
        p_nsi_attribute_type_id IN nsi_attribute.nsi_attribute_type_id%TYPE,
        p_nsi_id                IN nsi_attribute.nsi_id%TYPE,
        p_nsi_type_id           IN nsi_attribute.nsi_type_id%TYPE,
        p_value_1               IN nsi_attribute.value_1%TYPE,
        p_value_2_3             IN nsi_attribute.value_2_3%TYPE,
        p_value_4               IN nsi_attribute.value_4%TYPE,
        p_begin_date            IN nsi_attribute.begin_date%TYPE,
        p_end_date              IN nsi_attribute.end_date%TYPE)
    AS
        v_id            NUMBER;
        v_log_descr     nsi_log.descr%TYPE;
        v_value_type    nsi_attribute_type.value_type%TYPE;
        v_descr         nsi_attribute_type.descr%TYPE;
    BEGIN
        v_id := get_nsi_id;
        get_attribute_type(p_nsi_attribute_type_id, v_value_type, v_descr);

        IF (v_value_type = NSI_ATTRIBUTE_TYPE_STRING) THEN
            INSERT INTO nsi_attribute 
                (nsi_attribute_id, nsi_attribute_type_id, nsi_id, nsi_type_id, 
                 value_1, value_2_3, value_4, begin_date, end_date)
            VALUES (v_id, p_nsi_attribute_type_id, p_nsi_id, p_nsi_type_id,
                    p_value_1, null, null, p_begin_date, p_end_date);
                    
            v_log_descr := p_value_1;
                    
        ELSIF (v_value_type IN (NSI_ATTRIBUTE_TYPE_INT, NSI_ATTRIBUTE_TYPE_DOUBLE)) THEN
            INSERT INTO nsi_attribute 
                (nsi_attribute_id, nsi_attribute_type_id, nsi_id, nsi_type_id, 
                 value_1, value_2_3, value_4, begin_date, end_date)
            VALUES (v_id, p_nsi_attribute_type_id, p_nsi_id, p_nsi_type_id,
                    null, p_value_2_3, null, p_begin_date, p_end_date);
                    
            v_log_descr := p_value_2_3;
                    
        ELSE
            INSERT INTO nsi_attribute 
                (nsi_attribute_id, nsi_attribute_type_id, nsi_id, nsi_type_id, 
                 value_1, value_2_3, value_4, begin_date, end_date)
            VALUES (v_id, p_nsi_attribute_type_id, p_nsi_id, p_nsi_type_id,
                    null, null, p_value_4, p_begin_date, p_end_date);
                    
            v_log_descr := p_value_4;
        END IF;
        
        v_log_descr := '[' || get_nsi_descr(p_nsi_id, p_nsi_type_id) || '] ' ||
                       ' : ' || v_descr || 
                       ' : ' || v_log_descr || 
                       ' : ' || p_begin_date || ' - ' || p_end_date;
        log_oper(p_nsi_id, p_nsi_type_id, NSI_LOG_OPERNUM_ATTR_INSERT, v_log_descr);
    END;

    /*      .
    *  @param p_nsi_attribute_id nsi_attribute.nsi_attribute_id%TYPE -  
    *  @param p_value_1 nsi_attribute.value_1%TYPE -   
    *  @param p_value_2_3 nsi_attribute.value_2_3%TYPE -   
    *  @param p_value_4 nsi_attribute.value_4%TYPE -   
    */
    PROCEDURE nsi_attribute_value (
        p_nsi_attribute_id      IN nsi_attribute.nsi_attribute_id%TYPE,
        p_value_1               IN nsi_attribute.value_1%TYPE,
        p_value_2_3             IN nsi_attribute.value_2_3%TYPE,
        p_value_4               IN nsi_attribute.value_4%TYPE)
    AS
        v_nsi_id            nsi.nsi_id%TYPE;
        v_nsi_type_id       nsi.nsi_type_id%TYPE;
        v_log_descr         nsi_log.descr%TYPE;
        v_value_type        nsi_attribute_type.value_type%TYPE;
        v_descr             nsi_attribute_type.descr%TYPE;
        v_nsi_attribute_type_id  nsi_attribute.nsi_attribute_type_id%TYPE;
    BEGIN
        SELECT nsi_attribute_type_id, nsi_id, nsi_type_id
          INTO v_nsi_attribute_type_id, v_nsi_id, v_nsi_type_id
          FROM nsi_attribute
          WHERE nsi_attribute_id = p_nsi_attribute_id;
          
        get_attribute_type(v_nsi_attribute_type_id, v_value_type, v_descr);
        
        IF (v_value_type = NSI_ATTRIBUTE_TYPE_STRING) THEN
            UPDATE nsi_attribute
               SET value_1 = p_value_1,
                   value_2_3 = null,
                   value_4 = null
            WHERE nsi_attribute_id = p_nsi_attribute_id;

            v_log_descr := p_value_1;
                    
        ELSIF (v_value_type IN (NSI_ATTRIBUTE_TYPE_INT, NSI_ATTRIBUTE_TYPE_DOUBLE)) THEN
            UPDATE nsi_attribute
               SET value_1 = null,
                   value_2_3 = p_value_2_3,
                   value_4 = null
            WHERE nsi_attribute_id = p_nsi_attribute_id;

            v_log_descr := p_value_2_3;
                    
        ELSE
            UPDATE nsi_attribute
               SET value_1 = null,
                   value_2_3 = null,
                   value_4 = p_value_4
            WHERE nsi_attribute_id = p_nsi_attribute_id;

            v_log_descr := p_value_4;
        END IF;

         
        v_log_descr := '[' || get_nsi_descr(v_nsi_id, v_nsi_type_id) || '] ' ||
                       ' : ' || v_descr || 
                       '  : ' || v_log_descr;
        log_oper(v_nsi_id, v_nsi_type_id, NSI_LOG_OPERNUM_ATTR_UPDATE, v_log_descr);
    END;

    /*     .
    *  @param p_nsi_attribute_id nsi_attribute.nsi_attribute_id%TYPE -  
    *  @param p_begin_date nsi_attribute.begin_date%TYPE -    
    *  @param p_end_date nsi_attribute.end_date%TYPE -    
    */
    PROCEDURE nsi_attribute_period (
        p_nsi_attribute_id  IN nsi_attribute.nsi_attribute_id%TYPE,
        p_begin_date        IN nsi_attribute.begin_date%TYPE,
        p_end_date          IN nsi_attribute.end_date%TYPE)
    AS
        v_nsi_id        nsi.nsi_id%TYPE;
        v_nsi_type_id   nsi.nsi_type_id%TYPE;
        v_log_descr     nsi_log.descr%TYPE;
        v_value_type    nsi_attribute_type.value_type%TYPE;
        v_descr         nsi_attribute_type.descr%TYPE;
        v_nsi_attribute_type_id nsi_attribute.nsi_attribute_type_id%TYPE;
    BEGIN
        SELECT nsi_id, nsi_type_id, nsi_attribute_type_id
          INTO v_nsi_id, v_nsi_type_id, v_nsi_attribute_type_id
          FROM nsi_attribute
         WHERE nsi_attribute_id = p_nsi_attribute_id;
    
        get_attribute_type(v_nsi_attribute_type_id, v_value_type, v_descr);
        
        UPDATE nsi_attribute
           SET begin_date = p_begin_date,
               end_date = p_end_date
         WHERE nsi_attribute_id = p_nsi_attribute_id;
         
        v_log_descr := '[' || get_nsi_descr(v_nsi_id, v_nsi_type_id) || '] ' ||
                       ' : ' || v_descr || 
                       '  : ' || p_begin_date || ' - ' || p_end_date;
        log_oper(v_nsi_id, v_nsi_type_id, NSI_LOG_OPERNUM_ATTR_UPDATE, v_log_descr);
    END;

    /*   .
    *  @param p_nsi_attribute_id nsi_person.nsi_attribute_id%TYPE - id  nsi_attribute
    */
    PROCEDURE nsi_attribute_delete (p_nsi_attribute_id nsi_attribute.nsi_attribute_id%TYPE)
    AS
        v_nsi_id        nsi.nsi_id%TYPE;
        v_nsi_type_id   nsi.nsi_type_id%TYPE;
        v_log_descr     nsi_log.descr%TYPE;
        v_value_type    nsi_attribute_type.value_type%TYPE;
        v_descr         nsi_attribute_type.descr%TYPE;
        v_nsi_attribute_type_id nsi_attribute.nsi_attribute_type_id%TYPE;
    BEGIN
        SELECT nsi_id, nsi_type_id, nsi_attribute_type_id
          INTO v_nsi_id, v_nsi_type_id, v_nsi_attribute_type_id
          FROM nsi_attribute
         WHERE nsi_attribute_id = p_nsi_attribute_id;
    
        get_attribute_type(v_nsi_attribute_type_id, v_value_type, v_descr);
        
        DELETE FROM nsi_attribute
        WHERE nsi_attribute_id = p_nsi_attribute_id;
         
        v_log_descr := '[' || get_nsi_descr(v_nsi_id, v_nsi_type_id) || '] ' ||
                       ' : ' || v_descr;
        log_oper(v_nsi_id, v_nsi_type_id, NSI_LOG_OPERNUM_ATTR_DELETE, v_log_descr);
    END;

Now assign the appropriate attributes.

begin
    pkg_nsi.nsi_attribute_insert(1, 225, 6, '', null, null, sysdate, null);
    pkg_nsi.nsi_attribute_insert(2, 225, 6, '', null, null, sysdate, null);
    pkg_nsi.nsi_attribute_insert(3, 225, 6, '', null, null, sysdate, null);
end;

--      ,      ,  
--------------------------------------------------------------------------------------------
"NSI_ATTRIBUTE_ID"	"NSI_ATTRIBUTE_TYPE_ID"	"NSI_ID"	"NSI_TYPE_ID"	"VALUE_1"	"VALUE_2_3"	"VALUE_4"	"BEGIN_DATE"	"END_DATE"
230	1	225	6	""			11.03.20	
232	2	225	6	""			11.03.20	
234	3	225	6	""			11.03.20	
--------------------------------------------------------------------------------------------

begin
    pkg_nsi.nsi_attribute_value(230, '', null, null);
end;
--------------------------------------------------------------------------------------------
"NSI_ATTRIBUTE_ID"	"NSI_ATTRIBUTE_TYPE_ID"	"NSI_ID"	"NSI_TYPE_ID"	"VALUE_1"	"VALUE_2_3"	"VALUE_4"	"BEGIN_DATE"	"END_DATE"
230	1	225	6	""			11.03.20
232	2	225	6	""			11.03.20	
234	3	225	6	""			11.03.20	
--------------------------------------------------------------------------------------------

--       
begin
    pkg_nsi.nsi_attribute_period(230, sysdate-1, null);
    pkg_nsi.nsi_attribute_period(232, sysdate-1, null);
    pkg_nsi.nsi_attribute_period(234, sysdate-1, null);
end;
--------------------------------------------------------------------------------------------
"NSI_ATTRIBUTE_ID"	"NSI_ATTRIBUTE_TYPE_ID"	"NSI_ID"	"NSI_TYPE_ID"	"VALUE_1"	"VALUE_2_3"	"VALUE_4"	"BEGIN_DATE"	"END_DATE"
230	1	225	6	""			10.03.20	
232	2	225	6	""			10.03.20	
234	3	225	6	""			10.03.20	
--------------------------------------------------------------------------------------------

Thus, we will defeat the third problem .

In addition to the reference tables in the NSI system, the relationship between them is also important. So, for example, large organizations include various units, branches, departments, etc., which can be built into a tree structure. To begin with, we’ll create several more organizations in our system that will be subordinate to the existing β€œHorns and Hooves”.

INSERT INTO nsi_organization (name, full_name, inn)
VALUES ('   ', '   ', '1111111111');
INSERT INTO nsi_organization (name, full_name, inn)
VALUES ('   ', '   ', '2222222222');
INSERT INTO nsi_organization (name, full_name, inn)
VALUES ('   ', '   ', '3333333333');

----------------------------------------------------------------------------
281	1	   	13.03.20	13.03.20	13.03.20
283	1	   	13.03.20	13.03.20	13.03.20
285	1	   	13.03.20	13.03.20	13.03.20
1	1	 "  "	11.03.20	13.03.20	12.03.20
----------------------------------------------------------------------------

Now it is necessary to show in what relation these organizations are among themselves. To do this, you need a table with a tree structure and an indication of the period of action, because everything is subject to a change in time and you need to take this into account.

CREATE TABLE nsi_structure (
    nsi_structure_id    NUMBER(10) NOT NULL,
    nsi_parent_structure_id NUMBER(10),
    nsi_id              NUMBER(10) NOT NULL,
    nsi_type_id         NUMBER(10) NOT NULL,
    ordnum              NUMBER,
    begin_date          DATE NOT NULL,
    end_date            DATE,
    CONSTRAINT nsi_structure_pk PRIMARY KEY (nsi_structure_id),
    CONSTRAINT nsi_parent_struct_fk FOREIGN KEY (nsi_parent_structure_id) REFERENCES nsi_structure (nsi_structure_id),
    CONSTRAINT nsi_struct_nsi_fk FOREIGN KEY (nsi_id, nsi_type_id) REFERENCES nsi (nsi_id, nsi_type_id)
);

COMMENT ON TABLE nsi_structure IS '.   ';
COMMENT ON COLUMN nsi_structure.nsi_structure_id IS '';
COMMENT ON COLUMN nsi_structure.nsi_parent_structure_id IS ' ';
COMMENT ON COLUMN nsi_structure.nsi_id IS '';
COMMENT ON COLUMN nsi_structure.nsi_type_id IS ' ';
COMMENT ON COLUMN nsi_structure.ordnum IS ' ';
COMMENT ON COLUMN nsi_structure.begin_date IS '  ';
COMMENT ON COLUMN nsi_structure.end_date IS '  ';

Of course, you should expand the capabilities of the pkg_nsi package so that you can customize the structure for various tables.

    /*   .
    *  @param p_nsi_parent_structure_id nsi_structure.nsi_parent_structure_id%TYPE -  
    *  @param p_nsi_id nsi_structure.nsi_id%TYPE - 
    *  @param p_nsi_type_id nsi_structure.nsi_type_id%TYPE -  
    *  @param p_ordnum nsi_structure.ordnum%TYPE -  
    *  @param p_begin_date nsi_structure.begin_date%TYPE -    
    *  @param p_end_date nsi_structure.end_date%TYPE -    
    */
    FUNCTION nsi_structure_insert (
        p_nsi_parent_structure_id   IN nsi_structure.nsi_parent_structure_id%TYPE,
        p_nsi_id                    IN nsi_structure.nsi_id%TYPE,
        p_nsi_type_id               IN nsi_structure.nsi_type_id%TYPE,
        p_ordnum                    IN nsi_structure.ordnum%TYPE,
        p_begin_date                IN nsi_structure.begin_date%TYPE, 
        p_end_date                  IN nsi_structure.end_date%TYPE)
    RETURN nsi_structure.nsi_structure_id%TYPE
    AS
        v_id        NUMBER;
        v_log_descr nsi_log.descr%TYPE;
        v_type_id 	nsi.nsi_type_id%TYPE;
    BEGIN
        v_id := get_nsi_id;
        v_type_id := get_type_id('nsi_structure');

        INSERT INTO nsi_structure (
            nsi_structure_id, nsi_parent_structure_id,
            nsi_id, nsi_type_id, ordnum, begin_date, end_date)
        VALUES (
            v_id, p_nsi_parent_structure_id, 
            p_nsi_id, p_nsi_type_id, p_ordnum, Trunc(p_begin_date), Trunc(p_end_date));
         
        v_log_descr := '[' || get_nsi_descr(p_nsi_id, p_nsi_type_id) || '] ';
        v_log_descr := v_log_descr || ' ' || p_begin_date || ' - ' || p_end_date;
        log_oper (v_id, v_type_id, NSI_LOG_OPERNUM_INSERT, v_log_descr);
        
        RETURN v_id;
    END nsi_structure_insert;


    /*     .
    *  @param p_nsi_structure_id nsi_structure.nsi_structure_id%TYPE -  nsi_structure
    *  @param p_ordnum nsi_structure.ordnum%TYPE -  
    */
    PROCEDURE nsi_structure_ordnum (
        p_nsi_structure_id  IN nsi_structure.nsi_structure_id%TYPE,
        p_ordnum            IN nsi_structure.ordnum%TYPE)
    AS
        v_nsi_id 		    nsi_structure.nsi_id%TYPE;
        v_nsi_type_id 	    nsi_structure.nsi_type_id%TYPE;
        v_type_id 	        nsi.nsi_type_id%TYPE;
        v_log_descr         nsi_log.descr%TYPE;
    BEGIN
        v_type_id := get_type_id('nsi_structure');
        
        SELECT nsi_id, nsi_type_id
          INTO v_nsi_id, v_nsi_type_id
          FROM nsi_structure
         WHERE nsi_structure_id = p_nsi_structure_id;

        UPDATE nsi_structure
           SET ordnum = p_ordnum 
         WHERE nsi_structure_id = p_nsi_structure_id;
         
        v_log_descr := '[' || get_nsi_descr(v_nsi_id, v_nsi_type_id) || '] ';
        v_log_descr := v_log_descr || ' ' || p_ordnum;
        log_oper (p_nsi_structure_id, v_type_id, NSI_LOG_OPERNUM_UPDATE, v_log_descr);
    END;


    /*     .
    *  @param p_nsi_structure_id nsi_structure.nsi_structure_id%TYPE -  nsi_structure
    *  @param p_begin_date nsi_structure.begin_date%TYPE -   
    *  @param p_end_date nsi_structure.end_date%TYPE -   
    */
    PROCEDURE nsi_structure_period (
        p_nsi_structure_id  IN nsi_structure.nsi_structure_id%TYPE,
        p_begin_date        IN nsi_structure.begin_date%TYPE, 
        p_end_date          IN nsi_structure.end_date%TYPE)
    AS
        v_nsi_id 		    nsi_structure.nsi_id%TYPE;
        v_nsi_type_id 	    nsi_structure.nsi_type_id%TYPE;
        v_type_id 	        nsi.nsi_type_id%TYPE;
        v_log_descr         nsi_log.descr%TYPE;
    BEGIN
        v_type_id := get_type_id('nsi_structure');
        
        SELECT nsi_id, nsi_type_id
          INTO v_nsi_id, v_nsi_type_id
          FROM nsi_structure
         WHERE nsi_structure_id = p_nsi_structure_id;

        UPDATE nsi_structure
           SET begin_date = Trunc(p_begin_date),
               end_date = Trunc(p_end_date) 
         WHERE nsi_structure_id = p_nsi_structure_id;
         
        v_log_descr := '[' || get_nsi_descr(v_nsi_id, v_nsi_type_id) || '] ';
        v_log_descr := v_log_descr || ' ' || p_begin_date || ' - ' || p_end_date;
        log_oper (p_nsi_structure_id, v_type_id, NSI_LOG_OPERNUM_UPDATE, v_log_descr);
    END;


    /*   .
    *  @param p_nsi_structure_id nsi_structure.nsi_structure_id%TYPE -  nsi_structure
    */
    PROCEDURE nsi_structure_delete (p_nsi_structure_id IN nsi_structure.nsi_structure_id%TYPE)
    AS
        v_type_id 	nsi.nsi_type_id%TYPE;
        v_log_descr nsi_log.descr%TYPE;
    BEGIN
        v_type_id := pkg_nsi.get_type_id('nsi_structure');
        
        FOR rec IN (
            SELECT nsi_structure_id, nsi_parent_structure_id,
                    nsi_id, nsi_type_id, ordnum, begin_date, end_date
            FROM nsi_structure
            START WITH nsi_structure_id = p_nsi_structure_id
            CONNECT BY PRIOR nsi_structure_id = nsi_parent_structure_id
        )
        LOOP
            v_log_descr := '[' || pkg_nsi.get_nsi_descr(rec.nsi_id, rec.nsi_type_id) || '] ';
            v_log_descr := v_log_descr || ' ' || rec.begin_date || ' - ' || rec.end_date;
            pkg_nsi.log_oper (rec.nsi_structure_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_DELETE, v_log_descr);
        END LOOP;
        
        DELETE FROM nsi_structure
        WHERE nsi_structure_id = p_nsi_structure_id;
    END;

After the advent of such an instrument, one can safely build relations between organizations.

declare
    id number;
    root_id number;
begin
    root_id := pkg_nsi.nsi_structure_insert(null, 1, 1, null, to_date('13.02.20', 'dd.mm.yy'), null);
    id := pkg_nsi.nsi_structure_insert(root_id, 281, 1, null, to_date('13.02.20', 'dd.mm.yy'), to_date('15.02.20', 'dd.mm.yy'));
    id := pkg_nsi.nsi_structure_insert(root_id, 283, 1, null, to_date('13.02.20', 'dd.mm.yy'), null);
    id := pkg_nsi.nsi_structure_insert(id, 285, 1, null, to_date('13.02.20', 'dd.mm.yy'), null);
end;

SELECT *
FROM nsi_structure
START WITH (nsi_parent_structure_id IS NULL)
CONNECT BY (nsi_parent_structure_id = PRIOR nsi_structure_id);
-----------------------------------------------------------------------------------
316		1	1		13.02.20	
318	316	281	1		13.02.20	15.02.20
320	316	283	1		13.02.20	
322	320	285	1		13.02.20	
-----------------------------------------------------------------------------------

--      
begin
    pkg_nsi.nsi_structure_ordnum(320, 1);
    pkg_nsi.nsi_structure_ordnum(318, 2);
end;

SELECT *
FROM nsi_structure
START WITH (nsi_parent_structure_id IS NULL)
CONNECT BY (nsi_parent_structure_id = PRIOR nsi_structure_id)
ORDER SIBLINGS BY ordnum;
-----------------------------------------------------------------------------------
316		1	1		13.02.20	
320	316	283	1	1	13.02.20	
322	320	285	1		13.02.20	
318	316	281	1	2	13.02.20	15.02.20
-----------------------------------------------------------------------------------

--    
begin
    pkg_nsi.nsi_structure_period(320, to_date('14.02.20', 'dd.mm.yy'), to_date('14.02.20', 'dd.mm.yy'));
end;

SELECT *
FROM nsi_structure
START WITH (nsi_parent_structure_id IS NULL)
CONNECT BY (nsi_parent_structure_id = PRIOR nsi_structure_id)
ORDER SIBLINGS BY ordnum;
-----------------------------------------------------------------------------------
316		1	1		13.02.20	
320	316	283	1	1	14.02.20	14.02.20
322	320	285	1		13.02.20	
318	316	281	1	2	13.02.20	15.02.20
-----------------------------------------------------------------------------------

Since the directories are separated from the structure, each time it turns out to turn to organizations taking into account their relationships to be cumbersome, so we simplify our life a little.

CREATE OR REPLACE VIEW V_NSI_ORGANIZATION AS
SELECT 
    s.nsi_structure_id, s.nsi_parent_structure_id,
    s.ordnum, s.begin_date, s.end_date,
    s.nsi_id, s.nsi_type_id, o.name, o.full_name, o.inn
FROM nsi_structure s INNER JOIN nsi_organization o
    ON (s.nsi_id = o.nsi_id)
START WITH (nsi_parent_structure_id IS NULL)
CONNECT BY (nsi_parent_structure_id = PRIOR nsi_structure_id)
ORDER SIBLINGS BY ordnum;

SELECT * FROM v_nsi_organization;
-----------------------------------------------------------------------------------
316			13.02.20		1	1	 "  "	  "  "	99887766
320	316	1	14.02.20	14.02.20	283	1	   	   	2222222222
322	320		13.02.20		285	1	   	   	3333333333
318	316	2	13.02.20	15.02.20	281	1	   	   	1111111111
-----------------------------------------------------------------------------------

The fact that we are building a tree is wonderful, but all the nodes of this tree belong to one entity, and our task is to realize the construction of a relationship between different entities. This is also not a problem, because the structure is not tied to any specific reference book, but works as a whole on the entire NSI system. For example, we will construct a classifier for posts of the state civil service and a classifier for posts of the municipality.

CREATE TABLE nsi_classifier (
    nsi_id      NUMBER(10) NOT NULL,
    code        VARCHAR2(10),
    name        VARCHAR2(200) NOT NULL,
    CONSTRAINT nsi_classifier_pk PRIMARY KEY (nsi_id),
    CONSTRAINT nsi_classifier_nsi_fk FOREIGN KEY (nsi_id) REFERENCES nsi (nsi_id)
);

COMMENT ON TABLE nsi_classifier IS '. ';
COMMENT ON COLUMN nsi_classifier.nsi_id IS '';
COMMENT ON COLUMN nsi_classifier.code IS '';
COMMENT ON COLUMN nsi_classifier.name IS '';


CREATE OR REPLACE TRIGGER nsi_classifier_trg_insert 
BEFORE INSERT ON nsi_classifier FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_classifier');
    :NEW.nsi_id := pkg_nsi.get_nsi_id();

    INSERT INTO nsi (nsi_id, nsi_type_id, descr, create_date, modif_date, begin_date)
    VALUES (:NEW.nsi_id, v_type_id, :NEW.name, Trunc(Sysdate), Trunc(Sysdate), Trunc(Sysdate));
    
    v_log_query := 'SELECT ''' || :NEW.name || ''' AS name, ''' || :NEW.code || ''' AS code FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_INSERT, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_classifier_trg_update 
BEFORE UPDATE ON nsi_classifier FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_classifier');

    UPDATE nsi
       SET modif_date = Trunc(Sysdate)
     WHERE nsi_id = :NEW.nsi_id
       AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :NEW.name || ''' AS name, ''' || :NEW.code || ''' AS code FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_UPDATE, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_classifier_trg_delete 
AFTER DELETE ON nsi_classifier FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_classifier');

    DELETE FROM nsi_history 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi_attribute 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :OLD.name || ''' AS name, ''' || :OLD.code || ''' AS code FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:OLD.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_DELETE, v_log_descr);
END;

CREATE TABLE nsi_post_group (
    nsi_id   NUMBER(10) NOT NULL,
    name     VARCHAR2(50) NOT NULL,
    CONSTRAINT nsi_post_group_pk PRIMARY KEY (nsi_id),
    CONSTRAINT nsi_post_group_nsi_fk FOREIGN KEY (nsi_id) REFERENCES nsi (nsi_id)
);

COMMENT ON TABLE nsi_post_group is '.  ';
COMMENT ON COLUMN nsi_post_group.nsi_id is '';
COMMENT ON COLUMN nsi_post_group.name is '';


CREATE OR REPLACE TRIGGER nsi_post_group_trg_insert 
BEFORE INSERT ON nsi_post_group FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post_group');
    :NEW.nsi_id := pkg_nsi.get_nsi_id();

    INSERT INTO nsi (nsi_id, nsi_type_id, descr, create_date, modif_date, begin_date)
    VALUES (:NEW.nsi_id, v_type_id, :NEW.name, Trunc(Sysdate), Trunc(Sysdate), Trunc(Sysdate));
    
    v_log_query := 'SELECT ''' || :NEW.name || ''' AS name FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_INSERT, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_post_group_trg_update 
BEFORE UPDATE ON nsi_post_group FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post_group');

    UPDATE nsi
       SET modif_date = Trunc(Sysdate)
     WHERE nsi_id = :NEW.nsi_id
       AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :NEW.name || ''' AS name FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_UPDATE, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_post_group_trg_delete 
AFTER DELETE ON nsi_post_group FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post_group');

    DELETE FROM nsi_history 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi_attribute 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :OLD.name || ''' AS name FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:OLD.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_DELETE, v_log_descr);
END;

CREATE TABLE nsi_post_category (
    nsi_id   NUMBER(10) NOT NULL,
    name     VARCHAR2(50) NOT NULL,
    CONSTRAINT nsi_post_category_pk PRIMARY KEY (nsi_id),
    CONSTRAINT nsi_post_category_nsi_fk FOREIGN KEY (nsi_id) REFERENCES nsi (nsi_id)
);

COMMENT ON TABLE nsi_post_category is '.  ';
COMMENT ON COLUMN nsi_post_category.nsi_id is '';
COMMENT ON COLUMN nsi_post_category.name is '';


CREATE OR REPLACE TRIGGER nsi_post_category_trg_insert 
BEFORE INSERT ON nsi_post_category FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post_category');
    :NEW.nsi_id := pkg_nsi.get_nsi_id();

    INSERT INTO nsi (nsi_id, nsi_type_id, descr, create_date, modif_date, begin_date)
    VALUES (:NEW.nsi_id, v_type_id, :NEW.name, Trunc(Sysdate), Trunc(Sysdate), Trunc(Sysdate));
    
    v_log_query := 'SELECT ''' || :NEW.name || ''' AS name FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_INSERT, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_post_category_trg_update 
BEFORE UPDATE ON nsi_post_category FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post_category');

    UPDATE nsi
       SET modif_date = Trunc(Sysdate)
     WHERE nsi_id = :NEW.nsi_id
       AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :NEW.name || ''' AS name FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_UPDATE, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_post_category_trg_delete 
AFTER DELETE ON nsi_post_category FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post_category');

    DELETE FROM nsi_history 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi_attribute 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :OLD.name || ''' AS name FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:OLD.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_DELETE, v_log_descr);
END;

CREATE TABLE nsi_post (
    nsi_id          NUMBER(10) NOT NULL,
    code_OKPDTR     VARCHAR2(10),
    name            VARCHAR2(50) NOT NULL,
    CONSTRAINT nsi_post_pk PRIMARY KEY (nsi_id),
    CONSTRAINT nsi_post_nsi_fk FOREIGN KEY (nsi_id) REFERENCES nsi (nsi_id)
);

COMMENT ON TABLE nsi_post IS '. ';
COMMENT ON COLUMN nsi_post.nsi_id IS '';
COMMENT ON COLUMN nsi_post.code_OKPDTR IS ' ';
COMMENT ON COLUMN nsi_post.name IS '';


CREATE OR REPLACE TRIGGER nsi_post_trg_insert 
BEFORE INSERT ON nsi_post FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post');
    :NEW.nsi_id := pkg_nsi.get_nsi_id();

    INSERT INTO nsi (nsi_id, nsi_type_id, descr, create_date, modif_date, begin_date)
    VALUES (:NEW.nsi_id, v_type_id, :NEW.name, Trunc(Sysdate), Trunc(Sysdate), Trunc(Sysdate));
    
    v_log_query := 'SELECT ''' || :OLD.name || ''' AS name, ''' || :OLD.code_OKPDTR || ''' AS code_OKPDTR FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_INSERT, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_post_trg_update 
BEFORE UPDATE ON nsi_post FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post');

    UPDATE nsi
       SET modif_date = Trunc(Sysdate)
     WHERE nsi_id = :NEW.nsi_id
       AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :OLD.name || ''' AS name, ''' || :OLD.code_OKPDTR || ''' AS code_OKPDTR FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:NEW.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_UPDATE, v_log_descr);
END;

CREATE OR REPLACE TRIGGER nsi_post_trg_delete 
AFTER DELETE ON nsi_post FOR EACH ROW
DECLARE
    v_type_id 	nsi.nsi_type_id%TYPE;
    v_log_descr nsi_log.descr%TYPE;
    v_log_query VARCHAR(4000);
BEGIN
    v_type_id := pkg_nsi.get_type_id('nsi_post');

    DELETE FROM nsi_history 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi_attribute 
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;

    DELETE FROM nsi
    WHERE nsi_id = :OLD.nsi_id
      AND nsi_type_id = v_type_id;
    
    v_log_query := 'SELECT ''' || :OLD.name || ''' AS name, ''' || :OLD.code_OKPDTR || ''' AS code_OKPDTR FROM DUAL';
    v_log_descr := pkg_nsi.get_json(v_log_query);
    pkg_nsi.log_oper (:OLD.nsi_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_DELETE, v_log_descr);
END;

It remains only to fill out and collect the necessary classifiers.
INSERT INTO nsi_classifier (name) VALUES ('  ');
INSERT INTO nsi_classifier (name) VALUES ('  ');

INSERT INTO nsi_post_group (name) VALUES ('');
INSERT INTO nsi_post_group (name) VALUES ('');
INSERT INTO nsi_post_group (name) VALUES ('');
INSERT INTO nsi_post_group (name) VALUES ('');
INSERT INTO nsi_post_group (name) VALUES ('');

INSERT INTO nsi_post_category (name) VALUES ('');
INSERT INTO nsi_post_category (name) VALUES (' ()');
INSERT INTO nsi_post_category (name) VALUES ('');
INSERT INTO nsi_post_category (name) VALUES (' ');

INSERT INTO nsi_post (code_OKPDTR, name)
VALUES ('24742', ' ');
INSERT INTO nsi_post (code_OKPDTR, name)
VALUES ('26480', '');
INSERT INTO nsi_post (code_OKPDTR, name)
VALUES ('23509', '');
INSERT INTO nsi_post (code_OKPDTR, name)
VALUES ('20419', ' ');
INSERT INTO nsi_post (code_OKPDTR, name)
VALUES ('26541', '');
INSERT INTO nsi_post (code_OKPDTR, name)
VALUES ('26544', ' 2 ');

commit;

declare
    post_id number;
    classif_id number;
    categ_id number;
    group_id number;
begin
    --   
    classif_id := pkg_nsi.nsi_structure_insert(null, 331, 5, null, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    categ_id := pkg_nsi.nsi_structure_insert(classif_id, 347, 4, 1, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 355, 3, 1, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 357, 3, 2, to_date('13.02.20', 'dd.mm.yy'), null);
    --  
    post_id := pkg_nsi.nsi_structure_insert(group_id, 335, 2, 1, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 359, 3, 3, to_date('13.02.20', 'dd.mm.yy'), null);
    --  ()
    categ_id := pkg_nsi.nsi_structure_insert(classif_id, 349, 4, 2, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 355, 3, 1, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 357, 3, 2, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 359, 3, 3, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    post_id := pkg_nsi.nsi_structure_insert(group_id, 337, 2, 1, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    categ_id := pkg_nsi.nsi_structure_insert(classif_id, 351, 4, 3, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 355, 3, 1, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 357, 3, 2, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 359, 3, 3, to_date('13.02.20', 'dd.mm.yy'), null);
    --  
    post_id := pkg_nsi.nsi_structure_insert(group_id, 341, 2, 1, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 361, 3, 4, to_date('13.02.20', 'dd.mm.yy'), null);
    --  
    categ_id := pkg_nsi.nsi_structure_insert(classif_id, 353, 4, 4, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 357, 3, 1, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 359, 3, 2, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 361, 3, 3, to_date('13.02.20', 'dd.mm.yy'), null);
    -- 
    group_id := pkg_nsi.nsi_structure_insert(categ_id, 363, 3, 4, to_date('13.02.20', 'dd.mm.yy'), null);
    --  2 
    post_id := pkg_nsi.nsi_structure_insert(group_id, 345, 2, 1, to_date('13.02.20', 'dd.mm.yy'), null);

commit;
end;


SELECT *
FROM nsi_structure s
START WITH (nsi_id = 331)
CONNECT BY (nsi_parent_structure_id = PRIOR nsi_structure_id)
ORDER SIBLINGS BY ordnum;
----------------------------------------------------------------------------------
"NSI_STRUCTURE_ID"	"NSI_PARENT_STRUCTURE_ID"	"NSI_ID"	"NSI_TYPE_ID"	"ORDNUM"	"BEGIN_DATE"	"END_DATE"
385		331	5		13.02.20	
387	385	347	4	1	13.02.20	
389	387	355	3	1	13.02.20	
391	387	357	3	2	13.02.20	
393	391	335	2	1	13.02.20	
395	387	359	3	3	13.02.20	
397	385	349	4	2	13.02.20	
399	397	355	3	1	13.02.20	
401	397	357	3	2	13.02.20	
403	397	359	3	3	13.02.20	
405	403	337	2	1	13.02.20	
407	385	351	4	3	13.02.20	
409	407	355	3	1	13.02.20	
411	407	357	3	2	13.02.20	
413	407	359	3	3	13.02.20	
415	413	341	2	1	13.02.20	
417	407	361	3	4	13.02.20	
419	385	353	4	4	13.02.20	
421	419	357	3	1	13.02.20	
423	419	359	3	2	13.02.20	
425	419	361	3	3	13.02.20	
427	419	363	3	4	13.02.20	
429	427	345	2	1	13.02.20	
----------------------------------------------------------------------------------

Oh, how readable it is!

CREATE OR REPLACE VIEW V_NSI_CLASSIFIRE_GGS AS
SELECT 
    s.nsi_structure_id, s.nsi_parent_structure_id,
    s.ordnum, s.begin_date, s.end_date,
    n.nsi_id, n.nsi_type_id, n.descr
FROM nsi_structure s INNER JOIN nsi n
    ON (s.nsi_id = n.nsi_id)
START WITH (s.nsi_id = 331)
CONNECT BY (nsi_parent_structure_id = PRIOR nsi_structure_id)
ORDER SIBLINGS BY ordnum;


SELECT * FROM V_NSI_CLASSIFIRE_GGS ;
----------------------------------------------------------------------------------
"NSI_STRUCTURE_ID"	"NSI_PARENT_STRUCTURE_ID"	"NSI_ID"	"NSI_TYPE_ID"	"ORDNUM"	"BEGIN_DATE"	"END_DATE"
385			13.02.20		331	5	  
387	385	1	13.02.20		347	4	
389	387	1	13.02.20		355	3	
391	387	2	13.02.20		357	3	
393	391	1	13.02.20		335	2	 
395	387	3	13.02.20		359	3	
397	385	2	13.02.20		349	4	 ()
399	397	1	13.02.20		355	3	
401	397	2	13.02.20		357	3	
403	397	3	13.02.20		359	3	
405	403	1	13.02.20		337	2	
407	385	3	13.02.20		351	4	
409	407	1	13.02.20		355	3	
411	407	2	13.02.20		357	3	
413	407	3	13.02.20		359	3	
415	413	1	13.02.20		341	2	 
417	407	4	13.02.20		361	3	
419	385	4	13.02.20		353	4	 
421	419	1	13.02.20		357	3	
423	419	2	13.02.20		359	3	
425	419	3	13.02.20		361	3	
427	419	4	13.02.20		363	3	
429	427	1	13.02.20		345	2	 2 
----------------------------------------------------------------------------------

It should not be forgotten that in addition to the inclusion relation (including the tree one), there is an intersection relation, i.e., cross-tables. This adds an additional condition for checking time intersection.

CREATE TABLE nsi_cross (
    nsi_cross_id        NUMBER(10) NOT NULL,
    nsi_main_id         NUMBER(10) NOT NULL,
    nsi_main_type_id    NUMBER(10) NOT NULL,
    nsi_detail_id       NUMBER(10) NOT NULL,
    nsi_detail_type_id  NUMBER(10) NOT NULL,
    begin_date          DATE NOT NULL,
    end_date            DATE,
    CONSTRAINT nsi_cross_pk PRIMARY KEY (nsi_cross_id),
    CONSTRAINT nsi_cross_main_nsi_fk FOREIGN KEY (nsi_main_type_id, nsi_main_id) REFERENCES nsi (nsi_type_id, nsi_id),
    CONSTRAINT nsi_cross_detail_nsi_fk FOREIGN KEY (nsi_detail_type_id, nsi_detail_id) REFERENCES nsi (nsi_type_id, nsi_id)
);

COMMENT ON TABLE nsi_cross IS '. - ';
COMMENT ON COLUMN nsi_cross.nsi_cross_id IS '';
COMMENT ON COLUMN nsi_cross.nsi_main_id IS '  ';
COMMENT ON COLUMN nsi_cross.nsi_main_type_id IS '   ';
COMMENT ON COLUMN nsi_cross.nsi_detail_id IS '  ';
COMMENT ON COLUMN nsi_cross.nsi_detail_type_id IS '   ';
COMMENT ON COLUMN nsi_cross.begin_date IS '  ';
COMMENT ON COLUMN nsi_cross.end_date IS '  ';

    /*        -.
    *  @param p_nsi_main_id nsi_cross.nsi_main_id%TYPE -   
    *  @param p_nsi_main_type_id nsi_cross.nsi_main_type_id%TYPE -    
    *  @param p_nsi_detail_id nsi_cross.nsi_detail_id%TYPE -   
    *  @param p_nsi_detail_type_id nsi_cross.nsi_detail_type_id%TYPE -    
    *  @param p_begin_date DATE -    
    *  @param p_end_date DATE -    
    */
    PROCEDURE nsi_cross_check_period (
        p_nsi_cross_id          IN nsi_cross.nsi_cross_id%TYPE,
        p_begin_date            IN nsi_cross.begin_date%TYPE, 
        p_end_date              IN nsi_cross.end_date%TYPE)
    AS
        v_cnt NUMBER;
        v_nsi_main_id           nsi_cross.nsi_main_id%TYPE;
        v_nsi_main_type_id      nsi_cross.nsi_main_type_id%TYPE;
        v_nsi_detail_id         nsi_cross.nsi_detail_id%TYPE;
        v_nsi_detail_type_id    nsi_cross.nsi_detail_type_id%TYPE;
    BEGIN
        IF (p_end_date IS NOT NULL) AND (Trunc(p_begin_date) > Trunc(p_end_date)) THEN
            RAISE_APPLICATION_ERROR (NSI_ERROR_CODE, 
                '[nsi_cross_check_period]         ' || Trunc(p_begin_date) || ' - ' || Trunc(p_end_date)); 
        END IF;
        
        SELECT MIN(nsi_main_id), MIN(nsi_main_type_id),
               MIN(nsi_detail_id), MIN(nsi_detail_type_id) 
          INTO v_nsi_main_id, v_nsi_main_type_id,
               v_nsi_detail_id, v_nsi_detail_type_id 
          FROM nsi_cross
         WHERE nsi_cross_id = p_nsi_cross_id;
         
        v_cnt := 0;
        
        IF (v_nsi_main_id IS NOT NULL) THEN
        
            IF (p_end_date IS NOT NULL) THEN
                SELECT COUNT(*)
                  INTO v_cnt
                  FROM nsi_cross
                 WHERE nsi_main_id = v_nsi_main_id
                   AND nsi_main_type_id = v_nsi_main_type_id
                   AND nsi_detail_id = v_nsi_detail_id
                   AND nsi_detail_type_id = v_nsi_detail_type_id
                   AND nsi_cross_id <> p_nsi_cross_id
                   AND begin_date <= Trunc(p_end_date)
                   AND ((end_date IS NULL) OR (end_date >= Trunc(p_end_date)));
            ELSE
                SELECT COUNT(*)
                  INTO v_cnt
                  FROM nsi_cross
                 WHERE nsi_main_id = v_nsi_main_id
                   AND nsi_main_type_id = v_nsi_main_type_id
                   AND nsi_detail_id = v_nsi_detail_id
                   AND nsi_detail_type_id = v_nsi_detail_type_id
                   AND nsi_cross_id <> p_nsi_cross_id
                   AND ((
                        (end_date IS NOT NULL) AND (end_date >= Trunc(p_begin_date))
                        ) OR (end_date IS NULL)
                        );
            END IF;
        END IF;

        IF (v_cnt > 0) THEN
            RAISE_APPLICATION_ERROR (NSI_ERROR_CODE, 
                '[nsi_cross_check_period]     ' || p_begin_date || ' - ' || p_end_date);    
        END IF;
    END;


    /*   .
    *  @param p_nsi_main_id nsi_cross.nsi_main_id%TYPE -   
    *  @param p_nsi_main_type_id nsi_cross.nsi_main_type_id%TYPE -    
    *  @param p_nsi_detail_id nsi_cross.nsi_detail_id%TYPE -   
    *  @param p_nsi_detail_type_id nsi_cross.nsi_detail_type_id%TYPE -    
    *  @param p_begin_date DATE -    
    *  @param p_end_date DATE -    
    */
    PROCEDURE nsi_cross_insert (
        p_nsi_main_id           IN nsi_cross.nsi_main_id%TYPE,
        p_nsi_main_type_id      IN nsi_cross.nsi_main_type_id%TYPE,
        p_nsi_detail_id         IN nsi_cross.nsi_detail_id%TYPE,
        p_nsi_detail_type_id    IN nsi_cross.nsi_detail_type_id%TYPE,
        p_begin_date            IN nsi_cross.begin_date%TYPE, 
        p_end_date              IN nsi_cross.end_date%TYPE)
    AS
        v_id        NUMBER;
        v_log_descr nsi_log.descr%TYPE;
        v_type_id 	nsi.nsi_type_id%TYPE;
    BEGIN
        v_id := get_nsi_id;
        v_type_id := get_type_id('nsi_cross');

        INSERT INTO nsi_cross (
            nsi_cross_id, nsi_main_id, nsi_main_type_id,
            nsi_detail_id, nsi_detail_type_id, 
            begin_date, end_date)
        VALUES (
            v_id, p_nsi_main_id, p_nsi_main_type_id,
            p_nsi_detail_id, p_nsi_detail_type_id, 
            Trunc(p_begin_date), Trunc(p_end_date));

        nsi_cross_check_period (v_id, p_begin_date, p_end_date);

        v_log_descr := '[' || get_nsi_descr(p_nsi_main_id, p_nsi_main_type_id) || ' <=> ' || get_nsi_descr(p_nsi_detail_id, p_nsi_detail_type_id) || '] ';
        v_log_descr := v_log_descr || ' ' || p_begin_date || ' - ' || p_end_date;
        log_oper (v_id, v_type_id, NSI_LOG_OPERNUM_INSERT, v_log_descr);
    END nsi_cross_insert;


    /*     .
    *  @param p_nsi_cross_id nsi_cross.nsi_cross_id%TYPE -  nsi_cross
    *  @param p_begin_date nsi_cross.begin_date%TYPE -   
    *  @param p_end_date nsi_cross.end_date%TYPE -   
    */
    PROCEDURE nsi_cross_period (
        p_nsi_cross_id  IN nsi_cross.nsi_cross_id%TYPE,
        p_begin_date    IN nsi_cross.begin_date%TYPE, 
        p_end_date      IN nsi_cross.end_date%TYPE)
    AS
        v_main_id 		    nsi_cross.nsi_main_id%TYPE;
        v_main_type_id 	    nsi_cross.nsi_main_type_id%TYPE;
        v_detail_id 		nsi_cross.nsi_detail_id%TYPE;
        v_detail_type_id 	nsi_cross.nsi_detail_type_id%TYPE;
        v_type_id 	        nsi.nsi_type_id%TYPE;
        v_log_descr         nsi_log.descr%TYPE;
    BEGIN
        v_type_id := get_type_id('nsi_cross');
        
        SELECT nsi_main_id, nsi_main_type_id,
               nsi_detail_id, nsi_detail_type_id
          INTO v_main_id, v_main_type_id,
               v_detail_id, v_detail_type_id
          FROM nsi_cross
         WHERE nsi_cross_id = p_nsi_cross_id;

        nsi_cross_check_period (p_nsi_cross_id, p_begin_date, p_end_date);

        UPDATE nsi_cross
           SET begin_date = Trunc(p_begin_date),
               end_date = Trunc(p_end_date) 
         WHERE nsi_cross_id = p_nsi_cross_id;
         
        v_log_descr := '[' || get_nsi_descr(v_main_id, v_main_type_id) || ' <=> ' || get_nsi_descr(v_detail_id, v_detail_type_id) || '] ';
        v_log_descr := v_log_descr || ' ' || p_begin_date || ' - ' || p_end_date;
        log_oper (p_nsi_cross_id, v_type_id, NSI_LOG_OPERNUM_UPDATE, v_log_descr);
    END;


    /*   .
    *  @param p_nsi_cross_id nsi_cross.nsi_cross_id%TYPE -  nsi_cross
    */
    PROCEDURE nsi_cross_delete (p_nsi_cross_id IN nsi_cross.nsi_cross_id%TYPE)
    AS
        v_type_id 	nsi.nsi_type_id%TYPE;
        v_log_descr nsi_log.descr%TYPE;
    BEGIN
        v_type_id := pkg_nsi.get_type_id('nsi_cross');
        
        FOR rec IN (
            SELECT nsi_cross_id, nsi_main_id, nsi_main_type_id,
                    nsi_detail_id, nsi_detail_type_id,
                    begin_date, end_date
            FROM nsi_cross
            WHERE nsi_cross_id = p_nsi_cross_id
        )
        LOOP
            v_log_descr := '[' || pkg_nsi.get_nsi_descr(rec.nsi_main_id, rec.nsi_main_type_id) || ' <=> ' || pkg_nsi.get_nsi_descr(rec.nsi_detail_id, rec.nsi_detail_type_id) || '] ';
            v_log_descr := v_log_descr || ' ' || rec.begin_date || ' - ' || rec.end_date;
            pkg_nsi.log_oper (rec.nsi_cross_id, v_type_id, pkg_nsi.NSI_LOG_OPERNUM_DELETE, v_log_descr);
        END LOOP;
        
        DELETE FROM nsi_cross
        WHERE nsi_cross_id = p_nsi_cross_id;
    END;

That's it, now we can say with confidence that we have closed the first problem .
Of course, you can try to attach a lot of things to this system, but I think that I completed the task at the beginning of the article, and the rest can already be considered in the discussion process.

The material was prepared on Oracle version 18c, although native support for the json format is already present in version 12. Here is a link to the script archive.

All Articles