diff --git a/fhem/CHANGED b/fhem/CHANGED index 170b97769..33faf34d4 100644 --- a/fhem/CHANGED +++ b/fhem/CHANGED @@ -1,6 +1,10 @@ # Add changes at the top of the list. - SVN + - feature: 93_DbLog extended to give more functions for the charting frontend. + This includes new queries for raw table data and also statistics, + which get sum/max/min/avg values from the database. + Documentation has been updated. - feature: new module 31_LightScene to save and restore the state of a group of lights and other actors - feature: VIERA module added (by teevau) diff --git a/fhem/FHEM/93_DbLog.pm b/fhem/FHEM/93_DbLog.pm index 07b591290..8b87af547 100644 --- a/fhem/FHEM/93_DbLog.pm +++ b/fhem/FHEM/93_DbLog.pm @@ -395,15 +395,25 @@ DbLog_Connect($) } Log 3, "Connection to db $dbconn established"; $hash->{DBH}= $dbh; - + if ($hash->{DBMODEL} eq "SQLITE") { - $dbh->do("PRAGMA temp_store=MEMORY"); - $dbh->do("PRAGMA synchronous=NORMAL"); - $dbh->do("PRAGMA journal_mode=WAL"); - $dbh->do("CREATE TEMP TABLE IF NOT EXISTS current (TIMESTAMP TIMESTAMP, DEVICE varchar(32), TYPE varchar(32), EVENT varchar(512), READING varchar(32), VALUE varchar(32), UNIT varchar(32))"); - $dbh->do("CREATE TABLE IF NOT EXISTS history (TIMESTAMP TIMESTAMP, DEVICE varchar(32), TYPE varchar(32), EVENT varchar(512), READING varchar(32), VALUE varchar(32), UNIT varchar(32))"); - $dbh->do("CREATE INDEX IF NOT EXISTS Search_Idx ON `history` (DEVICE, READING, TIMESTAMP)"); + $dbh->do("PRAGMA temp_store=MEMORY"); + $dbh->do("PRAGMA synchronous=NORMAL"); + $dbh->do("PRAGMA journal_mode=WAL"); + $dbh->do("CREATE TEMP TABLE IF NOT EXISTS current (TIMESTAMP TIMESTAMP, DEVICE varchar(32), TYPE varchar(32), EVENT varchar(512), READING varchar(32), VALUE varchar(32), UNIT varchar(32))"); + $dbh->do("CREATE TABLE IF NOT EXISTS history (TIMESTAMP TIMESTAMP, DEVICE varchar(32), TYPE varchar(32), EVENT varchar(512), READING varchar(32), VALUE varchar(32), UNIT varchar(32))"); + $dbh->do("CREATE INDEX IF NOT EXISTS Search_Idx ON `history` (DEVICE, READING, TIMESTAMP)"); } + + # creating an own connection for the webfrontend, saved as DBHF in Hash + # this makes sure that the connection doesnt get lost due to other modules + my $dbhf = DBI->connect_cached("dbi:$dbconn", $dbuser, $dbpassword); + if(!$dbhf) { + Log 2, "Can't connect to $dbconn: $DBI::errstr"; + return 0; + } + Log 3, "Connection to db $dbconn established"; + $hash->{DBHF}= $dbhf; return 1; } @@ -739,7 +749,7 @@ DbLog_Get($@) ################################################################ sub jsonError($) { my $errormsg = $_[0]; - my $json = "{success: false, msg:'$errormsg'}\n"; + my $json = '{"success": "false", "msg":"'.$errormsg.'"}'; return $json; } @@ -751,6 +761,7 @@ sub jsonError($) { ################################################################ sub prepareSql(@_) { + my ($hash, @a) = @_; my $starttime = $_[5]; $starttime =~ s/_/ /; my $endtime = $_[6]; @@ -760,19 +771,139 @@ sub prepareSql(@_) { my $xaxis = $_[9]; my $yaxis = $_[10]; my $savename = $_[11]; - my ($sql, $jsonstring); - + my $jsonChartConfig = $_[12]; + my $pagingstart = $_[13]; + my $paginglimit = $_[14]; + my $dbmodel = $hash->{DBMODEL}; + my ($sql, $jsonstring, $countsql, $hourstats, $daystats, $weekstats, $monthstats, $yearstats); + + if ($dbmodel eq "POSTGRESQL") { + ### POSTGRESQL Queries for Statistics ### + ### hour: + $hourstats = "SELECT to_char(timestamp, 'YYYY-MM-DD HH24:00:00') AS TIMESTAMP, SUM(VALUE::float) AS SUM, "; + $hourstats .= "AVG(VALUE::float) AS AVG, MIN(VALUE::float) AS MIN, MAX(VALUE::float) AS MAX, "; + $hourstats .= "COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $hourstats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + ### day: + $daystats = "SELECT to_char(timestamp, 'YYYY-MM-DD 00:00:00') AS TIMESTAMP, SUM(VALUE::float) AS SUM, "; + $daystats .= "AVG(VALUE::float) AS AVG, MIN(VALUE::float) AS MIN, MAX(VALUE::float) AS MAX, "; + $daystats .= "COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $daystats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + ### week: + $weekstats = "SELECT date_trunc('week',timestamp) AS TIMESTAMP, SUM(VALUE::float) AS SUM, "; + $weekstats .= "AVG(VALUE::float) AS AVG, MIN(VALUE::float) AS MIN, MAX(VALUE::float) AS MAX, "; + $weekstats .= "COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $weekstats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + ### month: + $monthstats = "SELECT to_char(timestamp, 'YYYY-MM-01 00:00:00') AS TIMESTAMP, SUM(VALUE::float) AS SUM, "; + $monthstats .= "AVG(VALUE::float) AS AVG, MIN(VALUE::float) AS MIN, MAX(VALUE::float) AS MAX, "; + $monthstats .= "COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $monthstats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + ### year: + $yearstats = "SELECT to_char(timestamp, 'YYYY-01-01 00:00:00') AS TIMESTAMP, SUM(VALUE::float) AS SUM, "; + $yearstats .= "AVG(VALUE::float) AS AVG, MIN(VALUE::float) AS MIN, MAX(VALUE::float) AS MAX, "; + $yearstats .= "COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $yearstats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + } elsif ($dbmodel eq "MYSQL") { + ### MYSQL Queries for Statistics ### + ### hour: + $hourstats = "SELECT date_format(timestamp, '%Y-%m-%d %H:00:00') AS TIMESTAMP, SUM(CAST(VALUE AS DECIMAL(12,4))) AS SUM, "; + $hourstats .= "AVG(CAST(VALUE AS DECIMAL(12,4))) AS AVG, MIN(CAST(VALUE AS DECIMAL(12,4))) AS MIN, "; + $hourstats .= "MAX(CAST(VALUE AS DECIMAL(12,4))) AS MAX, COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' "; + $hourstats .= "AND DEVICE = '$device' AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + ### day: + $daystats = "SELECT date_format(timestamp, '%Y-%m-%d 00:00:00') AS TIMESTAMP, SUM(CAST(VALUE AS DECIMAL(12,4))) AS SUM, "; + $daystats .= "AVG(CAST(VALUE AS DECIMAL(12,4))) AS AVG, MIN(CAST(VALUE AS DECIMAL(12,4))) AS MIN, "; + $daystats .= "MAX(CAST(VALUE AS DECIMAL(12,4))) AS MAX, COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' "; + $daystats .= "AND DEVICE = '$device' AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + ### week: + $weekstats = "SELECT date_format(timestamp, '%Y-%m-%d 00:00:00') AS TIMESTAMP, SUM(CAST(VALUE AS DECIMAL(12,4))) AS SUM, "; + $weekstats .= "AVG(CAST(VALUE AS DECIMAL(12,4))) AS AVG, MIN(CAST(VALUE AS DECIMAL(12,4))) AS MIN, "; + $weekstats .= "MAX(CAST(VALUE AS DECIMAL(12,4))) AS MAX, COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' "; + $weekstats .= "AND DEVICE = '$device' AND TIMESTAMP Between '$starttime' AND '$endtime' "; + $weekstats .= "GROUP BY date_format(timestamp, '%Y-%u 00:00:00') ORDER BY 1;"; + + ### month: + $monthstats = "SELECT date_format(timestamp, '%Y-%m-01 00:00:00') AS TIMESTAMP, SUM(CAST(VALUE AS DECIMAL(12,4))) AS SUM, "; + $monthstats .= "AVG(CAST(VALUE AS DECIMAL(12,4))) AS AVG, MIN(CAST(VALUE AS DECIMAL(12,4))) AS MIN, "; + $monthstats .= "MAX(CAST(VALUE AS DECIMAL(12,4))) AS MAX, COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' "; + $monthstats .= "AND DEVICE = '$device' AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + ### year: + $yearstats = "SELECT date_format(timestamp, '%Y-01-01 00:00:00') AS TIMESTAMP, SUM(CAST(VALUE AS DECIMAL(12,4))) AS SUM, "; + $yearstats .= "AVG(CAST(VALUE AS DECIMAL(12,4))) AS AVG, MIN(CAST(VALUE AS DECIMAL(12,4))) AS MIN, "; + $yearstats .= "MAX(CAST(VALUE AS DECIMAL(12,4))) AS MAX, COUNT(VALUE) AS COUNT FROM history WHERE READING = '$yaxis' "; + $yearstats .= "AND DEVICE = '$device' AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY 1 ORDER BY 1;"; + + } elsif ($hash->{DBMODEL} eq "SQLITE") { + ### SQLITE Queries for Statistics ### + ### hour: + $hourstats = "SELECT TIMESTAMP, SUM(CAST(VALUE AS FLOAT)) AS SUM, AVG(CAST(VALUE AS FLOAT)) AS AVG, "; + $hourstats .= "MIN(CAST(VALUE AS FLOAT)) AS MIN, MAX(CAST(VALUE AS FLOAT)) AS MAX, COUNT(VALUE) AS COUNT "; + $hourstats .= "FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $hourstats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY strftime('%Y-%m-%d %H:00:00', TIMESTAMP);"; + + ### day: + $daystats = "SELECT TIMESTAMP, SUM(CAST(VALUE AS FLOAT)) AS SUM, AVG(CAST(VALUE AS FLOAT)) AS AVG, "; + $daystats .= "MIN(CAST(VALUE AS FLOAT)) AS MIN, MAX(CAST(VALUE AS FLOAT)) AS MAX, COUNT(VALUE) AS COUNT "; + $daystats .= "FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $daystats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY strftime('%Y-%m-%d 00:00:00', TIMESTAMP);"; + + ### week: + $weekstats = "SELECT TIMESTAMP, SUM(CAST(VALUE AS FLOAT)) AS SUM, AVG(CAST(VALUE AS FLOAT)) AS AVG, "; + $weekstats .= "MIN(CAST(VALUE AS FLOAT)) AS MIN, MAX(CAST(VALUE AS FLOAT)) AS MAX, COUNT(VALUE) AS COUNT "; + $weekstats .= "FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $weekstats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY strftime('%Y-%W 00:00:00', TIMESTAMP);"; + + ### month: + $monthstats = "SELECT TIMESTAMP, SUM(CAST(VALUE AS FLOAT)) AS SUM, AVG(CAST(VALUE AS FLOAT)) AS AVG, "; + $monthstats .= "MIN(CAST(VALUE AS FLOAT)) AS MIN, MAX(CAST(VALUE AS FLOAT)) AS MAX, COUNT(VALUE) AS COUNT "; + $monthstats .= "FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $monthstats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY strftime('%Y-%m 00:00:00', TIMESTAMP);"; + + ### year: + $yearstats = "SELECT TIMESTAMP, SUM(CAST(VALUE AS FLOAT)) AS SUM, AVG(CAST(VALUE AS FLOAT)) AS AVG, "; + $yearstats .= "MIN(CAST(VALUE AS FLOAT)) AS MIN, MAX(CAST(VALUE AS FLOAT)) AS MAX, COUNT(VALUE) AS COUNT "; + $yearstats .= "FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' "; + $yearstats .= "AND TIMESTAMP Between '$starttime' AND '$endtime' GROUP BY strftime('%Y 00:00:00', TIMESTAMP);"; + + } else { + $sql = "errordb"; + } + if($userquery eq "getreadings") { - $sql = "SELECT distinct(reading) FROM current WHERE device = '".$device."'"; + $sql = "SELECT distinct(reading) FROM history WHERE device = '".$device."'"; } elsif($userquery eq "getdevices") { - $sql = 'SELECT distinct(device) FROM history'; + $sql = "SELECT distinct(device) FROM history"; } elsif($userquery eq "timerange") { - $sql = 'SELECT '.$xaxis.', VALUE FROM history WHERE READING = "'.$yaxis.'" AND DEVICE = "'.$device.'" AND TIMESTAMP Between "'.$starttime.'" AND "'.$endtime.'";'; + $sql = "SELECT ".$xaxis.", VALUE FROM history WHERE READING = '$yaxis' AND DEVICE = '$device' AND TIMESTAMP Between '$starttime' AND '$endtime';"; + } elsif($userquery eq "hourstats") { + $sql = $hourstats; + } elsif($userquery eq "daystats") { + $sql = $daystats; + } elsif($userquery eq "weekstats") { + $sql = $weekstats; + } elsif($userquery eq "monthstats") { + $sql = $monthstats; + } elsif($userquery eq "yearstats") { + $sql = $yearstats; } elsif($userquery eq "savechart") { - $jsonstring = '[{x:"'.$xaxis.'",y:"'.$yaxis.'",device:"'.$device.'",starttime:"'.$starttime.'",endtime:"'.$endtime.'"}]'; - $sql = "INSERT INTO history (EVENT, READING, VALUE) VALUES('".$jsonstring."', 'savedchart', '".$savename."')"; + $sql = "INSERT INTO frontend (TYPE, NAME, VALUE) VALUES ('savedchart', '$savename', '$jsonChartConfig')"; + } elsif($userquery eq "deletechart") { + $sql = "DELETE FROM frontend WHERE TYPE = 'savedchart' AND ID = '".$savename."'"; } elsif($userquery eq "getcharts") { - $sql = 'SELECT * FROM history WHERE READING = "savedchart"'; + $sql = "SELECT * FROM frontend WHERE TYPE = 'savedchart'"; + } elsif($userquery eq "getTableData") { + $countsql = "SELECT count(*) FROM history"; + $sql = "SELECT * FROM history LIMIT ".$paginglimit." OFFSET ".$pagingstart; + return ($sql, $countsql); } else { $sql = "error"; } @@ -787,62 +918,88 @@ sub prepareSql(@_) { ################################################################ sub chartQuery($@) { - my $sql = prepareSql(@_); + my ($sql, $countsql) = prepareSql(@_); if ($sql eq "error") { - return jsonError("Could not setup SQL String"); + return jsonError("Could not setup SQL String. Maybe the Database is busy, please try again!"); + } elsif ($sql eq "errordb") { + return jsonError("The Database Type is not supported!"); } my ($hash, @a) = @_; - my $dbh= $hash->{DBH}; + my $dbhf= $hash->{DBHF}; + + my $totalcount; + if (defined $countsql && $countsql ne "") { + my $query_handle = $dbhf->prepare($countsql) + or return jsonError("Could not prepare statement: " . $dbhf->errstr . ", SQL was: " .$countsql); + + $query_handle->execute() + or return jsonError("Could not execute statement: " . $query_handle->errstr); + + my @data = $query_handle->fetchrow_array(); + $totalcount = join(", ", @data); + + } + # prepare the query - my $query_handle = $dbh->prepare($sql) - or return jsonError("Couldn't prepare statement: " . $dbh->errstr . ", SQL was: " .$sql); + my $query_handle = $dbhf->prepare($sql) + or return jsonError("Could not prepare statement: " . $dbhf->errstr . ", SQL was: " .$sql); # execute the query $query_handle->execute() - or return jsonError("Couldn't execute statement: " . $query_handle->errstr); + or return jsonError("Could not execute statement: " . $query_handle->errstr); my $columns = $query_handle->{'NAME'}; my $columncnt; - - # When columns are empty but execution was successful, we have done a successful INSERT + + # When columns are empty but execution was successful, we have done a successful INSERT, UPDATE or DELETE if($columns) { $columncnt = scalar @$columns; } else { - return "{success: true, msg:'Insert ok'}\n"; + return '{"success": "true", "msg":"All ok"}'; } my $i = 0; - my $jsonstring = "["; + my $jsonstring = '{"data":['; while ( my @data = $query_handle->fetchrow_array()) { if($i == 0) { - $jsonstring .= "{"; + $jsonstring .= '{'; } else { - $jsonstring .= ",{"; + $jsonstring .= ',{'; } - + for ($i = 0; $i < $columncnt; $i++) { - $jsonstring .= "'"; + $jsonstring .= '"'; $jsonstring .= uc($query_handle->{NAME}->[$i]); - $jsonstring .= "':'"; + $jsonstring .= '":'; if (defined $data[$i]) { - $jsonstring .= $data[$i]; - } - - if($i == ($columncnt -1)) { - $jsonstring .= "'"; + my $fragment = substr($data[$i],0,1); + if ($fragment eq "{") { + $jsonstring .= $data[$i]; + } else { + $jsonstring .= '"'.$data[$i].'"'; + } } else { - $jsonstring .= "',"; - } + $jsonstring .= '""' + } + + if($i != ($columncnt -1)) { + $jsonstring .= ','; + } } - $jsonstring .= "}"; + $jsonstring .= '}'; + } + $jsonstring .= ']'; + if (defined $totalcount && $totalcount ne "") { + $jsonstring .= ',"totalCount": '.$totalcount.'}'; + } else { + $jsonstring .= '}'; } - $jsonstring .= "]"; return $jsonstring; } ################################################################ @@ -1011,7 +1168,7 @@ sub chartQuery($@) {
logdb
.-
getdevices
to retrieve all available devicestimerange
to retrieve charting data, which requires a given xaxis, yaxis, device, to and fromsavechart
to save a chart configuration in the database. Requires a given xaxis, yaxis, device, to and from, and a 'savename' used to save the chartdeletechart
to delete a saved chart. Requires a given id which was set on save of the chartgetcharts
to get a list of all saved charts.getTableData
to get jsonformatted data from the database. Uses paging Parameters like start and limit.hourstats
to get statistics for a given value (yaxis) for an hour.daystats
to get statistics for a given value (yaxis) for a day.weekstats
to get statistics for a given value (yaxis) for a week.monthstats
to get statistics for a given value (yaxis) for a month.yearstats
to get statistics for a given value (yaxis) for a year.[{'TIMESTAMP':'2013-02-11 00:10:10','VALUE':'0.22431388090756'},{'TIMESTAMP'.....}]
get logdb - webchart 2013-02-11_00:00:00 2013-02-12_00:00:00 ESA2000_LED_011e savechart TIMESTAMP day_kwh tageskwh
get logdb - webchart "" "" "" deletechart "" "" 7
logdb
gesetzt werden.-
zu setzen.getdevices
um alle verfügbaren devices zu erhaltentimerange
um Chart-Daten abzufragen. Es werden die Parameter 'xaxis', 'yaxis', 'device', 'to' und 'from' benötigtsavechart
um einen Chart unter Angabe eines 'savename' und seiner zugehörigen Konfiguration abzuspeicherndeletechart
um einen zuvor gespeicherten Chart unter Angabe einer id zu löschengetcharts
um eine Liste aller gespeicherten Charts zu bekommen.getTableData
um Daten aus der Datenbank abzufragen und in einer Tabelle darzustellen. Benötigt paging Parameter wie start und limit.hourstats
um Statistiken für einen Wert (yaxis) für eine Stunde abzufragen.daystats
um Statistiken für einen Wert (yaxis) für einen Tag abzufragen.weekstats
um Statistiken für einen Wert (yaxis) für eine Woche abzufragen.monthstats
um Statistiken für einen Wert (yaxis) für einen Monat abzufragen.yearstats
um Statistiken für einen Wert (yaxis) für ein Jahr abzufragen.[{'TIMESTAMP':'2013-02-11 00:10:10','VALUE':'0.22431388090756'},{'TIMESTAMP'.....}]
get logdb - webchart 2013-02-11_00:00:00 2013-02-12_00:00:00 ESA2000_LED_011e savechart TIMESTAMP day_kwh tageskwh
get logdb - webchart "" "" "" deletechart "" "" 7