update equipment stuff
This commit is contained in:
269
database/migrations/fix_sprayer_pump_nozzle_relationships.sql
Normal file
269
database/migrations/fix_sprayer_pump_nozzle_relationships.sql
Normal file
@@ -0,0 +1,269 @@
|
||||
-- Fix Sprayer-Pump-Nozzle Relationships
|
||||
-- This creates proper equipment connections and comprehensive nozzle database
|
||||
|
||||
-- Step 1: Create equipment_pump_assignments table (sprayers can have pumps)
|
||||
CREATE TABLE IF NOT EXISTS equipment_pump_assignments (
|
||||
id SERIAL PRIMARY KEY,
|
||||
sprayer_equipment_id INTEGER REFERENCES user_equipment(id) ON DELETE CASCADE,
|
||||
pump_equipment_id INTEGER REFERENCES user_equipment(id) ON DELETE CASCADE,
|
||||
assigned_date DATE DEFAULT CURRENT_DATE,
|
||||
is_active BOOLEAN DEFAULT true,
|
||||
notes TEXT,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(sprayer_equipment_id, pump_equipment_id)
|
||||
);
|
||||
|
||||
-- Step 2: Update nozzle_types table with comprehensive flow rate data
|
||||
DROP TABLE IF EXISTS nozzle_types CASCADE;
|
||||
CREATE TABLE nozzle_types (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(255) NOT NULL UNIQUE,
|
||||
manufacturer VARCHAR(100) NOT NULL,
|
||||
model VARCHAR(100),
|
||||
orifice_size VARCHAR(20) NOT NULL,
|
||||
spray_angle INTEGER NOT NULL,
|
||||
droplet_size VARCHAR(50) NOT NULL, -- fine, medium, coarse, very_coarse, extremely_coarse
|
||||
spray_pattern VARCHAR(50) NOT NULL, -- flat_fan, hollow_cone, full_cone, flooding
|
||||
material VARCHAR(50), -- ceramic, stainless_steel, hardened_steel, polymer
|
||||
thread_size VARCHAR(20), -- 1/4", 3/8", 1/2"
|
||||
color_code VARCHAR(20), -- TeeJet color coding
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Step 3: Create nozzle flow rate data table (pressure vs flow rate charts)
|
||||
CREATE TABLE IF NOT EXISTS nozzle_flow_rates (
|
||||
id SERIAL PRIMARY KEY,
|
||||
nozzle_type_id INTEGER REFERENCES nozzle_types(id) ON DELETE CASCADE,
|
||||
pressure_psi INTEGER NOT NULL,
|
||||
flow_rate_gpm DECIMAL(6, 3) NOT NULL,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(nozzle_type_id, pressure_psi)
|
||||
);
|
||||
|
||||
-- Step 4: Insert comprehensive TeeJet nozzle database
|
||||
INSERT INTO nozzle_types (name, manufacturer, model, orifice_size, spray_angle, droplet_size, spray_pattern, material, thread_size, color_code) VALUES
|
||||
-- XR Extended Range Flat Fan Nozzles (Fine droplets)
|
||||
('XR8001', 'TeeJet', 'XR8001VK', '01', 80, 'fine', 'flat_fan', 'stainless_steel', '1/4"', 'Orange'),
|
||||
('XR8002', 'TeeJet', 'XR8002VK', '02', 80, 'fine', 'flat_fan', 'stainless_steel', '1/4"', 'Yellow'),
|
||||
('XR8003', 'TeeJet', 'XR8003VK', '03', 80, 'fine', 'flat_fan', 'stainless_steel', '1/4"', 'Blue'),
|
||||
('XR8004', 'TeeJet', 'XR8004VK', '04', 80, 'fine', 'flat_fan', 'stainless_steel', '1/4"', 'Red'),
|
||||
('XR8005', 'TeeJet', 'XR8005VK', '05', 80, 'fine', 'flat_fan', 'stainless_steel', '1/4"', 'Brown'),
|
||||
('XR8006', 'TeeJet', 'XR8006VK', '06', 80, 'fine', 'flat_fan', 'stainless_steel', '1/4"', 'Gray'),
|
||||
('XR8008', 'TeeJet', 'XR8008VK', '08', 80, 'fine', 'flat_fan', 'stainless_steel', '1/4"', 'White'),
|
||||
|
||||
-- AIXR Air Induction Extended Range (Medium droplets - drift reduction)
|
||||
('AIXR11001', 'TeeJet', 'AIXR11001', '01', 110, 'medium', 'flat_fan', 'polymer', '1/4"', 'Orange'),
|
||||
('AIXR11002', 'TeeJet', 'AIXR11002', '02', 110, 'medium', 'flat_fan', 'polymer', '1/4"', 'Yellow'),
|
||||
('AIXR11003', 'TeeJet', 'AIXR11003', '03', 110, 'medium', 'flat_fan', 'polymer', '1/4"', 'Blue'),
|
||||
('AIXR11004', 'TeeJet', 'AIXR11004', '04', 110, 'medium', 'flat_fan', 'polymer', '1/4"', 'Red'),
|
||||
('AIXR11005', 'TeeJet', 'AIXR11005', '05', 110, 'medium', 'flat_fan', 'polymer', '1/4"', 'Brown'),
|
||||
('AIXR11006', 'TeeJet', 'AIXR11006', '06', 110, 'medium', 'flat_fan', 'polymer', '1/4"', 'Gray'),
|
||||
('AIXR11008', 'TeeJet', 'AIXR11008', '08', 110, 'medium', 'flat_fan', 'polymer', '1/4"', 'White'),
|
||||
|
||||
-- TTI TurboDrop (Very coarse droplets - maximum drift reduction)
|
||||
('TTI11002', 'TeeJet', 'TTI11002', '02', 110, 'very_coarse', 'flat_fan', 'polymer', '1/4"', 'Yellow'),
|
||||
('TTI11003', 'TeeJet', 'TTI11003', '03', 110, 'very_coarse', 'flat_fan', 'polymer', '1/4"', 'Blue'),
|
||||
('TTI11004', 'TeeJet', 'TTI11004', '04', 110, 'very_coarse', 'flat_fan', 'polymer', '1/4"', 'Red'),
|
||||
('TTI11005', 'TeeJet', 'TTI11005', '05', 110, 'very_coarse', 'flat_fan', 'polymer', '1/4"', 'Brown'),
|
||||
('TTI11006', 'TeeJet', 'TTI11006', '06', 110, 'very_coarse', 'flat_fan', 'polymer', '1/4"', 'Gray'),
|
||||
|
||||
-- AI TeeJet Air Induction (Coarse droplets)
|
||||
('AI11002', 'TeeJet', 'AI11002-VS', '02', 110, 'coarse', 'flat_fan', 'stainless_steel', '1/4"', 'Yellow'),
|
||||
('AI11003', 'TeeJet', 'AI11003-VS', '03', 110, 'coarse', 'flat_fan', 'stainless_steel', '1/4"', 'Blue'),
|
||||
('AI11004', 'TeeJet', 'AI11004-VS', '04', 110, 'coarse', 'flat_fan', 'stainless_steel', '1/4"', 'Red'),
|
||||
('AI11005', 'TeeJet', 'AI11005-VS', '05', 110, 'coarse', 'flat_fan', 'stainless_steel', '1/4"', 'Brown'),
|
||||
|
||||
-- DG DropGuard (Extremely coarse droplets)
|
||||
('DG11002', 'TeeJet', 'DG11002-VS', '02', 110, 'extremely_coarse', 'flat_fan', 'stainless_steel', '1/4"', 'Yellow'),
|
||||
('DG11003', 'TeeJet', 'DG11003-VS', '03', 110, 'extremely_coarse', 'flat_fan', 'stainless_steel', '1/4"', 'Blue'),
|
||||
('DG11004', 'TeeJet', 'DG11004-VS', '04', 110, 'extremely_coarse', 'flat_fan', 'stainless_steel', '1/4"', 'Red'),
|
||||
|
||||
-- Hollow Cone Nozzles
|
||||
('D2-23', 'TeeJet', 'D2-23', '2', 80, 'fine', 'hollow_cone', 'hardened_steel', '1/4"', 'Yellow'),
|
||||
('D3-25', 'TeeJet', 'D3-25', '3', 80, 'fine', 'hollow_cone', 'hardened_steel', '1/4"', 'Blue'),
|
||||
('D4-25', 'TeeJet', 'D4-25', '4', 80, 'fine', 'hollow_cone', 'hardened_steel', '1/4"', 'Red'),
|
||||
|
||||
-- Full Cone Nozzles
|
||||
('TXA8002VK', 'TeeJet', 'TXA8002VK', '02', 80, 'medium', 'full_cone', 'stainless_steel', '1/4"', 'Yellow'),
|
||||
('TXA8004VK', 'TeeJet', 'TXA8004VK', '04', 80, 'medium', 'full_cone', 'stainless_steel', '1/4"', 'Red'),
|
||||
('TXA8006VK', 'TeeJet', 'TXA8006VK', '06', 80, 'medium', 'full_cone', 'stainless_steel', '1/4"', 'Gray');
|
||||
|
||||
-- Step 5: Insert flow rate data based on TeeJet charts
|
||||
-- XR Series Flow Rates (GPM at different PSI)
|
||||
INSERT INTO nozzle_flow_rates (nozzle_type_id, pressure_psi, flow_rate_gpm) VALUES
|
||||
-- XR8001
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8001'), 15, 0.10),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8001'), 20, 0.11),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8001'), 30, 0.14),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8001'), 40, 0.16),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8001'), 60, 0.20),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8001'), 80, 0.23),
|
||||
|
||||
-- XR8002
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8002'), 15, 0.20),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8002'), 20, 0.23),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8002'), 30, 0.28),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8002'), 40, 0.32),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8002'), 60, 0.39),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8002'), 80, 0.45),
|
||||
|
||||
-- XR8003
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8003'), 15, 0.30),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8003'), 20, 0.35),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8003'), 30, 0.42),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8003'), 40, 0.49),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8003'), 60, 0.60),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8003'), 80, 0.69),
|
||||
|
||||
-- XR8004
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8004'), 15, 0.40),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8004'), 20, 0.46),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8004'), 30, 0.56),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8004'), 40, 0.65),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8004'), 60, 0.80),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8004'), 80, 0.92),
|
||||
|
||||
-- XR8005
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8005'), 15, 0.50),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8005'), 20, 0.58),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8005'), 30, 0.71),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8005'), 40, 0.82),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8005'), 60, 1.00),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8005'), 80, 1.15),
|
||||
|
||||
-- XR8006
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8006'), 15, 0.60),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8006'), 20, 0.69),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8006'), 30, 0.85),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8006'), 40, 0.98),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8006'), 60, 1.20),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8006'), 80, 1.38),
|
||||
|
||||
-- XR8008
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8008'), 15, 0.80),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8008'), 20, 0.92),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8008'), 30, 1.13),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8008'), 40, 1.30),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8008'), 60, 1.60),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'XR8008'), 80, 1.84),
|
||||
|
||||
-- AIXR Series Flow Rates
|
||||
-- AIXR11002
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11002'), 15, 0.20),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11002'), 20, 0.23),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11002'), 30, 0.28),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11002'), 40, 0.32),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11002'), 60, 0.39),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11002'), 80, 0.45),
|
||||
|
||||
-- AIXR11003
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11003'), 15, 0.30),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11003'), 20, 0.35),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11003'), 30, 0.42),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11003'), 40, 0.49),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11003'), 60, 0.60),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11003'), 80, 0.69),
|
||||
|
||||
-- AIXR11004
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11004'), 15, 0.40),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11004'), 20, 0.46),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11004'), 30, 0.56),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11004'), 40, 0.65),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11004'), 60, 0.80),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11004'), 80, 0.92),
|
||||
|
||||
-- AIXR11005
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11005'), 15, 0.50),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11005'), 20, 0.58),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11005'), 30, 0.71),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11005'), 40, 0.82),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11005'), 60, 1.00),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'AIXR11005'), 80, 1.15),
|
||||
|
||||
-- TTI Series Flow Rates (similar to AIXR but slightly different due to design)
|
||||
-- TTI11002
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11002'), 15, 0.18),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11002'), 20, 0.21),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11002'), 30, 0.26),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11002'), 40, 0.30),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11002'), 60, 0.37),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11002'), 80, 0.42),
|
||||
|
||||
-- TTI11003
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11003'), 15, 0.28),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11003'), 20, 0.32),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11003'), 30, 0.39),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11003'), 40, 0.45),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11003'), 60, 0.55),
|
||||
((SELECT id FROM nozzle_types WHERE name = 'TTI11003'), 80, 0.64);
|
||||
|
||||
-- Step 6: Update user_nozzles to include current assignment info
|
||||
ALTER TABLE user_nozzles
|
||||
ADD COLUMN IF NOT EXISTS current_equipment_id INTEGER REFERENCES user_equipment(id),
|
||||
ADD COLUMN IF NOT EXISTS current_position VARCHAR(50),
|
||||
ADD COLUMN IF NOT EXISTS last_assigned_date DATE;
|
||||
|
||||
-- Step 7: Create equipment_nozzle_configurations table (for application planning)
|
||||
CREATE TABLE IF NOT EXISTS equipment_nozzle_configurations (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_equipment_id INTEGER REFERENCES user_equipment(id) ON DELETE CASCADE,
|
||||
configuration_name VARCHAR(255) NOT NULL,
|
||||
is_default BOOLEAN DEFAULT false,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Step 8: Create configuration_nozzle_assignments (specific nozzle setups)
|
||||
CREATE TABLE IF NOT EXISTS configuration_nozzle_assignments (
|
||||
id SERIAL PRIMARY KEY,
|
||||
configuration_id INTEGER REFERENCES equipment_nozzle_configurations(id) ON DELETE CASCADE,
|
||||
nozzle_type_id INTEGER REFERENCES nozzle_types(id) ON DELETE CASCADE,
|
||||
position VARCHAR(50) NOT NULL, -- boom_left_1, boom_right_1, center, etc.
|
||||
quantity INTEGER DEFAULT 1,
|
||||
operating_pressure_psi INTEGER,
|
||||
notes TEXT,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(configuration_id, position)
|
||||
);
|
||||
|
||||
-- Step 9: Add triggers for updated_at
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ language 'plpgsql';
|
||||
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT 1 FROM pg_trigger WHERE tgname = 'update_equipment_pump_assignments_updated_at') THEN
|
||||
CREATE TRIGGER update_equipment_pump_assignments_updated_at
|
||||
BEFORE UPDATE ON equipment_pump_assignments
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT 1 FROM pg_trigger WHERE tgname = 'update_equipment_nozzle_configurations_updated_at') THEN
|
||||
CREATE TRIGGER update_equipment_nozzle_configurations_updated_at
|
||||
BEFORE UPDATE ON equipment_nozzle_configurations
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_updated_at_column();
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- Step 10: Create indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_equipment_pump_assignments_sprayer ON equipment_pump_assignments(sprayer_equipment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_equipment_pump_assignments_pump ON equipment_pump_assignments(pump_equipment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_nozzle_flow_rates_type ON nozzle_flow_rates(nozzle_type_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_nozzle_flow_rates_pressure ON nozzle_flow_rates(pressure_psi);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_nozzles_equipment ON user_nozzles(current_equipment_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_configuration_nozzle_assignments_config ON configuration_nozzle_assignments(configuration_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_configuration_nozzle_assignments_nozzle ON configuration_nozzle_assignments(nozzle_type_id);
|
||||
|
||||
-- Migration completed successfully
|
||||
SELECT 'Sprayer-Pump-Nozzle relationship migration completed successfully!' as migration_status;
|
||||
Reference in New Issue
Block a user