From 05e21fda8e4864a3ccf28548794bc1f0646741b0 Mon Sep 17 00:00:00 2001 From: dtookey Date: Thu, 12 May 2022 09:56:08 -0400 Subject: [PATCH] migrated the sql scripts from the clarity-vitals project --- src/db/database-primitives.go | 15 +++++ src/mercury.go | 1 + src/mercury/Interconnect.go | 8 ++- src/sql/0-run-first/1-sanitize_init.sql | 21 +++++++ src/sql/0-run-first/all_projects.sql | 78 +++++++++++++++++++++++ src/sql/0-run-first/billing.sql | 27 ++++++++ src/sql/0-run-first/contributions.sql | 83 +++++++++++++++++++++++++ src/sql/0-run-first/durations.sql | 77 +++++++++++++++++++++++ src/sql/0-run-first/lifecycle.sql | 12 ++++ 9 files changed, 320 insertions(+), 2 deletions(-) create mode 100644 src/sql/0-run-first/1-sanitize_init.sql create mode 100644 src/sql/0-run-first/all_projects.sql create mode 100644 src/sql/0-run-first/billing.sql create mode 100644 src/sql/0-run-first/contributions.sql create mode 100644 src/sql/0-run-first/durations.sql create mode 100644 src/sql/0-run-first/lifecycle.sql diff --git a/src/db/database-primitives.go b/src/db/database-primitives.go index 55da0d2..72cee8c 100644 --- a/src/db/database-primitives.go +++ b/src/db/database-primitives.go @@ -82,6 +82,21 @@ func (c *ConnectorGeneric) QueryFromScript(scriptName string) *sql.Rows { return rows } +func (c *ConnectorGeneric) ProcessClarityScripts() { //@dream standardize these script names + tableCreationRunners := []*sqlScriptRunner{ + NewRunner("1-sanitize_init.sql", ClarityDatabaseName), + NewRunner("all_projects.sql", ClarityDatabaseName), + NewRunner("billing.sql", ClarityDatabaseName), + NewRunner("contributions.sql", ClarityDatabaseName), + NewRunner("durations.sql", ClarityDatabaseName), + NewRunner("lifecycle.sql", ClarityDatabaseName), + } + + for _, runner := range tableCreationRunners { + c.ExecuteSqlScript(runner) + } +} + func (c *ConnectorGeneric) CreateTables() { tableCreationRunners := []*sqlScriptRunner{ NewRunner("create-any-database.sql", ""), diff --git a/src/mercury.go b/src/mercury.go index 18bf0ef..9b86a82 100644 --- a/src/mercury.go +++ b/src/mercury.go @@ -32,6 +32,7 @@ func test() { func updateInsightData() { icx := mercury.NewInterconnect() + icx.Init() icx.UpdateUsers() icx.UpdateTimeEntries() } diff --git a/src/mercury/Interconnect.go b/src/mercury/Interconnect.go index 8ca346a..f6e8130 100644 --- a/src/mercury/Interconnect.go +++ b/src/mercury/Interconnect.go @@ -20,11 +20,15 @@ type Interconnect struct { func NewInterconnect() *Interconnect { connect := Interconnect{} connect.Client = projectInsight.NewIClient() - connect.InsightDBConnector = projectInsight.NewDBConnection() - connect.InsightDBConnector.ConnectorGeneric.CreateTables() return &connect } +func (ic *Interconnect) Init() { + ic.InsightDBConnector = projectInsight.NewDBConnection() + ic.InsightDBConnector.ConnectorGeneric.ProcessClarityScripts() + ic.InsightDBConnector.ConnectorGeneric.CreateTables() +} + func (ic *Interconnect) ResetTables() { ic.InsightDBConnector.CreateTables() } diff --git a/src/sql/0-run-first/1-sanitize_init.sql b/src/sql/0-run-first/1-sanitize_init.sql new file mode 100644 index 0000000..cfe8ec9 --- /dev/null +++ b/src/sql/0-run-first/1-sanitize_init.sql @@ -0,0 +1,21 @@ +DROP TABLE IF EXISTS tokens; + +CREATE OR REPLACE INDEX billing_refnum ON billing (refNumber); + +-- noinspection SqlWithoutWhere +UPDATE users SET hash = ''; + +UPDATE project_lifecycle SET new_value = '+CREATED', changed_column = 'status' WHERE changed_column = 'created'; +DELETE FROM project_lifecycle WHERE project_number = 'EVENT'; + +#TIMEZONE FIX +# we'll store the roll amount as a single variable +SET @roll = 4; +UPDATE billing set accepted_date = accepted_date - INTERVAL @roll HOUR, line_created = line_created - INTERVAL @roll HOUR; +UPDATE dispatch SET date_dispatched = date_dispatched - INTERVAL @roll HOUR; +UPDATE project_comments set timestamp = timestamp - INTERVAL @roll HOUR; +UPDATE project_lifecycle SET timestamp = timestamp - INTERVAL @roll HOUR; + +ALTER TABLE project_lifecycle ADD COLUMN id INT AUTO_INCREMENT KEY FIRST; +CREATE OR REPLACE INDEX lifecycle_timestamp on project_lifecycle (timestamp); +CREATE OR REPLACE INDEX lifecycle_newval on project_lifecycle (new_value); \ No newline at end of file diff --git a/src/sql/0-run-first/all_projects.sql b/src/sql/0-run-first/all_projects.sql new file mode 100644 index 0000000..a737813 --- /dev/null +++ b/src/sql/0-run-first/all_projects.sql @@ -0,0 +1,78 @@ +DROP VIEW IF EXISTS all_projects; +DROP TABLE IF EXISTS all_projects; + + +#todo we have to find out how to generate this from the info on tablemetadata +CREATE TABLE all_projects AS +SELECT * +FROM CLT2019 +UNION +SELECT * +FROM CLT2020 +UNION +SELECT * +FROM CLT2021 +UNION +SELECT * +FROM CLT2022 +UNION +SELECT * +FROM RDU2019 +UNION +SELECT * +FROM RDU2020 +UNION +SELECT * +FROM RDU2021 +UNION +SELECT * +FROM RDU2022 +UNION +SELECT * +FROM ENV2020 +UNION +SELECT * +FROM ENV2021 +UNION +SELECT * +FROM ENV2022 +UNION +SELECT * +FROM SRV2020 +UNION +SELECT * +FROM SRV2021; + +CREATE UNIQUE INDEX ref_num ON all_projects (refnum); +CREATE INDEX project_flavor ON all_projects (proj_type); + + +UPDATE all_projects +SET description = TRIM(BOTH ' ' FROM description) +WHERE description RLIKE '^ ' + OR description RLIKE ' $'; + +UPDATE all_projects +SET description = 'Soil/Footings' +WHERE description IN + ( + 'Soil/Footings - Revisit #1', + 'Soils/Footings', + 'Soils/Footings - Revisit #1', + 'Soils/Footings - Revisit #1' + ); + +UPDATE all_projects +SET description = 'Framing Items' +WHERE description IN + ( + 'Framing Item' + ); + +UPDATE all_projects +SET description = '3rd Party Footing Inspection' +WHERE description IN + ( + '3rd Party Footing Preparation Inspection' + '3rd Party Footing Preparation Inspection - Revisit #1' + ); diff --git a/src/sql/0-run-first/billing.sql b/src/sql/0-run-first/billing.sql new file mode 100644 index 0000000..94e834e --- /dev/null +++ b/src/sql/0-run-first/billing.sql @@ -0,0 +1,27 @@ +DROP TABLE IF EXISTS billing_report; + +CREATE TABLE billing_report AS +SELECT billing.pkey, + refNumber, + (SELECT all_projects.proj_type from all_projects where all_projects.refnum = refNumber) AS division, + line_created, + accepted_date, + (qty * default_price) AS fee, + invoice_accepted, + clients.name as Client +FROM billing + INNER JOIN all_projects on billing.refNumber = all_projects.refnum + INNER JOIN contacts on all_projects.contact_fkey = contacts.pkey + INNER JOIN clients on contacts.cl_fkey = clients.pkey +where invoice_accepted = 1; + +CREATE INDEX ref_num ON billing_report (refNumber); +CREATE INDEX div_idx ON billing_report (division); + + +UPDATE billing_report +SET division = IF( + division = 'Warranty', + CONCAT(SUBSTRING(refNumber, 1, 3), ' - ', 'Structural'), + CONCAT(SUBSTRING(refNumber, 1, 3), ' - ', division) + ); diff --git a/src/sql/0-run-first/contributions.sql b/src/sql/0-run-first/contributions.sql new file mode 100644 index 0000000..5d72379 --- /dev/null +++ b/src/sql/0-run-first/contributions.sql @@ -0,0 +1,83 @@ +DROP TABLE IF EXISTS engineer_contributions; + +#########################Engineer Contributions######################################################################## + + +CREATE TABLE engineer_contributions AS +SELECT CONCAT(users.lname, ', ', users.fname) AS `Engineer`, + users.email, + project_lifecycle.project_number AS `ProjectNumber`, + project_lifecycle.timestamp, + new_value AS `ActionType`, + CONCAT(SUBSTR(project_lifecycle.project_number, 1, 3), ' - ', + IF(ap.proj_type = 'Warranty', 'Structural', ap.proj_type)) AS `Region`, + clients.name AS `Client`, + ap.description AS `Description` +FROM users + INNER JOIN project_lifecycle ON pkey = modifier + INNER JOIN all_projects ap on project_lifecycle.project_number = ap.refnum + INNER JOIN contacts on ap.contact_fkey = contacts.pkey + INNER JOIN clients on contacts.cl_fkey = clients.pkey +WHERE project_lifecycle.new_value IN ('+SEALED') + AND users.priv & POW(2, 25) > 0; + + +ALTER TABLE engineer_contributions + ADD COLUMN IF NOT EXISTS id INT AUTO_INCREMENT KEY FIRST; + +#https://stackoverflow.com/a/9639548 +DELETE +FROM engineer_contributions +WHERE id IN (SELECT bad_rows.id + FROM engineer_contributions AS bad_rows + INNER JOIN (SELECT engineer_contributions.`ProjectNumber`, MAX(id) as min_id + FROM engineer_contributions + GROUP BY engineer_contributions.`ProjectNumber` + HAVING count(*) > 1) AS good_rows + ON good_rows.`ProjectNumber` = + bad_rows.`ProjectNumber` + AND good_rows.min_id <> bad_rows.id); + +ALTER TABLE engineer_contributions + DROP COLUMN IF EXISTS id; + +#########################Soil Contributions############################################################################# +DROP TABLE IF EXISTS rdu_soil_contributions; + + +CREATE TABLE rdu_soil_contributions AS +SELECT CONCAT(users.email) AS `Technician`, + project_lifecycle.project_number AS `ProjectNumber`, + project_lifecycle.timestamp, + new_value AS `ActionType`, + 'RDU - Soil' AS `Region`, + clients.name AS `Client`, + ap.description AS `Description` +FROM users + INNER JOIN project_lifecycle ON pkey = modifier + INNER JOIN all_projects ap on project_lifecycle.project_number = ap.refnum + INNER JOIN contacts on ap.contact_fkey = contacts.pkey + INNER JOIN clients on contacts.cl_fkey = clients.pkey +WHERE project_lifecycle.new_value IN ('+READY_FOR_REVIEW') + AND SUBSTR(ap.refnum, 1, 3) = 'RDU' + AND ap.proj_type = 'Soil'; + + +ALTER TABLE rdu_soil_contributions + ADD COLUMN IF NOT EXISTS id INT AUTO_INCREMENT KEY FIRST; + + +DELETE +FROM rdu_soil_contributions +WHERE id IN (SELECT bad_rows.id + FROM rdu_soil_contributions AS bad_rows + INNER JOIN (SELECT rdu_soil_contributions.`ProjectNumber`, MAX(id) as min_id + FROM rdu_soil_contributions + GROUP BY rdu_soil_contributions.`ProjectNumber` + HAVING count(*) > 1) AS good_rows + ON good_rows.`ProjectNumber` = + bad_rows.`ProjectNumber` + AND good_rows.min_id <> bad_rows.id); + +ALTER TABLE rdu_soil_contributions + DROP COLUMN IF EXISTS id; diff --git a/src/sql/0-run-first/durations.sql b/src/sql/0-run-first/durations.sql new file mode 100644 index 0000000..08d5be7 --- /dev/null +++ b/src/sql/0-run-first/durations.sql @@ -0,0 +1,77 @@ +CREATE OR REPLACE TABLE lifecycle_times +( + id int primary key auto_increment, + project_number varchar(25), + created datetime, + ready_for_review datetime, + ready_for_review_two datetime, + ready_for_deliver datetime, + sealed datetime, + delivered datetime, + has_been_invoiced datetime, + ready_to_invoice datetime +); +CREATE OR REPLACE INDEX lifetimes_refnum on project_lifecycle (project_number); + + +INSERT INTO lifecycle_times (project_number) +SELECT DISTINCT project_number +FROM project_lifecycle; + + +UPDATE lifecycle_times +set created = (SELECT timestamp + from project_lifecycle + where new_value = '+CREATED' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1), + ready_for_review = (SELECT timestamp + from project_lifecycle + where new_value = '+READY_FOR_REVIEW' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1), + ready_for_review_two = (SELECT timestamp + from project_lifecycle + where new_value = '+READY_FOR_REVIEW2' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1), + ready_for_deliver = (SELECT timestamp + from project_lifecycle + where new_value = '+READY_FOR_DELIVER' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1), + ready_for_deliver = (SELECT timestamp + from project_lifecycle + where new_value = '+READY_FOR_DELIVER' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1), + sealed = (SELECT timestamp + from project_lifecycle + where new_value = '+SEALED' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1), + delivered = (SELECT timestamp + from project_lifecycle + where new_value = '+DELIVERED' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1), + has_been_invoiced = (SELECT timestamp + from project_lifecycle + where new_value = '+HAS_BEEN_INVOICED' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1), + ready_to_invoice = (SELECT timestamp + from project_lifecycle + where new_value = '+READY_TO_INVOICE' + and project_lifecycle.project_number = lifecycle_times.project_number + order by timestamp desc + limit 1) +; \ No newline at end of file diff --git a/src/sql/0-run-first/lifecycle.sql b/src/sql/0-run-first/lifecycle.sql new file mode 100644 index 0000000..10ca2f0 --- /dev/null +++ b/src/sql/0-run-first/lifecycle.sql @@ -0,0 +1,12 @@ +DROP TABLE IF EXISTS event_counts; + +CREATE TABLE event_counts AS +SELECT DATE(timestamp) AS event_date, + all_projects.proj_type AS division_raw, + SUBSTRING(all_projects.refnum, 1, 3) AS prefix, + if(SUBSTRING(new_value, 1, 1) = '+', 1, -1) AS event_count, + SUBSTRING(`new_value` FROM 2) AS flag +FROM project_lifecycle + INNER JOIN all_projects ON project_lifecycle.project_number = all_projects.refnum +WHERE changed_column = 'status'; +