From 02f48f7a905973428fc7766cf92bb04614e1fdca Mon Sep 17 00:00:00 2001 From: yvesf Date: Sun, 24 Jul 2011 13:12:14 +0200 Subject: cleanup, tag version 0.3 --- sql/chart.r | 148 +++++++++++++++++++++++++++++++++++++++++++++++++ sql/populate_cache.sql | 45 +++++++++++++++ sql/refresh_cache.sql | 1 + sql/trigger.sql | 49 ++++++++++++++++ 4 files changed, 243 insertions(+) create mode 100755 sql/chart.r create mode 100644 sql/populate_cache.sql create mode 100644 sql/refresh_cache.sql create mode 100644 sql/trigger.sql (limited to 'sql') diff --git a/sql/chart.r b/sql/chart.r new file mode 100755 index 0000000..5575293 --- /dev/null +++ b/sql/chart.r @@ -0,0 +1,148 @@ +#!/usr/bin/Rscript --vanilla +require(RPostgreSQL) +require(RSvgDevice) +nulltime <- strptime("01.01.1970", "%d.%m.%Y") + +drv <- dbDriver("PostgreSQL") +con <- dbConnect(drv, host="10.2.2.22", user="jack", password="jack", dbname="ebus") + + +## plot 1 +#png(file = "Rplots.png", width=1500, height=800) +devSVG(file="Rplots.svg",width=15,height=10) +par(cex=1.25) +cat("Starte Abfragen\n") +brenner <- dbGetQuery(con, + paste("SELECT timestamp as \"time\" + , value_string + FROM value + WHERE sensor_id IN (select id from sensor where name = 'heizkreisregler1.betriebsdatenFeuerungsautomat.betriebszustand') + AND timestamp > now() - interval '1 day'", + " AND value_string IS NOT NULL", + " ORDER BY timestamp asc", sep="")) + +## Brennerstatus auf Brennerstaotusänderungen reduzieren + +brennerBla <- table(NULL,NULL) +liste <- c() +old_value_string <- "bla" +for (i in seq(1,nrow(brenner))) { + if (brenner$value_string[i] != old_value_string) { + old_value_string <- brenner$value_string[i] + brennerBla <- rbind(brennerBla, data.frame(time=brenner$time[i], value_string=brenner$value_string[i])) + } +} +brenner <- brennerBla + +# Solar Pumpe +solarEngine <- dbGetQuery(con, + paste("SELECT timestamp as \"time\", + value_int + FROM value + WHERE sensor_id IN (select id from sensor where name = 'heizkreisregler9.solarDaten.solarPumpe') + AND timestamp > now() - interval '1 day' + AND value_int IS NOT NULL + ORDER BY timestamp asc", sep="")) +# reduzieren +solarEngineNew <- table(NULL,NULL) +emptyList <- c() +old_value_int <- "blub" +for (i in seq(1,nrow(solarEngine))) { + if (solarEngine$value_int[i] != old_value_int) { + old_value_int <- solarEngine$value_int[i] + solarEngineNew <- rbind(solarEngineNew, data.frame(time=solarEngine$time[i], value_int=solarEngine$value_int[i])) + } +} +solarEngine <- solarEngineNew + +# Numerische Sensoren Lesen +readNumericSensorDay <- function (sensorName) { + d <- dbGetQuery(con, + paste("SELECT timestamp", + " , COALESCE(value_int,value_float) \"value\"", + " FROM value", + " WHERE sensor_id IN (select id from sensor where name = '",sensorName,"')", + " AND timestamp > now() - interval '1 day'", + # ausreißer ausblenden + " AND COALESCE(value_int,value_float) < 200", + " AND COALESCE(value_int,value_float) > -50", + " ORDER BY timestamp desc", sep="")) + d$timestamp <- as.POSIXct(round(d$timestamp, "mins")) + #d <- supsmu(as.vector(d$timestamp), as.vector(d$value)) + names(d) <- c("time", "value") + + myMean <- function(values) { + if (mad(values) > 2) { + print(paste("Streiche ",length(values), + " Werte aus",sensorName, + "mad =", mad(values))) + values <- values * NA + } + mean(values) + } + +# dm <- aggregate(d$value, list(time=d$time), myMean) + dm <- d + dm$time <- as.POSIXct(dm$time,origin=nulltime) + names(dm) <- c("time", sensorName) + dm +} + +warmwasser <- readNumericSensorDay("heizkreisregler9.solarDaten.tempWarmwasserSolar") +kessel <- readNumericSensorDay("heizkreisregler10.betriebsdatenRegler1.kesselTemperatur") +kollektor <- readNumericSensorDay("heizkreisregler9.solarDaten.tempKollektor") +aussenTemperatur <- readNumericSensorDay("feuerungsautomat1.betriebsdatenRegler1.aussenTemperatur") + +# -- TODO ausreißer als punkte darstellen +data <- Reduce(function(x,y) { merge(x,y,all.x=TRUE) }, list(kollektor, kessel, warmwasser, aussenTemperatur)) + + + +cat("Plotte\n") +plot.new() +plot.window(xlim=c(min(data$time), max(data$time)), + ylim=c(min(data[2:length(data)],na.rm=TRUE)*0.9, max(data[2:length(data)],na.rm=TRUE)*1.1)) +par(lwd=2) + + +for (i in c(2:length(data))) { + lines(subset(data,select=c(1,i)), + col=rainbow(length(data)-1)[i-1]) +} +box() + +for (i in c(1:nrow(brenner))) { + text(as.numeric(brenner$time[i]), max(data[2:length(data)],na.rm=TRUE)/2, paste("ab hier", brenner$value_string[i]) ,srt=90) +} + +# quick and dirty add solarEngine to plot + +rect_start <- 0 +rect_color <- rgb(255, 255, 0, alpha=40, maxColorValue=255) + +for (i in c(1:nrow(solarEngine))) { + if (solarEngine$value_int[i] == 1) { + rect_start <- solarEngine$time[i]; + } else if (rect_start != 0) { + end <- solarEngine$time[i]; + # plot + rect(rect_start, 0, solarEngine$time[i], 100, col=rect_color,border=F) + beginn <- 0 + } + #text(as.numeric(solarEngine$time[i]), max(data[2:length(data)],na.rm=TRUE)/2, paste("Solar Pumpe", solarEngine$value_int[i]), srt=90) +} + +rangeX <- as.POSIXct(range(data$time)) +s <- round.POSIXt(seq(rangeX[1], rangeX[2], by=60*60),"hour") +axis.POSIXct(1, at=s, format="%H:%M") + +r <- range(data[2:length(data)], na.rm=TRUE) +s <- seq(r[1], r[2], by=(r[2]-r[1])/8) +axis(2, at=s, labels=paste(round(s,1),"°C")) +legend('topleft', + legend=names(data)[2:length(data)], + fill=rainbow(length(data)-1)) +title(paste("Temperaturen ", rangeX[1], " bis ", rangeX[2])) +dev.off() + +dbDisconnect(con) diff --git a/sql/populate_cache.sql b/sql/populate_cache.sql new file mode 100644 index 0000000..f302607 --- /dev/null +++ b/sql/populate_cache.sql @@ -0,0 +1,45 @@ +drop table value_cache cascade; + +CREATE TABLE value_cache ( +value_real integer, +timestamp timestamp, +sensor_id integer +); + +create or replace view vi_value_cache as + SELECT timestamp, sensor_id, value_real, 'CACHE' + FROM value_cache +UNION + SELECT date_trunc('hour', timestamp), sensor_id, COALESCE(avg(value_int),avg(value_float)), 'LIVE' + FROM value + WHERE date_trunc('hour', timestamp) > coalesce((select max(timestamp) from value_cache), + now() - interval '2 days') +GROUP BY date_trunc('hour', timestamp), sensor_id; +; + + +CREATE OR REPLACE FUNCTION value_cache_aktualisieren() RETURNS timestamp AS $value_cache_aktualisieren$ +DECLARE + last_update timestamp = now(); +BEGIN + select max(date_trunc('hour'::text, "timestamp")) + into last_update + from value_cache; + + RAISE NOTICE 'last update=%', last_update; + if last_update is NULL then + last_update = now() - interval '20 days'; + RAISE NOTICE 'last update set to %', last_update; + end if; + + delete from value_cache where timestamp >= last_update; + + insert into value_cache + select COALESCE(avg(value_float),avg(value_int)), date_trunc('hour', timestamp), sensor_id + from value + where date_trunc('hour', timestamp) > last_update + group by date_trunc('hour', timestamp), sensor_id; + + RETURN last_update; +END; +$value_cache_aktualisieren$ LANGUAGE plpgsql; diff --git a/sql/refresh_cache.sql b/sql/refresh_cache.sql new file mode 100644 index 0000000..8734348 --- /dev/null +++ b/sql/refresh_cache.sql @@ -0,0 +1 @@ +select value_cache_aktualisieren(); diff --git a/sql/trigger.sql b/sql/trigger.sql new file mode 100644 index 0000000..fb60617 --- /dev/null +++ b/sql/trigger.sql @@ -0,0 +1,49 @@ +-- createlang pgpgsql ebus + +CREATE TABLE value_cache ( LIKE value ); + +DELETE FROM value_cache; + +-- Create a function that always returns the first non-NULL item +CREATE OR REPLACE FUNCTION public.first_agg ( anyelement, anyelement ) RETURNS anyelement AS $$ + SELECT CASE WHEN $1 IS NULL THEN $2 ELSE $1 END; +$$ LANGUAGE SQL STABLE; + +-- And then wrap an aggreagate around it +CREATE AGGREGATE public.first ( + sfunc = public.first_agg, + basetype = anyelement, + stype = anyelement +); + +DROP FUNCTION value_insert_trigger_func() CASCADE; + +CREATE FUNCTION value_insert_trigger_func() RETURNS trigger AS $$ + BEGIN + DELETE FROM value_cache + WHERE date_trunc('hour', timestamp) = + (SELECT date_trunc('hour', max(timestamp)) FROM value) + AND sensor_id = (SELECT sensor_id from value where id = (select max(id) from value)); + + INSERT INTO value_cache + SELECT + COALESCE(0, (select max(id)+1 from value_cache)) as "id" --XXX use seq + ,date_trunc('hour', timestamp) AS "timestamp" + ,sensor_id AS "sensor_id" + ,type AS "type" + ,AVG(value_float) AS "value_float" + ,AVG(value_int) AS "value_int" + ,first(value_string) AS "value_string" + FROM value + WHERE date_trunc('hour', timestamp) = (SELECT date_trunc('hour', max(timestamp)) FROM value) + AND sensor_id = (SELECT sensor_id FROM value WHERE id = (SELECT MAX(id) FROM value)) + GROUP BY type, sensor_id, date_trunc('hour', timestamp); + + RETURN NULL; + END; +$$ LANGUAGE plpgsql; + +-- DROP TRIGGER value_insert_trigger ON value; + +CREATE TRIGGER value_insert_trigger + AFTER INSERT ON value FOR EACH STATEMENT EXECUTE PROCEDURE value_insert_trigger_func(); -- cgit v1.2.1