163 lines
8.9 KiB
SQL
163 lines
8.9 KiB
SQL
-- apply changes
|
|
create table audit_log (
|
|
sys_pk bigint generated by default as identity not null,
|
|
deleted_on timestamp,
|
|
current_approval_level integer default 0 not null,
|
|
required_approval_levels integer default 0 not null,
|
|
deleted boolean default false not null,
|
|
version integer default 1 not null,
|
|
created_at timestamp default 'now()' not null,
|
|
modified_at timestamp default 'now()' not null,
|
|
deleted_by varchar(255),
|
|
approval_status varchar(8) default 'APPROVED' not null,
|
|
tags varchar[] default '{}' not null,
|
|
comments jsonb default '[]' not null,
|
|
tenant_id varchar(255) not null,
|
|
audit_type varchar(7) not null,
|
|
entity varchar(255) not null,
|
|
unique_identifier varchar(255) not null,
|
|
data jsonb not null,
|
|
changes jsonb not null,
|
|
created_by varchar(255) not null,
|
|
modified_by varchar(255) not null,
|
|
constraint ck_audit_log_approval_status check ( approval_status in ('PENDING','APPROVED','REJECTED')),
|
|
constraint ck_audit_log_audit_type check ( audit_type in ('CREATE','UPDATE','DELETE','VIEW','APPROVE','REJECT')),
|
|
constraint pk_audit_log primary key (sys_pk)
|
|
);
|
|
|
|
create table data_model (
|
|
sys_pk bigint generated by default as identity not null,
|
|
deleted_on timestamp,
|
|
current_approval_level integer default 0 not null,
|
|
required_approval_levels integer default 0 not null,
|
|
deleted boolean default false not null,
|
|
version integer default 1 not null,
|
|
created_at timestamp default 'now()' not null,
|
|
modified_at timestamp default 'now()' not null,
|
|
deleted_by varchar(255),
|
|
approval_status varchar(8) default 'APPROVED' not null,
|
|
tags varchar[] default '{}' not null,
|
|
comments jsonb default '[]' not null,
|
|
tenant_id varchar(255) not null,
|
|
unique_identifier varchar(255) not null,
|
|
entity_name varchar(255) not null,
|
|
data jsonb not null,
|
|
created_by varchar(255) not null,
|
|
modified_by varchar(255) not null,
|
|
constraint ck_data_model_approval_status check ( approval_status in ('PENDING','APPROVED','REJECTED')),
|
|
constraint entity_unique_id unique (entity_name,unique_identifier,tenant_id),
|
|
constraint pk_data_model primary key (sys_pk)
|
|
);
|
|
|
|
create table entity_model (
|
|
sys_pk bigint generated by default as identity not null,
|
|
deleted_on timestamp,
|
|
current_approval_level integer default 0 not null,
|
|
required_approval_levels integer default 0 not null,
|
|
approval_levels integer default 0 not null,
|
|
deleted boolean default false not null,
|
|
version integer default 1 not null,
|
|
created_at timestamp default 'now()' not null,
|
|
modified_at timestamp default 'now()' not null,
|
|
deleted_by varchar(255),
|
|
approval_status varchar(8) default 'APPROVED' not null,
|
|
tags varchar[] default '{}' not null,
|
|
comments jsonb default '[]' not null,
|
|
tenant_id varchar(255) not null,
|
|
name varchar(255) not null,
|
|
pre_save_script varchar(255),
|
|
post_save_script varchar(255),
|
|
actions varchar[] default '{}' not null,
|
|
allowed_fields varchar[] default '{}' not null,
|
|
allowed_field_types jsonb default '{}' not null,
|
|
audit_log_fields varchar[] default '{}' not null,
|
|
preferences jsonb default '{}' not null,
|
|
created_by varchar(255) not null,
|
|
modified_by varchar(255) not null,
|
|
constraint ck_entity_model_approval_status check ( approval_status in ('PENDING','APPROVED','REJECTED')),
|
|
constraint uq_entity_model_name unique (name),
|
|
constraint pk_entity_model primary key (sys_pk)
|
|
);
|
|
|
|
create table job_model (
|
|
sys_pk bigint generated by default as identity not null,
|
|
deleted_on timestamp,
|
|
current_approval_level integer default 0 not null,
|
|
required_approval_levels integer default 0 not null,
|
|
deleted boolean default false not null,
|
|
version integer default 1 not null,
|
|
created_at timestamp default 'now()' not null,
|
|
modified_at timestamp default 'now()' not null,
|
|
deleted_by varchar(255),
|
|
approval_status varchar(8) default 'APPROVED' not null,
|
|
tags varchar[] default '{}' not null,
|
|
comments jsonb default '[]' not null,
|
|
tenant_id varchar(255) not null,
|
|
job_name varchar(255) not null,
|
|
job_type varchar(6) not null,
|
|
job_path varchar(255) not null,
|
|
tenants varchar[] not null,
|
|
job_frequency_type varchar(8) not null,
|
|
frequency varchar(255) not null,
|
|
created_by varchar(255) not null,
|
|
modified_by varchar(255) not null,
|
|
constraint ck_job_model_approval_status check ( approval_status in ('PENDING','APPROVED','REJECTED')),
|
|
constraint ck_job_model_job_type check ( job_type in ('SCRIPT','DB')),
|
|
constraint ck_job_model_job_frequency_type check ( job_frequency_type in ('SPECIFIC','EVERY','CRON')),
|
|
constraint uq_job_model_job_name unique (job_name),
|
|
constraint pk_job_model primary key (sys_pk)
|
|
);
|
|
|
|
create table sql_model (
|
|
sys_pk bigint generated by default as identity not null,
|
|
deleted_on timestamp,
|
|
current_approval_level integer default 0 not null,
|
|
required_approval_levels integer default 0 not null,
|
|
sql text not null,
|
|
deleted boolean default false not null,
|
|
version integer default 1 not null,
|
|
created_at timestamp default 'now()' not null,
|
|
modified_at timestamp default 'now()' not null,
|
|
deleted_by varchar(255),
|
|
approval_status varchar(8) default 'APPROVED' not null,
|
|
tags varchar[] default '{}' not null,
|
|
comments jsonb default '[]' not null,
|
|
tenant_id varchar(255) not null,
|
|
sql_id varchar(255) not null,
|
|
entity_name varchar(255) not null,
|
|
created_by varchar(255) not null,
|
|
modified_by varchar(255) not null,
|
|
constraint ck_sql_model_approval_status check ( approval_status in ('PENDING','APPROVED','REJECTED')),
|
|
constraint sql_unique_id unique (entity_name,sql_id,tenant_id),
|
|
constraint pk_sql_model primary key (sys_pk)
|
|
);
|
|
|
|
create table tenant_model (
|
|
sys_pk bigint generated by default as identity not null,
|
|
deleted_on timestamp,
|
|
current_approval_level integer default 0 not null,
|
|
required_approval_levels integer default 0 not null,
|
|
deleted boolean default false not null,
|
|
version integer default 1 not null,
|
|
created_at timestamp default 'now()' not null,
|
|
modified_at timestamp default 'now()' not null,
|
|
deleted_by varchar(255),
|
|
approval_status varchar(8) default 'APPROVED' not null,
|
|
tags varchar[] default '{}' not null,
|
|
comments jsonb default '[]' not null,
|
|
name varchar(255) not null,
|
|
domain varchar(255) not null,
|
|
preferences jsonb not null,
|
|
created_by varchar(255) not null,
|
|
modified_by varchar(255) not null,
|
|
constraint ck_tenant_model_approval_status check ( approval_status in ('PENDING','APPROVED','REJECTED')),
|
|
constraint uq_tenant_model_name unique (name),
|
|
constraint pk_tenant_model primary key (sys_pk)
|
|
);
|
|
|
|
-- foreign keys and indices
|
|
create index if not exists ix_audit_log_audit_type_entity_unique_identifier_tenant_i_1 on audit_log (audit_type,entity,unique_identifier,tenant_id,created_by);
|
|
create index audit_log_values_idx on audit_log using GIN (data);
|
|
create index audit_log_changes_idx on audit_log using GIN (changes);
|
|
create index data_jsonb_idx on data_model using GIN (data) ;
|