Finalize the postgres package for release

This commit is contained in:
Tom Rogers 2025-03-25 10:33:39 -05:00
parent aa2f97bd0f
commit a273dd994f
13 changed files with 937 additions and 912 deletions

183
INSTALL.md Normal file
View File

@ -0,0 +1,183 @@
# Installation Guide for c77_dbh PostgreSQL Extension
This guide covers multiple installation methods for the c77_dbh PostgreSQL extension, including standard package installation and manual installation options.
## Table of Contents
- [Prerequisites](#prerequisites)
- [Option 1: Standard Installation](#option-1-standard-installation)
- [Option 2: Manual Installation](#option-2-manual-installation)
- [Post-Installation Setup](#post-installation-setup)
- [Verifying Installation](#verifying-installation)
- [Upgrading](#upgrading)
- [Troubleshooting](#troubleshooting)
## Prerequisites
- PostgreSQL 13 or higher
- PostgreSQL development packages (for building from source)
- Root or `sudo` access to the PostgreSQL server
- Access to `psql` with superuser privileges
- Optional extensions for enhanced functionality:
- `pgstattuple`: For precise bloat estimates
- `pg_stat_statements`: For detailed query performance metrics
- `pg_cron`: For automated statistics collection
## Option 1: Standard Installation
### From Repository
1. Clone the repository:
```bash
git clone https://git.jctr3.com/trogers1884/c77_dbh.git
cd c77_dbh
```
2. Build and install:
```bash
make
sudo make install
```
3. Connect to your PostgreSQL database and create the extension:
```sql
CREATE EXTENSION c77_dbh;
```
## Option 2: Manual Installation
If you prefer to install the extension manually or if you don't have build tools available, follow these steps:
### Step 1: Prepare the Extension Files
1. Create the extension directory in PostgreSQL's extension directory:
```bash
# Find PostgreSQL's extension directory
PG_EXT_DIR=$(pg_config --sharedir)/extension
sudo mkdir -p $PG_EXT_DIR
```
2. Create the control file:
```bash
cat << EOF | sudo tee $PG_EXT_DIR/c77_dbh.control
comment = 'Database health monitoring tools for vacuum, index, and materialized view performance'
default_version = '1.0'
module_pathname = '$libdir/c77_dbh'
relocatable = true
EOF
```
3. Copy the SQL script:
```bash
sudo cp c77_dbh--1.0.sql $PG_EXT_DIR/
```
If you don't have the repository, create the SQL file manually:
```bash
# Create the SQL file with the content from c77_dbh--1.0.sql
sudo nano $PG_EXT_DIR/c77_dbh--1.0.sql
# Copy the entire SQL file content into this file and save it
```
### Step 2: Create Extension in Database
Connect to your PostgreSQL database and create the extension:
```sql
CREATE EXTENSION c77_dbh;
```
## Post-Installation Setup
After installing the extension, you'll need to set up permissions and perform initial data collection:
1. Set permissions (optional):
```sql
-- For read-only access
GRANT SELECT ON ALL TABLES IN SCHEMA public TO readonly_role;
-- For administrative access
GRANT ALL ON ALL TABLES IN SCHEMA public TO admin_role;
```
2. Initialize statistics:
```sql
-- Update vacuum statistics
SELECT c77_dbh_update_vacuum_stats();
-- Update index statistics
SELECT c77_dbh_update_index_stats();
```
3. Set up automated updates with pg_cron (if installed):
```sql
-- Ensure pg_cron extension is created
CREATE EXTENSION IF NOT EXISTS pg_cron;
-- Schedule updates every 6 hours
SELECT cron.schedule('update_vacuum_stats', '0 */6 * * *', 'SELECT c77_dbh_update_vacuum_stats()');
SELECT cron.schedule('update_index_stats', '0 */6 * * *', 'SELECT c77_dbh_update_index_stats()');
```
## Verifying Installation
To verify the extension was installed correctly:
1. Check if the extension exists:
```sql
SELECT * FROM pg_extension WHERE extname = 'c77_dbh';
```
2. Verify tables were created:
```sql
\dt c77_dbh_*
```
3. Test a function:
```sql
SELECT c77_dbh_update_vacuum_stats();
SELECT * FROM c77_dbh_vacuum_stats LIMIT 5;
```
## Upgrading
When upgrading the extension to a new version:
1. Create the new version SQL script in the extensions directory.
2. Update the extension in the database:
```sql
ALTER EXTENSION c77_dbh UPDATE TO '1.1';
```
## Troubleshooting
### Common Issues
1. **Permission Denied Errors**:
- Ensure you have superuser privileges when creating the extension.
- Check file permissions on the extension files.
2. **Extension Not Found**:
- Verify the extension files are in the correct PostgreSQL extension directory.
- Check the control file for syntax errors.
3. **Dependency Issues**:
- If you see errors related to pgstattuple or pg_stat_statements, install these optional extensions.
4. **Limited Precision in Reports**:
- Install pgstattuple extension for more accurate bloat estimates.
### Debugging
If you encounter issues, check the PostgreSQL logs:
```bash
tail -100 /var/log/postgresql/postgresql.log
```
## Additional Resources
- PostgreSQL Documentation on Extensions: [https://www.postgresql.org/docs/current/extend-extensions.html](https://www.postgresql.org/docs/current/extend-extensions.html)
- pgstattuple Documentation: [https://www.postgresql.org/docs/current/pgstattuple.html](https://www.postgresql.org/docs/current/pgstattuple.html)
- pg_stat_statements Documentation: [https://www.postgresql.org/docs/current/pgstatstatements.html](https://www.postgresql.org/docs/current/pgstatstatements.html)

20
LICENSE
View File

@ -1,9 +1,21 @@
MIT License MIT License
Copyright (c) 2025 trogers1884 Copyright (c) 2025 c77_dbh Contributors
Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software without restriction, including without limitation the rights
to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
copies of the Software, and to permit persons to whom the Software is
furnished to do so, subject to the following conditions:
The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. The above copyright notice and this permission notice shall be included in all
copies or substantial portions of the Software.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.

6
Makefile Normal file
View File

@ -0,0 +1,6 @@
# Makefile
EXTENSION = c77_dbh
DATA = c77_dbh--1.0.sql
PG_CONFIG = pg_config
PGXS := $(shell $(PG_CONFIG) --pgxs)
include $(PGXS)

289
README.md
View File

@ -1,142 +1,183 @@
# c77_dbh - Postgres Database Health Extension # c77_dbh - PostgreSQL Database Health Extension
**c77_dbh** is a PostgreSQL extension designed to monitor and maintain database health, providing actionable insights for database administrators and non-technical users alike. It offers a suite of functions and tables to track vacuum performance, index efficiency, materialized view refresh health, and TOAST table overhead—all packaged as a self-contained, drop-in solution for Postgres environments. [![PostgreSQL](https://img.shields.io/badge/PostgreSQL-13%2B-blue.svg)](https://www.postgresql.org/)
[![License](https://img.shields.io/badge/license-MIT-green.svg)](LICENSE)
The extension pushes logic into the database itself, minimizing reliance on external frameworks, and outputs JSON-formatted data ideal for dashboards. It dynamically adjusts thresholds based on your databases behavior and adapts to optional Postgres extensions (e.g., `pgstattuple`, `pg_stat_statements`) for enhanced precision. A lightweight, intelligent PostgreSQL extension for database health monitoring and maintenance. Provides actionable insights through JSON-formatted metrics on table bloat, index efficiency, materialized view performance, and more.
## Features ## 🔍 Overview
- **Vacuum Health Monitoring**: Tracks table bloat, vacuum history, and TOAST overhead with dynamic thresholds. **c77_dbh** embeds health monitoring directly into your PostgreSQL database, eliminating the need for external monitoring tools. It uses statistical analysis to establish dynamic, database-specific thresholds for various health indicators, enabling both technical and non-technical users to identify and address performance issues.
- **Index Health Analysis**: Monitors index usage and bloat, excluding or isolating TOAST indexes as needed.
- **Materialized View Refresh Tracking**: Measures refresh performance with event triggers, identifying bottlenecks (I/O, CPU, RAM).
- **Human-Readable Insights**: Provides status (Red/Yellow/Green), severity scores, insights, and actions for each metric.
- **Dashboard-Ready**: JSON outputs structured for easy integration into graphical interfaces.
- **Resource Awareness**: Gracefully falls back when optional extensions are unavailable.
## Installation ## ✨ Features
### Prerequisites - **Intelligent Vacuum Monitoring**: Tracks table bloat with context-aware thresholds and TOAST overhead detection
- PostgreSQL 13 or higher (tested up to 15 as of March 2025). - **Index Usage Analysis**: Identifies unused or bloated indexes with efficiency metrics and specific recommendations
- Optional extensions for enhanced functionality: - **Materialized View Performance**: Monitors refresh times and bottlenecks (I/O, CPU, memory) with historical trending
- `pgstattuple`: Precise bloat estimates for tables and indexes. - **Adaptive Precision**: Automatically leverages `pgstattuple` and `pg_stat_statements` when available, with graceful fallbacks
- `pg_stat_statements`: Detailed query and refresh performance metrics. - **Human-readable Insights**: Provides clear status indicators (Red/Yellow/Green), severity scores (1-5), and actionable recommendations
- `pg_cron`: Automate periodic stat updates (recommended). - **Dashboard-Ready Outputs**: Structured JSON format ideal for integration with monitoring dashboards
- **Low Overhead**: Minimal impact on database performance with configurable collection frequencies
### Steps ## 📊 Example Output
1. **Clone the Repository**:
```bash
git clone https://git.jctr3.com/trogers1884/c77_dbh.git
cd c77_dbh
```
2. **Build and Install**: ```json
```bash [
make {
sudo make install "metric": "Table Vacuum Health",
``` "table_name": "public.large_table",
(Note: Assumes a standard Postgres extension build process; adjust paths if needed.) "status": "Red",
"severity": 5,
"insight": "Table bloat is critically high; TOAST overhead is significant.",
"action": "Run VACUUM FULL or CLUSTER; review large fields for TOAST impact.",
"last_vacuum": "2025-03-10 14:30:22",
"last_autovacuum": "2025-03-12 02:15:44",
"vacuum_count": 127,
"dead_tuples": 1543267,
"live_tuples": 4329856,
"table_size": "2.3 GB",
"bloat_estimate": "42% (precise)",
"details": {
"median_bloat": "15%",
"bloat_stddev": "8%",
"toast_bloat": "22%",
"explanation": "Includes TOAST bloat in total health assessment."
}
}
]
```
3. **Enable in Database**: ## 📋 Requirements
```sql
CREATE EXTENSION c77_dbh;
```
4. **Grant Permissions** (optional, adjust roles as needed): - PostgreSQL 13 or higher
```sql - Optional but recommended:
GRANT SELECT ON ALL TABLES IN SCHEMA public TO public; - `pgstattuple` extension for precise bloat measurements
GRANT ALL ON ALL TABLES IN SCHEMA public TO your_admin_role; - `pg_stat_statements` extension for enhanced query performance insights
``` - `pg_cron` extension for automated statistics collection
## Usage ## 🛠️ Installation
See the [Installation Guide](INSTALL.md) for detailed installation instructions, including manual installation steps.
## 📘 Usage
### Basic Setup
After installation, enable the extension in your database:
```sql
CREATE EXTENSION c77_dbh;
```
### Collecting Statistics
Initialize the statistics tables:
```sql
-- Update table and vacuum statistics
SELECT c77_dbh_update_vacuum_stats();
-- Update index statistics (including TOAST indexes)
SELECT c77_dbh_update_index_stats();
```
### Monitoring Health
Query health metrics:
```sql
-- Table health with bloat estimates and recommendations
SELECT * FROM c77_dbh_get_vacuum_health();
-- Index health analysis
SELECT * FROM c77_dbh_get_index_health();
-- TOAST index specific analysis
SELECT * FROM c77_dbh_get_toast_health();
-- Materialized view refresh performance
SELECT * FROM c77_dbh_get_mv_health();
```
### Automation
With `pg_cron` extension:
```sql
-- Update vacuum stats hourly
SELECT cron.schedule('update_vacuum_stats', '0 * * * *',
'SELECT c77_dbh_update_vacuum_stats()');
-- Update index stats hourly
SELECT cron.schedule('update_index_stats', '0 * * * *',
'SELECT c77_dbh_update_index_stats()');
```
## 🖥️ Dashboard Integration
The JSON output format makes integration with monitoring dashboards straightforward:
- **Grafana**: Use a PostgreSQL data source with JSON parsing
- **Pganalyze**: Import as custom metrics
- **Custom dashboards**: Use the structured JSON for consistency
## 🔄 Update Frequency Recommendations
| Database Characteristics | Recommended Update Frequency |
|--------------------------|------------------------------|
| High-write production | Hourly |
| Mixed read/write | Every 6 hours |
| Read-heavy, stable | Daily |
| Development/staging | On-demand or daily |
## 🔧 Advanced Configuration
- Adjust permissions as needed:
```sql
-- Grant read access to a reporting role
GRANT SELECT ON ALL TABLES IN SCHEMA public TO reporting_role;
-- Grant full access to admin roles
GRANT ALL ON ALL TABLES IN SCHEMA public TO admin_role;
```
- Include in schema backups:
```bash
pg_dump -s -n public mydatabase > schema.sql
```
## 📝 Contributing
Contributions are welcome! Please feel free to submit a Pull Request.
1. Fork the repository
2. Create your feature branch (`git checkout -b feature/amazing-feature`)
3. Commit your changes (`git commit -m 'Add some amazing feature'`)
4. Push to the branch (`git push origin feature/amazing-feature`)
5. Open a Pull Request
## 📜 License
This project is licensed under the MIT License - see the [LICENSE](LICENSE) file for details.
## 📊 Technical Details
The extension consists of:
### Core Components
- **Tables**: - **Tables**:
- `c77_dbh_vacuum_stats`: Stores table vacuum and bloat stats. - `c77_dbh_vacuum_stats`: Table vacuum statistics
- `c77_dbh_index_stats`: Tracks index size, usage, and bloat. - `c77_dbh_index_stats`: Index usage and bloat statistics
- `c77_dbh_mv_stats`: Records materialized view refresh metrics. - `c77_dbh_mv_stats`: Materialized view refresh metrics
- **Functions**: - **Functions**:
- `c77_dbh_update_vacuum_stats()`: Updates vacuum stats for all tables. - Data collection functions (e.g., `c77_dbh_update_vacuum_stats()`)
- `c77_dbh_update_index_stats()`: Updates index stats. - Health assessment functions (e.g., `c77_dbh_get_vacuum_health()`)
- `c77_dbh_get_vacuum_health()`: Returns JSON with table health status. - Event trigger functions for materialized views
- `c77_dbh_get_index_health()`: JSON for non-TOAST index health.
- `c77_dbh_get_toast_health()`: JSON for TOAST index health.
- `c77_dbh_get_mv_health()`: JSON for materialized view refresh health.
- `c77_dbh_get_mv_details(mv_name text)`: Detailed JSON for a specific MV.
- **Event Triggers**: Automatically track materialized view creation, alteration, and refreshes. - **Event Triggers**:
- Automatically tracks materialized view operations
### Example Workflow ## 🙏 Acknowledgments
1. **Initialize Stats**:
```sql
SELECT c77_dbh_update_vacuum_stats();
SELECT c77_dbh_update_index_stats();
```
2. **Query Health**:
```sql
SELECT * FROM c77_dbh_get_vacuum_health();
SELECT * FROM c77_dbh_get_index_health();
SELECT * FROM c77_dbh_get_mv_health();
```
3. **Automate Updates** (with `pg_cron`):
```sql
SELECT cron.schedule('update_vacuum_stats', '0 * * * *', $$SELECT c77_dbh_update_vacuum_stats()$$);
SELECT cron.schedule('update_index_stats', '0 * * * *', $$SELECT c77_dbh_update_index_stats()$$);
```
4. **Sample Output** (from `c77_dbh_get_vacuum_health()`):
```json
[
{
"metric": "Table Vacuum Health",
"table_name": "sales.orders",
"status": "Red",
"severity": 5,
"insight": "Table bloat is critically high; TOAST overhead significant.",
"action": "Run VACUUM FULL; review large fields.",
"table_size": "128 MB",
"bloat_estimate": "65%",
"details": {"toast_bloat": "40%", "median_bloat": "20%"}
}
]
```
### Dashboard Integration
- Use the JSON outputs to populate a dashboard:
- **Vacuum Health**: Pie chart of statuses, table of critical issues.
- **Index Health**: Bar chart of usage categories, recommendations.
- **MV Refresh**: Progress bars per view, bottleneck alerts.
- Link to detail pages using `details` fields or separate functions like `c77_dbh_get_toast_health()`.
## Configuration
- **Frequency**: Adjust update schedules based on database activity (hourly for high-write systems, daily for stable ones).
- **Permissions**: Default setup grants `SELECT` to `public` and full access to an admin role (e.g., `homestead`). Modify as needed.
- **Extensions**: Install `pgstattuple` and `pg_stat_statements` for best results; fallbacks work without them.
## Limitations
- TOAST bloat estimates are crude without `pgstattuple`.
- Materialized view bottleneck analysis is less precise without `pg_stat_statements`.
- Dynamic thresholds rely on sufficient historical data; new databases may need time to stabilize.
## Future Development
- Query performance monitoring with `pg_stat_statements`.
- Automated maintenance actions (e.g., trigger `VACUUM` on Red status).
- Integration with external frameworks (e.g., Laravel package).
## Contributing
Contributions are welcome! Fork the repo, submit pull requests, or open issues at `https://git.jctr3.com/trogers1884/c77_dbh`.
## License
MIT License see `LICENSE` file for details.
## Credits
Developed by [Your Name] with assistance from xAIs Grok. Inspired by Dr. W. Edwards Demings statistical quality control principles.
- Inspired by statistical process control principles
- Initial development facilitated by the PostgreSQL community

562
c77_dbh--1.0.sql Normal file
View File

@ -0,0 +1,562 @@
-- c77_dbh--1.0.sql
-- PostgreSQL extension for database health monitoring
\echo Use "CREATE EXTENSION c77_dbh" to load this file. \quit
-- Schema setup (optional, using public schema by default)
-- CREATE SCHEMA IF NOT EXISTS c77_dbh;
-- SET search_path TO c77_dbh, public;
-- Vacuum Stats Table
CREATE TABLE IF NOT EXISTS public.c77_dbh_vacuum_stats (
table_name text COLLATE pg_catalog."default" PRIMARY KEY,
last_vacuum timestamp without time zone,
last_autovacuum timestamp without time zone,
vacuum_count bigint DEFAULT 0,
dead_tuples bigint DEFAULT 0,
live_tuples bigint DEFAULT 0,
table_size bigint DEFAULT 0,
bloat_estimate numeric DEFAULT 0,
last_updated timestamp without time zone DEFAULT now()
);
REVOKE ALL ON TABLE public.c77_dbh_vacuum_stats FROM PUBLIC;
GRANT SELECT ON TABLE public.c77_dbh_vacuum_stats TO PUBLIC;
-- Index Stats Table
CREATE TABLE IF NOT EXISTS public.c77_dbh_index_stats (
index_name text COLLATE pg_catalog."default" PRIMARY KEY,
table_name text,
index_size bigint DEFAULT 0,
scan_count bigint DEFAULT 0,
bloat_estimate numeric DEFAULT 0,
last_updated timestamp without time zone DEFAULT now()
);
REVOKE ALL ON TABLE public.c77_dbh_index_stats FROM PUBLIC;
GRANT SELECT ON TABLE public.c77_dbh_index_stats TO PUBLIC;
-- Materialized View Stats Table
CREATE TABLE IF NOT EXISTS public.c77_dbh_mv_stats (
mv_name text COLLATE pg_catalog."default",
create_mv timestamp without time zone,
mod_mv timestamp without time zone,
refresh_mv_last timestamp without time zone,
refresh_count integer DEFAULT 0,
refresh_mv_time_last interval,
refresh_mv_time_total interval DEFAULT '00:00:00'::interval,
refresh_mv_time_min interval,
refresh_mv_time_max interval,
reset_last timestamp without time zone
);
REVOKE ALL ON TABLE public.c77_dbh_mv_stats FROM PUBLIC;
GRANT SELECT ON TABLE public.c77_dbh_mv_stats TO PUBLIC;
-- Vacuum Update Function
CREATE OR REPLACE FUNCTION public.c77_dbh_update_vacuum_stats()
RETURNS void AS $$
DECLARE
v_has_pgstattuple boolean;
BEGIN
SELECT EXISTS (SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple') INTO v_has_pgstattuple;
INSERT INTO public.c77_dbh_vacuum_stats (
table_name, last_vacuum, last_autovacuum, vacuum_count,
dead_tuples, live_tuples, table_size, last_updated
)
SELECT
(n.nspname || '.' || c.relname) AS table_name,
s.last_vacuum,
s.last_autovacuum,
COALESCE(s.vacuum_count, 0) + COALESCE(s.autovacuum_count, 0) AS vacuum_count,
s.n_dead_tup AS dead_tuples,
s.n_live_tup AS live_tuples,
pg_relation_size(c.oid) AS table_size,
now() AS last_updated
FROM pg_stat_all_tables s
JOIN pg_class c ON c.oid = s.relid
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')
ON CONFLICT (table_name) DO UPDATE
SET
last_vacuum = EXCLUDED.last_vacuum,
last_autovacuum = EXCLUDED.last_autovacuum,
vacuum_count = EXCLUDED.vacuum_count,
dead_tuples = EXCLUDED.dead_tuples,
live_tuples = EXCLUDED.live_tuples,
table_size = EXCLUDED.table_size,
last_updated = EXCLUDED.last_updated;
IF v_has_pgstattuple THEN
UPDATE public.c77_dbh_vacuum_stats v
SET bloat_estimate = ROUND(CAST(COALESCE(t.free_percent + t.dead_tuple_percent, 0) AS numeric), 2)
FROM (
SELECT (pgstattuple(c.oid)).*
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE (n.nspname || '.' || c.relname) = v.table_name
) t
WHERE v.last_updated = now();
ELSE
UPDATE public.c77_dbh_vacuum_stats
SET bloat_estimate = CASE
WHEN live_tuples + dead_tuples = 0 THEN 0
ELSE ROUND((dead_tuples::numeric / (live_tuples + dead_tuples)) * 100, 2)
END
WHERE last_updated = now();
END IF;
END;
$$ LANGUAGE plpgsql;
-- Index Update Function
CREATE OR REPLACE FUNCTION public.c77_dbh_update_index_stats()
RETURNS void AS $$
DECLARE
v_has_pgstattuple boolean;
BEGIN
SELECT EXISTS (SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple') INTO v_has_pgstattuple;
INSERT INTO public.c77_dbh_index_stats (
index_name, table_name, index_size, scan_count, bloat_estimate, last_updated
)
SELECT
(n.nspname || '.' || i.relname) AS index_name,
(n.nspname || '.' || t.relname) AS table_name,
pg_relation_size(i.oid) AS index_size,
COALESCE(s.idx_scan, 0) AS scan_count,
CASE WHEN v_has_pgstattuple THEN
ROUND(CAST(COALESCE((pgstattuple(i.oid)).free_percent + (pgstattuple(i.oid)).dead_tuple_percent, 0) AS numeric), 2)
ELSE 0 END AS bloat_estimate,
now() AS last_updated
FROM pg_index ix
JOIN pg_class i ON i.oid = ix.indexrelid
JOIN pg_class t ON t.oid = ix.indrelid
JOIN pg_namespace n ON n.oid = i.relnamespace
LEFT JOIN pg_stat_all_indexes s ON s.indexrelid = i.oid
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')
ON CONFLICT (index_name) DO UPDATE
SET
table_name = EXCLUDED.table_name,
index_size = EXCLUDED.index_size,
scan_count = EXCLUDED.scan_count,
bloat_estimate = EXCLUDED.bloat_estimate,
last_updated = EXCLUDED.last_updated;
END;
$$ LANGUAGE plpgsql;
-- Vacuum Health Function
CREATE OR REPLACE FUNCTION public.c77_dbh_get_vacuum_health()
RETURNS JSON AS $$
DECLARE
v_median_bloat numeric;
v_bloat_stddev numeric;
v_has_pgstattuple boolean;
BEGIN
SELECT EXISTS (SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple') INTO v_has_pgstattuple;
WITH toast_bloat AS (
SELECT
(n.nspname || '.' || c.relname) AS table_name,
CASE WHEN v_has_pgstattuple THEN
COALESCE((pgstattuple(c.oid)).free_percent + (pgstattuple(c.oid)).dead_tuple_percent, 0)
ELSE
CASE WHEN s.n_live_tup + s.n_dead_tup = 0 THEN 0
ELSE (s.n_dead_tup::numeric / (s.n_live_tup + s.n_dead_tup)) * 100 END
END AS bloat_estimate
FROM pg_stat_all_tables s
JOIN pg_class c ON c.oid = s.relid
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')
)
SELECT
percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate),
stddev(bloat_estimate)
INTO v_median_bloat, v_bloat_stddev
FROM toast_bloat;
RETURN (
SELECT json_agg(
json_build_object(
'metric', 'Table Vacuum Health',
'table_name', v.table_name,
'status', CASE
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN 'Red'
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN 5
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN 3
ELSE 1
END,
'insight', CASE
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN
'Table bloat is critically high' ||
(CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; TOAST overhead is significant.' ELSE '.' END)
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN
'Table bloat is above average' ||
(CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; TOAST overhead notable.' ELSE '.' END)
ELSE 'Table bloat is within normal range.'
END,
'action', CASE
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN
'Run VACUUM FULL or CLUSTER' ||
(CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; review large fields for TOAST impact.' ELSE '.' END)
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN
'Run VACUUM and ANALYZE' ||
(CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; check TOAST usage.' ELSE '.' END)
ELSE 'No immediate action required.'
END,
'last_vacuum', v.last_vacuum::text,
'last_autovacuum', v.last_autovacuum::text,
'vacuum_count', v.vacuum_count,
'dead_tuples', v.dead_tuples,
'live_tuples', v.live_tuples,
'table_size', pg_size_pretty(v.table_size),
'bloat_estimate', v.bloat_estimate::text || '%' ||
(CASE WHEN v_has_pgstattuple THEN ' (precise)' ELSE ' (estimated)' END),
'details', json_build_object(
'median_bloat', round(v_median_bloat)::text || '%',
'bloat_stddev', round(v_bloat_stddev)::text || '%',
'toast_bloat', round(COALESCE(t.toast_bloat, 0))::text || '%',
'explanation', 'Includes TOAST bloat in total health assessment.'
)
)
)
FROM public.c77_dbh_vacuum_stats v
LEFT JOIN (
SELECT
(n.nspname || '.' || c.relname) AS table_name,
CASE WHEN v_has_pgstattuple THEN
COALESCE((pgstattuple(tst.oid)).free_percent + (pgstattuple(tst.oid)).dead_tuple_percent, 0)
ELSE 0 END AS toast_bloat
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
LEFT JOIN pg_class tst ON tst.oid = c.reltoastrelid
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') AND c.reltoastrelid != 0
) t ON v.table_name = t.table_name
);
END;
$$ LANGUAGE plpgsql;
-- Index Health Function
CREATE OR REPLACE FUNCTION public.c77_dbh_get_index_health()
RETURNS JSON AS $$
DECLARE
v_median_bloat numeric;
v_median_usage numeric;
BEGIN
SELECT
percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate),
percentile_cont(0.5) WITHIN GROUP (ORDER BY scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))
INTO v_median_bloat, v_median_usage
FROM public.c77_dbh_index_stats
WHERE index_name NOT LIKE 'pg_toast.%';
RETURN (
SELECT json_agg(
json_build_object(
'metric', 'Index Health',
'index_name', index_name,
'table_name', table_name,
'status', CASE
WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 'Red'
WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 5
WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 3
ELSE 1
END,
'insight', CASE
WHEN scan_count = 0 THEN 'Index is unused; consider dropping.'
WHEN bloat_estimate > v_median_bloat * 2 THEN 'Index bloat is critically high.'
WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Index usage is low relative to size.'
ELSE 'Index is healthy and well-utilized.'
END,
'action', CASE
WHEN scan_count = 0 THEN 'Drop the index if not needed.'
WHEN bloat_estimate > v_median_bloat * 2 THEN 'Run REINDEX; check autovacuum.'
WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Review query patterns or consider reindexing.'
ELSE 'No action needed.'
END,
'index_size', pg_size_pretty(index_size),
'scan_count', scan_count,
'bloat_estimate', bloat_estimate::text || '%',
'details', json_build_object(
'usage_rate', round((scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))::numeric, 2)::text || ' scans/MB',
'median_bloat', round(v_median_bloat)::text || '%',
'median_usage', round(v_median_usage, 2)::text || ' scans/MB'
)
)
)
FROM public.c77_dbh_index_stats
WHERE index_name NOT LIKE 'pg_toast.%'
);
END;
$$ LANGUAGE plpgsql;
-- TOAST Health Function
CREATE OR REPLACE FUNCTION public.c77_dbh_get_toast_health()
RETURNS JSON AS $$
DECLARE
v_median_bloat numeric;
v_median_usage numeric;
v_has_pgstattuple boolean;
BEGIN
SELECT EXISTS (SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple') INTO v_has_pgstattuple;
SELECT
percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate),
percentile_cont(0.5) WITHIN GROUP (ORDER BY scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))
INTO v_median_bloat, v_median_usage
FROM public.c77_dbh_index_stats
WHERE index_name LIKE 'pg_toast.%';
RETURN (
SELECT json_agg(
json_build_object(
'metric', 'TOAST Index Health',
'index_name', index_name,
'parent_table', table_name,
'status', CASE
WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 'Red'
WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 5
WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 3
ELSE 1
END,
'insight', CASE
WHEN scan_count = 0 THEN 'TOAST index is unused; parent table may not need toasted columns indexed.'
WHEN bloat_estimate > v_median_bloat * 2 THEN 'TOAST index bloat is critically high.'
WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'TOAST index usage is low relative to size.'
ELSE 'TOAST index is healthy and well-utilized.'
END,
'action', CASE
WHEN scan_count = 0 THEN 'Review parent table queries; consider dropping TOAST index.'
WHEN bloat_estimate > v_median_bloat * 2 THEN 'Run REINDEX on TOAST table; optimize large fields in parent.'
WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Check parent table usage patterns.'
ELSE 'No action needed.'
END,
'index_size', pg_size_pretty(index_size),
'scan_count', scan_count,
'bloat_estimate', bloat_estimate::text || '%' ||
(CASE WHEN v_has_pgstattuple THEN ' (precise)' ELSE ' (estimated)' END),
'details', json_build_object(
'usage_rate', round((scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))::numeric, 2)::text || ' scans/MB',
'median_bloat', round(v_median_bloat)::text || '%',
'median_usage', round(v_median_usage, 2)::text || ' scans/MB',
'parent_columns', (
SELECT string_agg(attname, ', ')
FROM pg_attribute a
JOIN pg_class c ON c.oid = (SELECT oid FROM pg_class WHERE relname = split_part(table_name, '.', 2) AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = split_part(table_name, '.', 1)))
WHERE a.attrelid = c.oid AND a.attlen = -1
)
)
)
)
FROM public.c77_dbh_index_stats
WHERE index_name LIKE 'pg_toast.%'
);
END;
$$ LANGUAGE plpgsql;
-- MV Health Function
CREATE OR REPLACE FUNCTION public.c77_dbh_get_mv_health()
RETURNS JSON AS $$
DECLARE
v_has_pg_stat_statements boolean;
v_stats_reset timestamp;
v_base_io_load numeric;
v_base_mem_hit_ratio numeric;
v_avg_refresh_time interval;
BEGIN
SELECT EXISTS (SELECT 1 FROM pg_extension WHERE extname = 'pg_stat_statements') INTO v_has_pg_stat_statements;
SELECT
d.stats_reset,
(d.blks_read + d.blks_hit) / EXTRACT(EPOCH FROM (NOW() - d.stats_reset)),
CASE WHEN b.buffers_clean + b.buffers_backend = 0 THEN 1.0
ELSE b.buffers_clean::numeric / (b.buffers_clean + b.buffers_backend) END
INTO v_stats_reset, v_base_io_load, v_base_mem_hit_ratio
FROM pg_stat_database d
CROSS JOIN pg_stat_bgwriter b
WHERE d.datname = current_database();
SELECT AVG(refresh_mv_time_total / GREATEST(refresh_count, 1))
INTO v_avg_refresh_time
FROM public.c77_dbh_mv_stats
WHERE refresh_count > 0;
RETURN (
SELECT json_agg(
json_build_object(
'metric', 'Materialized View Refresh',
'mv_name', m.mv_name,
'status', CASE
WHEN m.refresh_mv_time_last > v_avg_refresh_time * 2 THEN 'Red'
WHEN m.refresh_mv_time_last > v_avg_refresh_time * 1.5 THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN m.refresh_mv_time_last > v_avg_refresh_time * 2 THEN 5
WHEN m.refresh_mv_time_last > v_avg_refresh_time * 1.5 THEN 3
ELSE 1
END,
'insight', CASE
WHEN v_io_load > 100 THEN 'Refreshes are slow due to high I/O load.'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Refreshes are slow due to CPU usage.'
WHEN v_mem_hit_ratio < 0.9 THEN 'Refreshes are slow due to memory pressure.'
ELSE 'Refresh performance is within normal range.'
END,
'action', CASE
WHEN v_io_load > 100 THEN 'Optimize I/O or schedule during off-peak hours.'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Increase CPU capacity or optimize queries.'
WHEN v_mem_hit_ratio < 0.9 THEN 'Adjust memory settings (e.g., work_mem).'
ELSE 'No action needed.'
END,
'last_refresh_time', m.refresh_mv_time_last::text,
'refresh_count', m.refresh_count,
'io_load', round(v_io_load)::text || ' blocks/sec',
'cpu_time', (CASE WHEN v_has_pg_stat_statements THEN round(v_cpu_time)::text || ' ms/call'
ELSE (v_cpu_time * 100)::text || '% waiting' END),
'buffer_hit_ratio', round(v_mem_hit_ratio * 100)::text || '%',
'bottleneck', CASE
WHEN v_io_load > 100 THEN 'I/O'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'CPU'
WHEN v_mem_hit_ratio < 0.9 THEN 'RAM'
ELSE 'None'
END,
'details', json_build_object(
'avg_refresh_time', v_avg_refresh_time::text,
'explanation', 'Thresholds based on average refresh time (' || v_avg_refresh_time::text || ').'
)
)
)
FROM public.c77_dbh_mv_stats m
CROSS JOIN LATERAL (
SELECT
CASE WHEN v_has_pg_stat_statements THEN
COALESCE(SUM(s.shared_blks_read) / EXTRACT(EPOCH FROM (NOW() - v_stats_reset)), 0)
ELSE v_base_io_load END AS v_io_load,
CASE WHEN v_has_pg_stat_statements THEN
COALESCE(SUM(s.total_time) / GREATEST(SUM(s.calls), 1), 0)
ELSE CASE WHEN EXISTS (
SELECT 1 FROM pg_stat_activity
WHERE query ILIKE '%REFRESH MATERIALIZED VIEW ' || m.mv_name || '%'
AND wait_event_type = 'CPU' AND state = 'active'
) THEN 1 ELSE 0 END END AS v_cpu_time,
CASE WHEN v_has_pg_stat_statements THEN
CASE WHEN SUM(s.shared_blks_hit + s.shared_blks_read) = 0 THEN 1.0
ELSE SUM(s.shared_blks_hit)::numeric / (SUM(s.shared_blks_hit) + SUM(s.shared_blks_read)) END
ELSE v_base_mem_hit_ratio END AS v_mem_hit_ratio
FROM (SELECT 1 AS dummy) AS dummy
LEFT JOIN pg_stat_statements s ON v_has_pg_stat_statements
AND s.query ILIKE '%REFRESH MATERIALIZED VIEW ' || m.mv_name || '%'
AND s.dbid = (SELECT datid FROM pg_stat_database WHERE datname = current_database())
) AS stats
);
END;
$$ LANGUAGE plpgsql;
-- MV Triggers
CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv()
RETURNS event_trigger LANGUAGE plpgsql AS $$
DECLARE
r RECORD;
flag boolean;
t_refresh_total interval;
BEGIN
FOR r IN SELECT * FROM pg_event_trigger_ddl_commands() LOOP
IF tg_tag = 'CREATE MATERIALIZED VIEW' THEN
INSERT INTO public.c77_dbh_mv_stats (mv_name, create_mv) VALUES (r.object_identity, now());
END IF;
IF tg_tag = 'ALTER MATERIALIZED VIEW' THEN
SELECT TRUE INTO flag FROM public.c77_dbh_mv_stats WHERE mv_name = r.object_identity;
IF NOT FOUND THEN
INSERT INTO public.c77_dbh_mv_stats (mv_name, create_mv) VALUES (r.object_identity, now());
DELETE FROM public.c77_dbh_mv_stats WHERE mv_name NOT IN (SELECT schemaname || '.' || matviewname FROM pg_catalog.pg_matviews);
ELSE
UPDATE public.c77_dbh_mv_stats SET mod_mv = now() WHERE mv_name = r.object_identity;
END IF;
END IF;
IF tg_tag = 'REFRESH MATERIALIZED VIEW' THEN
t_refresh_total := clock_timestamp() - (SELECT current_setting('mv_stats.start')::timestamp);
SET mv_stats.start TO DEFAULT;
UPDATE public.c77_dbh_mv_stats
SET refresh_mv_last = now(),
refresh_count = refresh_count + 1,
refresh_mv_time_last = t_refresh_total,
refresh_mv_time_total = refresh_mv_time_total + t_refresh_total,
refresh_mv_time_min = CASE
WHEN refresh_mv_time_min IS NULL THEN t_refresh_total
WHEN refresh_mv_time_min > t_refresh_total THEN t_refresh_total
ELSE refresh_mv_time_min
END,
refresh_mv_time_max = CASE
WHEN refresh_mv_time_max IS NULL THEN t_refresh_total
WHEN refresh_mv_time_max < t_refresh_total THEN t_refresh_total
ELSE refresh_mv_time_max
END
WHERE mv_name = r.object_identity;
END IF;
END LOOP;
END;
$$;
CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv_drop()
RETURNS event_trigger LANGUAGE plpgsql AS $$
DECLARE
r RECORD;
BEGIN
FOR r IN SELECT * FROM pg_event_trigger_dropped_objects() LOOP
DELETE FROM public.c77_dbh_mv_stats WHERE mv_name = r.object_identity;
END LOOP;
END;
$$;
CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv_start()
RETURNS event_trigger LANGUAGE plpgsql AS $$
BEGIN
PERFORM set_config('mv_stats.start', clock_timestamp()::text, true);
END;
$$;
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_event_trigger WHERE evtname = 'c77_dbh_trg_mv_info') THEN
CREATE EVENT TRIGGER c77_dbh_trg_mv_info
ON DDL_COMMAND_END
WHEN TAG IN ('CREATE MATERIALIZED VIEW', 'ALTER MATERIALIZED VIEW', 'REFRESH MATERIALIZED VIEW')
EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv();
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_event_trigger WHERE evtname = 'c77_dbh_trg_mv_info_drop') THEN
CREATE EVENT TRIGGER c77_dbh_trg_mv_info_drop
ON SQL_DROP
WHEN TAG IN ('DROP MATERIALIZED VIEW')
EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv_drop();
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_event_trigger WHERE evtname = 'c77_dbh_trg_mv_info_start') THEN
CREATE EVENT TRIGGER c77_dbh_trg_mv_info_start
ON DDL_COMMAND_START
WHEN TAG IN ('REFRESH MATERIALIZED VIEW')
EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv_start();
END IF;
END;
$$;
-- Materialized View Stats View
CREATE OR REPLACE VIEW public.c77_dbh_matv_stats AS
SELECT mv_name, create_mv, mod_mv, refresh_mv_last, refresh_count,
refresh_mv_time_last, refresh_mv_time_total, refresh_mv_time_min,
refresh_mv_time_max, reset_last
FROM public.c77_dbh_mv_stats;
GRANT SELECT ON TABLE public.c77_dbh_matv_stats TO PUBLIC;

5
c77_dbh.control Normal file
View File

@ -0,0 +1,5 @@
# c77_dbh.control
comment = 'Database health monitoring tools for vacuum, index, and materialized view performance'
default_version = '1.0'
module_pathname = '$libdir/c77_dbh'
relocatable = true

View File

@ -1,15 +0,0 @@
CREATE TABLE IF NOT EXISTS public.c77_dbh_vacuum_stats (
table_name text COLLATE pg_catalog."default" PRIMARY KEY, -- Fully qualified table name (schema.table)
last_vacuum timestamp without time zone, -- Last manual vacuum
last_autovacuum timestamp without time zone, -- Last autovacuum
vacuum_count bigint DEFAULT 0, -- Number of vacuums
dead_tuples bigint DEFAULT 0, -- Estimated dead tuples
live_tuples bigint DEFAULT 0, -- Estimated live tuples
table_size bigint DEFAULT 0, -- Table size in bytes
bloat_estimate numeric DEFAULT 0, -- Estimated bloat percentage
last_updated timestamp without time zone DEFAULT now() -- Last stats update
);
REVOKE ALL ON TABLE public.c77_dbh_vacuum_stats FROM PUBLIC;
GRANT SELECT ON TABLE public.c77_dbh_vacuum_stats TO PUBLIC;
GRANT ALL ON TABLE public.c77_dbh_vacuum_stats TO homestead; -- Adjust role as needed

View File

@ -1,122 +0,0 @@
<!DOCTYPE html>
<html>
<head>
<title>Database Health Dashboard</title>
<style>
.dashboard { font-family: Arial, sans-serif; max-width: 1200px; margin: 20px auto; }
.header { text-align: center; padding: 10px; background: #f0f0f0; }
.tabs { display: flex; justify-content: space-around; margin: 10px 0; }
.tab { padding: 10px; cursor: pointer; background: #ddd; }
.tab.active { background: #007bff; color: white; }
.section { border: 1px solid #ccc; padding: 20px; margin: 10px 0; }
.chart { width: 50%; float: left; }
.summary { width: 45%; float: right; }
.status-red { background: #dc3545; color: white; padding: 5px; border-radius: 3px; }
.status-yellow { background: #ffc107; color: black; padding: 5px; border-radius: 3px; }
.status-green { background: #28a745; color: white; padding: 5px; border-radius: 3px; }
.recommendation { font-style: italic; color: #555; }
.details-link { display: block; margin-top: 10px; color: #007bff; text-decoration: none; }
</style>
</head>
<body>
<div class="dashboard">
<div class="header">
<h1>Database Health Dashboard</h1>
</div>
<div class="tabs">
<div class="tab active">Vacuum Health</div>
<div class="tab">Index Health</div>
<div class="tab">MV Refresh</div>
</div>
<!-- Vacuum Health Section -->
<div class="section">
<h2>Vacuum Health Overview</h2>
<div class="chart">
<!-- Pie Chart: 60% Green, 30% Yellow, 10% Red -->
<canvas id="vacuumChart"></canvas>
<script>
// Placeholder for Chart.js or similar
const ctx = document.getElementById('vacuumChart').getContext('2d');
new Chart(ctx, {
type: 'pie',
data: {
labels: ['Healthy', 'Warning', 'Critical'],
datasets: [{ data: [60, 30, 10], backgroundColor: ['#28a745', '#ffc107', '#dc3545'] }]
}
});
</script>
</div>
<div class="summary">
<p><strong>Tables Scanned:</strong> 25</p>
<p><strong>Critical Issues:</strong> <span class="status-red">2 tables</span></p>
<p><strong>Warnings:</strong> <span class="status-yellow">5 tables</span></p>
<p><strong>Healthy:</strong> <span class="status-green">18 tables</span></p>
</div>
<div style="clear: both;"></div>
<p class="recommendation">
Recommendation: Run VACUUM FULL on 2 tables with critical bloat; TOAST overhead notable in 1 case.
</p>
<a href="/vacuum-details" class="details-link">View Detailed Vacuum Stats</a>
</div>
<!-- Index Health Section -->
<div class="section">
<h2>Index Health Overview</h2>
<div class="chart">
<!-- Bar Chart: Index Usage -->
<canvas id="indexChart"></canvas>
<script>
new Chart(document.getElementById('indexChart').getContext('2d'), {
type: 'bar',
data: {
labels: ['Healthy', 'Low Usage', 'Unused'],
datasets: [{ data: [15, 3, 1], backgroundColor: '#28a745' }]
},
options: { scales: { y: { beginAtZero: true } } }
});
</script>
</div>
<div class="summary">
<p><strong>Indexes Monitored:</strong> 19</p>
<p><strong>Critical Issues:</strong> <span class="status-red">1 unused</span></p>
<p><strong>Warnings:</strong> <span class="status-yellow">3 low usage</span></p>
<p><strong>Healthy:</strong> <span class="status-green">15 indexes</span></p>
</div>
<div style="clear: both;"></div>
<p class="recommendation">
Recommendation: Consider dropping 1 unused index; review query patterns for 3 others.
</p>
<a href="/index-details" class="details-link">View Detailed Index Stats</a>
<a href="/toast-details" class="details-link">View TOAST Index Stats</a>
</div>
<!-- MV Refresh Section -->
<div class="section">
<h2>Materialized View Refresh Overview</h2>
<div class="chart">
<!-- Progress Bars: Refresh Performance -->
<div style="margin-bottom: 10px;">
<label>MV1: <span class="status-green">Green</span></label>
<progress value="20" max="100" style="width: 100%;"></progress>
</div>
<div>
<label>MV2: <span class="status-yellow">Yellow</span></label>
<progress value="60" max="100" style="width: 100%;"></progress>
</div>
</div>
<div class="summary">
<p><strong>MVs Monitored:</strong> 2</p>
<p><strong>Critical Issues:</strong> <span class="status-red">0 MVs</span></p>
<p><strong>Warnings:</strong> <span class="status-yellow">1 MV</span></p>
<p><strong>Healthy:</strong> <span class="status-green">1 MV</span></p>
</div>
<div style="clear: both;"></div>
<p class="recommendation">
Recommendation: Monitor MV2 refresh; consider scheduling during off-peak hours.
</p>
<a href="/mv-details" class="details-link">View Detailed MV Stats</a>
</div>
</div>
</body>
</html>

View File

@ -1,216 +0,0 @@
CREATE OR REPLACE FUNCTION public.c77_dbh_get_mv_health()
RETURNS JSON AS $$
DECLARE
v_has_pg_stat_statements boolean;
v_stats_reset timestamp;
v_base_io_load numeric;
v_base_mem_hit_ratio numeric;
v_avg_refresh_time interval; -- Average refresh time across all MVs
BEGIN
SELECT EXISTS (
SELECT 1 FROM pg_extension WHERE extname = 'pg_stat_statements'
) INTO v_has_pg_stat_statements;
SELECT
d.stats_reset,
(d.blks_read + d.blks_hit) / EXTRACT(EPOCH FROM (NOW() - d.stats_reset)),
CASE WHEN b.buffers_clean + b.buffers_backend = 0 THEN 1.0
ELSE b.buffers_clean::numeric / (b.buffers_clean + b.buffers_backend) END
INTO v_stats_reset, v_base_io_load, v_base_mem_hit_ratio
FROM pg_stat_database d
CROSS JOIN pg_stat_bgwriter b
WHERE d.datname = current_database();
-- Calculate average refresh time across all MVs
SELECT AVG(refresh_mv_time_total / GREATEST(refresh_count, 1))
INTO v_avg_refresh_time
FROM public.c77_dbh_mv_stats
WHERE refresh_count > 0;
RETURN (
SELECT json_agg(
json_build_object(
'metric', 'Materialized View Refresh',
'mv_name', m.mv_name,
'status', CASE
WHEN m.refresh_mv_time_last > v_avg_refresh_time * 2 THEN 'Red'
WHEN m.refresh_mv_time_last > v_avg_refresh_time * 1.5 THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN m.refresh_mv_time_last > v_avg_refresh_time * 2 THEN 5
WHEN m.refresh_mv_time_last > v_avg_refresh_time * 1.5 THEN 3
ELSE 1
END,
'insight', CASE
WHEN v_io_load > 100 THEN 'Refreshes are slow due to high I/O load.'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Refreshes are slow due to CPU usage.'
WHEN v_mem_hit_ratio < 0.9 THEN 'Refreshes are slow due to memory pressure.'
ELSE 'Refresh performance is within normal range.'
END,
'action', CASE
WHEN v_io_load > 100 THEN 'Optimize I/O or schedule during off-peak hours.'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Increase CPU capacity or optimize queries.'
WHEN v_mem_hit_ratio < 0.9 THEN 'Adjust memory settings (e.g., work_mem).'
ELSE 'No action needed.'
END,
'last_refresh_time', m.refresh_mv_time_last::text,
'refresh_count', m.refresh_count,
'io_load', round(v_io_load)::text || ' blocks/sec',
'cpu_time', (CASE WHEN v_has_pg_stat_statements THEN round(v_cpu_time)::text || ' ms/call'
ELSE (v_cpu_time * 100)::text || '% waiting' END),
'buffer_hit_ratio', round(v_mem_hit_ratio * 100)::text || '%',
'bottleneck', CASE
WHEN v_io_load > 100 THEN 'I/O'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'CPU'
WHEN v_mem_hit_ratio < 0.9 THEN 'RAM'
ELSE 'None'
END,
'details', json_build_object(
'avg_refresh_time', v_avg_refresh_time::text,
'explanation', 'Thresholds based on average refresh time (' || v_avg_refresh_time::text || ').'
)
)
)
FROM public.c77_dbh_mv_stats m
CROSS JOIN LATERAL (
SELECT
CASE WHEN v_has_pg_stat_statements THEN
COALESCE(SUM(s.shared_blks_read) / EXTRACT(EPOCH FROM (NOW() - v_stats_reset)), 0)
ELSE v_base_io_load END AS v_io_load,
CASE WHEN v_has_pg_stat_statements THEN
COALESCE(SUM(s.total_time) / GREATEST(SUM(s.calls), 1), 0)
ELSE CASE WHEN EXISTS (
SELECT 1 FROM pg_stat_activity
WHERE query ILIKE '%REFRESH MATERIALIZED VIEW ' || m.mv_name || '%'
AND wait_event_type = 'CPU' AND state = 'active'
) THEN 1 ELSE 0 END END AS v_cpu_time,
CASE WHEN v_has_pg_stat_statements THEN
CASE WHEN SUM(s.shared_blks_hit + s.shared_blks_read) = 0 THEN 1.0
ELSE SUM(s.shared_blks_hit)::numeric / (SUM(s.shared_blks_hit) + SUM(s.shared_blks_read)) END
ELSE v_base_mem_hit_ratio END AS v_mem_hit_ratio
FROM (SELECT 1 AS dummy) AS dummy
LEFT JOIN pg_stat_statements s ON v_has_pg_stat_statements
AND s.query ILIKE '%REFRESH MATERIALIZED VIEW ' || m.mv_name || '%'
AND s.dbid = (SELECT datid FROM pg_stat_database WHERE datname = current_database())
) AS stats
);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.c77_dbh_get_mv_details(p_mv_name text)
RETURNS JSON AS $$
DECLARE
v_io_load numeric; -- Blocks read per second
v_cpu_time numeric; -- CPU time per call (ms)
v_mem_hit_ratio numeric; -- Cache hit ratio
v_has_pg_stat_statements boolean; -- Check if extension is available
v_stats_reset timestamp; -- Time of last stats reset
BEGIN
-- Check if pg_stat_statements is installed
SELECT EXISTS (
SELECT 1 FROM pg_extension WHERE extname = 'pg_stat_statements'
) INTO v_has_pg_stat_statements;
-- Get stats_reset separately for the current database
SELECT stats_reset
INTO v_stats_reset
FROM pg_stat_database
WHERE datname = current_database();
-- If pg_stat_statements is available, use it for refined stats
IF v_has_pg_stat_statements THEN
SELECT
COALESCE(SUM(s.shared_blks_read) / EXTRACT(EPOCH FROM (NOW() - v_stats_reset)), 0) AS io_load,
COALESCE(SUM(s.total_time) / GREATEST(SUM(s.calls), 1), 0) AS cpu_time,
CASE
WHEN SUM(s.shared_blks_hit + s.shared_blks_read) = 0 THEN 1.0
ELSE SUM(s.shared_blks_hit)::numeric / (SUM(s.shared_blks_hit) + SUM(s.shared_blks_read))
END AS mem_hit_ratio
INTO v_io_load, v_cpu_time, v_mem_hit_ratio
FROM pg_stat_statements s
JOIN pg_stat_database d ON s.dbid = d.datid
WHERE s.query ILIKE '%REFRESH MATERIALIZED VIEW ' || p_mv_name || '%'
AND d.datname = current_database();
ELSE
-- Fallback to basic stats without pg_stat_statements
SELECT
(d.blks_read + d.blks_hit) / EXTRACT(EPOCH FROM (NOW() - d.stats_reset)) AS io_load,
EXISTS (
SELECT 1
FROM pg_stat_activity
WHERE query ILIKE '%REFRESH MATERIALIZED VIEW%'
AND wait_event_type = 'CPU'
AND state = 'active'
)::numeric AS cpu_time, -- 1 if waiting, 0 if not (crude proxy)
CASE
WHEN b.buffers_clean + b.buffers_backend = 0 THEN 1.0
ELSE b.buffers_clean::numeric / (b.buffers_clean + b.buffers_backend)
END AS mem_hit_ratio
INTO v_io_load, v_cpu_time, v_mem_hit_ratio
FROM pg_stat_database d
CROSS JOIN pg_stat_bgwriter b
WHERE d.datname = current_database();
END IF;
RETURN (
SELECT json_build_object(
'metric', 'Materialized View Refresh',
'mv_name', mv_name,
'status', CASE
WHEN refresh_mv_time_last > refresh_mv_time_max * 0.9 THEN 'Red'
WHEN refresh_mv_time_last > (refresh_mv_time_total / GREATEST(refresh_count, 1)) * 1.2 THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN refresh_mv_time_last > refresh_mv_time_max * 0.9 THEN 5
WHEN refresh_mv_time_last > (refresh_mv_time_total / GREATEST(refresh_count, 1)) * 1.2 THEN 3
ELSE 1
END,
'insight', CASE
WHEN v_io_load > 100 THEN 'Refreshes are slower due to high I/O load.'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Refreshes are slower due to CPU usage.'
WHEN v_mem_hit_ratio < 0.9 THEN 'Refreshes are slower due to memory pressure.'
ELSE 'Refreshes are performing normally.'
END,
'action', CASE
WHEN v_io_load > 100 THEN 'Optimize I/O or schedule during off-peak hours.'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'Increase CPU capacity or optimize queries.'
WHEN v_mem_hit_ratio < 0.9 THEN 'Adjust memory settings (e.g., work_mem, shared_buffers).'
ELSE 'No action needed.'
END,
'details', json_build_object(
'last_refresh_time', refresh_mv_time_last::text,
'avg_refresh_time', (refresh_mv_time_total / GREATEST(refresh_count, 1))::text,
'min_refresh_time', refresh_mv_time_min::text,
'max_refresh_time', refresh_mv_time_max::text,
'refresh_count', refresh_count,
'io_load', round(v_io_load)::text || ' blocks/sec',
'cpu_time', (CASE
WHEN v_has_pg_stat_statements THEN round(v_cpu_time)::text || ' ms/call'
ELSE (v_cpu_time * 100)::text || '% waiting'
END),
'buffer_hit_ratio', round(v_mem_hit_ratio * 100)::text || '%',
'bottleneck', CASE
WHEN v_io_load > 100 THEN 'I/O'
WHEN v_cpu_time > (CASE WHEN v_has_pg_stat_statements THEN 1000 ELSE 0.5 END) THEN 'CPU'
WHEN v_mem_hit_ratio < 0.9 THEN 'RAM'
ELSE 'None'
END,
'explanations', json_build_object(
'last_refresh_time', 'Last refresh duration compared to historical min/max.',
'io_load', 'Blocks read per second; high values indicate disk I/O bottleneck.',
'cpu_time', (CASE
WHEN v_has_pg_stat_statements THEN 'Average CPU time per refresh; high values suggest CPU bottleneck.'
ELSE 'Percentage of time waiting on CPU (crude estimate).'
END),
'buffer_hit_ratio', 'Percentage of blocks from cache; <90% suggests memory pressure.'
)
)
)
FROM public.c77_dbh_mv_stats
WHERE mv_name = p_mv_name
);
END;
$$ LANGUAGE plpgsql;

View File

@ -1,100 +0,0 @@
CREATE TABLE IF NOT EXISTS public.c77_dbh_mv_stats (
mv_name text COLLATE pg_catalog."default",
create_mv timestamp without time zone,
mod_mv timestamp without time zone,
refresh_mv_last timestamp without time zone,
refresh_count integer DEFAULT 0,
refresh_mv_time_last interval,
refresh_mv_time_total interval DEFAULT '00:00:00'::interval,
refresh_mv_time_min interval,
refresh_mv_time_max interval,
reset_last timestamp without time zone
);
REVOKE ALL ON TABLE public.c77_dbh_mv_stats FROM PUBLIC;
GRANT SELECT ON TABLE public.c77_dbh_mv_stats TO PUBLIC;
GRANT ALL ON TABLE public.c77_dbh_mv_stats TO homestead;
CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv()
RETURNS event_trigger LANGUAGE plpgsql AS $$
DECLARE
r RECORD;
flag boolean;
t_refresh_total interval;
BEGIN
FOR r IN SELECT * FROM pg_event_trigger_ddl_commands() LOOP
IF tg_tag = 'CREATE MATERIALIZED VIEW' THEN
INSERT INTO public.c77_dbh_mv_stats (mv_name, create_mv) VALUES (r.object_identity, now());
END IF;
IF tg_tag = 'ALTER MATERIALIZED VIEW' THEN
SELECT TRUE INTO flag FROM public.c77_dbh_mv_stats WHERE mv_name = r.object_identity;
IF NOT FOUND THEN
INSERT INTO public.c77_dbh_mv_stats (mv_name, create_mv) VALUES (r.object_identity, now());
DELETE FROM public.c77_dbh_mv_stats WHERE mv_name NOT IN (SELECT schemaname || '.' || matviewname FROM pg_catalog.pg_matviews);
ELSE
UPDATE public.c77_dbh_mv_stats SET mod_mv = now() WHERE mv_name = r.object_identity;
END IF;
END IF;
IF tg_tag = 'REFRESH MATERIALIZED VIEW' THEN
t_refresh_total := clock_timestamp() - (SELECT current_setting('mv_stats.start')::timestamp);
SET mv_stats.start TO DEFAULT;
UPDATE public.c77_dbh_mv_stats
SET refresh_mv_last = now(),
refresh_count = refresh_count + 1,
refresh_mv_time_last = t_refresh_total,
refresh_mv_time_total = refresh_mv_time_total + t_refresh_total,
refresh_mv_time_min = CASE
WHEN refresh_mv_time_min IS NULL THEN t_refresh_total
WHEN refresh_mv_time_min > t_refresh_total THEN t_refresh_total
ELSE refresh_mv_time_min
END,
refresh_mv_time_max = CASE
WHEN refresh_mv_time_max IS NULL THEN t_refresh_total
WHEN refresh_mv_time_max < t_refresh_total THEN t_refresh_total
ELSE refresh_mv_time_max
END
WHERE mv_name = r.object_identity;
END IF;
END LOOP;
END;
$$;
CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv_drop()
RETURNS event_trigger LANGUAGE plpgsql AS $$
DECLARE
r RECORD;
BEGIN
FOR r IN SELECT * FROM pg_event_trigger_dropped_objects() LOOP
DELETE FROM public.c77_dbh_mv_stats WHERE mv_name = r.object_identity;
END LOOP;
END;
$$;
CREATE OR REPLACE FUNCTION public.c77_dbh_fn_trg_mv_start()
RETURNS event_trigger LANGUAGE plpgsql AS $$
BEGIN
PERFORM set_config('mv_stats.start', clock_timestamp()::text, true);
END;
$$;
CREATE EVENT TRIGGER c77_dbh_trg_mv_info
ON DDL_COMMAND_END
WHEN TAG IN ('CREATE MATERIALIZED VIEW', 'ALTER MATERIALIZED VIEW', 'REFRESH MATERIALIZED VIEW')
EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv();
CREATE EVENT TRIGGER c77_dbh_trg_mv_info_drop
ON SQL_DROP
WHEN TAG IN ('DROP MATERIALIZED VIEW')
EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv_drop();
CREATE EVENT TRIGGER c77_dbh_trg_mv_info_start
ON DDL_COMMAND_START
WHEN TAG IN ('REFRESH MATERIALIZED VIEW')
EXECUTE PROCEDURE public.c77_dbh_fn_trg_mv_start();
CREATE OR REPLACE VIEW public.c77_dbh_matv_stats AS
SELECT mv_name, create_mv, mod_mv, refresh_mv_last, refresh_count,
refresh_mv_time_last, refresh_mv_time_total, refresh_mv_time_min,
refresh_mv_time_max, reset_last
FROM public.c77_dbh_mv_stats;
GRANT SELECT ON TABLE public.c77_dbh_matv_stats TO PUBLIC;
GRANT ALL ON TABLE public.c77_dbh_matv_stats TO homestead;

View File

@ -1,96 +0,0 @@
CREATE OR REPLACE FUNCTION public.c77_dbh_get_vacuum_health()
RETURNS JSON AS $$
DECLARE
v_median_bloat numeric;
v_bloat_stddev numeric;
v_has_pgstattuple boolean;
BEGIN
SELECT EXISTS (
SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple'
) INTO v_has_pgstattuple;
-- Calculate median and stddev including TOAST-adjusted bloat
WITH toast_bloat AS (
SELECT
(n.nspname || '.' || c.relname) AS table_name,
CASE WHEN v_has_pgstattuple THEN
COALESCE((pgstattuple(c.oid)).free_percent + (pgstattuple(c.oid)).dead_tuple_percent, 0)
ELSE
CASE WHEN s.n_live_tup + s.n_dead_tup = 0 THEN 0
ELSE (s.n_dead_tup::numeric / (s.n_live_tup + s.n_dead_tup)) * 100 END
END AS bloat_estimate
FROM pg_stat_all_tables s
JOIN pg_class c ON c.oid = s.relid
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')
)
SELECT
percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate),
stddev(bloat_estimate)
INTO v_median_bloat, v_bloat_stddev
FROM toast_bloat;
RETURN (
SELECT json_agg(
json_build_object(
'metric', 'Table Vacuum Health',
'table_name', v.table_name,
'status', CASE
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN 'Red'
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN 5
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN 3
ELSE 1
END,
'insight', CASE
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN
'Table bloat is critically high' ||
(CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; TOAST overhead is significant.' ELSE '.' END)
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN
'Table bloat is above average' ||
(CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; TOAST overhead notable.' ELSE '.' END)
ELSE 'Table bloat is within normal range.'
END,
'action', CASE
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + 2 * v_bloat_stddev THEN
'Run VACUUM FULL or CLUSTER' ||
(CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; review large fields for TOAST impact.' ELSE '.' END)
WHEN (v.bloat_estimate + COALESCE(t.toast_bloat, 0)) > v_median_bloat + v_bloat_stddev THEN
'Run VACUUM and ANALYZE' ||
(CASE WHEN t.toast_bloat > v.bloat_estimate THEN '; check TOAST usage.' ELSE '.' END)
ELSE 'No immediate action required.'
END,
'last_vacuum', v.last_vacuum::text,
'last_autovacuum', v.last_autovacuum::text,
'vacuum_count', v.vacuum_count,
'dead_tuples', v.dead_tuples,
'live_tuples', v.live_tuples,
'table_size', pg_size_pretty(v.table_size),
'bloat_estimate', v.bloat_estimate::text || '%' ||
(CASE WHEN v_has_pgstattuple THEN ' (precise)' ELSE ' (estimated)' END),
'details', json_build_object(
'median_bloat', round(v_median_bloat)::text || '%',
'bloat_stddev', round(v_bloat_stddev)::text || '%',
'toast_bloat', round(COALESCE(t.toast_bloat, 0))::text || '%',
'explanation', 'Includes TOAST bloat in total health assessment.'
)
)
)
FROM public.c77_dbh_vacuum_stats v
LEFT JOIN (
SELECT
(n.nspname || '.' || c.relname) AS table_name,
CASE WHEN v_has_pgstattuple THEN
COALESCE((pgstattuple(tst.oid)).free_percent + (pgstattuple(tst.oid)).dead_tuple_percent, 0)
ELSE 0 END AS toast_bloat
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
LEFT JOIN pg_class tst ON tst.oid = c.reltoastrelid
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema') AND c.reltoastrelid != 0
) t ON v.table_name = t.table_name
);
END;
$$ LANGUAGE plpgsql;

View File

@ -1,174 +0,0 @@
CREATE TABLE IF NOT EXISTS public.c77_dbh_index_stats (
index_name text COLLATE pg_catalog."default" PRIMARY KEY, -- Fully qualified index name
table_name text, -- Associated table
index_size bigint DEFAULT 0, -- Size in bytes
scan_count bigint DEFAULT 0, -- Number of scans
bloat_estimate numeric DEFAULT 0, -- Estimated bloat percentage
last_updated timestamp without time zone DEFAULT now() -- Last stats update
);
CREATE OR REPLACE FUNCTION public.c77_dbh_update_index_stats()
RETURNS void AS $$
DECLARE
v_has_pgstattuple boolean;
BEGIN
SELECT EXISTS (
SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple'
) INTO v_has_pgstattuple;
INSERT INTO public.c77_dbh_index_stats (
index_name, table_name, index_size, scan_count, bloat_estimate, last_updated
)
SELECT
(n.nspname || '.' || i.relname) AS index_name,
(n.nspname || '.' || t.relname) AS table_name,
pg_relation_size(i.oid) AS index_size,
COALESCE(s.idx_scan, 0) AS scan_count,
CASE WHEN v_has_pgstattuple THEN
ROUND(CAST(COALESCE((pgstattuple(i.oid)).free_percent + (pgstattuple(i.oid)).dead_tuple_percent, 0) AS numeric), 2)
ELSE
0 -- Placeholder; could estimate based on size vs. usage
END AS bloat_estimate,
now() AS last_updated
FROM pg_index ix
JOIN pg_class i ON i.oid = ix.indexrelid
JOIN pg_class t ON t.oid = ix.indrelid
JOIN pg_namespace n ON n.oid = i.relnamespace
LEFT JOIN pg_stat_all_indexes s ON s.indexrelid = i.oid
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')
ON CONFLICT (index_name) DO UPDATE
SET
table_name = EXCLUDED.table_name,
index_size = EXCLUDED.index_size,
scan_count = EXCLUDED.scan_count,
bloat_estimate = EXCLUDED.bloat_estimate,
last_updated = EXCLUDED.last_updated;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.c77_dbh_get_index_health()
RETURNS JSON AS $$
DECLARE
v_median_bloat numeric;
v_median_usage numeric;
BEGIN
SELECT
percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate),
percentile_cont(0.5) WITHIN GROUP (ORDER BY scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))
INTO v_median_bloat, v_median_usage
FROM public.c77_dbh_index_stats
WHERE index_name NOT LIKE 'pg_toast.%';
RETURN (
SELECT json_agg(
json_build_object(
'metric', 'Index Health',
'index_name', index_name,
'table_name', table_name,
'status', CASE
WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 'Red'
WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 5
WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 3
ELSE 1
END,
'insight', CASE
WHEN scan_count = 0 THEN 'Index is unused; consider dropping.'
WHEN bloat_estimate > v_median_bloat * 2 THEN 'Index bloat is critically high.'
WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Index usage is low relative to size.'
ELSE 'Index is healthy and well-utilized.'
END,
'action', CASE
WHEN scan_count = 0 THEN 'Drop the index if not needed.'
WHEN bloat_estimate > v_median_bloat * 2 THEN 'Run REINDEX; check autovacuum.'
WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Review query patterns or consider reindexing.'
ELSE 'No action needed.'
END,
'index_size', pg_size_pretty(index_size),
'scan_count', scan_count,
'bloat_estimate', bloat_estimate::text || '%',
'details', json_build_object(
'usage_rate', round((scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))::numeric, 2)::text || ' scans/MB',
'median_bloat', round(v_median_bloat)::text || '%',
'median_usage', round(v_median_usage, 2)::text || ' scans/MB'
)
)
)
FROM public.c77_dbh_index_stats
WHERE index_name NOT LIKE 'pg_toast.%'
);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION public.c77_dbh_get_toast_health()
RETURNS JSON AS $$
DECLARE
v_median_bloat numeric;
v_median_usage numeric;
v_has_pgstattuple boolean;
BEGIN
SELECT EXISTS (
SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple'
) INTO v_has_pgstattuple;
SELECT
percentile_cont(0.5) WITHIN GROUP (ORDER BY bloat_estimate),
percentile_cont(0.5) WITHIN GROUP (ORDER BY scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))
INTO v_median_bloat, v_median_usage
FROM public.c77_dbh_index_stats
WHERE index_name LIKE 'pg_toast.%';
RETURN (
SELECT json_agg(
json_build_object(
'metric', 'TOAST Index Health',
'index_name', index_name,
'parent_table', table_name,
'status', CASE
WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 'Red'
WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Yellow'
ELSE 'Green'
END,
'severity', CASE
WHEN bloat_estimate > v_median_bloat * 2 OR scan_count = 0 THEN 5
WHEN bloat_estimate > v_median_bloat * 1.2 OR (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 3
ELSE 1
END,
'insight', CASE
WHEN scan_count = 0 THEN 'TOAST index is unused; parent table may not need toasted columns indexed.'
WHEN bloat_estimate > v_median_bloat * 2 THEN 'TOAST index bloat is critically high.'
WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'TOAST index usage is low relative to size.'
ELSE 'TOAST index is healthy and well-utilized.'
END,
'action', CASE
WHEN scan_count = 0 THEN 'Review parent table queries; consider dropping TOAST index.'
WHEN bloat_estimate > v_median_bloat * 2 THEN 'Run REINDEX on TOAST table; optimize large fields in parent.'
WHEN (scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0)) < v_median_usage * 0.5 THEN 'Check parent table usage patterns.'
ELSE 'No action needed.'
END,
'index_size', pg_size_pretty(index_size),
'scan_count', scan_count,
'bloat_estimate', bloat_estimate::text || '%' ||
(CASE WHEN v_has_pgstattuple THEN ' (precise)' ELSE ' (estimated)' END),
'details', json_build_object(
'usage_rate', round((scan_count::numeric / NULLIF(index_size::numeric / 1024^2, 0))::numeric, 2)::text || ' scans/MB',
'median_bloat', round(v_median_bloat)::text || '%',
'median_usage', round(v_median_usage, 2)::text || ' scans/MB',
'parent_columns', (
SELECT string_agg(attname, ', ')
FROM pg_attribute a
JOIN pg_class c ON c.oid = (SELECT oid FROM pg_class WHERE relname = split_part(table_name, '.', 2) AND relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = split_part(table_name, '.', 1)))
WHERE a.attrelid = c.oid AND a.attlen = -1 -- Variable-length columns likely toasted
)
)
)
)
FROM public.c77_dbh_index_stats
WHERE index_name LIKE 'pg_toast.%'
);
END;
$$ LANGUAGE plpgsql;

View File

@ -1,61 +0,0 @@
CREATE OR REPLACE FUNCTION public.c77_dbh_update_vacuum_stats()
RETURNS void AS $$
DECLARE
v_has_pgstattuple boolean;
BEGIN
-- Check if pgstattuple is installed
SELECT EXISTS (
SELECT 1 FROM pg_extension WHERE extname = 'pgstattuple'
) INTO v_has_pgstattuple;
-- Insert or update vacuum stats for all user tables
INSERT INTO public.c77_dbh_vacuum_stats (
table_name, last_vacuum, last_autovacuum, vacuum_count,
dead_tuples, live_tuples, table_size, last_updated
)
SELECT
(n.nspname || '.' || c.relname) AS table_name,
s.last_vacuum,
s.last_autovacuum,
COALESCE(s.vacuum_count, 0) + COALESCE(s.autovacuum_count, 0) AS vacuum_count,
s.n_dead_tup AS dead_tuples,
s.n_live_tup AS live_tuples,
pg_relation_size(c.oid) AS table_size,
now() AS last_updated
FROM pg_stat_all_tables s
JOIN pg_class c ON c.oid = s.relid
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')
ON CONFLICT (table_name) DO UPDATE
SET
last_vacuum = EXCLUDED.last_vacuum,
last_autovacuum = EXCLUDED.last_autovacuum,
vacuum_count = EXCLUDED.vacuum_count,
dead_tuples = EXCLUDED.dead_tuples,
live_tuples = EXCLUDED.live_tuples,
table_size = EXCLUDED.table_size,
last_updated = EXCLUDED.last_updated;
-- Update bloat estimate
IF v_has_pgstattuple THEN
-- Use pgstattuple for precise bloat if available
UPDATE public.c77_dbh_vacuum_stats v
SET bloat_estimate = ROUND(CAST(COALESCE(t.free_percent + t.dead_tuple_percent, 0) AS numeric), 2)
FROM (
SELECT (pgstattuple(c.oid)).*
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE (n.nspname || '.' || c.relname) = v.table_name
) t
WHERE v.last_updated = now();
ELSE
-- Fallback to heuristic bloat estimate
UPDATE public.c77_dbh_vacuum_stats
SET bloat_estimate = CASE
WHEN live_tuples + dead_tuples = 0 THEN 0
ELSE ROUND((dead_tuples::numeric / (live_tuples + dead_tuples)) * 100, 2)
END
WHERE last_updated = now();
END IF;
END;
$$ LANGUAGE plpgsql;