turash/bugulma/backend/migrations/postgres/013_create_geographical_features_table.up.sql
Damir Mukimov 0df4812c82
feat: Complete geographical features implementation with full test coverage
- Add comprehensive geographical data models (GeographicalFeature, TransportMode, TransportProfile, TransportOption)
- Implement geographical feature repository with PostGIS support and spatial queries
- Create transportation service for cost calculation and route optimization
- Build spatial resource matcher for geographical resource matching
- Develop environmental impact service for site environmental scoring
- Implement facility location optimizer with multi-criteria analysis
- Add geographical data migration service for SQLite to PostgreSQL migration
- Create database migrations for geographical features and site footprints
- Update geospatial service integration and server initialization
- Add CLI command for geographical data synchronization
- Implement complete test coverage for all geographical components (28 test cases)
- Update test infrastructure for geographical table creation and PostGIS handling

This implements advanced geospatial capabilities including transportation cost modeling, environmental impact assessment, and facility location optimization for the Turash platform.
2025-11-25 06:42:18 +01:00

50 lines
2.4 KiB
SQL

-- +migrate Up
-- Migration to create geographical_features table for OSM data
-- Run this after enabling PostGIS extension
-- Create geographical_features table for storing OSM geographical data
CREATE TABLE IF NOT EXISTS geographical_features (
id TEXT PRIMARY KEY,
name TEXT,
feature_type VARCHAR(50) NOT NULL,
-- PostGIS geometry column for spatial data (supports all geometry types)
geometry GEOMETRY(GEOMETRY, 4326),
-- OSM metadata
osm_type VARCHAR(50),
osm_id VARCHAR(50),
-- Properties from OSM or other sources (stored as JSONB for flexible querying)
properties JSONB DEFAULT '{}'::jsonb,
-- Processing metadata
processing_version VARCHAR(20) DEFAULT '1.0',
quality_score DOUBLE PRECISION DEFAULT 0.0,
source VARCHAR(100) DEFAULT 'osm',
-- Timestamps
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Create indexes for efficient querying
CREATE INDEX IF NOT EXISTS idx_geographical_features_geometry ON geographical_features USING GIST (geometry);
CREATE INDEX IF NOT EXISTS idx_geographical_features_type ON geographical_features (feature_type);
CREATE INDEX IF NOT EXISTS idx_geographical_features_osm_id ON geographical_features (osm_type, osm_id);
CREATE INDEX IF NOT EXISTS idx_geographical_features_properties ON geographical_features USING GIN (properties);
CREATE INDEX IF NOT EXISTS idx_geographical_features_created_at ON geographical_features (created_at);
-- Add check constraints
ALTER TABLE geographical_features ADD CONSTRAINT chk_geographical_features_geometry
CHECK (geometry IS NULL OR ST_IsValid(geometry));
ALTER TABLE geographical_features ADD CONSTRAINT chk_geographical_features_quality_score
CHECK (quality_score >= 0.0 AND quality_score <= 1.0);
-- Add comments for documentation
COMMENT ON TABLE geographical_features IS 'Geographical features imported from OpenStreetMap and other geospatial sources';
COMMENT ON COLUMN geographical_features.geometry IS 'PostGIS geometry field storing spatial data (roads, green spaces, etc.) in WGS84 (SRID 4326)';
COMMENT ON COLUMN geographical_features.properties IS 'Additional properties from the source data stored as JSONB for flexible querying';
COMMENT ON COLUMN geographical_features.quality_score IS 'Data quality score from 0.0 to 1.0 indicating reliability of the geographical data';