turash/bugulma/backend/migrations/postgres/000003_add_optimization_indexes.up.sql
Damir Mukimov 000eab4740
Major repository reorganization and missing backend endpoints implementation
Repository Structure:
- Move files from cluttered root directory into organized structure
- Create archive/ for archived data and scraper results
- Create bugulma/ for the complete application (frontend + backend)
- Create data/ for sample datasets and reference materials
- Create docs/ for comprehensive documentation structure
- Create scripts/ for utility scripts and API tools

Backend Implementation:
- Implement 3 missing backend endpoints identified in gap analysis:
  * GET /api/v1/organizations/{id}/matching/direct - Direct symbiosis matches
  * GET /api/v1/users/me/organizations - User organizations
  * POST /api/v1/proposals/{id}/status - Update proposal status
- Add complete proposal domain model, repository, and service layers
- Create database migration for proposals table
- Fix CLI server command registration issue

API Documentation:
- Add comprehensive proposals.md API documentation
- Update README.md with Users and Proposals API sections
- Document all request/response formats, error codes, and business rules

Code Quality:
- Follow existing Go backend architecture patterns
- Add proper error handling and validation
- Match frontend expected response schemas
- Maintain clean separation of concerns (handler -> service -> repository)
2025-11-25 06:01:16 +01:00

76 lines
4.0 KiB
SQL
Executable File

-- +migrate Up
-- Enable required extensions
CREATE EXTENSION IF NOT EXISTS pg_trgm;
CREATE EXTENSION IF NOT EXISTS btree_gin;
-- Organizations Table Indexes
CREATE INDEX IF NOT EXISTS idx_org_certifications_gin ON organizations USING GIN (certifications);
CREATE INDEX IF NOT EXISTS idx_org_business_focus_gin ON organizations USING GIN (business_focus);
CREATE INDEX IF NOT EXISTS idx_org_technical_expertise_gin ON organizations USING GIN (technical_expertise);
CREATE INDEX IF NOT EXISTS idx_org_products_gin ON organizations USING GIN (products);
CREATE INDEX IF NOT EXISTS idx_org_sells_products_gin ON organizations USING GIN (sells_products);
CREATE INDEX IF NOT EXISTS idx_org_offers_services_gin ON organizations USING GIN (offers_services);
CREATE INDEX IF NOT EXISTS idx_org_supply_chain_sector ON organizations (supply_chain_role, industrial_sector);
CREATE INDEX IF NOT EXISTS idx_org_trust_score ON organizations (trust_score DESC);
-- Sites Table Indexes
CREATE INDEX IF NOT EXISTS idx_sites_type_ownership ON sites (site_type, ownership);
CREATE INDEX IF NOT EXISTS idx_sites_utilities_gin ON sites USING GIN (available_utilities);
CREATE INDEX IF NOT EXISTS idx_sites_waste_mgmt_gin ON sites USING GIN (waste_management);
CREATE INDEX IF NOT EXISTS idx_sites_has_space ON sites ((floor_area_m2 > 0)) WHERE floor_area_m2 IS NOT NULL;
-- Resource Flows Table Indexes
CREATE INDEX IF NOT EXISTS idx_rf_matching ON resource_flows (type, direction, precision_level)
WHERE precision_level IN ('measured', 'estimated');
CREATE INDEX IF NOT EXISTS idx_rf_quality_gin ON resource_flows USING GIN (quality);
CREATE INDEX IF NOT EXISTS idx_rf_constraints_gin ON resource_flows USING GIN (constraints);
-- Addresses Table Indexes
CREATE INDEX IF NOT EXISTS idx_addresses_formatted_ru_trgm ON addresses USING GIN (formatted_ru gin_trgm_ops);
CREATE INDEX IF NOT EXISTS idx_addresses_city_region ON addresses (city, region);
-- Shared Assets Table Indexes
CREATE INDEX IF NOT EXISTS idx_shared_assets_available ON shared_assets (type, utilization_rate)
WHERE operational_status = 'operational' AND utilization_rate < 1.0;
CREATE INDEX IF NOT EXISTS idx_shared_assets_users_gin ON shared_assets USING GIN (current_users);
-- Matches Table Indexes
CREATE INDEX IF NOT EXISTS idx_matches_active ON matches (status, priority DESC, compatibility_score DESC)
WHERE status IN ('suggested', 'negotiating', 'reserved');
CREATE INDEX IF NOT EXISTS idx_matches_expiring ON matches (reserved_until)
WHERE reserved_until IS NOT NULL AND status = 'reserved';
-- Check Constraints
DO $$
BEGIN
-- Check constraints
IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'chk_org_trust_score') THEN
ALTER TABLE organizations ADD CONSTRAINT chk_org_trust_score CHECK (trust_score >= 0 AND trust_score <= 1);
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'chk_org_company_size') THEN
ALTER TABLE organizations ADD CONSTRAINT chk_org_company_size CHECK (company_size >= 0);
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'chk_site_floor_area') THEN
ALTER TABLE sites ADD CONSTRAINT chk_site_floor_area CHECK (floor_area_m2 >= 0);
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'chk_site_capacity') THEN
ALTER TABLE sites ADD CONSTRAINT chk_site_capacity CHECK (crane_capacity_tonnes >= 0);
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'chk_rf_valid_direction') THEN
ALTER TABLE resource_flows ADD CONSTRAINT chk_rf_valid_direction CHECK (direction IN ('input', 'output'));
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'chk_asset_capacity') THEN
ALTER TABLE shared_assets ADD CONSTRAINT chk_asset_capacity CHECK (capacity >= 0);
END IF;
END
$$;
-- Partial Unique Constraints
CREATE UNIQUE INDEX IF NOT EXISTS idx_matches_unique_active ON matches (source_resource_id, target_resource_id)
WHERE status IN ('negotiating', 'reserved', 'contracted', 'live');