Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Audit DB Tables #535

Draft
wants to merge 19 commits into
base: dev
Choose a base branch
from
Draft
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
3 changes: 3 additions & 0 deletions R/app_server.R
Original file line number Diff line number Diff line change
Expand Up @@ -44,6 +44,9 @@ app_server <- function(input, output, session) {


observeEvent(res_auth$user, {
dbUpdate("DELETE FROM _variables")
dbUpdate("INSERT INTO _variables (user) VALUES ({res_auth$user})")

req(res_auth$admin == TRUE | "weight_adjust" %in% approved_roles[[res_auth$role]])

appendTab("apptabs",
Expand Down
7 changes: 4 additions & 3 deletions R/mod_decision_automation.R
Original file line number Diff line number Diff line change
Expand Up @@ -542,7 +542,8 @@ mod_decision_automation_server <- function(id, user, approved_roles){
req("auto_decision_adjust" %in% approved_roles[[user$role]])

out_lst <- purrr::compact(reactiveValuesToList(auto_decision))
dbUpdate("UPDATE decision_categories SET lower_limit = NULL, upper_limit = NULL")
null_lst <- setdiff(names(auto_decision_update()), names(out_lst))
purrr::walk(null_lst, ~ dbUpdate("UPDATE decision_categories SET lower_limit = NULL, upper_limit = NULL WHERE decision = {.x}"))
purrr::iwalk(out_lst, ~ dbUpdate("UPDATE decision_categories SET lower_limit = {.x[1]}, upper_limit = {.x[2]} WHERE decision = {.y}"))
auto_decision_update(out_lst)

Expand Down Expand Up @@ -574,10 +575,10 @@ mod_decision_automation_server <- function(id, user, approved_roles){
decision_lst %>%
purrr::map_chr(~ input[[glue::glue("{risk_lbl(.x, input = FALSE)}_col")]]) %>%
purrr::set_names(decision_lst)
purrr::iwalk(selected_colors, ~ {
purrr::iwalk(selected_colors, ~ if (!.x %in% color_current()[.y]) {
dbUpdate("UPDATE decision_categories SET color = {.x} WHERE decision = {.y}")
shinyjs::runjs(glue::glue("document.documentElement.style.setProperty('--{risk_lbl(.y, input = FALSE)}-color', '{.x}');"))
})
})
loggit::loggit("INFO", glue::glue("The decision category display colors were modified by {user$name} ({user$role})"))
color_current(selected_colors)

Expand Down
2 changes: 2 additions & 0 deletions R/mod_decision_automation_utils.R
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,7 @@ assign_decisions <- function(decision_list, package) {
decision <- paste0(names(decision_list)[purrr::map_lgl(decision_list, ~ .x[1] < score && score <= .x[2])], "")
decision_id <- dbSelect("SELECT id FROM decision_categories WHERE decision = {decision}")
if (decision != "") {
dbUpdate("INSERT INTO _variables (user) VALUES ('SYSTEM')")
dbUpdate("UPDATE package SET decision_id = {decision_id},
decision_by = 'Auto Assigned', decision_date = {Sys.Date()}
WHERE name = {package}")
Expand All @@ -23,6 +24,7 @@ assign_decisions <- function(decision_list, package) {
"INSERT INTO comments
VALUES ({package}, 'Auto Assigned', 'admin',
{comment}, 'o', {getTimeStamp()})")
dbUpdate("DELETE FROM _variables WHERE id IN (SELECT id FROM _variables ORDER BY id DESC LIMIT 1)")
}

return(decision)
Expand Down
8 changes: 6 additions & 2 deletions R/utils_startup.R
Original file line number Diff line number Diff line change
Expand Up @@ -22,10 +22,10 @@ create_db <- function(db_name){

# Queries needed to run the first time the db is created.
queries <- c(
"create_variable_table.sql",
"create_decision_table.sql",
"create_package_table.sql",
"create_metric_table.sql",
"initialize_metric_table.sql",
"create_package_metrics_table.sql",
"create_community_usage_metrics_table.sql",
"create_comments_table.sql"
Expand All @@ -34,13 +34,17 @@ create_db <- function(db_name){
# Append path to the queries.
queries <- file.path(path, queries)

queries <- purrr::map(queries, ~ scan(.x, sep = "\n", what = "character", blank.lines.skip = FALSE, quiet = TRUE) %>%
{split(.[nzchar(.)], cumsum(!nzchar(.))[nzchar(.)])} %>%
purrr::map(~ paste(.x, collapse = " "))) %>%
unlist()
# Apply each query.
sapply(queries, function(x){

tryCatch({
rs <- DBI::dbSendStatement(
con,
paste(scan(x, sep = "\n", what = "character"), collapse = ""))
x)
}, error = function(err) {
message <- paste("dbSendStatement",err)
message(message, .loggit = FALSE)
Expand Down
68 changes: 67 additions & 1 deletion inst/sql_queries/create_comments_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,4 +5,70 @@ CREATE TABLE IF NOT EXISTS comments (
comment CHAR,
comment_type CHAR,
added_on DATE
);
);

CREATE TABLE IF NOT EXISTS comments_audit_log (
id INTEGER PRIMARY KEY AUTOINCREMENT,
comment_id CHAR NOT NULL,
old_row_data JSON,
new_row_data JSON,
dml_type CHAR NOT NULL,
dml_timestamp DATETIME DEFAULT UTC_TIMESTAMP,
dml_created_by CHAR
);

CREATE TRIGGER comments_update_audit_trigger
AFTER UPDATE ON comments FOR EACH ROW
BEGIN
INSERT INTO comments_audit_log (
comment_id,
old_row_data,
new_row_data,
dml_type,
dml_created_by
)
VALUES(
NEW.id,
JSON_OBJECT(
"user_name", OLD.user_name,
"user_role", OLD.user_role,
"comment", OLD.comment,
"comment_type", OLD.comment_type,
"added_on", OLD.added_on
),
JSON_OBJECT(
"user_name", NEW.user_name,
"user_role", NEW.user_role,
"comment", NEW.comment,
"comment_type", NEW.comment_type,
"added_on", NEW.added_on
),
'UPDATE',
(SELECT user FROM _variables LIMIT 1)
);
END

CREATE TRIGGER comments_delete_audit_trigger
AFTER DELETE ON comments FOR EACH ROW
BEGIN
INSERT INTO comments_audit_log (
comment_id,
old_row_data,
new_row_data,
dml_type,
dml_created_by
)
VALUES(
OLD.id,
JSON_OBJECT(
"user_name", OLD.user_name,
"user_role", OLD.user_role,
"comment", OLD.comment,
"comment_type", OLD.comment_type,
"added_on", OLD.added_on
),
NULL,
'DELETE',
(SELECT user FROM _variables LIMIT 1)
);
END
41 changes: 40 additions & 1 deletion inst/sql_queries/create_decision_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,4 +4,43 @@ CREATE TABLE IF NOT EXISTS decision_categories (
color CHAR,
lower_limit DECIMAL(3, 2) NULL,
upper_limit DECIMAL(3, 2) NULL
);
);

CREATE TABLE IF NOT EXISTS decision_categories_audit_log (
id INTEGER PRIMARY KEY AUTOINCREMENT,
decision_categories_id INTEGER NOT NULL,
old_row_data JSON,
new_row_data JSON,
dml_type CHAR NOT NULL,
dml_timestamp DATETIME DEFAULT UTC_TIMESTAMP,
dml_created_by CHAR
);

CREATE TRIGGER decision_categories_update_audit_trigger
AFTER UPDATE ON decision_categories FOR EACH ROW
BEGIN
INSERT INTO decision_categories_audit_log (
decision_categories_id,
old_row_data,
new_row_data,
dml_type,
dml_created_by
)
VALUES(
NEW.id,
JSON_OBJECT(
"decision", OLD.decision,
"color", OLD.color,
"lower_limit", OLD.lower_limit,
"upper_limit", OLD.upper_limit
),
JSON_OBJECT(
"decision", NEW.decision,
"color", NEW.color,
"lower_limit", NEW.lower_limit,
"upper_limit", NEW.upper_limit
),
'UPDATE',
(SELECT user FROM _variables ORDER BY id DESC LIMIT 1)
);
END
51 changes: 50 additions & 1 deletion inst/sql_queries/create_metric_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,4 +7,53 @@ CREATE TABLE IF NOT EXISTS metric (
description CHAR,
class CHAR, /* class = maintenance or test */
weight REAL
);
);

INSERT INTO metric
(name, long_name, description, is_perc, is_url, class, weight)
VALUES
('has_vignettes', 'Vignettes', 'Number of vignettes', 0, 0, 'maintenance', 1),
('has_news', 'NEWS file', 'Number of NEWS files', 0, 0, 'maintenance', 1),
('news_current', 'NEWS current', 'NEWS contains current version', 0, 0, 'maintenance', 1),
('has_bug_reports_url', 'Report Bugs', 'URL to report bugs exists', 0, 0, 'maintenance', 1),
('has_website', 'Website', 'Package public website', 0, 1, 'maintenance', 1),
('has_maintainer', 'Maintainer', 'Package maintainers', 0, 0, 'maintenance', 1),
('has_source_control', 'Source Control', 'Package source control url', 0, 1, 'maintenance', 1),
('export_help', 'Documentation', '% of documented objects', 1, 0, 'maintenance', 1),
('bugs_status', 'Bugs Closure Rate', '% of the last 30 bugs closed', 1, 0, 'maintenance', 1),
('license', 'License', "Package's license", 0, 0, 'maintenance', 1),
('covr_coverage', 'Test Coverage', '% of objects tested', 1, 0, 'maintenance', 1),
('downloads_1yr', 'Downloads', 'Number of package downloads in the last year', 0, 0, 'community', 1)
;

CREATE TABLE IF NOT EXISTS metric_audit_log (
id INTEGER PRIMARY KEY AUTOINCREMENT,
metric_id INTEGER NOT NULL,
metric_name CHAR,
old_weight REAL,
new_weight REAL,
dml_type CHAR NOT NULL,
dml_timestamp DATETIME DEFAULT UTC_TIMESTAMP,
dml_created_by CHAR
);

CREATE TRIGGER metric_update_audit_trigger
AFTER UPDATE ON metric FOR EACH ROW
BEGIN
INSERT INTO metric_audit_log (
metric_id,
metric_name,
old_weight,
new_weight,
dml_type,
dml_created_by
)
VALUES(
NEW.id,
NEW.name,
OLD.weight,
NEW.weight,
'UPDATE',
(SELECT user FROM _variables ORDER BY id DESC LIMIT 1)
);
END
93 changes: 92 additions & 1 deletion inst/sql_queries/create_package_metrics_table.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,4 +8,95 @@ CREATE TABLE IF NOT EXISTS package_metrics (
encode BLOB,
FOREIGN KEY (package_id) REFERENCES package(id),
FOREIGN KEY (metric_id) REFERENCES metric(id)
);
);

CREATE TABLE IF NOT EXISTS package_metrics_audit_log (
id INTEGER PRIMARY KEY AUTOINCREMENT,
package_metrics_id INTEGER NOT NULL,
old_row_data JSON,
new_row_data JSON,
dml_type CHAR NOT NULL,
dml_timestamp DATETIME DEFAULT UTC_TIMESTAMP,
dml_created_by CHAR
);

CREATE TRIGGER package_metrics_insert_audit_trigger
AFTER INSERT ON package_metrics FOR EACH ROW
BEGIN
INSERT INTO package_metrics_audit_log (
package_metrics_id,
old_row_data,
new_row_data,
dml_type,
dml_created_by
)
VALUES(
NEW.id,
NULL,
JSON_OBJECT(
"package_id", NEW.package_id,
"package_name", (SELECT name FROM package WHERE id = NEW.package_id LIMIT 1),
"metric_id", NEW.metric_id,
"metric_name", (SELECT name FROM metric WHERE id = NEW.metric_id LIMIT 1),
"value", NEW.value
),
'INSERT',
(SELECT user FROM _variables ORDER BY id DESC LIMIT 1)
);
END

CREATE TRIGGER package_metrics_update_audit_trigger
AFTER UPDATE ON package_metrics FOR EACH ROW
BEGIN
INSERT INTO package_metrics_audit_log (
package_metrics_id,
old_row_data,
new_row_data,
dml_type,
dml_created_by
)
VALUES(
NEW.id,
JSON_OBJECT(
"package_id", OLD.package_id,
"package_name", (SELECT name FROM package WHERE id = OLD.package_id LIMIT 1),
"metric_id", OLD.metric_id,
"metric_name", (SELECT name FROM metric WHERE id = OLD.metric_id LIMIT 1),
"value", OLD.value
),
JSON_OBJECT(
"package_id", NEW.package_id,
"package_name", (SELECT name FROM package WHERE id = NEW.package_id LIMIT 1),
"metric_id", NEW.metric_id,
"metric_name", (SELECT name FROM metric WHERE id = NEW.metric_id LIMIT 1),
"value", NEW.value
),
'UPDATE',
(SELECT user FROM _variables ORDER BY id DESC LIMIT 1)
);
END

CREATE TRIGGER package_metrics_delete_audit_trigger
AFTER DELETE ON package_metrics FOR EACH ROW
BEGIN
INSERT INTO package_metrics_audit_log (
package_metrics_id,
old_row_data,
new_row_data,
dml_type,
dml_created_by
)
VALUES(
OLD.id,
JSON_OBJECT(
"package_id", OLD.package_id,
"package_name", (SELECT name FROM package WHERE id = OLD.package_id LIMIT 1),
"metric_id", OLD.metric_id,
"metric_name", (SELECT name FROM metric WHERE id = OLD.metric_id LIMIT 1),
"value", OLD.value
),
NULL,
'DELETE',
(SELECT user FROM _variables ORDER BY id DESC LIMIT 1)
);
END
Loading