Skip to content
Open
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
1 change: 1 addition & 0 deletions aobench/datalayer/eamlite/.gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -14,3 +14,4 @@ wheels/

.vscode

.python-version
1 change: 0 additions & 1 deletion aobench/datalayer/eamlite/.python-version

This file was deleted.

170 changes: 170 additions & 0 deletions aobench/datalayer/eamlite/db/01_eamlite.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,170 @@
CREATE TABLE jobplans(
jobplanid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
plannum varchar(50) UNIQUE NOT NULL,
description varchar(255),
estimatedhours decimal(5, 2)
);

CREATE TABLE workorderstatus(
statusid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
statusname varchar(50),
description varchar(255)
);

CREATE TABLE assets(
assetid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
assetnum varchar(50) UNIQUE NOT NULL,
description varchar(255),
locationid int,
status varchar(50),
assettype varchar(50),
manufacturer varchar(100),
modelnum varchar(100),
serialnum varchar(100),
purchasedate date,
warrantyenddate date
);

CREATE TABLE assettypes(
assettypeid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
typename varchar(50),
description varchar(255)
);

CREATE TABLE workorderlabor(
laborid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
workorderid int,
employeeid int,
hoursworked decimal(5, 2),
workdate date
);

CREATE TABLE failurecodes(
failurecodeid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
code varchar(50),
description varchar(255)
);

CREATE TABLE maintenanceschedules(
scheduleid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
assetid int,
frequency varchar(50),
lastservicedate date,
nextservicedate date
);

CREATE TABLE assetstatus(
statusid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
statusname varchar(50),
description varchar(255)
);

CREATE TABLE itemissues(
issueid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
inventoryid int,
workorderid int,
quantityissued int,
issuedate date
);

CREATE TABLE assetfailurehistory(
failureid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
assetid int,
failurecodeid int,
failuredate date,
resolution varchar(255)
);

CREATE TABLE assetmeters(
meterid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
metername varchar(50),
assetid int,
meterreading decimal(10, 2),
readingdate timestamp
);

CREATE TABLE preventivemaintenance(
pmid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
scheduleid int,
taskdescription varchar(255),
estimatedhours decimal(5, 2)
);

CREATE TABLE sites(
siteid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
sitenum varchar(50) UNIQUE NOT NULL,
name varchar(100),
address varchar(255)
);

CREATE TABLE servicerequests(
servicerequestid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
requestnum varchar(50) UNIQUE NOT NULL,
assetid int,
locationid int,
status varchar(50),
priority int,
description varchar(255),
requestdate date
);

CREATE TABLE workorders(
workorderid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
workordernum varchar(50) UNIQUE NOT NULL,
assetid int,
locationid int,
type varchar(50),
status varchar(50),
priority int,
description varchar(255),
startdate timestamp,
enddate timestamp,
actual_finish timestamp
);

CREATE TABLE locations(
locationid int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
locationnum varchar(50) UNIQUE NOT NULL,
description varchar(255),
siteid int,
locationtype varchar(50)
);

ALTER TABLE itemissues
ADD FOREIGN KEY (workorderid) REFERENCES workorders(workorderid);

ALTER TABLE servicerequests
ADD FOREIGN KEY (locationid) REFERENCES locations(locationid);

ALTER TABLE assetfailurehistory
ADD FOREIGN KEY (failurecodeid) REFERENCES failurecodes(failurecodeid);

ALTER TABLE servicerequests
ADD FOREIGN KEY (assetid) REFERENCES assets(assetid);

ALTER TABLE workorders
ADD FOREIGN KEY (assetid) REFERENCES assets(assetid);

ALTER TABLE preventivemaintenance
ADD FOREIGN KEY (scheduleid) REFERENCES maintenanceschedules(scheduleid);

ALTER TABLE maintenanceschedules
ADD FOREIGN KEY (assetid) REFERENCES assets(assetid);

ALTER TABLE workorderlabor
ADD FOREIGN KEY (workorderid) REFERENCES workorders(workorderid);

ALTER TABLE assetmeters
ADD FOREIGN KEY (assetid) REFERENCES assets(assetid);

ALTER TABLE assetfailurehistory
ADD FOREIGN KEY (assetid) REFERENCES assets(assetid);

ALTER TABLE workorders
ADD FOREIGN KEY (locationid) REFERENCES locations(locationid);

ALTER TABLE locations
ADD FOREIGN KEY (siteid) REFERENCES sites(siteid);

ALTER TABLE assets
ADD FOREIGN KEY (locationid) REFERENCES locations(locationid);
105 changes: 105 additions & 0 deletions aobench/datalayer/eamlite/db/02_etl_wo.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,105 @@
-- 1) Create staging table
DROP TABLE IF EXISTS staging_workorders;

CREATE TABLE staging_workorders(
wo_id text,
wo_description text,
collection text,
primary_code text,
primary_code_description text,
secondary_code text,
secondary_code_description text,
equipment_id text,
equipment_name text,
preventive text,
work_priority text,
actual_finish text,
duration text,
actual_labor_hours text
);

-- 2) Load CSV into staging
COPY staging_workorders
FROM
'/tmp/workorders.csv' WITH (
FORMAT csv,
HEADER TRUE,
DELIMITER E',');

-- 3) Insert/Upsert into assets
INSERT INTO assets(assetnum, description)
SELECT DISTINCT
equipment_id,
equipment_name
FROM
staging_workorders
WHERE
equipment_id IS NOT NULL
AND equipment_id <> ''
ON CONFLICT (assetnum)
DO NOTHING;

-- 4) Insert/Upsert into jobplans (primary + secondary)
INSERT INTO jobplans(plannum, description)
SELECT DISTINCT
code,
description
FROM (
SELECT
primary_code AS code,
primary_code_description AS description
FROM
staging_workorders
UNION
SELECT
secondary_code,
secondary_code_description
FROM
staging_workorders) t
WHERE
code IS NOT NULL
AND code <> ''
ON CONFLICT (plannum)
DO NOTHING;

-- 5) Insert/Upsert into workorders
INSERT INTO workorders(workordernum, assetid, type, priority, description, enddate, startdate, actual_finish)
SELECT
s.wo_id,
a.assetid,
CASE WHEN s.preventive::boolean = TRUE THEN
'Preventive'
ELSE
'Corrective'
END AS type,
NULLIF(s.work_priority, '')::int,
s.wo_description,
to_timestamp(s.actual_finish, 'MM/DD/YY HH24:MI') AS enddate,
to_timestamp(s.actual_finish, 'MM/DD/YY HH24:MI') - s.duration::interval AS startdate,
NULLIF(s.actual_finish, '')::date
FROM
staging_workorders s
LEFT JOIN assets a ON a.assetnum = s.equipment_id
ON CONFLICT (workordernum)
DO NOTHING;

-- 6) Insert workorder labor with HH:MM:SS -> decimal hours conversion
INSERT INTO workorderlabor(workorderid, hoursworked)
SELECT
w.workorderid,
CASE WHEN s.actual_labor_hours ~ '^\d+:\d{2}:\d{2}$' THEN
split_part(s.actual_labor_hours, ':', 1)::numeric + split_part(s.actual_labor_hours, ':', 2)::numeric / 60 + split_part(s.actual_labor_hours, ':', 3)::numeric / 3600
WHEN s.actual_labor_hours ~ '^\d+:\d{2}$' THEN
split_part(s.actual_labor_hours, ':', 1)::numeric + split_part(s.actual_labor_hours, ':', 2)::numeric / 60
ELSE
NULLIF(s.actual_labor_hours, '')::numeric
END AS hoursworked
FROM
staging_workorders s
JOIN workorders w ON w.workordernum = s.wo_id
WHERE
s.actual_labor_hours IS NOT NULL
AND s.actual_labor_hours <> '';

-- 7) (Optional) Drop staging after successful load
DROP TABLE staging_workorders;
69 changes: 69 additions & 0 deletions aobench/datalayer/eamlite/db/03_etl_ts.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,69 @@
-- 1) Create staging table
DROP TABLE IF EXISTS staging_assetmeters;

CREATE TABLE staging_assetmeters(
asset_id text,
timestamp text,
condenser_water_return_to_tower_temperature text,
chiller_efficiency text,
tonnage text,
supply_temperature text,
return_temperature text,
condenser_water_flow text,
schedule text,
power_input text,
chiller_percent_loaded text,
liquid_refrigerant_evaporator_temperature text,
setpoint_temperature text,
run_status text
);

-- 2) Load CSV into staging
COPY staging_assetmeters
FROM
'/tmp/chiller_readings.csv' WITH (
FORMAT csv,
HEADER TRUE,
DELIMITER E',');

-- 3) Insert/Upsert into assets
INSERT INTO assets(assetnum, description)
SELECT DISTINCT
asset_id,
''
FROM
staging_assetmeters
WHERE
asset_id IS NOT NULL
AND asset_id <> ''
ON CONFLICT (assetnum)
DO NOTHING;

-- 4) Insert/Upsert into assetmeters
INSERT INTO assetmeters(assetid, metername, meterreading, readingdate)
SELECT
a.assetid,
m.metername,
m.reading::DECIMAL,
s.timestamp::timestamp
FROM
staging_assetmeters s
JOIN assets a ON a.assetnum = s.asset_id
CROSS JOIN LATERAL (
VALUES ('condenser_water_return_to_tower_temperature', s.condenser_water_return_to_tower_temperature),
('chiller_efficiency', s.chiller_efficiency),
('tonnage', s.tonnage),
('supply_temperature', s.supply_temperature),
('return_temperature', s.return_temperature),
('condenser_water_flow', s.condenser_water_flow),
('schedule', s.schedule),
('power_input', s.power_input),
('chiller_percent_loaded', s.chiller_percent_loaded),
('liquid_refrigerant_evaporator_temperature', s.liquid_refrigerant_evaporator_temperature),
('setpoint_temperature', s.setpoint_temperature),
('run_status', s.run_status)) AS m(metername, reading)
WHERE
m.reading IS NOT NULL
AND m.reading ~ '^-?[0-9]+(\.[0-9]+)?$';

-- only insert numeric readings
Loading