Data model

This commit is contained in:
Jan Kvetina 2021-12-18 09:40:21 +01:00
parent b71cd4b444
commit a6c0e9f918
11 changed files with 382 additions and 0 deletions

3
sequences/log_id.sql Normal file
View File

@ -0,0 +1,3 @@
--DROP SEQUENCE log_id;
CREATE SEQUENCE log_id START WITH 10000 CACHE 100;

26
tables/apps.sql Normal file
View File

@ -0,0 +1,26 @@
--DROP TABLE apps CASCADE CONSTRAINTS;
CREATE TABLE apps (
app_id NUMBER(4) CONSTRAINT nn_apps_app_id NOT NULL,
app_name VARCHAR2(32),
--
message VARCHAR2(256),
is_active CHAR(1),
--
updated_by VARCHAR2(30),
updated_at DATE,
--
CONSTRAINT pk_apps
PRIMARY KEY (app_id),
--
CONSTRAINT ch_apps_is_active
CHECK (is_active = 'Y' OR is_active IS NULL)
)
STORAGE (BUFFER_POOL KEEP);
--
COMMENT ON TABLE apps IS 'List of apps';
--
COMMENT ON COLUMN apps.app_id IS 'APEX application ID';
COMMENT ON COLUMN apps.app_name IS 'Application name';
COMMENT ON COLUMN apps.message IS 'Announcement to users when taking app for maintenance';
COMMENT ON COLUMN apps.is_active IS 'Flag to deny access to app to users (not developers)';

31
tables/events.sql Normal file
View File

@ -0,0 +1,31 @@
--DROP TABLE logs_events PURGE;
--DROP TABLE events PURGE;
CREATE TABLE events (
app_id NUMBER(4) CONSTRAINT nn_events_app_id NOT NULL,
event_id VARCHAR2(30) CONSTRAINT nn_events_event_id NOT NULL,
--
description_ VARCHAR2(1000),
is_active CHAR(1),
--
updated_by VARCHAR2(30),
updated_at DATE,
--
CONSTRAINT pk_events
PRIMARY KEY (app_id, event_id),
--
CONSTRAINT fk_events_app_id
FOREIGN KEY (app_id)
REFERENCES apps (app_id),
--
CONSTRAINT ch_events_is_active
CHECK (is_active = 'Y' OR is_active IS NULL)
)
STORAGE (BUFFER_POOL KEEP);
--
COMMENT ON TABLE events IS 'List of events interesting for business';
--
COMMENT ON COLUMN events.app_id IS 'APEX application ID';
COMMENT ON COLUMN events.event_id IS 'Event id';
COMMENT ON COLUMN events.description_ IS 'Human friendly event description';
COMMENT ON COLUMN events.is_active IS 'Flag to disable tracking';

66
tables/logs.sql Normal file
View File

@ -0,0 +1,66 @@
/*
UPDATE sessions SET log_id = NULL;
UPDATE uploaded_file_sheets SET result_log_id = NULL;
--
DROP TABLE logs_events PURGE;
DROP TABLE logs_lobs PURGE;
DROP TABLE logs_setup PURGE;
DROP TABLE logs PURGE;
--
SELECT * FROM logs ORDER BY 1 DESC;
*/
CREATE TABLE logs (
log_id INTEGER CONSTRAINT nn_logs_log_id NOT NULL, -- NUMBER GENERATED BY DEFAULT AS IDENTITY NOT NULL
log_parent INTEGER,
--
app_id NUMBER(4) CONSTRAINT nn_logs_app_id NOT NULL,
page_id NUMBER(6),
user_id VARCHAR2(30),
--
flag CHAR(1) CONSTRAINT nn_logs_flag NOT NULL,
--
module_name VARCHAR2(48), -- 48 chars, DBMS_APPLICATION_INFO limit
module_line NUMBER(8),
module_time INTERVAL DAY(1) TO SECOND(3),
--
action_name VARCHAR2(32),
--
arguments VARCHAR2(2000),
payload VARCHAR2(4000),
--
session_id NUMBER,
created_at TIMESTAMP CONSTRAINT nn_logs_created_at NOT NULL,
--
CONSTRAINT pk_logs
PRIMARY KEY (log_id)
--
-- NO MORE CONSTRAINTS TO KEEP THIS AS FAST AS POSSIBLE
--
)
PARTITION BY RANGE (created_at)
INTERVAL (NUMTODSINTERVAL(1, 'DAY')) (
PARTITION P00 VALUES LESS THAN (TIMESTAMP '2021-01-01 00:00:00')
/*
--today VARCHAR2(10) CONSTRAINT nn_logs_today NOT NULL, -- virtual column?
PARTITION BY LIST (today, app_id) AUTOMATIC (
PARTITION "P_20210101_0" VALUES (('2021-01-01', 0)) SEGMENT CREATION IMMEDIATE
*/
);
--
COMMENT ON TABLE logs IS 'Various logs raised in application; daily partitions';
--
COMMENT ON COLUMN logs.log_id IS 'Log ID generated from LOG_ID sequence';
COMMENT ON COLUMN logs.log_parent IS 'Parent log record; dont use FK to avoid deadlocks';
COMMENT ON COLUMN logs.app_id IS 'APEX Application ID';
COMMENT ON COLUMN logs.user_id IS 'User ID';
COMMENT ON COLUMN logs.page_id IS 'APEX Application PAGE ID';
COMMENT ON COLUMN logs.flag IS 'Type of error listed in tree package specification; FK missing for performance reasons';
COMMENT ON COLUMN logs.module_name IS 'Module name (procedure or function name)';
COMMENT ON COLUMN logs.module_line IS 'Line in the module';
COMMENT ON COLUMN logs.module_time IS 'Time interval indicating successful finish';
COMMENT ON COLUMN logs.action_name IS 'Action name to distinguish position in module or use it as warning/error names';
COMMENT ON COLUMN logs.arguments IS 'Arguments passed to module';
COMMENT ON COLUMN logs.payload IS 'Formatted call stack, error stack or query with DML error';
COMMENT ON COLUMN logs.session_id IS 'Session ID (generated by APEX) from sessions table';
COMMENT ON COLUMN logs.created_at IS 'Timestamp of creation';

39
tables/logs_events.sql Normal file
View File

@ -0,0 +1,39 @@
--DROP TABLE logs_events PURGE;
CREATE TABLE logs_events (
log_id INTEGER CONSTRAINT nn_logs_events_log_id NOT NULL,
log_parent INTEGER,
--
app_id NUMBER(4) CONSTRAINT nn_logs_events_app_id NOT NULL,
page_id NUMBER(6) CONSTRAINT nn_logs_events_page_id NOT NULL,
user_id VARCHAR2(30) CONSTRAINT nn_logs_events_user_id NOT NULL,
session_id NUMBER CONSTRAINT nn_logs_events_session_id NOT NULL,
--
event_id VARCHAR2(30) CONSTRAINT nn_logs_events_event_id NOT NULL,
event_value NUMBER,
--
created_at DATE CONSTRAINT nn_logs_events_created_at NOT NULL,
--
CONSTRAINT pk_logs_events
PRIMARY KEY (log_id),
--
CONSTRAINT fk_logs_events_event_id
FOREIGN KEY (app_id, event_id)
REFERENCES events (app_id, event_id),
--
CONSTRAINT fk_logs_events_users
FOREIGN KEY (user_id)
REFERENCES users (user_id)
);
--
COMMENT ON TABLE logs_events IS 'List of business events';
--
COMMENT ON COLUMN logs_events.log_id IS 'Log ID';
COMMENT ON COLUMN logs_events.log_parent IS 'Referenced log_id from LOGS table';
COMMENT ON COLUMN logs_events.app_id IS 'App';
COMMENT ON COLUMN logs_events.page_id IS 'Page';
COMMENT ON COLUMN logs_events.user_id IS 'User';
COMMENT ON COLUMN logs_events.session_id IS 'Session id';
COMMENT ON COLUMN logs_events.event_id IS 'Event code from EVENTS table';
COMMENT ON COLUMN logs_events.event_value IS 'Optional business value';
COMMENT ON COLUMN logs_events.created_at IS 'Datetime of the event';

41
tables/logs_setup.sql Normal file
View File

@ -0,0 +1,41 @@
--DROP TABLE logs_setup CASCADE CONSTRAINTS PURGE;
CREATE TABLE logs_setup (
--
-- @TODO: ??? trigger/proc when new app is created (apps table) to prefill setup...
--
app_id NUMBER(4) CONSTRAINT nn_logs_setup_app_id NOT NULL,
user_id VARCHAR2(240),
page_id NUMBER(6),
flag CHAR(1),
module_like VARCHAR2(30),
--
is_ignored CHAR(1),
--
updated_by VARCHAR2(30),
updated_at DATE,
--
CONSTRAINT uq_logs_setup
UNIQUE (app_id, user_id, page_id, flag, module_like),
--
CONSTRAINT fk_logs_setup_app_id
FOREIGN KEY (app_id)
REFERENCES apps (app_id),
--
CONSTRAINT fk_logs_setup_user_id
FOREIGN KEY (user_id)
REFERENCES users (user_id),
--
CONSTRAINT ch_logs_setup_is_ignored
CHECK (is_ignored = 'Y' OR is_ignored IS NULL)
)
STORAGE (BUFFER_POOL KEEP);
--
COMMENT ON TABLE logs_setup IS 'Define what logs will or wont be tracked';
--
COMMENT ON COLUMN logs_setup.app_id IS 'App ID';
COMMENT ON COLUMN logs_setup.page_id IS 'APEX page ID, NULL = any page';
COMMENT ON COLUMN logs_setup.user_id IS 'User ID, NULL = any user';
COMMENT ON COLUMN logs_setup.flag IS 'Flag to differentiate logs, NULL = any flag';
COMMENT ON COLUMN logs_setup.module_like IS 'Module name, NULL = any module';
COMMENT ON COLUMN logs_setup.is_ignored IS 'Y = dont store in table';

41
tables/navigation.sql Normal file
View File

@ -0,0 +1,41 @@
--DROP TABLE navigation PURGE;
CREATE TABLE navigation (
app_id NUMBER(4) CONSTRAINT nn_navigation_app_id NOT NULL,
page_id NUMBER(6) CONSTRAINT nn_navigation_page_id NOT NULL,
--
parent_id NUMBER(6),
order# NUMBER(4),
is_hidden VARCHAR2(1),
is_reset VARCHAR2(1),
--
updated_by VARCHAR2(30),
updated_at DATE,
--
CONSTRAINT pk_navigation
PRIMARY KEY (app_id, page_id),
--
CONSTRAINT fk_navigation_app_id
FOREIGN KEY (app_id)
REFERENCES apps (app_id),
--
CONSTRAINT fk_navigation_parent
FOREIGN KEY (app_id, parent_id)
REFERENCES navigation (app_id, page_id),
--
CONSTRAINT ch_navigation_is_hidden
CHECK (is_hidden = 'Y' OR is_hidden IS NULL),
--
CONSTRAINT ch_navigation_is_reset
CHECK (is_reset = 'Y' OR is_reset IS NULL)
)
STORAGE (BUFFER_POOL KEEP);
--
COMMENT ON TABLE navigation IS 'Navigation items';
--
COMMENT ON COLUMN navigation.app_id IS 'APEX application ID';
COMMENT ON COLUMN navigation.page_id IS 'APEX page ID';
COMMENT ON COLUMN navigation.parent_id IS 'Parent id for tree structure';
COMMENT ON COLUMN navigation.order# IS 'Order of siblings';
COMMENT ON COLUMN navigation.is_hidden IS 'Y = dont show in menu';
COMMENT ON COLUMN navigation.is_reset IS 'Y = reset all items not passed in url';

30
tables/roles.sql Normal file
View File

@ -0,0 +1,30 @@
--DROP TABLE roles PURGE;
CREATE TABLE roles (
app_id NUMBER(4) CONSTRAINT nn_roles_app_id NOT NULL,
role_id VARCHAR2(30) CONSTRAINT nn_roles_role_id NOT NULL,
--
description_ VARCHAR2(1000),
is_active CHAR(1),
--
updated_by VARCHAR2(30),
updated_at DATE,
--
CONSTRAINT pk_roles
PRIMARY KEY (app_id, role_id),
--
CONSTRAINT fk_roles_app_id
FOREIGN KEY (app_id)
REFERENCES apps (app_id),
--
CONSTRAINT ch_roles_is_active
CHECK (is_active = 'Y' OR is_active IS NULL)
)
STORAGE (BUFFER_POOL KEEP);
--
COMMENT ON TABLE roles IS 'List of roles';
--
COMMENT ON COLUMN roles.app_id IS 'Application ID';
COMMENT ON COLUMN roles.role_id IS 'Role ID';
COMMENT ON COLUMN roles.description_ IS 'Description';
COMMENT ON COLUMN roles.is_active IS 'Flag to disable role';

30
tables/sessions.sql Normal file
View File

@ -0,0 +1,30 @@
--DROP TABLE sessions PURGE;
CREATE TABLE sessions (
app_id NUMBER(4) CONSTRAINT nn_sessions_app_id NOT NULL,
session_id NUMBER CONSTRAINT nn_sessions_session_id NOT NULL,
user_id VARCHAR2(30) CONSTRAINT nn_sessions_user_id NOT NULL,
--
created_at DATE CONSTRAINT nn_sessions_created_at NOT NULL,
updated_at DATE CONSTRAINT nn_sessions_updated_at NOT NULL,
--
CONSTRAINT pk_sessions
PRIMARY KEY (app_id, session_id),
--
CONSTRAINT fk_sessions_app_id
FOREIGN KEY (app_id)
REFERENCES apps (app_id),
--
CONSTRAINT fk_sessions_users
FOREIGN KEY (user_id)
REFERENCES users (user_id)
)
STORAGE (BUFFER_POOL KEEP);
--
COMMENT ON TABLE sessions IS 'List of sessions';
--
COMMENT ON COLUMN sessions.app_id IS 'APEX application ID';
COMMENT ON COLUMN sessions.session_id IS 'Session ID generated by APEX, used also in LOGS';
COMMENT ON COLUMN sessions.user_id IS 'User ID';
COMMENT ON COLUMN sessions.created_at IS 'Time of creation';
COMMENT ON COLUMN sessions.updated_at IS 'Time of last update';

40
tables/user_roles.sql Normal file
View File

@ -0,0 +1,40 @@
--DROP TABLE user_roles PURGE;
CREATE TABLE user_roles (
app_id NUMBER(4) CONSTRAINT nn_user_roles_app_id NOT NULL,
user_id VARCHAR2(30) CONSTRAINT nn_user_roles_user_id NOT NULL,
role_id VARCHAR2(30) CONSTRAINT nn_user_roles_role_id NOT NULL,
--
is_active CHAR(1),
--
updated_by VARCHAR2(30),
updated_at DATE,
--
CONSTRAINT pk_user_roles
PRIMARY KEY (app_id, user_id, role_id),
--
CONSTRAINT fk_users_roles_app_id
FOREIGN KEY (app_id)
REFERENCES apps (app_id),
--
CONSTRAINT fk_users_roles_user_id
FOREIGN KEY (user_id)
REFERENCES users (user_id),
--
CONSTRAINT fk_users_roles_role_id
FOREIGN KEY (app_id, role_id)
REFERENCES roles (app_id, role_id),
--
CONSTRAINT ch_user_roles_is_active
CHECK (is_active = 'Y' OR is_active IS NULL)
)
STORAGE (BUFFER_POOL KEEP);
--
ALTER TABLE user_roles MODIFY CONSTRAINT fk_users_roles_user_id DISABLE; -- to assign roles before user is created
--
COMMENT ON TABLE user_roles IS 'List of roles assigned to users';
--
COMMENT ON COLUMN user_roles.app_id IS 'APEX application ID';
COMMENT ON COLUMN user_roles.user_id IS 'User ID from USERS table';
COMMENT ON COLUMN user_roles.role_id IS 'Role ID from ROLES table';
COMMENT ON COLUMN user_roles.is_active IS 'Flag to deactivate permission temporarly';

35
tables/users.sql Normal file
View File

@ -0,0 +1,35 @@
/*
DROP TABLE sessions CASCADE CONSTRAINTS PURGE;
DROP TABLE user_roles CASCADE CONSTRAINTS PURGE;
DROP TABLE users CASCADE CONSTRAINTS PURGE;
*/
CREATE TABLE users (
user_id VARCHAR2(30) CONSTRAINT nn_users_user_id NOT NULL,
user_login VARCHAR2(128) CONSTRAINT nn_users_login NOT NULL,
user_name VARCHAR2(64),
--
lang_id VARCHAR2(5),
is_active CHAR(1),
--
updated_by VARCHAR2(30),
updated_at DATE,
--
CONSTRAINT pk_users
PRIMARY KEY (user_id),
--
CONSTRAINT uq_users_user_login
UNIQUE (user_login),
--
CONSTRAINT ch_users_is_active
CHECK (is_active = 'Y' OR is_active IS NULL)
)
STORAGE (BUFFER_POOL KEEP);
--
COMMENT ON TABLE users IS 'List of users';
--
COMMENT ON COLUMN users.user_id IS 'User ID used internally (short)';
COMMENT ON COLUMN users.user_login IS 'User login used for login into the app';
COMMENT ON COLUMN users.user_name IS 'User name visible in the app';
COMMENT ON COLUMN users.lang_id IS 'Preferred language';
COMMENT ON COLUMN users.is_active IS 'Flag to disable user without changing roles';