-- 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 types master table (shared across all users) CREATE TABLE equipment_types ( id SERIAL PRIMARY KEY, name VARCHAR(255) NOT NULL UNIQUE, category VARCHAR(100) NOT NULL, -- mower, trimmer, spreader, sprayer, aerator, dethatcher created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- User equipment table 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), custom_name VARCHAR(255), tank_size DECIMAL(8, 2), -- gallons (for sprayers) pump_gpm DECIMAL(8, 2), -- gallons per minute (for sprayers) nozzle_gpm DECIMAL(8, 2), -- gallons per minute per nozzle nozzle_count INTEGER, -- number of nozzles spreader_width DECIMAL(8, 2), -- width in feet (for spreaders) created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- 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 default equipment types INSERT INTO equipment_types (name, category) VALUES ('Walk-behind Mower', 'mower'), ('Riding Mower', 'mower'), ('Zero-turn Mower', 'mower'), ('String Trimmer', 'trimmer'), ('Backpack Sprayer', 'sprayer'), ('Pull-behind Sprayer', 'sprayer'), ('Boom Sprayer', 'sprayer'), ('Broadcast Spreader', 'spreader'), ('Drop Spreader', 'spreader'), ('Hand Spreader', 'spreader'), ('Core Aerator', 'aerator'), ('Spike Aerator', 'aerator'), ('Dethatcher', 'dethatcher'), ('Power Rake', 'dethatcher'); -- 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_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();