diff --git a/fhem/contrib/ch.eick/Photovoltaik/99_myUtils.pm_Ergänzungen.txt b/fhem/contrib/ch.eick/Photovoltaik/99_myUtils.pm_Ergänzungen.txt new file mode 100644 index 000000000..4f740031a --- /dev/null +++ b/fhem/contrib/ch.eick/Photovoltaik/99_myUtils.pm_Ergänzungen.txt @@ -0,0 +1,268 @@ +use strict; +use warnings; + +use UConv; # used for wunderground conversion + +use Blocking; # for sendmail + +sub +MyUtils_Initialize($$) +{ + my ($hash) = @_; +} + +# Enter your functions below _this_ line. +################################################### + + +############################################################################################################ +######## DbRep readings separieren und erstellen +############################################################################################################ +sub splitReading { + my ($name,$reading,$value) = @_; + my $hash = $defs{$name}; + + if($reading =~ /^.*SqlResultRow_.*$/ and + $value =~ /^(\d+)-(\d+)-(\d+) (\d+):(\d+):(\d+)\|(.*)\|(.*)/ ) { + + my $TIMESTAMP = "$1-$2-$3 $4:$5:$6"; + my $READING = "$7"; + my $VALUE = "$8"; + + setReadingsVal($hash,$READING,$VALUE,$TIMESTAMP); + } +return; +} + + +########################################################### +## Kostal Plenticore Autentifizierung PV_Anlage_1 +########################################################### + +use Encode qw(decode encode); +use PBKDF2::Tiny qw/derive verify/; +use Digest::SHA qw(sha256 hmac_sha256); +use Crypt::URandom qw( urandom ); +use Crypt::AuthEnc::GCM; + +###################################################### +# {KeyValue("read|store","PW_PV_Anlage_1_API_user","")} +###################################################### +sub KeyValue { + my ($step, $index, $value) = @_; + my $key = getUniqueId().$index; + my $e_value = ""; + my $error; + + if (eval "use Digest::MD5;1") { + $key = Digest::MD5::md5_hex(unpack "H*", $key); + $key .= Digest::MD5::md5_hex($key); + } + + if ($step eq "read") { + ($error, $value) = getKeyValue($index); + + if ( defined($error) ) { + Log3 $index,3, "$index, can't read key from FhemUtils/uniqueID: $error"; + return undef; + } + + if ( defined($value) ) { + my $dec_value = ''; + + for my $char (map { pack('C', hex($_)) } ($value =~ /(..)/g)) { + my $decode = chop($key); + $dec_value .= chr(ord($char)^ord($decode)); + $key = $decode.$key; + } + return $dec_value; + } + else { + Log3 $index,3,"$index, no key found in FhemUtils/uniqueID"; + return undef; + } + } + + if ($step eq "store") { + for my $char (split //, $value) { + my $encode = chop($key); + $e_value .= sprintf("%.2x",ord($char)^ord($encode)); + $key = $encode.$key; + } + $error = setKeyValue($index, $e_value); + return "error while saving key : $error" if(defined($error)); + return "Key successfully saved in FhemUtils/uniqueID Key $index"; + } +}; + + +########################################################### +# {plenticore_auth("WR_1_API","[user|master]","auth_randomString64","auth_nonce","auth_salt","auth_rounds","auth_token","auth_transactionId")} +# {plenticore_auth("start|finish|session","user","WR_1_API","TESMUWZnwkJZbnpF","TE2MUWZnwkJZbnpFQ5ulCfolNNdAD0vT","DbAC0R85jwF0rh+r","29000","1376720346bea40cdf770a8f84b5975cfeb20c5e6ac6d89b7862df3ca9695e43","acafc66c0e1975293d35512a1e4bcceea55840b3109a703514e75b5ebce9b7c5")} +########################################################### +sub plenticore_auth { + my ($step, $user, $logdevice, $randomString, $nonce, $salt, $rounds, $transactionId, $token) = @_; + + my $verbose = AttrVal($logdevice,"verbose",0) ; + + my $PASSWD = KeyValue("read","PW_".$logdevice."_".$user); + + if ($verbose >= 3) { + Log3 $logdevice,3,"====Start plenticore_auth=============================="; + Log3 $logdevice,3,"auth_step : ".$step; + Log3 $logdevice,3,"auth_user : ".$user; + Log3 $logdevice,3,"auth_device : ".$logdevice; + Log3 $logdevice,3,"auth_KeyValue read: PW_".$logdevice."_".$user; + }; + + if($step eq "start") + { + my @chars = ('0'..'9', 'A'..'Z', 'a'..'z'); + my $len = 12; + my $string; + + if ($verbose >= 3) { + Log3 $logdevice,3,"====End arguments======================================"; + }; + + while($len--){ $string .= $chars[rand @chars] }; + $string = encode("UTF-8", $string); + $string = decode("UTF-8", $string); + my $u = encode_base64($string); + $u =~ s/\n$//g; + + my $message = '{"nonce": "'.$u.'","username": "'.$user.'"}'; + + if ($verbose >= 3) { + Log3 $logdevice,3,"auth_nonce : ".$u; + Log3 $logdevice,3,"auth_return : ".$message; + Log3 $logdevice,3,"====End output========================================="; + }; + + CommandSetReading(undef, $logdevice." auth_randomString64 ".$u) ; + + return $message; + } + + ######### This code is identical for finish and session ################# + my $bitSalt = decode_base64($salt); + my $r = derive( 'SHA-256', $PASSWD, $bitSalt, $rounds ); + my $ck = encode('UTF-8', "Client Key"); + my $s = hmac_sha256($ck, $r); + my $underscore = sha256($s); + my $d = "n=".$user.",r=".$randomString.",r=".$nonce.",s=".$salt.",i=".$rounds.",c=biws,r=".$nonce; + + if ($verbose >= 3) { + Log3 $logdevice,3,"auth_randomString : ".$randomString; + Log3 $logdevice,3,"auth_nonce : ".$nonce; + Log3 $logdevice,3,"auth_salt : ".$salt; + Log3 $logdevice,3,"auth_rounds : ".$rounds; + Log3 $logdevice,3,"auth_transactionId: ".$transactionId; + }; + + if($step eq "finish") + { + Log3 $logdevice,3,"====End arguments======================================"; + + my $sk = encode('UTF-8', "Server Key"); + my $c = hmac_sha256($sk, $r); + my $pd = encode('UTF-8', $d); + my $p = hmac_sha256($pd, $c); + my $gd = encode('UTF-8', $d); + my $g = hmac_sha256($gd, $underscore); + my $f = ""; + my $g1 = ""; + my $s1 = ""; + my $f1 = ""; + my $j = 0; + for($j=0; $j= 3) { + Log3 $logdevice,3,"auth_proof : ".$proof; + Log3 $logdevice,3,"auth_return : ".$message; + Log3 $logdevice,3,"====End output========================================="; + }; + + return $message; + } + + if($step eq "session") + { + Log3 $logdevice,3,"auth_token : ".$token; + Log3 $logdevice,3,"====End arguments======================================"; + + my $sk = encode('UTF-8', "Session Key"); + my $dd = encode('UTF-8', $d); + my $protocol_key = hmac_sha256($sk, $dd, $s, $underscore); + +## Test only my $t = "7244ba6f73c8cdc47b232e1311451939"; + my $t = $token; + $t =~ s/([a-fA-F0-9][a-fA-F0-9])/chr(hex($1))/eg; + my $e2 = Crypt::AuthEnc::GCM->new("AES", $protocol_key, $t); + + my $tt = encode('UTF-8', $token); + if($user eq "master") + { + $PASSWD = KeyValue("read","PW_".$logdevice."_".$user."_Service"); ## Das ist der Service Key + $tt = encode('UTF-8', $token.":".$PASSWD); + if ($verbose >= 3) { + Log3 $logdevice,3,"using master : PW_".$logdevice."_".$user."_Service"; + } + } + + my $e2ct = $e2->encrypt_add($tt); + my $authtag = $e2->encrypt_done(); + + $tt = encode_base64($t); + $tt =~ s/\n$//g; # Korrektur: \n am Ende des Strings entfernen, Ursache unbekannt + my $iv = decode('UTF-8', $tt); + + my $aa = encode_base64($authtag); + $aa =~ s/\n$//g; # Korrektur: \n am Ende des Strings entfernen, Ursache unbekannt + $authtag = decode('UTF-8', $aa); + + my $pp = encode_base64($e2ct); + $pp =~ s/\n//g; # Korrektur: \n am Ende des Strings entfernen, Ursache unbekannt + my $payload = decode('UTF-8', $pp); + + my $message = '{"transactionId": "'.$transactionId.'", "iv": "'.$iv.'", "tag": "'.$authtag.'", "payload": "'.$payload.'"}'; + + if ($verbose >= 3) { + Log3 $logdevice,3,"auth_iv : ".$iv; + Log3 $logdevice,3,"auth_authtag : ".$authtag; + Log3 $logdevice,3,"auth_payload : ".$payload; + Log3 $logdevice,3,"auth_return : ".$message; + Log3 $logdevice,3,"====End output========================================="; + }; + + return $message; + } +}; + + +#### Log-abriss vermeiden +sub +addLog($$$) { + my ($logdb, $logdevice, $reading) = @_; # device and reading to be used + my $logentry = ReadingsVal($logdevice,$reading,"invalid reading"); + my $timestamp = strftime "%Y-%m-%d %H:%M:%S", localtime; + +# if ($reading =~ m,state,i) { + if ($reading eq 'state') { + fhem "set ".$logdb." addCacheLine ".$timestamp."|".$logdevice."|addlog|".$logentry."|".$reading."|".$logentry."|"; + } else { + fhem "set ".$logdb." addCacheLine ".$timestamp."|".$logdevice."|addlog|".$reading.": ".$logentry."|".$reading."|".$logentry."|"; + } +} + +1; diff --git a/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/MySQL_dwd_load_Procedure.txt b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/MySQL_dwd_load_Procedure.txt new file mode 100644 index 000000000..5799e0016 --- /dev/null +++ b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/MySQL_dwd_load_Procedure.txt @@ -0,0 +1,1123 @@ +CREATE DEFINER=`fhemuser`@`%` PROCEDURE `dwd_load`(IN var_date DATE, IN display char(10)) +BEGIN + +SET @date:= var_date; +-- die alte Tabelle löschen +DROP TABLE IF EXISTS dwdfull; + +-- eine neue Tabelle anlegen +CREATE TABLE IF NOT EXISTS `dwdfull` ( + `TIMESTAMP` datetime NOT NULL, + `year` int NOT NULL, + `month` int NOT NULL, + `day` int NOT NULL, + `hour` int NOT NULL, + `TTT` float NOT NULL DEFAULT 0, + `DD` float NOT NULL DEFAULT 0, + `VV` float NOT NULL DEFAULT 0, + `N` float NOT NULL DEFAULT 0, + `Neff` float NOT NULL DEFAULT 0, + `R101` float NOT NULL DEFAULT 0, + `RRS1c` float NOT NULL DEFAULT 0, + `SunD1` float NOT NULL DEFAULT 0, + `Rad1h` float NOT NULL DEFAULT 0, + `SunAz` float NOT NULL DEFAULT 0, + `SunAlt` float NOT NULL DEFAULT 0, + `yield` float DEFAULT 0, + `yield_max` float DEFAULT 0, + `forecast` float NOT NULL DEFAULT 0, + PRIMARY KEY (`TIMESTAMP`), + INDEX (`TIMESTAMP`) +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_bin COMMENT='DWD Forecast'; + +-- als erstes die Grundlegenden Daten mit Zeitstempeln erzeugen +-- Rad1h wird als erstes eingetragen +INSERT INTO dwdfull (TIMESTAMP, year, month ,day ,hour ,Rad1h) + SELECT concat(t1.DATE, " ", LPAD(t1.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + year(t1.DATE) AS year, + month(t1.DATE) AS month, + day(t1.DATE) AS day, + t1.HOUR AS hour, + t1.Rad1h + FROM + ( -- fc0 Rad1h ältere Werte eintragen + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + x1.DATE, + x1.HOUR, + h.VALUE AS Rad1h + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + LPAD(REGEXP_SUBSTR(READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_Rad1h' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE,HOUR + ) x1 USING(TIMESTAMP,READING) + ) t1 +ON DUPLICATE KEY UPDATE + Rad1h = t1.Rad1h +; + +INSERT INTO dwdfull (TIMESTAMP, year, month ,day ,hour ,Rad1h) + SELECT concat(t1.DATE, " ", LPAD(t1.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + year(t1.DATE) AS year, + month(t1.DATE) AS month, + day(t1.DATE) AS day, + t1.HOUR AS hour, + t1.Rad1h + FROM + ( -- fc1 Rad1h Werte von morgen eintragen + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + x1.DATE, + x1.HOUR, + h.VALUE AS Rad1h + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + LPAD(REGEXP_SUBSTR(READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_Rad1h' + AND TIMESTAMP >= @date + GROUP BY READING,DATE,HOUR + ) x1 USING(TIMESTAMP,READING) + ) t1 +ON DUPLICATE KEY UPDATE + Rad1h = t1.Rad1h +; + +-- Mit update alle weiteren Spalten füllen +UPDATE dwdfull tt +JOIN + ( -- SunAz + SELECT concat(x1.DATE, " ", LPAD(x1.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS SunAz + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + min(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'Astro' + AND READING = 'SunAz' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + AND hour(TIMESTAMP) >= 6 + AND hour(TIMESTAMP) <= 21 + GROUP BY READING,DATE,HOUR + ) x1 USING(TIMESTAMP,READING) + ) t2 USING(TIMESTAMP) +SET tt.SunAz = t2.SunAz +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 SunAz + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS SunAz + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'Astro' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_SunAz' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t3 USING(TIMESTAMP) +SET tt.SunAz = t3.SunAz +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 SunAz + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS SunAz + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'Astro' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_SunAz' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t3 USING(TIMESTAMP) +SET tt.SunAz = t3.SunAz +; +UPDATE dwdfull tt +JOIN + ( -- SunAlt + SELECT concat(x1.DATE, " ", LPAD(x1.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS SunAlt + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + min(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'Astro' + AND READING = 'SunAlt' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + AND hour(TIMESTAMP) >= 6 + AND hour(TIMESTAMP) <= 21 + GROUP BY READING,DATE,HOUR + ) x1 USING(TIMESTAMP,READING) + ) t3 USING(TIMESTAMP) +SET tt.SunAlt = t3.SunAlt +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 SunAlt + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS SunAlt + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'Astro' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_SunAlt' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t3 USING(TIMESTAMP) +SET tt.SunAlt = t3.SunAlt +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 SunAlt + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS SunAlt + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'Astro' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_SunAlt' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t3 USING(TIMESTAMP) +SET tt.SunAlt = t3.SunAlt +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 SunD1 + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS SunD1 + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_SunD1' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t4 USING(TIMESTAMP) +SET tt.SunD1 = t4.SunD1 +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 SunD1 + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS SunD1 + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_SunD1' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t4 USING(TIMESTAMP) +SET tt.SunD1 = t4.SunD1 +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 Neff + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS Neff + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_Neff' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t5 USING(TIMESTAMP) +SET tt.Neff = t5.Neff +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 Neff + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS Neff + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_Neff' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t5 USING(TIMESTAMP) +SET tt.Neff = t5.Neff +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 VV + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS VV + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_VV' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t6 USING(TIMESTAMP) +SET tt.VV = t6.VV +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 VV + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS VV + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_VV' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t5 USING(TIMESTAMP) +SET tt.VV = t5.VV +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 DD + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS DD + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_DD' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t7 USING(TIMESTAMP) +SET tt.DD = t7.DD +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 DD + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS DD + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_DD' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t5 USING(TIMESTAMP) +SET tt.DD = t5.DD +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 TTT + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS TTT + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_TTT' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t8 USING(TIMESTAMP) +SET tt.TTT = t8.TTT +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 TTT + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS TTT + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_TTT' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t5 USING(TIMESTAMP) +SET tt.TTT = t5.TTT +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 R101 + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS R101 + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_R101' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t9 USING(TIMESTAMP) +SET tt.R101 = t9.R101 +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 R101 + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS R101 + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_R101' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t5 USING(TIMESTAMP) +SET tt.R101 = t5.R101 +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 N + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS N + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_N' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t10 USING(TIMESTAMP) +SET tt.N = t10.N +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 N + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS N + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_N' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t5 USING(TIMESTAMP) +SET tt.N = t5.N +; + +UPDATE dwdfull tt +JOIN + ( -- fc0 RRS1c + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS RRS1c + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc0_([6-9]|1[0-9]|2[0-1])_RRS1c' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t11 USING(TIMESTAMP) +SET tt.RRS1c = t11.RRS1c +; + +UPDATE dwdfull tt +JOIN + ( -- fc1 RRS1c + SELECT concat(x1.DATE, " ", LPAD(REGEXP_SUBSTR(h.READING, '[6-9]|1[0-9]|2[0-1]'), 2, 0), ":00:00") AS TIMESTAMP, + h.VALUE AS RRS1c + FROM history h + INNER JOIN + (SELECT date(DATE_ADD(TIMESTAMP,INTERVAL +1 DAY)) AS DATE, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'DWD_Forecast' + AND READING REGEXP 'fc1_([6-9]|1[0-9]|2[0-1])_RRS1c' + AND TIMESTAMP >= @date + GROUP BY READING,DATE + ) x1 USING(TIMESTAMP,READING) + ) t5 USING(TIMESTAMP) +SET tt.RRS1c = t5.RRS1c +; + +UPDATE dwdfull tt +JOIN + ( -- yield from Plenticore with Accu + -- start left join + SELECT TIMESTAMP, + WR.yield AS WR, + Speicher.yield AS Speicher, + cast( -- validate yield + if((Speicher.yield IS NULL), + WR.yield, + if((WR.yield IS NULL),Speicher.yield,WR.yield + Speicher.yield) + ) + AS DECIMAL(6)) AS yield + FROM + ( -- WR + SELECT TIMESTAMP, + if(t1.DELTA > 6,0,t1.DIFF) AS yield + FROM + (SELECT TIMESTAMP,READING,VALUE, + if(@diff = 0,0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR,@delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x1.DATE, " ", LPAD(x1.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x1.DATE, + x1.HOUR, + h.READING, + h.VALUE, + @diff:=0,@delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'SW_Yield_Daily' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE,HOUR + ) x1 + USING(TIMESTAMP,READING) + WHERE x1.HOUR >= 6 + AND x1.HOUR <= 21 + ) x2 + ) t1 + ) WR + left JOIN + ( -- Speicher full join from DCto and DCfrom + SELECT TIMESTAMP, DCto, DCfrom, + cast( + if((DCfrom IS NULL), + DCto, + if((DCto IS NULL), DCfrom * -1, DCto - DCfrom) + )*0.85 AS DECIMAL(6) + ) AS yield + FROM + (SELECT TIMESTAMP, y1.DCto, y2.DCfrom + FROM + (-- DCto + SELECT TIMESTAMP, + if(t2.DELTA > 6, 0, t2.DIFF) AS DCto, + t2.DELTA + FROM + (SELECT TIMESTAMP, + READING, + VALUE, + if(@diff = 0, 0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR, @delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x3.DATE, " ", LPAD(x3.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x3.DATE, + x3.HOUR, + h.READING, + h.VALUE, + @diff:=0, @delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'Battery_Total_DC_ChargeEnergy_DCsideToBattery' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY)) + GROUP BY READING,DATE,HOUR + ) x3 + USING(TIMESTAMP,READING) + WHERE x3.HOUR >= 6 + AND x3.HOUR <= 21 + ) x4 + ) t2 + ) y1 -- DCto + LEFT JOIN + (-- DCfrom + SELECT TIMESTAMP, + if(t2.DELTA > 6, 0, t2.DIFF) AS DCfrom, + t2.DELTA + FROM + (SELECT TIMESTAMP, + READING, + VALUE, + if(@diff = 0, 0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR, @delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x3.DATE, " ", LPAD(x3.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x3.DATE, + x3.HOUR, + h.READING, + h.VALUE, @diff:=0,@delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'Battery_Total_DC_DischargeEnergy_DCsideFromBattery' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY)) + GROUP BY READING,DATE,HOUR + ) x3 + USING(TIMESTAMP,READING) + WHERE x3.HOUR >= 6 + AND x3.HOUR <= 21 + ) x4 + ) t2 + ) y2 -- DCfrom + USING(TIMESTAMP) -- LEFT JOIN + + UNION + + SELECT TIMESTAMP, y1.DCto, y2.DCfrom + FROM + (-- DCto + SELECT TIMESTAMP, + if(t2.DELTA > 6, 0, t2.DIFF) AS DCto, + t2.DELTA + FROM + (SELECT TIMESTAMP, + READING, + VALUE, + if(@diff = 0, 0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR, @delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x3.DATE, " ", LPAD(x3.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x3.DATE, + x3.HOUR, + h.READING, + h.VALUE, + @diff:=0,@delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'Battery_Total_DC_ChargeEnergy_DCsideToBattery' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY)) + GROUP BY READING,DATE,HOUR + ) x3 + USING(TIMESTAMP,READING) + WHERE x3.HOUR >= 6 + AND x3.HOUR <= 21 + ) x4 + ) t2 + ) y1 -- DCto + RIGHT JOIN + (-- DCfrom + SELECT TIMESTAMP, + if(t2.DELTA > 6, 0, t2.DIFF) AS DCfrom, + t2.DELTA + FROM + (SELECT TIMESTAMP, + READING, + VALUE, + if(@diff = 0, 0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR, @delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x3.DATE, " ", LPAD(x3.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x3.DATE, + x3.HOUR, + h.READING, + h.VALUE, + @diff:=0,@delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'Battery_Total_DC_DischargeEnergy_DCsideFromBattery' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY)) + GROUP BY READING,DATE,HOUR + ) x3 + USING(TIMESTAMP,READING) + WHERE x3.HOUR >= 6 + AND x3.HOUR <= 21 + ) x4 + ) t2 + ) y2 -- DCfrom + USING(TIMESTAMP) -- RIGHT JOIN + ) y3 + + ) Speicher -- full join + USING(TIMESTAMP) + -- end left join + + UNION -- for left and right join + + -- start right join + SELECT TIMESTAMP, + WR.yield AS WR, + Speicher.yield AS Speicher, + cast( -- validate yield + if((Speicher.yield IS NULL), + WR.yield, + if((WR.yield IS NULL),Speicher.yield,WR.yield + Speicher.yield) + ) + AS DECIMAL(6)) AS yield + FROM + ( -- WR + SELECT TIMESTAMP, + if(t1.DELTA > 6,0,t1.DIFF) AS yield + FROM + (SELECT TIMESTAMP,READING,VALUE, + if(@diff = 0,0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR,@delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x1.DATE, " ", LPAD(x1.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x1.DATE, + x1.HOUR, + h.READING, + h.VALUE, + @diff:=0,@delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'SW_Yield_Daily' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY) + ) + GROUP BY READING,DATE,HOUR + ) x1 + USING(TIMESTAMP,READING) + WHERE x1.HOUR >= 6 + AND x1.HOUR <= 21 + ) x2 + ) t1 + ) WR + right JOIN + ( -- Speicher full join from DCto and DCfrom + SELECT TIMESTAMP, DCto, DCfrom, + cast( + if((DCfrom IS NULL), + DCto, + if((DCto IS NULL), DCfrom * -1, DCto - DCfrom) + )*0.85 AS DECIMAL(6) + ) AS yield + FROM + (SELECT TIMESTAMP, y1.DCto, y2.DCfrom + FROM + (-- DCto + SELECT TIMESTAMP, + if(t2.DELTA > 6, 0, t2.DIFF) AS DCto, + t2.DELTA + FROM + (SELECT TIMESTAMP, + READING, + VALUE, + if(@diff = 0, 0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR, @delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x3.DATE, " ", LPAD(x3.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x3.DATE, + x3.HOUR, + h.READING, + h.VALUE, + @diff:=0, @delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'Battery_Total_DC_ChargeEnergy_DCsideToBattery' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY)) + GROUP BY READING,DATE,HOUR + ) x3 + USING(TIMESTAMP,READING) + WHERE x3.HOUR >= 6 + AND x3.HOUR <= 21 + ) x4 + ) t2 + ) y1 -- DCto + LEFT JOIN + (-- DCfrom + SELECT TIMESTAMP, + if(t2.DELTA > 6, 0, t2.DIFF) AS DCfrom, + t2.DELTA + FROM + (SELECT TIMESTAMP, + READING, + VALUE, + if(@diff = 0, 0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR, @delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x3.DATE, " ", LPAD(x3.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x3.DATE, + x3.HOUR, + h.READING, + h.VALUE, @diff:=0,@delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'Battery_Total_DC_DischargeEnergy_DCsideFromBattery' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY)) + GROUP BY READING,DATE,HOUR + ) x3 + USING(TIMESTAMP,READING) + WHERE x3.HOUR >= 6 + AND x3.HOUR <= 21 + ) x4 + ) t2 + ) y2 -- DCfrom + USING(TIMESTAMP) -- LEFT JOIN + + UNION + + SELECT TIMESTAMP, y1.DCto, y2.DCfrom + FROM + (-- DCto + SELECT TIMESTAMP, + if(t2.DELTA > 6, 0, t2.DIFF) AS DCto, + t2.DELTA + FROM + (SELECT TIMESTAMP, + READING, + VALUE, + if(@diff = 0, 0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR, @delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x3.DATE, " ", LPAD(x3.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x3.DATE, + x3.HOUR, + h.READING, + h.VALUE, + @diff:=0,@delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'Battery_Total_DC_ChargeEnergy_DCsideToBattery' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY)) + GROUP BY READING,DATE,HOUR + ) x3 + USING(TIMESTAMP,READING) + WHERE x3.HOUR >= 6 + AND x3.HOUR <= 21 + ) x4 + ) t2 + ) y1 -- DCto + RIGHT JOIN + (-- DCfrom + SELECT TIMESTAMP, + if(t2.DELTA > 6, 0, t2.DIFF) AS DCfrom, + t2.DELTA + FROM + (SELECT TIMESTAMP, + READING, + VALUE, + if(@diff = 0, 0, cast((VALUE-@diff) AS DECIMAL(10))) AS DIFF, + @diff:=VALUE AS curr_V, + TIMESTAMPDIFF(HOUR, @delta,TIMESTAMP) AS DELTA, + @delta:=TIMESTAMP AS curr_T + FROM + (SELECT concat(x3.DATE, " ", LPAD(x3.HOUR, 2, 0), ":00:00") AS TIMESTAMP, + x3.DATE, + x3.HOUR, + h.READING, + h.VALUE, + @diff:=0,@delta:=NULL + FROM history h + INNER JOIN + (SELECT date(TIMESTAMP) AS DATE, + hour(TIMESTAMP) AS HOUR, + max(TIMESTAMP) AS TIMESTAMP, + READING + FROM history + WHERE DEVICE = 'WR_1' + AND READING = 'Battery_Total_DC_DischargeEnergy_DCsideFromBattery' + AND ( TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(365-30) DAY) + OR TIMESTAMP > DATE_ADD(@date,INTERVAL -(2*365+30) DAY) + AND TIMESTAMP < DATE_ADD(@date,INTERVAL -(2*365-30) DAY)) + GROUP BY READING,DATE,HOUR + ) x3 + USING(TIMESTAMP,READING) + WHERE x3.HOUR >= 6 + AND x3.HOUR <= 21 + ) x4 + ) t2 + ) y2 -- DCfrom + USING(TIMESTAMP) -- RIGHT JOIN + ) y3 + + ) Speicher -- full join + USING(TIMESTAMP) + -- end right join + + -- UNION end + + ) t12 USING(TIMESTAMP) +SET tt.yield = t12.yield +; + +-- Ermittle Ertrags Maximum der letzten 30 Tage um die Prognose zu limitieren +UPDATE dwdfull tt +JOIN + ( -- yield_max und Schnee Begrenzung + SELECT hour -1 AS hour, + if(yield_min > yield_max*0.04, yield_max, yield_min) AS yield_max + FROM ( + SELECT hour, + -- Ist der letzte Tag 90% kleiner als der Durchschnitt der letzten Tage, + -- dann liegt Schnee auf den Modulen + cast(max(if(yield > 0,yield,0)) AS DECIMAL(6)) AS yield_max + FROM dwdfull + WHERE TIMESTAMP > DATE_ADD(@date,INTERVAL -30 DAY) + GROUP BY hour ) x1 + INNER JOIN + -- Wie waren die letzten Tag? Extrem kleine Werte bedeuten abgedeckte Module, + -- was die Ki_Prognose nicht so schnell lernen kann. + (SELECT hour, + cast(min(if(yield > 0,yield,0)) AS DECIMAL(6)) AS yield_min + FROM dwdfull + WHERE TIMESTAMP > DATE_ADD(@date,INTERVAL -1 DAY) + AND TIMESTAMP < @date + GROUP BY hour + ) X2 USING(hour) + ) t2 USING(hour) +SET tt.yield_max = t2.yield_max +WHERE TIMESTAMP > @date +; + +IF display = 'show' THEN + select * from dwdfull LIMIT 3000; +ELSE + select now(); +END IF +; + +END \ No newline at end of file diff --git a/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/PV_KI_Prognose.py b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/PV_KI_Prognose.py new file mode 100644 index 000000000..205ee3649 --- /dev/null +++ b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/PV_KI_Prognose.py @@ -0,0 +1,375 @@ +#!/usr/bin/python3 +# coding: utf-8 + +# Version die eine Vorhersage auf Basis der Messwerte - Analyseversion +# Analyse via Random Forest Regressor + +import fhem +import json + +# Einlesen der Übergabeparameter +import sys +DbLog = sys.argv[1] +web = sys.argv[2] +webport = 8083 +DbRep = sys.argv[3] +WRname = sys.argv[4] +WRread = sys.argv[5] + + +try: + with open('/opt/fhem/python/pwd_fhem.json', 'r') as f: + credentials=json.load(f) + fhem_user = credentials["username"] + fhem_pass = credentials["password"] + fh = fhem.Fhem(web, protocol="http", port=webport, username=fhem_user, password=fhem_pass) + print("PV_KI_Prognose running - start") + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running start") +except Exception as e: + + print('Something went wrong: {}'.format(e)) + + +try: + with open('/opt/fhem/python/pwd_sql.json', 'r') as f: + credentials=json.load(f) +except Exception as e: + + print('Something went wrong: {}'.format(e)) + + +verbose = fh.get_device_attribute(DbRep, "verbose") + +if (verbose >= 4): + print("PV_KI_Prognose running - start") + print("PV_KI_Prognose DbLog ",DbLog,"/fhem") + print("PV_KI_Prognose Fhem ",web,":",webport) + + +Inverter_Max_Power = fh.get_device_reading("WR_1_Speicher_1_ExternControl", "SpeicherMidday_Inverter_Max_Power") +# Inverter_Max_Power = fh.get_device_reading(WRname, "SpeicherMidday_Inverter_Max_Power") + +if (verbose >= 4): + print("Inverter_Max_Power {}".format(Inverter_Max_Power["Value"])) + + +import pandas as pd +import numpy as np +from sqlalchemy import create_engine +import pymysql + +# betrifft beide relevanten Tabellen +db_connection_str = 'mysql+pymysql://'+credentials["username"]+':'+credentials["password"]+'@'+DbLog+'/fhem' +db_connection = create_engine(db_connection_str) + +if (verbose >= 3): + print("PV_KI_Prognose running - connected to "+DbLog) + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running connected to "+DbLog) + +import datetime +from datetime import date, timedelta + +today = datetime.datetime.now() +de = today.strftime("%Y-%m-%d 00:00:00") +# print(de) + +# alle Wetterdaten ohne den start Tag der Prognose +dflern = pd.read_sql('SELECT * FROM dwdfull WHERE TIMESTAMP < '+"'"+de+"'", con=db_connection) +dfask = pd.read_sql('SELECT * FROM dwdfull WHERE TIMESTAMP >= '+"'"+de+"'", con=db_connection) + +dfhour_start = pd.read_sql('SELECT min(hour(TIMESTAMP)) AS VALUE FROM dwdfull WHERE date(TIMESTAMP) = '+"'"+today.strftime("%Y-%m-%d")+"'", con=db_connection) +dfhour_stop = pd.read_sql('SELECT max(hour(TIMESTAMP)) AS VALUE FROM dwdfull WHERE date(TIMESTAMP) = '+"'"+today.strftime("%Y-%m-%d")+"'", con=db_connection) +dfhours = dfhour_stop['VALUE'].values[0] - dfhour_start['VALUE'].values[0] +1 + +if (verbose >= 3): + print("PV_KI_Prognose running - dwdfull read from DbLog "+DbLog) + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running dwdfull read from DbLog "+DbLog) + +# Rad1h = Globale Einstrahlung +# TTT = Temperature 2m above surface [°C] +# Neff = Effektive Wolkendecke +# R101 = Niederschlagswahrscheinlichkeit> 0,1 mm während der letzten Stunde +# SunD1 = Sonnenscheindauer während der letzten Stunde +# VV = Sichtweite +# N = Gesamte Wolkendecke +# DD = Windrichtung +# RRS1c = Schneeregen-Äquivalent während der letzten Stunde + +columns = ['Rad1h','Neff','R101','TTT','DD','SunAz','SunAlt','SunD1','VV','N','RRS1c'] + +# jetzt gehen wir die Analyse an +from sklearn.ensemble import RandomForestRegressor + +if (verbose >= 3): + print("PV_KI_Prognose running - RandomForestRegressor loading") + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running RandomForestRegressor loading") + +clf = RandomForestRegressor(n_estimators = 4000, bootstrap=True, random_state = 42) + +if (verbose >= 3): + print("PV_KI_Prognose running - RandomForestRegressor loaded") + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running RandomForestRegressor loaded") + +# train the model +df = dflern[:] + +if (verbose >= 3): + print("PV_KI_Prognose running - RandomForestRegressor trained") + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running RandomForestRegressor trained") + +# bring das gelernte in Bezug zum yield +clf.fit(df[columns], df['yield']) + +if (verbose >= 3): + print("PV_KI_Prognose running - RandomForestRegressor fitted with yield") + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running RandomForestRegressor fitted with yield") + +if (verbose >= 4): + print("PV_KI_Prognose running - RandomForestRegressor read statistics") + # Auslesen und Anzeigen von Statistiken + # Get numerical feature importances + importances = list(clf.feature_importances_) + # List of tuples with variable and importance + feature_importances = [(feature, round(importance, 2)) for feature, importance in zip(columns, importances)] + # Sort the feature importances by most important first + feature_importances = sorted(feature_importances, key = lambda x: x[1], reverse = True) + # Print out the feature and importances + [print('Variable: {:20} Importance: {}'.format(*pair)) for pair in feature_importances] + +# Immer einen Forecast für heute und morgen erstellen +start_date = datetime.datetime.now() +delta = timedelta(days=1) +end_date = start_date + delta + +Prognose_faktor = 1 # Falls die Prognose generell daneben liegt kann der Faktor verwendet werden + +loop_hour = 0 +loop_date = start_date +loop_count = 0 + + +while loop_date <= end_date: + # Daten Tagesmaximum + middayhigh = 0 # Ein Merker, ob das Tagesmaximum überschritten wird + middayhigh_start = "00:00" + middayhigh_stop = "00:00" + middayhigh_tmp = 0 + middayhigh_start_tmp = 0 + middayhigh_stop_tmp = 0 + + # Pro Prognosetag die Tages Zähler zurück setzen + Prognose_max = 0 + Prognose_pre = 0 + Prognose_4h = 0 + Prognose_rest = 0 + Prognose_morning = 0 + Prognose_afternoon = 0 + Prognose_day = 0 + + # Löschen der bisherigen Prognose von diesem + sql = "DELETE FROM history WHERE DEVICE = '"+WRname+"' AND TIMESTAMP >= '"+str(loop_date.strftime("%Y-%m-%d"))+" 00:00:00' AND READING = '"+WRread+str(loop_count)+"' ;" + db_connection.execute(str(sql)) + + if (verbose >= 3): + print("PV_KI_Prognose running - old forecast deleted") + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running old forecast deleted") + + New_year = str(loop_date.year) + New_month = str(loop_date.month) + New_day = str(loop_date.day) + New_hour = loop_date.hour + + if (verbose >= 4): + print("--------------------------------------------") + print("Forecast fc%d %s" % (loop_count,loop_date.strftime("%Y-%m-%d"))) + + fcolumns = columns[:] + fcolumns.insert(0, 'TIMESTAMP') + fcolumns.append('yield') + + # hole die Werte für den Tag, der bearbeitet wird + query = 'year == "'+New_year+'" and month == "'+New_month+'" and day == "'+New_day+'"' + dfq = dfask.query(query)[fcolumns].reset_index() + + # erstelle die Prognose für den Tag + predict = clf.predict(dfq[columns]) + + # bearbeite jede einzelne Stunde der Prognose + + Prognose_pre = 0 + + if (verbose >= 3): + print("PV_KI_Prognose running - start forecast") + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running start forecast") + + for loop_hour in range(dfhours): + + parms = dfq.iloc[loop_hour].values + list = parms.reshape(1, -1) + date = loop_date.strftime("%Y-%m-%d") + + # Hier wird die Prognose noch etwas angehoben, da bisher zu niedrige Werte prognostiziert werden. + # Das kann sich mit mehr Vergleichsdaten noch ändern + # + # Zusätzlich wird noch interpoliert, wodurch die Summen korrekter erscheinen + Prognose = int(round((Prognose_pre + predict[loop_hour]*Prognose_faktor)/2)) + Prognose_pre = int(round(predict[loop_hour]*Prognose_faktor)) + + # Zu kleine Werte werden verworfen + if (Prognose < 20): + if (verbose >= 4): + print("Forecast value to smale") + Prognose = 0 + + # Zu große Werte werden limitiert + # Achtung, die yield Prognose Werte sind Angaben zum Ende der Stunde + if (Prognose > 0): + timestamp = date+" %02d:00:00" % (dfhour_start['VALUE'].values[0]+loop_hour) + Limit = int(round(dfask.loc[dfask['TIMESTAMP'] == timestamp].yield_max.values[0],0)) + if (verbose >= 4): + # Hier wird beim Anzeigen der Wert um eine Stunde vorher angezeigt + print(dfhour_start['VALUE'].values[0]+loop_hour-1,Prognose,Limit) + + if (Prognose > Limit): + if (verbose >= 4): + print("Forecast value to high : " + str(Prognose)+" > " + str(Limit)) + Prognose = Limit + + ## hier beginnt die Ermittung für das Mittagshoch + if ( middayhigh == 0 and Prognose > Inverter_Max_Power["Value"] ): + middayhigh = 1 + # der Start wird auf eine Stunde vorher vorverlegt + middayhigh_start_tmp = loop_hour-1 + ## einige Durchläufe später endet hier das Mittagshoch + if ( middayhigh == 1 and Prognose < Inverter_Max_Power["Value"] and middayhigh_stop_tmp == 0 ): + middayhigh_stop_tmp = loop_hour + ## prüfen, ob es einen kurzen Leistungseinbruch gegeben hat, der soll übersprungen werden + if ( middayhigh == 1 and Prognose > Inverter_Max_Power["Value"] and middayhigh_stop != "00:00" ): + # da war ein kurzer Einbruch, es sollte noch länger sein. + middayhigh_stop_tmp = 0 + + ## hier ist dann das richtige Ende vom Mittagshoch + if ( middayhigh == 1 + and middayhigh_stop_tmp != 0 + and middayhigh_stop_tmp == loop_hour): + + ## Wie lang ist das gefundene Mittagshoch + middayhigh_tmp = middayhigh_stop_tmp - middayhigh_start_tmp + if ( middayhigh_tmp > 4 ): # das Middayhigh wird zu lang + if (verbose >= 4): # die bisherigen Zeiten ausgeben + print("Middayhigh to long-------------------") + print("Middayhigh_start %02d:00" % (dfhour_start['VALUE'].values[0]+middayhigh_start_tmp)) + print("Middayhigh_stop %02d:00" % (dfhour_start['VALUE'].values[0]+middayhigh_stop_tmp)) + print("--------------------------------------------") + ## jetzt wird die Zeit vom Mittagshoch verkürzt + ## beim Start etwas mehr kürzen, als zum Ende hin + middayhigh_start_tmp = middayhigh_start_tmp + round(middayhigh_tmp/3-0.2) # es wird um ganze Stunden verkürzt + middayhigh_stop_tmp = middayhigh_stop_tmp - round(middayhigh_tmp/6-0.2) + if (verbose >= 4): # melde die Verkürzung + print("Middayhigh cut about %d h" % (round(middayhigh_tmp/3-0.2)+round(middayhigh_tmp/6-0.2)) ) + + ## Die neuen Mittagshochzeiten formatieren + middayhigh_start = "%02d:00" % (dfhour_start['VALUE'].values[0]+middayhigh_start_tmp) + middayhigh_stop = "%02d:00" % (dfhour_start['VALUE'].values[0]+middayhigh_stop_tmp) + + ## End if (middayhigh == 1... + + ### Bildung der Prognose Summen ### + + if (Prognose > Prognose_max): + Prognose_max = Prognose + Prognose_max_time = "%02d:00" % (dfhour_start['VALUE'].values[0]+loop_hour-1) + + # Hier wird die Summe der nächsten 4 h gebildet + if ( dfhour_start['VALUE'].values[0]+loop_hour > New_hour + and dfhour_start['VALUE'].values[0]+loop_hour <= New_hour+3): + Prognose_4h += Prognose + + # Hier wird die Summe für den Resttag gebildet + if (dfhour_start['VALUE'].values[0]+loop_hour > New_hour): + Prognose_rest += Prognose + + # Hier wird die Summe für den Vormittag gebildet + if (dfhour_start['VALUE'].values[0]+loop_hour < 13): + Prognose_morning += Prognose + + # Hier wird die Summe für den Nachmittag gebildet + if (dfhour_start['VALUE'].values[0]+loop_hour >= 13): + Prognose_afternoon += Prognose + + # Summe für den ganzen Tag + Prognose_day += Prognose + + ###################################################################### + + # Die Prognose anzeigen und in die dwdfull Tabelle eintragen + if (loop_hour-1 >= 0): + + # Achtung, der Wert wird um eine Stunde früher in die Datenbank eingetragen + timestamp = date+" "+"%02d:00:00" % (dfhour_start['VALUE'].values[0]+loop_hour-1) + sql = "UPDATE dwdfull SET forecast ="+str(Prognose)+" WHERE TIMESTAMP = '"+timestamp+"' AND hour ="+str(dfhour_start['VALUE'].values[0]+loop_hour-1)+";" + db_connection.execute(str(sql)) + + sql = "INSERT INTO history (TIMESTAMP, DEVICE, TYPE ,READING ,VALUE) VALUES('"+timestamp+"','"+WRname+"','addlog','"+WRread+str(loop_count)+"','"+str(Prognose)+"') ;" + db_connection.execute(str(sql)) + + # Die Prognose Werte ins FHEM schreiben + reading = WRread+str(loop_count)+"_%02d" % (dfhour_start['VALUE'].values[0]+loop_hour-1) + fh.send_cmd("setreading "+WRname+" "+reading+" "+str(Prognose)) + + if (verbose >= 3): + print("%s %02d %d" % (reading,dfhour_start['VALUE'].values[0]+loop_hour-1,Prognose)) + + # Zum Ende der Prognose alle Werte in die readings schreiben + if (loop_hour == dfhours-1): + if (loop_date.day == start_date.day): + # Für den aktuellen Tag diese Werte schreiben + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_max "+str(Prognose_max)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_max_time "+str(Prognose_max_time)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_middayhigh "+str(middayhigh)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_middayhigh_start "+str(middayhigh_start)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_middayhigh_stop "+str(middayhigh_stop)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_4h "+str(Prognose_4h)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_rest "+str(Prognose_rest)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_morning "+str(Prognose_morning)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_afternoon "+str(Prognose_afternoon)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_day "+str(Prognose_day)) + + if (loop_date.day != start_date.day): + # für weiter Prognosen sind nur diese Werte relevant + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_max "+str(Prognose_max)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_max_time "+str(Prognose_max_time)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_middayhigh "+str(middayhigh)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_middayhigh_start "+str(middayhigh_start)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_middayhigh_stop "+str(middayhigh_stop)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_morning "+str(Prognose_morning)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_afternoon "+str(Prognose_afternoon)) + fh.send_cmd("setreading "+WRname+" "+WRread+str(loop_count)+"_day "+str(Prognose_day)) + + if (verbose >= 3): + # für das Logging noch etwas formatieren + print("--------------------------------------------") + print("max off/at",Prognose_max,Prognose_max_time) + print("Middayhigh_start",middayhigh_start) + print("Middayhigh_stop ",middayhigh_stop) + print("4h ",Prognose_4h) + print("rest ",Prognose_rest) + print("morning ",Prognose_morning) + print("afternoon ",Prognose_afternoon) + print("day ",Prognose_day) + print("--------------------------------------------") + + if (verbose >= 3): + print("PV_KI_Prognose running - forecast written to FHEM") + fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose running forecast written") + + loop_date += delta + loop_count += 1 + + +if (verbose >= 3): + print("PV_KI_Prognose done") + +# Zum Schluss noch einen Trigger ins FHEM schreiben +fh.send_cmd("setreading "+DbRep+" PV_KI_Prognose done") + diff --git a/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/RAW_LogDBRep_PV_KI_Prognose.txt b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/RAW_LogDBRep_PV_KI_Prognose.txt new file mode 100644 index 000000000..8125c5bea --- /dev/null +++ b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/RAW_LogDBRep_PV_KI_Prognose.txt @@ -0,0 +1,16 @@ +defmod LogDBRep_PV_KI_Prognose DbRep LogDB +attr LogDBRep_PV_KI_Prognose DbLogExclude .* +attr LogDBRep_PV_KI_Prognose comment Version 2023.02.23 12:00\ +\ +Hier wird die Vorbereitung für die KI PV-Leistungsprognose durchgeführt\ +\ +sqlCmd call dwd_load(curdate(),'none');;\ +[none|show] zum Anzeigen des Ergebnisses\ +\ +executeAfterProc:\ + +attr LogDBRep_PV_KI_Prognose executeAfterProc "/opt/fhem/python/bin/PV_KI_Prognose.py 192.168.178.40 192.168.178.40 LogDBRep_PV_KI_Prognose WR_ctl Yield_fc" +attr LogDBRep_PV_KI_Prognose room System +attr LogDBRep_PV_KI_Prognose verbose 3 + +setstate LogDBRep_PV_KI_Prognose 2024-01-25 14:07:24 sqlCmd call dwd_load(curdate(),'none');; \ No newline at end of file diff --git a/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/pwd_fhem.json b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/pwd_fhem.json new file mode 100644 index 000000000..eac95acc0 --- /dev/null +++ b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/pwd_fhem.json @@ -0,0 +1,4 @@ +{ + "username": "< Benutzername zum FHEM >", + "password": "< Passwort zum FHEM >" +} diff --git a/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/pwd_sql.json b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/pwd_sql.json new file mode 100644 index 000000000..7287b5012 --- /dev/null +++ b/fhem/contrib/ch.eick/Photovoltaik/KI_Prognose/pwd_sql.json @@ -0,0 +1,4 @@ +{ + "username": "< fhemuser zum MySQL >", + "password": "< Passwort zum MySQL >" +}