From 77077d316316d94964b51631d898c3beb32d639f Mon Sep 17 00:00:00 2001 From: Jake Kasper Date: Fri, 22 Aug 2025 09:20:05 -0400 Subject: [PATCH] db fixes --- .../comprehensive_equipment_upgrade_fixed.sql | 219 ++++++++++++++++++ 1 file changed, 219 insertions(+) create mode 100644 database/migrations/comprehensive_equipment_upgrade_fixed.sql diff --git a/database/migrations/comprehensive_equipment_upgrade_fixed.sql b/database/migrations/comprehensive_equipment_upgrade_fixed.sql new file mode 100644 index 0000000..18ca4f6 --- /dev/null +++ b/database/migrations/comprehensive_equipment_upgrade_fixed.sql @@ -0,0 +1,219 @@ +-- Comprehensive Equipment System Migration - FIXED VERSION +-- This migration transforms the basic equipment system into a comprehensive one + +-- Step 1: Create new equipment categories table +CREATE TABLE IF NOT EXISTS equipment_categories ( + id SERIAL PRIMARY KEY, + name VARCHAR(100) NOT NULL UNIQUE, + description TEXT, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP +); + +-- Step 2: Insert equipment categories +INSERT INTO equipment_categories (name, description) VALUES + ('Mower', 'Lawn mowing equipment'), + ('Spreader', 'Granular product application equipment'), + ('Sprayer', 'Liquid product application equipment'), + ('Nozzle', 'Spray nozzles and tips'), + ('Pump', 'Water and chemical pumps'), + ('Aerator', 'Soil aeration equipment'), + ('Dethatcher', 'Thatch removal equipment'), + ('Scarifier', 'Soil scarification equipment'), + ('Trimmer', 'Edge and trim equipment'), + ('Other', 'Miscellaneous lawn care equipment') +ON CONFLICT (name) DO NOTHING; + +-- Step 3: Add category_id to equipment_types if it doesn't exist +ALTER TABLE equipment_types +ADD COLUMN IF NOT EXISTS category_id INTEGER REFERENCES equipment_categories(id), +ADD COLUMN IF NOT EXISTS manufacturer VARCHAR(100), +ADD COLUMN IF NOT EXISTS model VARCHAR(100); + +-- Step 4: Update existing equipment_types with category_id based on legacy category field +UPDATE equipment_types SET category_id = ( + CASE + WHEN category = 'mower' THEN (SELECT id FROM equipment_categories WHERE name = 'Mower') + WHEN category = 'spreader' THEN (SELECT id FROM equipment_categories WHERE name = 'Spreader') + WHEN category = 'sprayer' THEN (SELECT id FROM equipment_categories WHERE name = 'Sprayer') + WHEN category = 'aerator' THEN (SELECT id FROM equipment_categories WHERE name = 'Aerator') + WHEN category = 'dethatcher' THEN (SELECT id FROM equipment_categories WHERE name = 'Dethatcher') + WHEN category = 'trimmer' THEN (SELECT id FROM equipment_categories WHERE name = 'Trimmer') + ELSE (SELECT id FROM equipment_categories WHERE name = 'Other') + END +) WHERE category_id IS NULL; + +-- Step 5: Add comprehensive fields to user_equipment table +ALTER TABLE user_equipment +ADD COLUMN IF NOT EXISTS category_id INTEGER REFERENCES equipment_categories(id), +ADD COLUMN IF NOT EXISTS manufacturer VARCHAR(100), +ADD COLUMN IF NOT EXISTS model VARCHAR(100), +-- Spreader specific fields +ADD COLUMN IF NOT EXISTS capacity_lbs DECIMAL(8, 2), +ADD COLUMN IF NOT EXISTS spreader_type VARCHAR(50) CHECK (spreader_type IN ('walk_behind', 'pull_behind', 'handheld')), +ADD COLUMN IF NOT EXISTS spread_width DECIMAL(8, 2), +-- Sprayer specific fields (rename existing fields) +ADD COLUMN IF NOT EXISTS tank_size_gallons DECIMAL(8, 2), +ADD COLUMN IF NOT EXISTS sprayer_type VARCHAR(50) CHECK (sprayer_type IN ('tow_behind', 'mower_mounted', 'ride_on', 'walk_behind', 'hand_pump')), +ADD COLUMN IF NOT EXISTS spray_width_feet DECIMAL(8, 2), +ADD COLUMN IF NOT EXISTS pump_psi DECIMAL(8, 2), +ADD COLUMN IF NOT EXISTS boom_sections INTEGER, +-- Mower specific fields +ADD COLUMN IF NOT EXISTS mower_style VARCHAR(50) CHECK (mower_style IN ('push', 'self_propelled', 'zero_turn', 'lawn_tractor', 'riding')), +ADD COLUMN IF NOT EXISTS cutting_width_inches DECIMAL(6, 2), +ADD COLUMN IF NOT EXISTS engine_hp DECIMAL(6, 2), +ADD COLUMN IF NOT EXISTS fuel_type VARCHAR(30), +-- Tool specific fields (aerator, dethatcher, scarifier) +ADD COLUMN IF NOT EXISTS tool_type VARCHAR(50) CHECK (tool_type IN ('walk_behind', 'tow_behind', 'handheld')), +ADD COLUMN IF NOT EXISTS working_width_inches DECIMAL(6, 2), +-- Pump specific fields +ADD COLUMN IF NOT EXISTS pump_type VARCHAR(50), +ADD COLUMN IF NOT EXISTS max_gpm DECIMAL(8, 2), +ADD COLUMN IF NOT EXISTS max_psi DECIMAL(8, 2), +ADD COLUMN IF NOT EXISTS power_source VARCHAR(50), +-- General fields +ADD COLUMN IF NOT EXISTS purchase_date DATE, +ADD COLUMN IF NOT EXISTS purchase_price DECIMAL(10, 2), +ADD COLUMN IF NOT EXISTS is_active BOOLEAN DEFAULT true; + +-- Step 6: Migrate existing data to new fields +UPDATE user_equipment +SET + tank_size_gallons = tank_size, + spread_width = spreader_width +WHERE (tank_size_gallons IS NULL AND tank_size IS NOT NULL) + OR (spread_width IS NULL AND spreader_width IS NOT NULL); + +-- Set category_id based on equipment_type +UPDATE user_equipment SET category_id = ( + SELECT et.category_id FROM equipment_types et + WHERE et.id = user_equipment.equipment_type_id +) WHERE category_id IS NULL; + +-- Step 7: Create nozzle types master table +CREATE TABLE IF NOT EXISTS nozzle_types ( + id SERIAL PRIMARY KEY, + name VARCHAR(255) NOT NULL, + manufacturer VARCHAR(100), + model VARCHAR(100), + orifice_size VARCHAR(20), + spray_angle INTEGER, + flow_rate_gpm DECIMAL(6, 3), + droplet_size VARCHAR(50), -- fine, medium, coarse, very_coarse, extremely_coarse + spray_pattern VARCHAR(50), -- flat_fan, hollow_cone, full_cone, flooding + pressure_range_psi VARCHAR(50), + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP +); + +-- Step 8: Insert common nozzle types +INSERT INTO nozzle_types (name, manufacturer, orifice_size, spray_angle, flow_rate_gpm, droplet_size, spray_pattern, pressure_range_psi) VALUES + ('XR8002', 'TeeJet', '02', 80, 0.20, 'fine', 'flat_fan', '15-60'), + ('XR8003', 'TeeJet', '03', 80, 0.30, 'fine', 'flat_fan', '15-60'), + ('XR8004', 'TeeJet', '04', 80, 0.40, 'fine', 'flat_fan', '15-60'), + ('XR8005', 'TeeJet', '05', 80, 0.50, 'fine', 'flat_fan', '15-60'), + ('AIXR11002', 'TeeJet', '02', 110, 0.20, 'medium', 'flat_fan', '15-60'), + ('AIXR11003', 'TeeJet', '03', 110, 0.30, 'medium', 'flat_fan', '15-60'), + ('AIXR11004', 'TeeJet', '04', 110, 0.40, 'medium', 'flat_fan', '15-60'), + ('TTI11002', 'TeeJet', '02', 110, 0.20, 'very_coarse', 'flat_fan', '15-60'), + ('TTI11003', 'TeeJet', '03', 110, 0.30, 'very_coarse', 'flat_fan', '15-60'), + ('TTI11004', 'TeeJet', '04', 110, 0.40, 'very_coarse', 'flat_fan', '15-60') +ON CONFLICT DO NOTHING; + +-- Step 9: Create user nozzles table +CREATE TABLE IF NOT EXISTS user_nozzles ( + id SERIAL PRIMARY KEY, + user_id INTEGER REFERENCES users(id) ON DELETE CASCADE, + nozzle_type_id INTEGER REFERENCES nozzle_types(id), + custom_name VARCHAR(255), + quantity INTEGER DEFAULT 1, + condition VARCHAR(50) DEFAULT 'good', -- excellent, good, fair, poor, needs_replacement + purchase_date DATE, + notes TEXT, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP +); + +-- Step 10: Create equipment nozzle assignments table +CREATE TABLE IF NOT EXISTS equipment_nozzle_assignments ( + id SERIAL PRIMARY KEY, + user_equipment_id INTEGER REFERENCES user_equipment(id) ON DELETE CASCADE, + user_nozzle_id INTEGER REFERENCES user_nozzles(id) ON DELETE CASCADE, + position VARCHAR(50), -- left, right, center, boom_1, boom_2, etc. + quantity_assigned INTEGER DEFAULT 1, + assigned_date DATE DEFAULT CURRENT_DATE, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + UNIQUE(user_equipment_id, user_nozzle_id, position) +); + +-- Step 11: Add new equipment types with both category and category_id +-- First, let's check which equipment types already exist to avoid conflicts +DO $$ +DECLARE + equipment_types_to_add TEXT[][] := ARRAY[ + ARRAY['Self-Propelled Mower', 'Mower'], + ARRAY['Lawn Tractor', 'Mower'], + ARRAY['Pull-behind Spreader', 'Spreader'], + ARRAY['Hand Pump Sprayer', 'Sprayer'], + ARRAY['Ride-on Sprayer', 'Sprayer'], + ARRAY['Mower-mounted Sprayer', 'Sprayer'], + ARRAY['Centrifugal Pump', 'Pump'], + ARRAY['Diaphragm Pump', 'Pump'], + ARRAY['Roller Pump', 'Pump'], + ARRAY['Gear Pump', 'Pump'], + ARRAY['Plug Aerator', 'Aerator'], + ARRAY['Vertical Mower', 'Dethatcher'], + ARRAY['Walk-behind Scarifier', 'Scarifier'], + ARRAY['Tow-behind Scarifier', 'Scarifier'], + ARRAY['Brush Cutter', 'Trimmer'], + ARRAY['Edger', 'Trimmer'] + ]; + i INTEGER; + type_name TEXT; + category_name TEXT; + cat_id INTEGER; +BEGIN + FOR i IN 1..array_length(equipment_types_to_add, 1) LOOP + type_name := equipment_types_to_add[i][1]; + category_name := equipment_types_to_add[i][2]; + + SELECT id INTO cat_id FROM equipment_categories WHERE name = category_name; + + INSERT INTO equipment_types (name, category, category_id) + VALUES (type_name, LOWER(category_name), cat_id) + ON CONFLICT (name) DO NOTHING; + END LOOP; +END $$; + +-- Step 12: Create triggers for updated_at fields +CREATE OR REPLACE FUNCTION update_updated_at_column() +RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at = CURRENT_TIMESTAMP; + RETURN NEW; +END; +$$ language 'plpgsql'; + +-- Add trigger for user_nozzles if it doesn't exist +DO $$ +BEGIN + IF NOT EXISTS (SELECT 1 FROM pg_trigger WHERE tgname = 'update_user_nozzles_updated_at') THEN + CREATE TRIGGER update_user_nozzles_updated_at + BEFORE UPDATE ON user_nozzles + FOR EACH ROW + EXECUTE FUNCTION update_updated_at_column(); + END IF; +END $$; + +-- Step 13: Create indexes for better performance +CREATE INDEX IF NOT EXISTS idx_user_equipment_category_id ON user_equipment(category_id); +CREATE INDEX IF NOT EXISTS idx_user_equipment_user_category ON user_equipment(user_id, category_id); +CREATE INDEX IF NOT EXISTS idx_equipment_types_category_id ON equipment_types(category_id); +CREATE INDEX IF NOT EXISTS idx_user_nozzles_user_id ON user_nozzles(user_id); +CREATE INDEX IF NOT EXISTS idx_user_nozzles_type_id ON user_nozzles(nozzle_type_id); +CREATE INDEX IF NOT EXISTS idx_equipment_nozzle_assignments_equipment ON equipment_nozzle_assignments(user_equipment_id); +CREATE INDEX IF NOT EXISTS idx_equipment_nozzle_assignments_nozzle ON equipment_nozzle_assignments(user_nozzle_id); + +-- Step 14: Make the old category column nullable so we can drop the NOT NULL constraint +ALTER TABLE equipment_types ALTER COLUMN category DROP NOT NULL; + +-- Migration completed successfully +SELECT 'Equipment system migration completed successfully!' as migration_status; \ No newline at end of file