[Author Prev][Author Next][Thread Prev][Thread Next][Author Index][Thread Index]
[or-cvs] [metrics-db/master] Add new materialized view on relays flags with 1-hour detail.
Author: Karsten Loesing <karsten.loesing@xxxxxxx>
Date: Mon, 11 Oct 2010 21:07:46 +0200
Subject: Add new materialized view on relays flags with 1-hour detail.
Commit: d43012613480083de4cbeb7f1da879be2796ac75
---
db/refresh.sql | 1 +
db/tordir.sql | 40 ++++++++++++++++++++++++++++++++++++++--
2 files changed, 39 insertions(+), 2 deletions(-)
diff --git a/db/refresh.sql b/db/refresh.sql
index 9b98b1a..200b19c 100644
--- a/db/refresh.sql
+++ b/db/refresh.sql
@@ -10,6 +10,7 @@ BEGIN;
SELECT * FROM refresh_relay_statuses_per_day();
SELECT * FROM refresh_network_size();
+SELECT * FROM refresh_network_size_hour();
SELECT * FROM refresh_relay_platforms();
SELECT * FROM refresh_relay_versions();
SELECT * FROM refresh_total_bandwidth();
diff --git a/db/tordir.sql b/db/tordir.sql
index 85a6f22..56789cf 100644
--- a/db/tordir.sql
+++ b/db/tordir.sql
@@ -122,6 +122,17 @@ CREATE TABLE network_size (
CONSTRAINT network_size_pkey PRIMARY KEY(date)
);
+-- TABLE network_size_hour
+CREATE TABLE network_size_hour (
+ validafter TIMESTAMP WITHOUT TIME ZONE NOT NULL,
+ avg_running INTEGER NOT NULL,
+ avg_exit INTEGER NOT NULL,
+ avg_guard INTEGER NOT NULL,
+ avg_fast INTEGER NOT NULL,
+ avg_stable INTEGER NOT NULL,
+ CONSTRAINT network_size_hour_pkey PRIMARY KEY(validafter)
+);
+
-- TABLE relay_platforms
CREATE TABLE relay_platforms (
date TIMESTAMP WITHOUT TIME ZONE NOT NULL,
@@ -326,7 +337,7 @@ CREATE OR REPLACE FUNCTION refresh_network_size() RETURNS INTEGER AS $$
INSERT INTO network_size
(date, avg_running, avg_exit, avg_guard, avg_fast, avg_stable)
SELECT
- DATE(validafter) as date,
+ DATE(validafter) AS date,
COUNT(*) / relay_statuses_per_day.count AS avg_running,
SUM(CASE WHEN isexit IS TRUE THEN 1 ELSE 0 END)
/ relay_statuses_per_day.count AS avg_exit,
@@ -349,6 +360,31 @@ CREATE OR REPLACE FUNCTION refresh_network_size() RETURNS INTEGER AS $$
END;
$$ LANGUAGE plpgsql;
+-- FUNCTION refresh_network_size_hour()
+CREATE OR REPLACE FUNCTION refresh_network_size_hour() RETURNS INTEGER AS $$
+ BEGIN
+
+ DELETE FROM network_size_hour
+ WHERE DATE(validafter) IN (SELECT * FROM updates);
+
+ INSERT INTO network_size_hour
+ (validafter, avg_running, avg_exit, avg_guard, avg_fast, avg_stable)
+ SELECT validafter, COUNT(*) AS avg_running,
+ SUM(CASE WHEN isexit IS TRUE THEN 1 ELSE 0 END) AS avg_exit,
+ SUM(CASE WHEN isguard IS TRUE THEN 1 ELSE 0 END) AS avg_guard,
+ SUM(CASE WHEN isfast IS TRUE THEN 1 ELSE 0 END) AS avg_fast,
+ SUM(CASE WHEN isstable IS TRUE THEN 1 ELSE 0 END) AS avg_stable
+ FROM statusentry
+ WHERE isrunning = TRUE
+ AND DATE(validafter) >= (SELECT MIN(date) FROM updates)
+ AND DATE(validafter) <= (SELECT MAX(date) FROM updates)
+ AND DATE(validafter) IN (SELECT date FROM updates)
+ GROUP BY validafter;
+
+ RETURN 1;
+ END;
+$$ LANGUAGE plpgsql;
+
-- FUNCTION refresh_relay_platforms()
CREATE OR REPLACE FUNCTION refresh_relay_platforms() RETURNS INTEGER AS $$
BEGIN
@@ -476,7 +512,7 @@ CREATE OR REPLACE FUNCTION refresh_total_bwhist() RETURNS INTEGER AS $$
SUM(CASE WHEN dirread IS NULL THEN NULL ELSE read END) AS dirread
FROM (
SELECT fingerprint,
- DATE(intervalend) as date,
+ DATE(intervalend) AS date,
SUM(read) AS read,
SUM(written) AS written,
SUM(dirread) AS dirread,
--
1.7.1