# 🗄️ Database Design & Data Structure Documentation ## 📋 Table of Contents 1. [Database Overview](#database-overview) 2. [Entity Relationship Diagram](#entity-relationship-diagram) 3. [Table Specifications](#table-specifications) 4. [Indexes & Performance](#indexes--performance) 5. [Data Migration Strategy](#data-migration-strategy) 6. [Backup & Recovery](#backup--recovery) 7. [Scaling Considerations](#scaling-considerations) --- ## 🌐 Database Overview ### Technology Stack ```json { "primary_database": "PostgreSQL 15.x", "cache_layer": "Redis 7.x", "orm": "TypeORM", "connection_pooling": "pg_pool", "backup_strategy": "Continuous WAL archiving", "monitoring": "PostgreSQL Stats + Custom metrics" } ``` ### Database Characteristics - **ACID Compliance**: Full ACID transaction support - **Concurrency**: Multi-version concurrency control (MVCC) - **Extensibility**: PostGIS for spatial operations - **Performance**: Optimized indexes for geospatial queries - **Scalability**: Read replicas and partitioning strategies --- ## 🔗 Entity Relationship Diagram ```mermaid erDiagram Users ||--o{ Reservations : makes Users ||--o{ Reviews : writes Users ||--o{ Favorites : has Users ||--o{ Payments : processes ParkingLots ||--o{ ParkingSpots : contains ParkingLots ||--o{ Reservations : receives ParkingLots ||--o{ Reviews : receives ParkingLots ||--o{ Favorites : featured_in ParkingLots ||--o{ PricingRules : has ParkingLots }|--|| Operators : managed_by ParkingSpots ||--o{ Reservations : reserved_for ParkingSpots ||--o{ SpotHistory : tracks Reservations ||--|| Payments : triggers Reservations ||--o{ ReservationHistory : logs Operators ||--o{ ParkingLots : manages Operators ||--o{ OperatorUsers : employs Users { uuid id PK string email UK string password_hash string full_name string phone timestamp created_at timestamp updated_at boolean is_active user_role role } ParkingLots { uuid id PK string name text address decimal latitude decimal longitude integer total_spots integer available_spots decimal price_per_hour jsonb operating_hours text[] amenities uuid operator_id FK timestamp created_at timestamp updated_at boolean is_active } ParkingSpots { uuid id PK uuid parking_lot_id FK string spot_number spot_type type boolean is_occupied boolean is_reserved timestamp last_updated } Reservations { uuid id PK uuid user_id FK uuid parking_spot_id FK timestamp start_time timestamp end_time decimal total_cost reservation_status status timestamp created_at timestamp updated_at } ``` --- ## 📊 Table Specifications ### 1. Users Table ```sql CREATE TYPE user_role AS ENUM ('customer', 'operator', 'admin'); CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, full_name VARCHAR(255) NOT NULL, phone VARCHAR(20), avatar_url TEXT, -- Preferences stored as JSONB for flexibility preferences JSONB DEFAULT '{}', -- Metadata created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_login_at TIMESTAMP WITH TIME ZONE, -- Status fields is_active BOOLEAN DEFAULT TRUE, email_verified BOOLEAN DEFAULT FALSE, phone_verified BOOLEAN DEFAULT FALSE, role user_role DEFAULT 'customer', -- Constraints CONSTRAINT valid_email CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$'), CONSTRAINT valid_phone CHECK (phone IS NULL OR phone ~* '^\+?[1-9]\d{1,14}$') ); -- Indexes CREATE INDEX idx_users_email ON users (email); CREATE INDEX idx_users_role_active ON users (role, is_active); CREATE INDEX idx_users_created_at ON users (created_at); -- Update trigger 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(); ``` ### 2. Operators Table ```sql CREATE TABLE operators ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), company_name VARCHAR(255) NOT NULL, contact_email VARCHAR(255) NOT NULL, contact_phone VARCHAR(20), address TEXT, -- Business information business_license VARCHAR(100), tax_id VARCHAR(50), -- Settings commission_rate DECIMAL(5,4) DEFAULT 0.1000, -- 10% default auto_approval BOOLEAN DEFAULT FALSE, -- Metadata created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, is_active BOOLEAN DEFAULT TRUE, CONSTRAINT valid_commission_rate CHECK (commission_rate >= 0 AND commission_rate <= 1) ); -- Indexes CREATE INDEX idx_operators_active ON operators (is_active); CREATE INDEX idx_operators_company_name ON operators (company_name); ``` ### 3. Parking Lots Table ```sql CREATE TABLE parking_lots ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), operator_id UUID REFERENCES operators(id) ON DELETE CASCADE, -- Basic information name VARCHAR(255) NOT NULL, description TEXT, address TEXT NOT NULL, -- Geolocation (using decimal for precision) latitude DECIMAL(10,8) NOT NULL, longitude DECIMAL(11,8) NOT NULL, -- Capacity total_spots INTEGER NOT NULL DEFAULT 0, available_spots INTEGER NOT NULL DEFAULT 0, -- Pricing price_per_hour DECIMAL(10,2) NOT NULL, currency CHAR(3) DEFAULT 'USD', -- Operating hours stored as JSONB for flexibility operating_hours JSONB DEFAULT '{ "monday": {"open": "00:00", "close": "23:59", "is24Hours": true}, "tuesday": {"open": "00:00", "close": "23:59", "is24Hours": true}, "wednesday": {"open": "00:00", "close": "23:59", "is24Hours": true}, "thursday": {"open": "00:00", "close": "23:59", "is24Hours": true}, "friday": {"open": "00:00", "close": "23:59", "is24Hours": true}, "saturday": {"open": "00:00", "close": "23:59", "is24Hours": true}, "sunday": {"open": "00:00", "close": "23:59", "is24Hours": true} }', -- Amenities as array amenities TEXT[] DEFAULT '{}', -- Images images JSONB DEFAULT '[]', -- Ratings average_rating DECIMAL(3,2) DEFAULT 0, total_reviews INTEGER DEFAULT 0, -- Metadata created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_availability_update TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, is_active BOOLEAN DEFAULT TRUE, -- Constraints CONSTRAINT valid_coordinates CHECK ( latitude BETWEEN -90 AND 90 AND longitude BETWEEN -180 AND 180 ), CONSTRAINT valid_capacity CHECK ( total_spots >= 0 AND available_spots >= 0 AND available_spots <= total_spots ), CONSTRAINT valid_price CHECK (price_per_hour >= 0), CONSTRAINT valid_rating CHECK (average_rating BETWEEN 0 AND 5) ); -- Spatial index for location-based queries CREATE INDEX idx_parking_lots_location ON parking_lots USING GIST (ll_to_earth(latitude, longitude)); -- Regular indexes CREATE INDEX idx_parking_lots_operator ON parking_lots (operator_id); CREATE INDEX idx_parking_lots_active ON parking_lots (is_active); CREATE INDEX idx_parking_lots_price ON parking_lots (price_per_hour); CREATE INDEX idx_parking_lots_availability ON parking_lots (available_spots, is_active); CREATE INDEX idx_parking_lots_rating ON parking_lots (average_rating DESC); -- Composite index for common queries CREATE INDEX idx_parking_lots_active_location ON parking_lots (is_active, latitude, longitude); ``` ### 4. Parking Spots Table ```sql CREATE TYPE spot_type AS ENUM ('regular', 'disabled', 'electric', 'compact', 'motorcycle'); CREATE TABLE parking_spots ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), parking_lot_id UUID REFERENCES parking_lots(id) ON DELETE CASCADE, -- Spot identification spot_number VARCHAR(20) NOT NULL, floor_level INTEGER DEFAULT 0, section VARCHAR(10), -- Spot characteristics type spot_type DEFAULT 'regular', size_category VARCHAR(20) DEFAULT 'standard', -- compact, standard, large -- Status is_occupied BOOLEAN DEFAULT FALSE, is_reserved BOOLEAN DEFAULT FALSE, is_maintenance BOOLEAN DEFAULT FALSE, -- Timestamps last_updated TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, occupied_since TIMESTAMP WITH TIME ZONE, -- Constraints UNIQUE(parking_lot_id, spot_number), CONSTRAINT valid_floor CHECK (floor_level BETWEEN -10 AND 50) ); -- Indexes CREATE INDEX idx_parking_spots_lot ON parking_spots (parking_lot_id); CREATE INDEX idx_parking_spots_status ON parking_spots (is_occupied, is_reserved, is_maintenance); CREATE INDEX idx_parking_spots_type ON parking_spots (type); CREATE INDEX idx_parking_spots_availability ON parking_spots (parking_lot_id, is_occupied, is_reserved, is_maintenance); ``` ### 5. Reservations Table ```sql CREATE TYPE reservation_status AS ENUM ( 'pending', 'confirmed', 'active', 'completed', 'cancelled', 'no_show', 'expired' ); CREATE TABLE reservations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, parking_spot_id UUID REFERENCES parking_spots(id) ON DELETE CASCADE, -- Timing start_time TIMESTAMP WITH TIME ZONE NOT NULL, end_time TIMESTAMP WITH TIME ZONE NOT NULL, actual_start_time TIMESTAMP WITH TIME ZONE, actual_end_time TIMESTAMP WITH TIME ZONE, -- Pricing base_cost DECIMAL(10,2) NOT NULL, discount_amount DECIMAL(10,2) DEFAULT 0, tax_amount DECIMAL(10,2) DEFAULT 0, total_cost DECIMAL(10,2) NOT NULL, currency CHAR(3) DEFAULT 'USD', -- Vehicle information vehicle_info JSONB DEFAULT '{}', -- Status and notes status reservation_status DEFAULT 'pending', special_requests TEXT, cancellation_reason TEXT, -- Metadata created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, confirmation_code VARCHAR(10) UNIQUE, -- Constraints CONSTRAINT valid_duration CHECK (end_time > start_time), CONSTRAINT valid_costs CHECK ( base_cost >= 0 AND discount_amount >= 0 AND tax_amount >= 0 AND total_cost >= 0 ) ); -- Generate confirmation code CREATE OR REPLACE FUNCTION generate_confirmation_code() RETURNS TRIGGER AS $$ BEGIN IF NEW.confirmation_code IS NULL THEN NEW.confirmation_code := upper(substring(md5(random()::text) from 1 for 8)); END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER set_confirmation_code BEFORE INSERT ON reservations FOR EACH ROW EXECUTE FUNCTION generate_confirmation_code(); -- Indexes CREATE INDEX idx_reservations_user ON reservations (user_id); CREATE INDEX idx_reservations_spot ON reservations (parking_spot_id); CREATE INDEX idx_reservations_status ON reservations (status); CREATE INDEX idx_reservations_time_range ON reservations (start_time, end_time); CREATE INDEX idx_reservations_confirmation ON reservations (confirmation_code); -- Composite indexes for common queries CREATE INDEX idx_reservations_user_status ON reservations (user_id, status); CREATE INDEX idx_reservations_spot_time ON reservations (parking_spot_id, start_time, end_time); ``` ### 6. Payments Table ```sql CREATE TYPE payment_method AS ENUM ('credit_card', 'debit_card', 'digital_wallet', 'bank_transfer', 'cash'); CREATE TYPE payment_status AS ENUM ('pending', 'processing', 'completed', 'failed', 'refunded', 'disputed'); CREATE TABLE payments ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), reservation_id UUID REFERENCES reservations(id) ON DELETE CASCADE, user_id UUID REFERENCES users(id) ON DELETE CASCADE, -- Payment details amount DECIMAL(10,2) NOT NULL, currency CHAR(3) DEFAULT 'USD', method payment_method NOT NULL, status payment_status DEFAULT 'pending', -- External payment provider information provider_name VARCHAR(50), -- stripe, paypal, etc. provider_transaction_id VARCHAR(255), provider_fee DECIMAL(10,2) DEFAULT 0, -- Payment metadata payment_date TIMESTAMP WITH TIME ZONE, processed_at TIMESTAMP WITH TIME ZONE, failure_reason TEXT, refund_amount DECIMAL(10,2) DEFAULT 0, refund_date TIMESTAMP WITH TIME ZONE, -- Metadata created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, CONSTRAINT valid_amount CHECK (amount > 0), CONSTRAINT valid_refund CHECK (refund_amount >= 0 AND refund_amount <= amount) ); -- Indexes CREATE INDEX idx_payments_reservation ON payments (reservation_id); CREATE INDEX idx_payments_user ON payments (user_id); CREATE INDEX idx_payments_status ON payments (status); CREATE INDEX idx_payments_method ON payments (method); CREATE INDEX idx_payments_provider ON payments (provider_name, provider_transaction_id); CREATE INDEX idx_payments_date ON payments (payment_date); ``` ### 7. Reviews Table ```sql CREATE TABLE reviews ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, parking_lot_id UUID REFERENCES parking_lots(id) ON DELETE CASCADE, reservation_id UUID REFERENCES reservations(id) ON DELETE SET NULL, -- Review content rating INTEGER NOT NULL, title VARCHAR(255), comment TEXT, -- Review metadata is_verified BOOLEAN DEFAULT FALSE, -- verified if linked to actual reservation is_flagged BOOLEAN DEFAULT FALSE, admin_response TEXT, -- Timestamps created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, -- Constraints CONSTRAINT valid_rating CHECK (rating BETWEEN 1 AND 5), UNIQUE(user_id, parking_lot_id) -- One review per user per parking lot ); -- Indexes CREATE INDEX idx_reviews_parking_lot ON reviews (parking_lot_id); CREATE INDEX idx_reviews_user ON reviews (user_id); CREATE INDEX idx_reviews_rating ON reviews (rating); CREATE INDEX idx_reviews_verified ON reviews (is_verified); CREATE INDEX idx_reviews_created_at ON reviews (created_at); ``` --- ## 🚀 Indexes & Performance ### 1. Spatial Indexes for Location Queries ```sql -- Enable PostGIS extension for advanced spatial operations CREATE EXTENSION IF NOT EXISTS postgis; -- Convert existing lat/lng to geometry for better performance ALTER TABLE parking_lots ADD COLUMN geom GEOMETRY(POINT, 4326); -- Populate geometry column UPDATE parking_lots SET geom = ST_SetSRID(ST_MakePoint(longitude, latitude), 4326); -- Create spatial index CREATE INDEX idx_parking_lots_geom ON parking_lots USING GIST (geom); -- Function for distance-based queries CREATE OR REPLACE FUNCTION find_nearby_parking( user_lat DECIMAL, user_lng DECIMAL, radius_meters INTEGER DEFAULT 5000 ) RETURNS TABLE( id UUID, name VARCHAR, distance_meters DECIMAL ) AS $$ BEGIN RETURN QUERY SELECT pl.id, pl.name, ST_Distance( ST_SetSRID(ST_MakePoint(user_lng, user_lat), 4326)::geography, pl.geom::geography ) as distance_meters FROM parking_lots pl WHERE pl.is_active = TRUE AND ST_DWithin( ST_SetSRID(ST_MakePoint(user_lng, user_lat), 4326)::geography, pl.geom::geography, radius_meters ) ORDER BY distance_meters; END; $$ LANGUAGE plpgsql; ``` ### 2. Partitioning Strategy ```sql -- Partition reservations by month for better performance CREATE TABLE reservations_partitioned ( LIKE reservations INCLUDING ALL ) PARTITION BY RANGE (start_time); -- Create partitions for current and future months CREATE TABLE reservations_2024_08 PARTITION OF reservations_partitioned FOR VALUES FROM ('2024-08-01') TO ('2024-09-01'); CREATE TABLE reservations_2024_09 PARTITION OF reservations_partitioned FOR VALUES FROM ('2024-09-01') TO ('2024-10-01'); -- Automated partition creation function CREATE OR REPLACE FUNCTION create_monthly_partition() RETURNS void AS $$ DECLARE start_date DATE; end_date DATE; table_name TEXT; BEGIN start_date := DATE_TRUNC('month', CURRENT_DATE + INTERVAL '1 month'); end_date := start_date + INTERVAL '1 month'; table_name := 'reservations_' || TO_CHAR(start_date, 'YYYY_MM'); EXECUTE FORMAT( 'CREATE TABLE %I PARTITION OF reservations_partitioned FOR VALUES FROM (%L) TO (%L)', table_name, start_date, end_date ); END; $$ LANGUAGE plpgsql; -- Schedule monthly partition creation SELECT cron.schedule('create-partition', '0 0 1 * *', 'SELECT create_monthly_partition();'); ``` ### 3. Performance Monitoring Views ```sql -- View for monitoring table sizes CREATE VIEW table_sizes AS SELECT schemaname, tablename, attname, n_distinct, correlation, pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) as size FROM pg_stats WHERE schemaname = 'public' ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC; -- View for monitoring index usage CREATE VIEW index_usage AS SELECT schemaname, tablename, attname, n_distinct, correlation FROM pg_stats WHERE schemaname = 'public'; -- View for monitoring slow queries CREATE VIEW slow_queries AS SELECT query, calls, total_time, mean_time, rows FROM pg_stat_statements WHERE mean_time > 100 ORDER BY mean_time DESC; ``` --- ## 🔄 Data Migration Strategy ### 1. Migration Scripts Structure ```sql -- Migration: 001_initial_schema.sql -- Description: Create initial database schema -- Date: 2024-08-03 -- Author: System BEGIN; -- Create enums CREATE TYPE user_role AS ENUM ('customer', 'operator', 'admin'); CREATE TYPE spot_type AS ENUM ('regular', 'disabled', 'electric', 'compact', 'motorcycle'); -- ... rest of schema creation -- Create migration tracking table CREATE TABLE IF NOT EXISTS schema_migrations ( version VARCHAR(255) PRIMARY KEY, applied_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); INSERT INTO schema_migrations (version) VALUES ('001_initial_schema'); COMMIT; ``` ### 2. Data Seeding ```sql -- Seed: 001_default_data.sql -- Description: Insert default operational data -- Date: 2024-08-03 BEGIN; -- Insert default operator INSERT INTO operators (id, company_name, contact_email, contact_phone, is_active) VALUES ( 'b123b123-b123-b123-b123-b123b123b123', 'City Parking Management', 'admin@cityparking.com', '+1234567890', TRUE ); -- Insert sample parking lots INSERT INTO parking_lots ( id, operator_id, name, address, latitude, longitude, total_spots, available_spots, price_per_hour, amenities ) VALUES ( 'a123a123-a123-a123-a123-a123a123a123', 'b123b123-b123-b123-b123-b123b123b123', 'Downtown Parking Garage', '123 Main St, Downtown', 40.7128, -74.0060, 200, 150, 5.00, ARRAY['covered', 'security', 'electric_charging'] ); COMMIT; ``` ### 3. Backup Strategy ```bash #!/bin/bash # backup_database.sh # Automated database backup script DB_NAME="smart_parking" BACKUP_DIR="/backups/postgresql" DATE=$(date +%Y%m%d_%H%M%S) # Create full backup pg_dump -h localhost -U postgres -d $DB_NAME \ --verbose --format=custom \ --file="$BACKUP_DIR/full_backup_$DATE.backup" # Create schema-only backup pg_dump -h localhost -U postgres -d $DB_NAME \ --schema-only --verbose \ --file="$BACKUP_DIR/schema_backup_$DATE.sql" # Cleanup old backups (keep last 30 days) find $BACKUP_DIR -name "*.backup" -mtime +30 -delete find $BACKUP_DIR -name "*.sql" -mtime +30 -delete ``` --- ## 📈 Scaling Considerations ### 1. Read Replicas Configuration ```sql -- Master database configuration -- postgresql.conf wal_level = replica max_wal_senders = 3 wal_keep_segments = 64 hot_standby = on -- Replica database queries -- Route read-only queries to replicas CREATE OR REPLACE FUNCTION is_read_only_query(query_text TEXT) RETURNS BOOLEAN AS $$ BEGIN RETURN query_text ~* '^(SELECT|WITH)' AND query_text !~* '(FOR UPDATE|FOR SHARE)'; END; $$ LANGUAGE plpgsql; ``` ### 2. Connection Pooling ```javascript // Database connection pool configuration const poolConfig = { host: process.env.DB_HOST, port: process.env.DB_PORT, database: process.env.DB_NAME, user: process.env.DB_USER, password: process.env.DB_PASSWORD, // Pool configuration min: 5, // Minimum connections max: 50, // Maximum connections idle: 10000, // Idle timeout (10 seconds) acquire: 60000, // Acquire timeout (60 seconds) evict: 1000, // Eviction run interval (1 second) // Connection validation validate: true, validateTimeout: 3000, // Logging logging: (sql, timing) => { if (timing > 1000) { console.warn(`Slow query detected: ${timing}ms - ${sql}`); } } }; ``` ### 3. Caching Strategy ```sql -- Materialized views for expensive aggregations CREATE MATERIALIZED VIEW parking_lot_stats AS SELECT pl.id, pl.name, pl.total_spots, pl.available_spots, ROUND(AVG(r.rating), 2) as avg_rating, COUNT(r.id) as total_reviews, COUNT(res.id) as total_reservations FROM parking_lots pl LEFT JOIN reviews r ON pl.id = r.parking_lot_id LEFT JOIN reservations res ON pl.id = res.parking_spot_id WHERE pl.is_active = TRUE GROUP BY pl.id, pl.name, pl.total_spots, pl.available_spots; -- Refresh materialized view regularly CREATE OR REPLACE FUNCTION refresh_parking_stats() RETURNS void AS $$ BEGIN REFRESH MATERIALIZED VIEW CONCURRENTLY parking_lot_stats; END; $$ LANGUAGE plpgsql; -- Schedule refresh every hour SELECT cron.schedule('refresh-stats', '0 * * * *', 'SELECT refresh_parking_stats();'); ``` ### 4. Database Monitoring ```sql -- Create monitoring functions CREATE OR REPLACE FUNCTION database_health_check() RETURNS TABLE( metric VARCHAR, value DECIMAL, status VARCHAR ) AS $$ BEGIN RETURN QUERY WITH metrics AS ( SELECT 'active_connections' as metric, COUNT(*)::DECIMAL as value, CASE WHEN COUNT(*) > 80 THEN 'WARNING' ELSE 'OK' END as status FROM pg_stat_activity WHERE state = 'active' UNION ALL SELECT 'cache_hit_ratio' as metric, ROUND( 100.0 * sum(blks_hit) / (sum(blks_hit) + sum(blks_read)), 2 ) as value, CASE WHEN 100.0 * sum(blks_hit) / (sum(blks_hit) + sum(blks_read)) < 95 THEN 'WARNING' ELSE 'OK' END as status FROM pg_stat_database UNION ALL SELECT 'table_bloat' as metric, pg_size_pretty(pg_database_size(current_database()))::DECIMAL as value, 'INFO' as status ) SELECT * FROM metrics; END; $$ LANGUAGE plpgsql; ``` --- *Last Updated: August 3, 2025* *Version: 1.0.0*