diff --git a/database/start-scripts/0-init.sql b/database/start-scripts/0-init.sql index 3f65f3e..f0431f9 100644 --- a/database/start-scripts/0-init.sql +++ b/database/start-scripts/0-init.sql @@ -57,36 +57,32 @@ create table tree_types ( family varchar(255) not null, genus varchar(255) not null, species varchar(255) unique, - photo_id int, created_at timestamp default current_timestamp, updated_at timestamp, deleted_at timestamp, - foreign key (photo_id) references photos(id), constraint UC_TreeType unique (family, genus, species) ); -create table task_types ( +create table tasks ( id int auto_increment primary key, name varchar(255) unique, - photo_id int, + description varchar(255), + require_tree_type boolean default false, created_at timestamp default current_timestamp, updated_at timestamp, - deleted_at timestamp, - foreign key (photo_id) references photos(id) + deleted_at timestamp ); -create table pruning_types ( +create table element_types ( id int auto_increment primary key, - name varchar(20) unique, + name varchar(255) not null, description varchar(255), - photo_id int, created_at timestamp default current_timestamp, updated_at timestamp, - deleted_at timestamp, - foreign key (photo_id) references photos(id) + deleted_at timestamp ); ---* Points, zones and routes +--* Points and zones create table points ( id int auto_increment primary key, latitude decimal(10, 7) not null, @@ -99,60 +95,36 @@ create table points ( create table zones ( id int auto_increment primary key, - point_id int, - created_at timestamp default current_timestamp, - updated_at timestamp, - deleted_at timestamp, - foreign key (point_id) references points(id) -); - -create table zones_predefined ( - id int auto_increment primary key, - zone_id int unique, name varchar(255) not null, - photo_id int, + point_id int, + contract_id int, + city varchar(255), + element_type_id int, + amount int, created_at timestamp default current_timestamp, updated_at timestamp, deleted_at timestamp, - foreign key (zone_id) references zones(id), - foreign key (photo_id) references photos(id), - constraint UC_ZonePredefined unique (zone_id, name) -); - -create table routes ( - id int auto_increment primary key, - distance float, - travel_time int, - created_at timestamp default current_timestamp, - updated_at timestamp, - deleted_at timestamp -); - -create table route_points ( - id int auto_increment primary key, - route_id int not null, - point_id int not null, - point_order int not null, - created_at timestamp default current_timestamp, - foreign key (route_id) references routes(id), - foreign key (point_id) references points(id) + foreign key (point_id) references points(id), + foreign key (contract_id) references contracts(id), + foreign key (element_type_id) references element_types(id) ); --* Elements and incidences create table elements ( id int auto_increment primary key, - name varchar(255) not null, + element_type_id int not null, contract_id int not null, zone_id int not null, - -- point_id int unique, - tree_type_id int not null, + point_id int unique, + tree_type_id int null, created_at timestamp default current_timestamp, updated_at timestamp, deleted_at timestamp, foreign key (contract_id) references contracts(id), foreign key (zone_id) references zones(id), - -- foreign key (point_id) references points(id), - foreign key (tree_type_id) references tree_types(id) + foreign key (point_id) references points(id), + foreign key (tree_type_id) references tree_types(id), + foreign key (element_type_id) references element_types(id) ); create table incidences ( @@ -160,62 +132,71 @@ create table incidences ( element_id int not null, name varchar(255) not null, description varchar(255), + photo_id int, created_at timestamp default current_timestamp, updated_at timestamp, deleted_at timestamp, - foreign key (element_id) references elements(id) -); - -create table incidence_photos ( - id int auto_increment primary key, - incidence_id int not null, - photo_id int not null, - created_at timestamp default current_timestamp, - foreign key (incidence_id) references incidences(id), - foreign key (photo_id) references photos(id), - constraint UC_IncidencePhoto unique (incidence_id, photo_id) + foreign key (element_id) references elements(id), + foreign key (photo_id) references photos(id) ); --* Work orders, tasks and reports create table work_orders ( id int auto_increment primary key, contract_id int, + date timestamp, created_at timestamp default current_timestamp, updated_at timestamp, deleted_at timestamp, foreign key (contract_id) references contracts(id) ); -create table tasks ( +create table work_orders_users ( id int auto_increment primary key, work_order_id int not null, - task_type_id int not null, - notes varchar(255), - route_id int, + user_id int not null, created_at timestamp default current_timestamp, updated_at timestamp, deleted_at timestamp, foreign key (work_order_id) references work_orders(id), - foreign key (task_type_id) references task_types(id), - foreign key (route_id) references routes(id) + foreign key (user_id) references users(id), + constraint UC_WorkOrderUser unique (work_order_id, user_id) ); -create table tasks_users ( +create table work_orders_blocks ( id int auto_increment primary key, - task_id int, - user_id int, + work_order_id int not null, + notes varchar(255), created_at timestamp default current_timestamp, - foreign key (task_id) references tasks(id), - foreign key (user_id) references users(id) + updated_at timestamp, + deleted_at timestamp, + foreign key (work_order_id) references work_orders(id) ); -create table tasks_zones ( +create table work_orders_blocks_zones ( id int auto_increment primary key, - task_id int, - zone_id int, + work_orders_block_id int not null, + zone_id int not null, created_at timestamp default current_timestamp, + updated_at timestamp, + deleted_at timestamp, + foreign key (work_orders_block_id) references work_orders_blocks(id), + foreign key (zone_id) references zones(id), + constraint UC_WorkOrderBlockZone unique (work_orders_block_id, zone_id) +); + +create table work_orders_blocks_tasks ( + id int auto_increment primary key, + work_orders_block_id int not null, + task_id int not null, + tree_type_id int, + status int default 0, + created_at timestamp default current_timestamp, + updated_at timestamp, + deleted_at timestamp, + foreign key (work_orders_block_id) references work_orders_blocks(id), foreign key (task_id) references tasks(id), - foreign key (zone_id) references zones(id) + foreign key (tree_type_id) references tree_types(id) ); create table work_reports ( @@ -225,6 +206,7 @@ create table work_reports ( spent_fuel decimal, created_at timestamp default current_timestamp, updated_at timestamp, + deleted_at timestamp, foreign key (work_order_id) references work_orders(id) ); @@ -233,6 +215,8 @@ create table work_report_photos ( work_report_id int not null, photo_id int not null, created_at timestamp default current_timestamp, + updated_at timestamp, + deleted_at timestamp, foreign key (work_report_id) references work_reports(id), foreign key (photo_id) references photos(id), constraint UC_WorkReportPhoto unique (work_report_id, photo_id) @@ -247,6 +231,8 @@ create table sensors ( model varchar(255), is_active boolean, created_at timestamp default current_timestamp, + updated_at timestamp, + deleted_at timestamp, foreign key (contract_id) references contracts(id), foreign key (zone_id) references zones(id), foreign key (point_id) references points(id), @@ -260,6 +246,8 @@ create table sensor_history ( humidity float, inclination float, created_at timestamp default current_timestamp, + updated_at timestamp, + deleted_at timestamp, foreign key (sensor_id) references sensors(id), constraint UC_SensorHistory unique (sensor_id, created_at) ); diff --git a/database/start-scripts/1-seed.sql b/database/start-scripts/1-seed.sql index 0376755..fcfcf7a 100644 --- a/database/start-scripts/1-seed.sql +++ b/database/start-scripts/1-seed.sql @@ -1,86 +1,106 @@ ---* Users, contracts and machines +--* Users INSERT INTO users (company, name, surname, dni, password, email, role) VALUES ('TechCorp', 'Carlos', 'García', '12345678A', 'hashedpassword1', 'carlos.garcia@example.com', 1), ('InnovaTech', 'Ana', 'Martínez', '23456789B', 'hashedpassword2', 'ana.martinez@example.com', 1), ('DesignWorks', 'José', 'Rodríguez', '34567890C', 'hashedpassword3', 'jose.rodriguez@example.com', 2); + +--* Contracts INSERT INTO contracts (name, start_date, end_date, invoice_proposed, invoice_agreed, invoice_paid) VALUES ('Ayuntamiento de Valencia', '2021-01-01', '2021-12-31', 1000.00, 900.00, 900.00), ('Administración General del Estado', '2021-01-01', '2021-12-31', 2000.00, 1800.00, 1800.00), ('Ayuntamiento de Carlet', '2021-01-01', '2021-12-31', 3000.00, 2700.00, 2700.00); + +--* Machines INSERT INTO machines (name, max_basket_size) VALUES ('Cesta elevadora', 200.00), ('Plataforma elevadora', 300.00), ('Tijera elevadora', 400.00); ---* Tree, task and pruning types + +--* Element Types +INSERT INTO element_types (name, description) VALUES +('Árbol', 'Elemento tipo árbol'), +('Banco', 'Elemento tipo banco'), +('Fuente', 'Elemento tipo fuente'); + +--* Tree Types INSERT INTO tree_types (family, genus, species) VALUES ('Fagaceae', 'Quercus', 'Quercus robur'), ('Pinaceae', 'Pinus', 'Pinus sylvestris'), ('Sapindaceae', 'Acer', 'Acer campestre'); -INSERT INTO task_types (name) VALUES -('Abono arbustos'), -('Podar setos'), -('Abono setos'); -INSERT INTO pruning_types (name, description) VALUES -('A', 'Poda de mantenimiento en árbol tipo A, caduco, de p.c. entre 41/80 cm.'), -('B', 'Poda de mantenimiento en árbol tipo B, caduco, de p.c. mayor de 81 cm.'), -('C', 'Poda de mantenimiento en árbol tipo C, perenne, de p.c. entre 41/60 cm.'); ---* Points, zones and routes + +--* Tasks +INSERT INTO tasks (name, description, require_tree_type) VALUES +('Podar árboles', 'Tarea de poda general', TRUE), +('Riego de árboles', 'Riego programado', FALSE), +('Fertilización', 'Fertilización básica', NULL); + +--* Points INSERT INTO points (latitude, longitude) VALUES (40.416775, -3.703790), (40.416776, -3.703795), (40.416777, -3.703800); -INSERT INTO zones (point_id) VALUES -(1), -(2), -(3); -INSERT INTO zones_predefined (zone_id, name) VALUES -(1, 'Zona 1'), -(3, 'Zona 3'); -INSERT INTO routes (distance, travel_time) VALUES -(1000, 60), -(2000, 120), -(3000, 180); -INSERT INTO route_points (route_id, point_id, point_order) VALUES -(1, 1, 1), -(1, 2, 2), -(1, 3, 3), -(2, 3, 1), -(2, 2, 2), -(2, 1, 3), -(3, 1, 1), -(3, 3, 2), -(3, 2, 3); ---* Elements and incidences -INSERT INTO elements (name, contract_id, zone_id, tree_type_id) VALUES -('Árbol 1', 1, 1, 1), -('Árbol 2', 2, 2, 2), -('Árbol 3', 3, 3, 3); -INSERT INTO incidences (name, element_id, description) VALUES -('Rama caída', 1, 'Rama caída en el suelo'), -('Banco roto', 2, 'Banco roto en el parque'), -('Fuente sin agua', 3, 'Fuente sin agua en el parque'), -('Árbol enfermo', 1, 'Árbol con signos de enfermedad'), -('Banco pintado', 2, 'Banco pintado con grafitis'), -('Fuente con fuga', 3, 'Fuente con fuga de agua'); ---* Work orders, tasks and reports + +--* Zones +INSERT INTO zones (name, point_id, contract_id, city, element_type_id, amount) VALUES +('Zona Norte', 1, 1, 'Madrid', 1, 50), +('Zona Sur', 2, 2, 'Barcelona', 2, 30), +('Zona Este', 3, 3, 'Valencia', 3, 20); + +--* Elements +INSERT INTO elements (element_type_id, contract_id, zone_id, point_id, tree_type_id) VALUES +(1, 1, 1, 1, 1), +(2, 2, 2, 2, NULL), +(3, 3, 3, 3, NULL); + +--* Incidences +INSERT INTO incidences (element_id, name, description) VALUES +(1, 'Rama caída', 'Rama caída en el suelo'), +(2, 'Banco roto', 'Banco roto en el parque'), +(3, 'Fuente sin agua', 'Fuente sin agua en el parque'); + +--* Work Orders INSERT INTO work_orders (contract_id) VALUES (1), (2), (3); -INSERT INTO tasks (work_order_id, task_type_id, notes) VALUES -(1, 1, 'Poda de mantenimiento en árbol tipo A, caduco, de p.c. entre 41/80 cm.'), -(2, 2, 'Poda de mantenimiento en árbol tipo B, caduco, de p.c. entre 50/100 cm.'), -(3, 3, 'Poda de mantenimiento en árbol tipo C, caduco, de p.c. entre 60/120 cm.'); -INSERT INTO tasks_zones (task_id, zone_id) VALUES + +--* Work Orders Users +INSERT INTO work_orders_users (work_order_id, user_id) VALUES (1, 1), (2, 2), (3, 3); -INSERT INTO tasks_users (task_id, user_id) VALUES + +--* Work Reports +INSERT INTO work_reports (work_order_id, observation, spent_fuel) VALUES +(1, 'Observación de la orden 1', 50.0), +(2, 'Observación de la orden 2', 60.0), +(3, 'Observación de la orden 3', 70.0); + +--* Sensors +INSERT INTO sensors (zone_id, contract_id, point_id, model, is_active) VALUES +(1, 1, 1, 'Sensor Modelo A', TRUE), +(2, 2, 2, 'Sensor Modelo B', TRUE), +(3, 3, 3, 'Sensor Modelo C', FALSE); + +--* Sensor History +INSERT INTO sensor_history (sensor_id, temperature, humidity, inclination) VALUES +(1, 22.5, 60.0, 15.0), +(2, 21.0, 55.0, 10.0), +(3, 19.0, 50.0, 12.0); + +--* Work Orders Blocks +INSERT INTO work_orders_blocks (work_order_id) VALUES +(1), +(2), +(3); + +--* Work Orders Blocks Zones +INSERT INTO work_orders_blocks_zones (work_orders_block_id, zone_id) VALUES (1, 1), (2, 2), (3, 3); ---* Sensors and sensor history -INSERT INTO sensors (zone_id, contract_id, point_id, model, is_active) VALUES -(1, 1, 1, 'Sensor 1', 1), -(2, 2, 2, 'Sensor 2', 1), -(3, 3, 3, 'Sensor 3', 1); + +INSERT INTO work_orders_blocks_tasks (work_orders_block_id, task_id, tree_type_id) VALUES +(1, 1, 1), +(2, 2, NULL), +(3, 3, NULL);