initial commit
This commit is contained in:
34
applications.sql
Normal file
34
applications.sql
Normal file
@@ -0,0 +1,34 @@
|
|||||||
|
SELECT 'dynamic' AS component, sqlpage.run_sql('shell.sql') AS properties;
|
||||||
|
|
||||||
|
|
||||||
|
--Insert new application or update existing one
|
||||||
|
INSERT INTO application (name)
|
||||||
|
SELECT :Name
|
||||||
|
WHERE :Name IS NOT NULL AND $edit IS NULL;
|
||||||
|
|
||||||
|
UPDATE application SET name = :Name WHERE id = $edit and :Name IS NOT NULL;
|
||||||
|
|
||||||
|
--Delete an application
|
||||||
|
DELETE FROM application WHERE id = $delete
|
||||||
|
|
||||||
|
SELECT 'table' AS component,
|
||||||
|
'id' AS ID_Number,
|
||||||
|
'Applications' AS title,
|
||||||
|
'Edit_Action' AS markdown,
|
||||||
|
'Remove_Action' AS markdown,
|
||||||
|
TRUE AS sort,
|
||||||
|
TRUE AS search;
|
||||||
|
|
||||||
|
SELECT id AS ID_Number,
|
||||||
|
name AS title,
|
||||||
|
'[Edit](applications.sql?edit=' || id || ')' AS Edit_Action,
|
||||||
|
'[🗑️](applications.sql?delete=' || id || ')' AS Remove_Action
|
||||||
|
FROM application;
|
||||||
|
|
||||||
|
-- Add "Add New" button to set the $add parameter
|
||||||
|
SELECT 'button' as component, 'center' as justify;
|
||||||
|
SELECT '?add=1' as link, 'Add New' as title; -- Dynamic link for add new
|
||||||
|
|
||||||
|
-- Display a form for adding or editing an application
|
||||||
|
SELECT 'form' AS component, 'multipart/form-data' AS enctype, 'Add an application' AS title;
|
||||||
|
SELECT (SELECT name FROM application WHERE id = $edit) AS value, 'Name' AS name;
|
||||||
7
dashboard.css
Normal file
7
dashboard.css
Normal file
@@ -0,0 +1,7 @@
|
|||||||
|
.resolved .card-body {
|
||||||
|
background-color: lightgrey;
|
||||||
|
opacity: .3;
|
||||||
|
}
|
||||||
|
.resolved .card-body,.resolved .card-body .text-secondary {
|
||||||
|
color: black !important;
|
||||||
|
}
|
||||||
58
incident.sql
Normal file
58
incident.sql
Normal file
@@ -0,0 +1,58 @@
|
|||||||
|
SELECT 'dynamic' AS component, sqlpage.run_sql('shell.sql') AS properties;
|
||||||
|
|
||||||
|
-- Write the name of the group in the title of the page
|
||||||
|
SELECT 'title' as component, title as contents FROM incident WHERE id = $id;
|
||||||
|
|
||||||
|
select
|
||||||
|
'datagrid' as component,
|
||||||
|
title as title,
|
||||||
|
description as description_md
|
||||||
|
FROM incident WHERE incident.id = $id
|
||||||
|
;
|
||||||
|
select
|
||||||
|
'Status' as title,
|
||||||
|
status as description,
|
||||||
|
CASE
|
||||||
|
WHEN incident.status = 'CLOSED' THEN 'green'
|
||||||
|
ELSE 'yellow'
|
||||||
|
END
|
||||||
|
as color
|
||||||
|
FROM incident WHERE id = $id
|
||||||
|
;
|
||||||
|
select
|
||||||
|
'Severity' as title,
|
||||||
|
severity.name as description,
|
||||||
|
severity.color as color
|
||||||
|
FROM incident, severity WHERE incident.id = $id
|
||||||
|
AND severity.id = incident.severity
|
||||||
|
;
|
||||||
|
select
|
||||||
|
'Who is affected' as title,
|
||||||
|
who_is_affected as description
|
||||||
|
FROM incident WHERE id = $id
|
||||||
|
;
|
||||||
|
select
|
||||||
|
'Estimated duration' as title,
|
||||||
|
estimated_duration as description
|
||||||
|
FROM incident WHERE id = $id
|
||||||
|
;
|
||||||
|
select 'list' as component,
|
||||||
|
'Affected applications' as title;
|
||||||
|
select a.name as title
|
||||||
|
from application a
|
||||||
|
join incident_application on a.id = incident_application.application_id
|
||||||
|
where incident_application.incident_id = $id;
|
||||||
|
|
||||||
|
-- Display a form for adding or editing an incident
|
||||||
|
SELECT 'form' AS component, 'multipart/form-data' AS enctype, 'Add information' AS title, 'incident_update.sql' as action;
|
||||||
|
SELECT (SELECT datetime()) AS value, 'DateTime' AS name, 'datetime-local' as type, 4 as width;
|
||||||
|
select
|
||||||
|
'status' as name,
|
||||||
|
true as required,
|
||||||
|
4 as 'width',
|
||||||
|
(select status from incident WHERE incident.id = $id) as value,
|
||||||
|
'select' as type,
|
||||||
|
'Select a status...' as empty_option,
|
||||||
|
'[{"label": "DETECTION", "value": "DETECTION"}, {"label": "ANALYSIS", "value": "ANALYSIS"}
|
||||||
|
, {"label": "RESOLUTION", "value": "RESOLUTION"}, {"label": "CLOSED", "value": "CLOSED"}]' as options;
|
||||||
|
SELECT 'Information' AS name, 'textarea' AS type, 8 as 'width', true as required;
|
||||||
74
incidents.sql
Normal file
74
incidents.sql
Normal file
@@ -0,0 +1,74 @@
|
|||||||
|
SELECT 'dynamic' AS component, sqlpage.run_sql('shell.sql') AS properties;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
|
--Delete an incident
|
||||||
|
DELETE FROM incident WHERE id = $delete
|
||||||
|
|
||||||
|
SELECT 'table' AS component,
|
||||||
|
'id' AS ID_Number,
|
||||||
|
'Title' AS title,
|
||||||
|
'Description' AS Description,
|
||||||
|
'EstimatedDuration' AS EstimatedDuration,
|
||||||
|
'WhoIsAffected' AS WhoIsAffected,
|
||||||
|
'Applications' AS Application,
|
||||||
|
'Date' AS Date,
|
||||||
|
'Edit_Action' AS markdown,
|
||||||
|
'Remove_Action' AS markdown,
|
||||||
|
TRUE AS sort,
|
||||||
|
TRUE AS search;
|
||||||
|
|
||||||
|
SELECT i.id AS ID_Number,
|
||||||
|
i.title AS title,
|
||||||
|
i.Description AS Description,
|
||||||
|
i.estimated_duration AS EstimatedDuration,
|
||||||
|
i.who_is_affected AS WhoIsAffected,
|
||||||
|
i.date_time AS Date,
|
||||||
|
'[Edit](incidents.sql?edit=' || i.id || ')' AS Edit_Action,
|
||||||
|
'[🗑️](incidents.sql?delete=' || i.id || ')' AS Remove_Action
|
||||||
|
FROM incident i
|
||||||
|
;
|
||||||
|
|
||||||
|
-- Add "Add New" button to set the $add parameter
|
||||||
|
SELECT 'button' as component, 'center' as justify;
|
||||||
|
SELECT '?add=1' as link, 'Add New' as title; -- Dynamic link for add new
|
||||||
|
|
||||||
|
-- Display a form for adding or editing an incident
|
||||||
|
SELECT 'form' AS component, 'multipart/form-data' AS enctype, 'Add an incident' AS title, 'incidents_submit.sql' as action;
|
||||||
|
SELECT (SELECT title FROM incident WHERE id = $edit) AS value, 'Title' AS name, 8 as 'width';
|
||||||
|
SELECT (SELECT estimated_duration FROM incident WHERE id = $edit) AS value, 'EstimatedDuration' AS name, 4 as 'width';
|
||||||
|
SELECT (SELECT Description FROM incident WHERE id = $edit) AS value, 'Description' AS name, 'textarea' AS type, 8 as 'width';
|
||||||
|
SELECT (SELECT who_is_affected FROM incident WHERE id = $edit) AS value, 'WhoIsAffected' AS name, 4 as 'width';
|
||||||
|
SELECT (SELECT date_time FROM incident WHERE id = $edit) AS value, 'DateTime' AS name, 'datetime-local' as type, 4 as width;
|
||||||
|
SELECT
|
||||||
|
'Status' as name,
|
||||||
|
true as required,
|
||||||
|
4 as 'width',
|
||||||
|
(select status from incident WHERE incident.id = $id) as value,
|
||||||
|
'select' as type,
|
||||||
|
'Select a status...' as empty_option,
|
||||||
|
'[{"label": "DETECTION", "value": "DETECTION"}, {"label": "ANALYSIS", "value": "ANALYSIS"}
|
||||||
|
, {"label": "RESOLUTION", "value": "RESOLUTION"}, {"label": "CLOSED", "value": "CLOSED"}]' as options,
|
||||||
|
'DETECTION' as selected;
|
||||||
|
SELECT 'Severity' AS name,
|
||||||
|
'radio' as type,
|
||||||
|
'1' as value,
|
||||||
|
'part of the application is not useable' as description,
|
||||||
|
'Severe' as label,
|
||||||
|
'orange' as color;
|
||||||
|
SELECT 'Severity' AS name,
|
||||||
|
'radio' as type,
|
||||||
|
'2' as value,
|
||||||
|
'the whole application is not useable' as description,
|
||||||
|
'Blocking' as label,
|
||||||
|
'red' as color;
|
||||||
|
|
||||||
|
;
|
||||||
|
|
||||||
|
select 'checkbox' as type,
|
||||||
|
2 as width,
|
||||||
|
'Applications[]' AS name,
|
||||||
|
application.id AS value,
|
||||||
|
application.name AS label
|
||||||
|
FROM application
|
||||||
11
incidents_submit.sql
Normal file
11
incidents_submit.sql
Normal file
@@ -0,0 +1,11 @@
|
|||||||
|
--Insert new incident or update existing one
|
||||||
|
INSERT INTO incident (title, description, estimated_duration, who_is_affected, date_time, severity, status )
|
||||||
|
VALUES (:Title, :Description, :EstimatedDuration, :WhoIsAffected, :DateTime, :Severity, :Status );
|
||||||
|
|
||||||
|
INSERT INTO incident_application (incident_id, application_id)
|
||||||
|
SELECT last_insert_rowid(),
|
||||||
|
CAST(application.value AS INTEGER)
|
||||||
|
FROM json_each(:Applications) as application
|
||||||
|
WHERE application.value IS NOT NULL;
|
||||||
|
|
||||||
|
SELECT 'redirect' AS component, 'incidents.sql?id=' || last_insert_rowid() AS link;
|
||||||
37
index.sql
Normal file
37
index.sql
Normal file
@@ -0,0 +1,37 @@
|
|||||||
|
SELECT 'dynamic' AS component, sqlpage.run_sql('shell.sql') AS properties;
|
||||||
|
|
||||||
|
SELECT 'card' AS component,
|
||||||
|
'Applications' AS title;
|
||||||
|
|
||||||
|
SELECT name AS title,
|
||||||
|
coalesce(severity_color,'green' ) AS background_color,
|
||||||
|
incident_title as description
|
||||||
|
|
||||||
|
FROM application_status;
|
||||||
|
|
||||||
|
SELECT 'divider' AS component,
|
||||||
|
'incidents' AS contents
|
||||||
|
;
|
||||||
|
|
||||||
|
select
|
||||||
|
'timeline' as component;
|
||||||
|
select
|
||||||
|
i.title as title,
|
||||||
|
'incident.sql?id=' || i.id AS link,
|
||||||
|
CASE
|
||||||
|
WHEN i.status = 'CLOSED' THEN 'resolved'
|
||||||
|
ELSE ''
|
||||||
|
END
|
||||||
|
AS class,
|
||||||
|
i.date_time as date,
|
||||||
|
i.description as description,
|
||||||
|
s.color AS color,
|
||||||
|
CASE
|
||||||
|
WHEN i.status = 'CLOSED' THEN 'alert-triangle-off'
|
||||||
|
ELSE 'alert-triangle'
|
||||||
|
END
|
||||||
|
AS icon
|
||||||
|
from incident i
|
||||||
|
JOIN severity s on i.severity = s.id
|
||||||
|
order by i.date_time desc
|
||||||
|
;
|
||||||
12
shell.sql
Normal file
12
shell.sql
Normal file
@@ -0,0 +1,12 @@
|
|||||||
|
SELECT
|
||||||
|
'shell' AS component,
|
||||||
|
'Dashboard' AS title,
|
||||||
|
'home' AS icon,
|
||||||
|
'dark' AS theme,
|
||||||
|
'dashboard.css' AS css,
|
||||||
|
'fluid' AS layout,
|
||||||
|
JSON('{"title":"Main","submenu":[
|
||||||
|
{"link":"/applications.sql", "title":"Applications", "icon":"squares"},
|
||||||
|
{"link":"/incidents.sql", "title":"Incidents", "icon":"forms"},
|
||||||
|
]}') AS menu_item,
|
||||||
|
'[SQLPage](https://sql.ophir.dev)' as footer;
|
||||||
48
sqlpage/migrations/0001_create_tables.sql
Normal file
48
sqlpage/migrations/0001_create_tables.sql
Normal file
@@ -0,0 +1,48 @@
|
|||||||
|
CREATE TABLE severity (
|
||||||
|
id INTEGER PRIMARY KEY,
|
||||||
|
name NOT NULL,
|
||||||
|
weight INTEGER NOT NULL,
|
||||||
|
color NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
INSERT INTO severity VALUES (1, 'severe', 100, 'orange');
|
||||||
|
INSERT INTO severity VALUES (2, 'blocking', 200, 'red');
|
||||||
|
INSERT INTO severity VALUES (3, 'maintenance', 1000, 'blue');
|
||||||
|
|
||||||
|
CREATE TABLE application (
|
||||||
|
id INTEGER PRIMARY KEY,
|
||||||
|
name TEXT NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE incident (
|
||||||
|
id INTEGER PRIMARY KEY,
|
||||||
|
title NOT NULL,
|
||||||
|
description NOT NULL,
|
||||||
|
estimated_duration NOT NULL,
|
||||||
|
who_is_affected NOT NULL,
|
||||||
|
date_time DATETIME NOT NULL,
|
||||||
|
severity INTEGER NOT NULL REFERENCES severity(id),
|
||||||
|
status CHECK(status IN ('DETECTION', 'ANALYSIS', 'RESOLUTION', 'CLOSED')) NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE incident_info(
|
||||||
|
id INTEGER PRIMARY KEY,
|
||||||
|
incident_id INTEGER NOT NULL REFERENCES incident(id),
|
||||||
|
description NOT NULL,
|
||||||
|
status CHECK(status IN ('DETECTION', 'ANALYSIS', 'RESOLUTION', 'CLOSED')) NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TABLE incident_application (
|
||||||
|
incident_id INTEGER NOT NULL REFERENCES incident(id),
|
||||||
|
application_id INTEGER NOT NULL REFERENCES application(id),
|
||||||
|
PRIMARY KEY (incident_id,application_id)
|
||||||
|
) WITHOUT ROWID;
|
||||||
|
|
||||||
|
CREATE VIEW application_status AS
|
||||||
|
SELECT a.name, s.name as severity, i.title AS incident_title, MAX(s.WEIGHT), s.color AS severity_color FROM application a
|
||||||
|
LEFT JOIN incident_application ia ON a.id = ia.application_id
|
||||||
|
LEFT JOIN incident i ON ia.incident_id = i.id
|
||||||
|
AND i.status <> 'CLOSED'
|
||||||
|
LEFT JOIN severity s ON i.severity = s.id
|
||||||
|
GROUP BY a.name
|
||||||
|
;
|
||||||
18
sqlpage/migrations/0002_create_dummy_data.sql
Normal file
18
sqlpage/migrations/0002_create_dummy_data.sql
Normal file
@@ -0,0 +1,18 @@
|
|||||||
|
INSERT INTO application (id,name) VALUES (1,'incident management system');
|
||||||
|
INSERT INTO application (id,name) VALUES (2,'coffee machine');
|
||||||
|
INSERT INTO application (id,name) VALUES (3,'web site');
|
||||||
|
INSERT INTO application (id,name) VALUES (4,'internet');
|
||||||
|
|
||||||
|
INSERT INTO incident (id,title,description,estimated_duration,who_is_affected,date_time,severity, status)
|
||||||
|
VALUES (1,"incident system down", "incident management system is down", '2h','everyone','2025-04-01 10:15', 2, 'ANALYSIS');
|
||||||
|
INSERT INTO incident (id,title,description,estimated_duration,who_is_affected,date_time,severity, status)
|
||||||
|
VALUES (2,"network issue", "there is a network issue impacting performance", '2h','everyone','2025-04-01 14:15', 1, 'DETECTION');
|
||||||
|
INSERT INTO incident (id,title,description,estimated_duration,who_is_affected,date_time,severity, status)
|
||||||
|
VALUES (3,"slowness", "general slowness", '2h','everyone','2025-04-01 07:15', 1, 'CLOSED');
|
||||||
|
|
||||||
|
INSERT INTO incident_application(incident_id, application_id) VALUES (1,1);
|
||||||
|
INSERT INTO incident_application(incident_id, application_id) VALUES (2,1);
|
||||||
|
INSERT INTO incident_application(incident_id, application_id) VALUES (2,3);
|
||||||
|
INSERT INTO incident_application(incident_id, application_id) VALUES (2,4);
|
||||||
|
INSERT INTO incident_application(incident_id, application_id) VALUES (3,2);
|
||||||
|
|
||||||
1
sqlpage/sqlpage.json
Normal file
1
sqlpage/sqlpage.json
Normal file
@@ -0,0 +1 @@
|
|||||||
|
{ "database_url": "sqlite://:memory:" }
|
||||||
Reference in New Issue
Block a user