-- PostgreSQL initialization script for Turash MVP -- This script creates the initial database schema and extensions -- Enable PostGIS extension for geospatial queries CREATE EXTENSION IF NOT EXISTS postgis; CREATE EXTENSION IF NOT EXISTS postgis_topology; -- Create schema for spatial data (optional, for organization) -- CREATE SCHEMA IF NOT EXISTS spatial; -- Create table for geospatial site data (mirrored from Neo4j for spatial queries) CREATE TABLE IF NOT EXISTS site_geos ( site_id UUID PRIMARY KEY, business_id UUID NOT NULL, latitude DOUBLE PRECISION NOT NULL, longitude DOUBLE PRECISION NOT NULL, location GEOGRAPHY(POINT, 4326) NOT NULL, address TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create indexes for performance CREATE INDEX IF NOT EXISTS idx_site_geos_business_id ON site_geos(business_id); CREATE INDEX IF NOT EXISTS idx_site_geos_location ON site_geos USING GIST(location); CREATE INDEX IF NOT EXISTS idx_site_geos_latitude_longitude ON site_geos(latitude, longitude); -- Create table for match results caching (optional, for analytics) CREATE TABLE IF NOT EXISTS match_results ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), source_flow_id UUID NOT NULL, target_flow_id UUID NOT NULL, compatibility_score DOUBLE PRECISION NOT NULL, economic_value DOUBLE PRECISION, distance_km DOUBLE PRECISION, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), UNIQUE(source_flow_id, target_flow_id) ); -- Create indexes for match results CREATE INDEX IF NOT EXISTS idx_match_results_source_flow ON match_results(source_flow_id); CREATE INDEX IF NOT EXISTS idx_match_results_target_flow ON match_results(target_flow_id); CREATE INDEX IF NOT EXISTS idx_match_results_score ON match_results(compatibility_score DESC); CREATE INDEX IF NOT EXISTS idx_match_results_created_at ON match_results(created_at DESC); -- Create table for business statistics (for analytics dashboard) CREATE TABLE IF NOT EXISTS business_stats ( business_id UUID PRIMARY KEY, total_sites INTEGER DEFAULT 0, total_resource_flows INTEGER DEFAULT 0, active_matches INTEGER DEFAULT 0, co2_savings_tonnes DOUBLE PRECISION DEFAULT 0, economic_value_eur DOUBLE PRECISION DEFAULT 0, last_updated TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create table for system metrics (for monitoring) CREATE TABLE IF NOT EXISTS system_metrics ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), metric_name VARCHAR(255) NOT NULL, metric_value DOUBLE PRECISION, metric_type VARCHAR(50), recorded_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Create indexes for system metrics CREATE INDEX IF NOT EXISTS idx_system_metrics_name ON system_metrics(metric_name); CREATE INDEX IF NOT EXISTS idx_system_metrics_recorded_at ON system_metrics(recorded_at DESC); -- Insert sample geospatial data (mirroring Neo4j sample data) INSERT INTO site_geos (site_id, business_id, latitude, longitude, location, address) VALUES ('site-001'::uuid, 'business-001'::uuid, 52.5200, 13.4050, ST_GeogFromText('POINT(13.4050 52.5200)'), 'Hauptstraße 123, 10115 Berlin'), ('site-002'::uuid, 'business-002'::uuid, 52.5230, 13.4120, ST_GeogFromText('POINT(13.4120 52.5230)'), 'Braustraße 45, 10179 Berlin'), ('site-003'::uuid, 'business-003'::uuid, 52.5180, 13.4080, ST_GeogFromText('POINT(13.4080 52.5180)'), 'Hotelweg 78, 10117 Berlin') ON CONFLICT (site_id) DO NOTHING; -- Insert sample business stats INSERT INTO business_stats (business_id, total_sites, total_resource_flows) VALUES ('business-001'::uuid, 1, 1), ('business-002'::uuid, 1, 1), ('business-003'::uuid, 1, 1) ON CONFLICT (business_id) DO NOTHING; -- Create function for calculating distance between two points (in kilometers) CREATE OR REPLACE FUNCTION calculate_distance_km( lat1 DOUBLE PRECISION, lon1 DOUBLE PRECISION, lat2 DOUBLE PRECISION, lon2 DOUBLE PRECISION ) RETURNS DOUBLE PRECISION AS $$ DECLARE dlat DOUBLE PRECISION; dlon DOUBLE PRECISION; a DOUBLE PRECISION; c DOUBLE PRECISION; earth_radius_km DOUBLE PRECISION := 6371; BEGIN dlat := radians(lat2 - lat1); dlon := radians(lon2 - lon1); a := sin(dlat/2)^2 + cos(radians(lat1)) * cos(radians(lat2)) * sin(dlon/2)^2; c := 2 * atan2(sqrt(a), sqrt(1-a)); RETURN earth_radius_km * c; END; $$ LANGUAGE plpgsql IMMUTABLE; -- Create function to find sites within radius (example usage) CREATE OR REPLACE FUNCTION find_sites_within_radius( center_lat DOUBLE PRECISION, center_lon DOUBLE PRECISION, radius_km DOUBLE PRECISION ) RETURNS TABLE( site_id UUID, business_id UUID, latitude DOUBLE PRECISION, longitude DOUBLE PRECISION, distance_km DOUBLE PRECISION, address TEXT ) AS $$ BEGIN RETURN QUERY SELECT sg.site_id, sg.business_id, sg.latitude, sg.longitude, calculate_distance_km(center_lat, center_lon, sg.latitude, sg.longitude) as distance_km, sg.address FROM site_geos sg WHERE ST_DWithin( sg.location, ST_GeogFromText('POINT(' || center_lon || ' ' || center_lat || ')'), radius_km * 1000 -- Convert km to meters ) ORDER BY sg.location <-> ST_GeogFromText('POINT(' || center_lon || ' ' || center_lat || ')'); END; $$ LANGUAGE plpgsql; -- Grant permissions (for development) -- GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO turash; -- GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO turash;