57 lines
1.8 KiB
SQL
57 lines
1.8 KiB
SQL
-- TimescaleDB hypertable for time-series audio metrics
|
|
|
|
-- Enable TimescaleDB extension
|
|
CREATE EXTENSION IF NOT EXISTS timescaledb;
|
|
|
|
-- Create audio data table
|
|
CREATE TABLE IF NOT EXISTS audio_data (
|
|
time TIMESTAMPTZ NOT NULL,
|
|
rms_db REAL CHECK (rms_db >= -40.0 AND rms_db <= 80.0),
|
|
frequency_hz INTEGER CHECK (frequency_hz >= 100 AND frequency_hz <= 8000),
|
|
is_silence BOOLEAN NOT NULL DEFAULT FALSE
|
|
);
|
|
|
|
-- Convert to hypertable (time-series optimization)
|
|
SELECT create_hypertable('audio_data', 'time', if_not_exists => TRUE);
|
|
|
|
-- Create index for frequency queries (exclude silence for performance)
|
|
CREATE INDEX IF NOT EXISTS idx_frequency
|
|
ON audio_data(frequency_hz)
|
|
WHERE NOT is_silence;
|
|
|
|
-- Create index for time-based queries
|
|
CREATE INDEX IF NOT EXISTS idx_time_desc
|
|
ON audio_data(time DESC);
|
|
|
|
-- Optional: Create continuous aggregate for 1-minute averages
|
|
CREATE MATERIALIZED VIEW IF NOT EXISTS audio_data_1min
|
|
WITH (timescaledb.continuous) AS
|
|
SELECT
|
|
time_bucket('1 minute', time) AS bucket,
|
|
AVG(rms_db) AS avg_rms_db,
|
|
MAX(rms_db) AS max_rms_db,
|
|
MIN(rms_db) AS min_rms_db,
|
|
mode() WITHIN GROUP (ORDER BY frequency_hz) AS dominant_freq_hz,
|
|
SUM(CASE WHEN is_silence THEN 1 ELSE 0 END)::REAL / COUNT(*) AS silence_ratio
|
|
FROM audio_data
|
|
GROUP BY bucket
|
|
WITH NO DATA;
|
|
|
|
-- Refresh policy: update aggregate every 5 minutes
|
|
SELECT add_continuous_aggregate_policy('audio_data_1min',
|
|
start_offset => INTERVAL '1 hour',
|
|
end_offset => INTERVAL '1 minute',
|
|
schedule_interval => INTERVAL '5 minutes',
|
|
if_not_exists => TRUE
|
|
);
|
|
|
|
-- Data retention: keep raw data for 7 days
|
|
SELECT add_retention_policy('audio_data',
|
|
INTERVAL '7 days',
|
|
if_not_exists => TRUE
|
|
);
|
|
|
|
-- Grant permissions
|
|
GRANT ALL ON audio_data TO postgres;
|
|
GRANT SELECT ON audio_data_1min TO postgres;
|