- **Migration to uv package manager**: Replace pip/requirements with modern pyproject.toml - Add pyproject.toml with complete dependency management - Update all scripts and Makefile to use uv commands - Maintain backward compatibility with existing workflows - **PostgreSQL integration and migration tools**: - Enhanced config.py with automatic password URL encoding - Complete PostgreSQL setup scripts and documentation - High-performance SQLite to PostgreSQL migration tool (91x speed improvement) - Support for both connection strings and individual components - **Executable distribution system**: - PyInstaller integration for standalone .exe creation - Automated build scripts with batch file generation - Complete packaging system for end-user distribution - **Enhanced data management**: - Fix --fill-gaps command with proper method implementation - Add gap detection and historical data backfill capabilities - Implement data update functionality for existing records - Add comprehensive database adapter methods - **Developer experience improvements**: - Password encoding tools for special characters - Interactive setup wizards for PostgreSQL configuration - Comprehensive documentation and migration guides - Automated testing and validation tools 🤖 Generated with [Claude Code](https://claude.ai/code) Co-Authored-By: Claude <noreply@anthropic.com>
162 lines
6.4 KiB
PL/PgSQL
162 lines
6.4 KiB
PL/PgSQL
-- Northern Thailand Ping River Monitor - PostgreSQL Database Schema
|
|
-- This script initializes the database tables for water monitoring data
|
|
|
|
-- Enable required extensions
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- Create schema for better organization
|
|
CREATE SCHEMA IF NOT EXISTS water_monitor;
|
|
SET search_path TO water_monitor, public;
|
|
|
|
-- Stations table - stores monitoring station information
|
|
CREATE TABLE IF NOT EXISTS stations (
|
|
id SERIAL PRIMARY KEY,
|
|
station_code VARCHAR(10) UNIQUE NOT NULL,
|
|
thai_name VARCHAR(255) NOT NULL,
|
|
english_name VARCHAR(255) NOT NULL,
|
|
latitude DECIMAL(10,8),
|
|
longitude DECIMAL(11,8),
|
|
geohash VARCHAR(20),
|
|
elevation DECIMAL(8,2), -- meters above sea level
|
|
river_basin VARCHAR(100),
|
|
province VARCHAR(100),
|
|
district VARCHAR(100),
|
|
is_active BOOLEAN DEFAULT true,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Water measurements table - stores time series data
|
|
CREATE TABLE IF NOT EXISTS water_measurements (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
timestamp TIMESTAMP NOT NULL,
|
|
station_id INTEGER NOT NULL,
|
|
water_level NUMERIC(10,3), -- meters
|
|
discharge NUMERIC(10,2), -- cubic meters per second
|
|
discharge_percent NUMERIC(5,2), -- percentage of normal discharge
|
|
status VARCHAR(20) DEFAULT 'active',
|
|
data_quality VARCHAR(20) DEFAULT 'good', -- good, fair, poor, missing
|
|
remarks TEXT,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (station_id) REFERENCES stations(id) ON DELETE CASCADE,
|
|
UNIQUE(timestamp, station_id)
|
|
);
|
|
|
|
-- Alert thresholds table - stores warning/danger levels for each station
|
|
CREATE TABLE IF NOT EXISTS alert_thresholds (
|
|
id SERIAL PRIMARY KEY,
|
|
station_id INTEGER NOT NULL,
|
|
threshold_type VARCHAR(20) NOT NULL, -- 'warning', 'danger', 'critical'
|
|
water_level_min NUMERIC(10,3),
|
|
water_level_max NUMERIC(10,3),
|
|
discharge_min NUMERIC(10,2),
|
|
discharge_max NUMERIC(10,2),
|
|
is_active BOOLEAN DEFAULT true,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (station_id) REFERENCES stations(id) ON DELETE CASCADE
|
|
);
|
|
|
|
-- Data quality log - tracks data collection issues
|
|
CREATE TABLE IF NOT EXISTS data_quality_log (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
timestamp TIMESTAMP NOT NULL,
|
|
station_id INTEGER,
|
|
issue_type VARCHAR(50) NOT NULL, -- 'connection_failed', 'invalid_data', 'missing_data'
|
|
description TEXT,
|
|
severity VARCHAR(20) DEFAULT 'info', -- 'info', 'warning', 'error', 'critical'
|
|
resolved_at TIMESTAMP,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (station_id) REFERENCES stations(id) ON DELETE SET NULL
|
|
);
|
|
|
|
-- Create indexes for better query performance
|
|
CREATE INDEX IF NOT EXISTS idx_water_measurements_timestamp ON water_measurements(timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_water_measurements_station_id ON water_measurements(station_id);
|
|
CREATE INDEX IF NOT EXISTS idx_water_measurements_station_timestamp ON water_measurements(station_id, timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_water_measurements_status ON water_measurements(status);
|
|
CREATE INDEX IF NOT EXISTS idx_stations_code ON stations(station_code);
|
|
CREATE INDEX IF NOT EXISTS idx_stations_active ON stations(is_active);
|
|
CREATE INDEX IF NOT EXISTS idx_data_quality_timestamp ON data_quality_log(timestamp DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_data_quality_station ON data_quality_log(station_id);
|
|
|
|
-- Create a view for latest measurements per station
|
|
CREATE OR REPLACE VIEW latest_measurements AS
|
|
SELECT
|
|
s.id as station_id,
|
|
s.station_code,
|
|
s.english_name,
|
|
s.thai_name,
|
|
s.latitude,
|
|
s.longitude,
|
|
s.province,
|
|
s.river_basin,
|
|
m.timestamp,
|
|
m.water_level,
|
|
m.discharge,
|
|
m.discharge_percent,
|
|
m.status,
|
|
m.data_quality,
|
|
CASE
|
|
WHEN m.timestamp > CURRENT_TIMESTAMP - INTERVAL '2 hours' THEN 'online'
|
|
WHEN m.timestamp > CURRENT_TIMESTAMP - INTERVAL '24 hours' THEN 'delayed'
|
|
ELSE 'offline'
|
|
END as station_status
|
|
FROM stations s
|
|
LEFT JOIN LATERAL (
|
|
SELECT * FROM water_measurements
|
|
WHERE station_id = s.id
|
|
ORDER BY timestamp DESC
|
|
LIMIT 1
|
|
) m ON true
|
|
WHERE s.is_active = true
|
|
ORDER BY s.station_code;
|
|
|
|
-- Create a function to update the updated_at timestamp
|
|
CREATE OR REPLACE FUNCTION update_modified_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
-- Create triggers to automatically update updated_at
|
|
DROP TRIGGER IF EXISTS update_stations_modtime ON stations;
|
|
CREATE TRIGGER update_stations_modtime
|
|
BEFORE UPDATE ON stations
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_modified_column();
|
|
|
|
-- Insert sample stations (Northern Thailand Ping River stations)
|
|
INSERT INTO stations (id, station_code, thai_name, english_name, latitude, longitude, province, river_basin) VALUES
|
|
(1, 'P.1', 'เชียงใหม่', 'Chiang Mai', 18.7883, 98.9853, 'Chiang Mai', 'Ping River'),
|
|
(2, 'P.4A', 'ท่าแพ', 'Tha Phae', 18.7875, 99.0045, 'Chiang Mai', 'Ping River'),
|
|
(3, 'P.12', 'สันป่าตอง', 'San Pa Tong', 18.6167, 98.9500, 'Chiang Mai', 'Ping River'),
|
|
(4, 'P.20', 'ลำพูน', 'Lamphun', 18.5737, 99.0081, 'Lamphun', 'Ping River'),
|
|
(5, 'P.30', 'ลี้', 'Li', 17.4833, 99.3000, 'Lamphun', 'Ping River'),
|
|
(6, 'P.35', 'ป่าซาง', 'Pa Sang', 18.5444, 98.9397, 'Lamphun', 'Ping River'),
|
|
(7, 'P.67', 'ตาก', 'Tak', 16.8839, 99.1267, 'Tak', 'Ping River'),
|
|
(8, 'P.75', 'สามเงา', 'Sam Ngao', 17.1019, 99.4644, 'Tak', 'Ping River')
|
|
ON CONFLICT (id) DO NOTHING;
|
|
|
|
-- Insert sample alert thresholds
|
|
INSERT INTO alert_thresholds (station_id, threshold_type, water_level_min, water_level_max) VALUES
|
|
(1, 'warning', 4.5, NULL),
|
|
(1, 'danger', 6.0, NULL),
|
|
(1, 'critical', 7.5, NULL),
|
|
(2, 'warning', 4.0, NULL),
|
|
(2, 'danger', 5.5, NULL),
|
|
(2, 'critical', 7.0, NULL)
|
|
ON CONFLICT DO NOTHING;
|
|
|
|
-- Grant permissions (adjust as needed for your setup)
|
|
GRANT USAGE ON SCHEMA water_monitor TO postgres;
|
|
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA water_monitor TO postgres;
|
|
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA water_monitor TO postgres;
|
|
|
|
-- Optional: Create a read-only user for reporting
|
|
-- CREATE USER water_monitor_readonly WITH PASSWORD 'readonly_password';
|
|
-- GRANT USAGE ON SCHEMA water_monitor TO water_monitor_readonly;
|
|
-- GRANT SELECT ON ALL TABLES IN SCHEMA water_monitor TO water_monitor_readonly;
|
|
|
|
COMMIT; |