Files
turftracker/database/init.sql
2025-08-22 09:17:22 -04:00

381 lines
15 KiB
PL/PgSQL

-- TurfTracker Database Schema
-- PostgreSQL initialization script
-- Users table
CREATE TABLE users (
id SERIAL PRIMARY KEY,
email VARCHAR(255) UNIQUE NOT NULL,
password_hash VARCHAR(255),
first_name VARCHAR(100),
last_name VARCHAR(100),
role VARCHAR(20) DEFAULT 'user' CHECK (role IN ('admin', 'user')),
oauth_provider VARCHAR(50),
oauth_id VARCHAR(255),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Properties table (multiple lawns/houses per user)
CREATE TABLE properties (
id SERIAL PRIMARY KEY,
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
name VARCHAR(255) NOT NULL,
address TEXT,
latitude DECIMAL(10, 8),
longitude DECIMAL(11, 8),
total_area DECIMAL(10, 2), -- in square feet
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Lawn sections table (users can divide their property into sections)
CREATE TABLE lawn_sections (
id SERIAL PRIMARY KEY,
property_id INTEGER REFERENCES properties(id) ON DELETE CASCADE,
name VARCHAR(255) NOT NULL,
area DECIMAL(10, 2), -- in square feet
polygon_data JSON, -- GeoJSON polygon data
grass_type VARCHAR(100),
soil_type VARCHAR(100),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Equipment categories master table
CREATE TABLE equipment_categories (
id SERIAL PRIMARY KEY,
name VARCHAR(100) NOT NULL UNIQUE,
description TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Equipment types master table (shared across all users)
CREATE TABLE equipment_types (
id SERIAL PRIMARY KEY,
name VARCHAR(255) NOT NULL UNIQUE,
category_id INTEGER REFERENCES equipment_categories(id),
manufacturer VARCHAR(100),
model VARCHAR(100),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- User equipment table - comprehensive equipment management
CREATE TABLE user_equipment (
id SERIAL PRIMARY KEY,
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
equipment_type_id INTEGER REFERENCES equipment_types(id),
category_id INTEGER REFERENCES equipment_categories(id),
custom_name VARCHAR(255),
manufacturer VARCHAR(100),
model VARCHAR(100),
-- Spreader specific fields
capacity_lbs DECIMAL(8, 2),
spreader_type VARCHAR(50) CHECK (spreader_type IN ('walk_behind', 'pull_behind', 'handheld')),
spread_width DECIMAL(8, 2),
-- Sprayer specific fields
tank_size_gallons DECIMAL(8, 2),
sprayer_type VARCHAR(50) CHECK (sprayer_type IN ('tow_behind', 'mower_mounted', 'ride_on', 'walk_behind', 'hand_pump')),
spray_width_feet DECIMAL(8, 2),
pump_gpm DECIMAL(8, 2),
pump_psi DECIMAL(8, 2),
boom_sections INTEGER,
-- Mower specific fields
mower_style VARCHAR(50) CHECK (mower_style IN ('push', 'self_propelled', 'zero_turn', 'lawn_tractor', 'riding')),
cutting_width_inches DECIMAL(6, 2),
engine_hp DECIMAL(6, 2),
fuel_type VARCHAR(30),
-- Tool specific fields (aerator, dethatcher, scarifier)
tool_type VARCHAR(50) CHECK (tool_type IN ('walk_behind', 'tow_behind', 'handheld')),
working_width_inches DECIMAL(6, 2),
-- Pump specific fields
pump_type VARCHAR(50),
max_gpm DECIMAL(8, 2),
max_psi DECIMAL(8, 2),
power_source VARCHAR(50), -- electric, gas, pto, etc.
-- General fields
purchase_date DATE,
purchase_price DECIMAL(10, 2),
notes TEXT,
is_active BOOLEAN DEFAULT true,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Nozzle types master table
CREATE TABLE 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
);
-- User's nozzle inventory
CREATE TABLE 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
);
-- Equipment nozzle assignments (which nozzles are on which sprayers)
CREATE TABLE 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)
);
-- Product categories
CREATE TABLE product_categories (
id SERIAL PRIMARY KEY,
name VARCHAR(100) NOT NULL UNIQUE,
description TEXT
);
-- Products master table (shared across all users)
CREATE TABLE products (
id SERIAL PRIMARY KEY,
name VARCHAR(255) NOT NULL,
brand VARCHAR(100),
category_id INTEGER REFERENCES product_categories(id),
product_type VARCHAR(50) CHECK (product_type IN ('granular', 'liquid')),
active_ingredients TEXT,
description TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Product application rates (products can have multiple rates for different uses)
CREATE TABLE product_rates (
id SERIAL PRIMARY KEY,
product_id INTEGER REFERENCES products(id) ON DELETE CASCADE,
application_type VARCHAR(100), -- fertilizer, weed control, pre-emergent, etc.
rate_amount DECIMAL(8, 4),
rate_unit VARCHAR(50), -- oz/1000sqft, lbs/acre, oz/gal/1000sqft, etc.
notes TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- User products (users can add custom products)
CREATE TABLE user_products (
id SERIAL PRIMARY KEY,
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
product_id INTEGER REFERENCES products(id),
custom_name VARCHAR(255),
custom_brand VARCHAR(100),
category_id INTEGER REFERENCES product_categories(id),
custom_product_type VARCHAR(50) CHECK (custom_product_type IN ('granular', 'liquid')),
custom_active_ingredients TEXT,
custom_description TEXT,
custom_rate_amount DECIMAL(8, 4),
custom_rate_unit VARCHAR(50),
notes TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Application plans (what user plans to apply)
CREATE TABLE application_plans (
id SERIAL PRIMARY KEY,
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
lawn_section_id INTEGER REFERENCES lawn_sections(id) ON DELETE CASCADE,
equipment_id INTEGER REFERENCES user_equipment(id),
planned_date DATE,
status VARCHAR(20) DEFAULT 'planned' CHECK (status IN ('planned', 'in_progress', 'completed', 'cancelled')),
notes TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Application plan products (products in each plan - allows tank mixing)
CREATE TABLE application_plan_products (
id SERIAL PRIMARY KEY,
plan_id INTEGER REFERENCES application_plans(id) ON DELETE CASCADE,
product_id INTEGER REFERENCES products(id),
user_product_id INTEGER REFERENCES user_products(id),
rate_amount DECIMAL(8, 4),
rate_unit VARCHAR(50),
calculated_product_amount DECIMAL(10, 4),
calculated_water_amount DECIMAL(10, 4),
target_speed_mph DECIMAL(5, 2)
);
-- Application logs (actual applications performed)
CREATE TABLE application_logs (
id SERIAL PRIMARY KEY,
plan_id INTEGER REFERENCES application_plans(id),
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
lawn_section_id INTEGER REFERENCES lawn_sections(id),
equipment_id INTEGER REFERENCES user_equipment(id),
application_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
weather_conditions JSON, -- temperature, humidity, wind speed, etc.
gps_track JSON, -- GPS coordinates and timestamps
average_speed DECIMAL(5, 2),
area_covered DECIMAL(10, 2),
notes TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Application log products (products actually applied)
CREATE TABLE application_log_products (
id SERIAL PRIMARY KEY,
log_id INTEGER REFERENCES application_logs(id) ON DELETE CASCADE,
product_id INTEGER REFERENCES products(id),
user_product_id INTEGER REFERENCES user_products(id),
rate_amount DECIMAL(8, 4),
rate_unit VARCHAR(50),
actual_product_amount DECIMAL(10, 4),
actual_water_amount DECIMAL(10, 4),
actual_speed_mph DECIMAL(5, 2)
);
-- Weather data cache
CREATE TABLE weather_data (
id SERIAL PRIMARY KEY,
property_id INTEGER REFERENCES properties(id) ON DELETE CASCADE,
date DATE,
temperature_high INTEGER,
temperature_low INTEGER,
humidity INTEGER,
wind_speed DECIMAL(5, 2),
precipitation DECIMAL(5, 2),
conditions VARCHAR(100),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- 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');
-- Insert default equipment types
INSERT INTO equipment_types (name, category_id) VALUES
-- Mowers
('Walk-behind Mower', 1),
('Self-Propelled Mower', 1),
('Zero-turn Mower', 1),
('Lawn Tractor', 1),
('Riding Mower', 1),
-- Spreaders
('Broadcast Spreader', 2),
('Drop Spreader', 2),
('Hand Spreader', 2),
('Pull-behind Spreader', 2),
-- Sprayers
('Backpack Sprayer', 3),
('Pull-behind Sprayer', 3),
('Boom Sprayer', 3),
('Hand Pump Sprayer', 3),
('Ride-on Sprayer', 3),
('Mower-mounted Sprayer', 3),
-- Pumps
('Centrifugal Pump', 5),
('Diaphragm Pump', 5),
('Roller Pump', 5),
('Gear Pump', 5),
-- Aerators
('Core Aerator', 6),
('Spike Aerator', 6),
('Plug Aerator', 6),
-- Dethatchers
('Power Rake', 7),
('Vertical Mower', 7),
('Dethatcher', 7),
-- Scarifiers
('Walk-behind Scarifier', 8),
('Tow-behind Scarifier', 8),
-- Trimmers
('String Trimmer', 9),
('Brush Cutter', 9),
('Edger', 9);
-- 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');
-- Insert product categories
INSERT INTO product_categories (name, description) VALUES
('Fertilizer', 'Synthetic and organic fertilizers'),
('Herbicide', 'Weed control products'),
('Pre-emergent', 'Pre-emergent herbicides'),
('Fungicide', 'Disease control products'),
('Insecticide', 'Insect control products'),
('Soil Amendment', 'Soil conditioners and amendments');
-- Insert some common products
INSERT INTO products (name, brand, category_id, product_type, active_ingredients) VALUES
('Scotts Turf Builder', 'Scotts', 1, 'granular', '32-0-4 NPK'),
('Milorganite', 'Milorganite', 1, 'granular', '6-4-0 NPK (Organic)'),
('2,4-D Selective Herbicide', 'Generic', 2, 'liquid', '2,4-Dichlorophenoxyacetic acid'),
('Glyphosate', 'Generic', 2, 'liquid', 'Glyphosate'),
('Prodiamine', 'Generic', 3, 'granular', 'Prodiamine'),
('Iron Sulfate', 'Generic', 1, 'granular', 'Iron Sulfate');
-- Insert common application rates
INSERT INTO product_rates (product_id, application_type, rate_amount, rate_unit, notes) VALUES
(1, 'Spring Feeding', 2.5, 'lbs/1000sqft', 'Early spring application'),
(1, 'Fall Feeding', 3.0, 'lbs/1000sqft', 'Fall application'),
(2, 'Summer Feeding', 32.0, 'lbs/1000sqft', 'Slow release organic'),
(3, 'Broadleaf Weed Control', 1.0, 'oz/gal/1000sqft', 'Post-emergent herbicide'),
(4, 'Non-selective Herbicide', 2.0, 'oz/gal/1000sqft', 'Total vegetation control'),
(5, 'Pre-emergent Control', 1.5, 'lbs/1000sqft', 'Crabgrass prevention'),
(6, 'Iron Supplement', 5.0, 'lbs/1000sqft', 'Green-up treatment');
-- Create indexes for better performance
CREATE INDEX idx_users_email ON users(email);
CREATE INDEX idx_properties_user_id ON properties(user_id);
CREATE INDEX idx_lawn_sections_property_id ON lawn_sections(property_id);
CREATE INDEX idx_user_equipment_user_id ON user_equipment(user_id);
CREATE INDEX idx_application_plans_user_id ON application_plans(user_id);
CREATE INDEX idx_application_logs_user_id ON application_logs(user_id);
CREATE INDEX idx_weather_data_property_date ON weather_data(property_id, date);
-- Create triggers for updated_at timestamps
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_properties_updated_at BEFORE UPDATE ON properties FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_lawn_sections_updated_at BEFORE UPDATE ON lawn_sections FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_user_equipment_updated_at BEFORE UPDATE ON user_equipment FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_user_nozzles_updated_at BEFORE UPDATE ON user_nozzles FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_user_products_updated_at BEFORE UPDATE ON user_products FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_application_plans_updated_at BEFORE UPDATE ON application_plans FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();