-
Notifications
You must be signed in to change notification settings - Fork 1
/
weather.sql
executable file
·286 lines (235 loc) · 8.88 KB
/
weather.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
-- phpMyAdmin SQL Dump
-- version 4.1.14
-- http://www.phpmyadmin.net
--
-- Host: localhost
-- Generation Time: Aug 01, 2014 at 04:24 PM
-- Server version: 5.5.37-MariaDB
-- PHP Version: 5.5.13
SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO";
SET time_zone = "+00:00";
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8 */;
--
-- Database: `weather`
--
CREATE DATABASE IF NOT EXISTS `weather` DEFAULT CHARACTER SET latin1 COLLATE latin1_swedish_ci;
USE `weather`;
-- --------------------------------------------------------
--
-- Stand-in structure for view `historyvalues`
--
CREATE TABLE IF NOT EXISTS `historyvalues` (
`id` int(10) unsigned
,`timestamp` datetime
,`packettype` int(10) unsigned
,`stationid` int(10) unsigned
,`sid` int(10) unsigned
,`value` double
);
-- --------------------------------------------------------
--
-- Table structure for table `hourly`
--
CREATE TABLE IF NOT EXISTS `hourly` (
`stations_id` int(11) NOT NULL,
`midnight` int(11) NOT NULL,
`hour` int(11) NOT NULL,
`packets_id` int(11) NOT NULL,
PRIMARY KEY (`stations_id`,`midnight`,`hour`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
-- --------------------------------------------------------
--
-- Table structure for table `packetdump`
--
CREATE TABLE IF NOT EXISTS `packetdump` (
`pid` int(10) unsigned NOT NULL,
`http_id` varchar(5) DEFAULT NULL,
`payload` tinyblob,
`packettype` int(10) unsigned DEFAULT NULL,
PRIMARY KEY (`pid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
--
-- Table structure for table `packets`
--
CREATE TABLE IF NOT EXISTS `packets` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT COMMENT 'unique id',
`timestamp` datetime NOT NULL COMMENT 'date/time of packet',
`packettype` int(10) unsigned NOT NULL COMMENT 'packetypes.id',
`stationid` int(10) unsigned NOT NULL,
PRIMARY KEY (`id`),
KEY `Index_2` (`timestamp`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 ;
-- --------------------------------------------------------
--
-- Table structure for table `packettypes`
--
CREATE TABLE IF NOT EXISTS `packettypes` (
`id` int(10) unsigned NOT NULL,
`name` varchar(45) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
-- --------------------------------------------------------
--
-- Table structure for table `records`
--
CREATE TABLE IF NOT EXISTS `records` (
`stations_id` int(11) NOT NULL,
`sid` int(11) NOT NULL,
`max_flag` bit(1) NOT NULL,
`pid` int(11) NOT NULL,
`value` double DEFAULT NULL,
PRIMARY KEY (`stations_id`,`sid`,`max_flag`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
-- --------------------------------------------------------
--
-- Table structure for table `sensordates`
--
CREATE TABLE IF NOT EXISTS `sensordates` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`name` varchar(45) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1 AUTO_INCREMENT=1 ;
INSERT INTO `sensordates` (`name`) VALUES('Last Rain Reset');
-- --------------------------------------------------------
--
-- Table structure for table `sensordatevalues`
--
CREATE TABLE IF NOT EXISTS `sensordatevalues` (
`pid` int(10) unsigned NOT NULL,
`did` int(10) unsigned NOT NULL,
`date` datetime NOT NULL,
`prior_value` double NOT NULL,
PRIMARY KEY (`did`,`pid`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
-- --------------------------------------------------------
--
-- Table structure for table `sensors`
--
CREATE TABLE IF NOT EXISTS `sensors` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`name` varchar(45) NOT NULL,
`format` varchar(45) DEFAULT NULL,
`valtype` int(10) unsigned DEFAULT NULL,
`digits` int(10) unsigned DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 AUTO_INCREMENT=1 ;
INSERT INTO `sensors` VALUES
(1, 'Sample Time', '', 0, 0),
(2, 'Inside Temp', '', 0, 1),
(3, 'Inside Humidity', '', 0, 0),
(4, 'Outside Temp', NULL, NULL, 1),
(5, 'Outside Humidity', NULL, NULL, 0),
(6, 'Barometric Pressure', NULL, NULL, 2),
(7, 'Wind Direction', NULL, NULL, 1),
(8, 'Wind Speed', NULL, NULL, 1),
(9, 'Rainfall Total', NULL, NULL, 2),
(10, 'Rainfall 1H', NULL, NULL, 2),
(11, 'Rainfall 24H', NULL, NULL, 2),
(12, 'Rainfall Wk', NULL, NULL, 2),
(13, 'Rainfall Mo', NULL, NULL, 2),
(14, 'Wind Chill', NULL, NULL, 1),
(15, 'Wind Gust', NULL, NULL, 1),
(16, 'Dew Point', NULL, NULL, 1),
(17, 'Unknown history value', NULL, NULL, 2);
-- --------------------------------------------------------
--
-- Table structure for table `sensorvalues`
--
CREATE TABLE IF NOT EXISTS `sensorvalues` (
`id` int(10) unsigned NOT NULL COMMENT 'packets.id',
`sid` int(10) unsigned NOT NULL COMMENT 'sensors.id',
`value` double NOT NULL COMMENT 'current value',
PRIMARY KEY (`id`,`sid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
--
-- Triggers `sensorvalues`
--
DROP TRIGGER IF EXISTS `sensorvalues_upd_records`;
DELIMITER //
CREATE TRIGGER `sensorvalues_upd_records` AFTER INSERT ON `sensorvalues`
FOR EACH ROW UPDATE `records`
SET `pid` = NEW.id, `value` = NEW.value
WHERE stations_id = (SELECT stationid FROM `packets` WHERE id = NEW.id)
AND sid = NEW.sid
AND ((max_flag AND NEW.value > value) OR (NOT max_flag AND NEW.value < value))
//
DELIMITER ;
-- --------------------------------------------------------
--
-- Table structure for table `stations`
--
CREATE TABLE IF NOT EXISTS `stations` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT 'Station ID',
`description` varchar(25) NOT NULL DEFAULT 'New Station',
`mac` char(8) NOT NULL COMMENT 'Gateway MAC',
`serial` varchar(8) NOT NULL COMMENT 'Station serial #',
`station_serial` varchar(16) NOT NULL DEFAULT '7FFF000000000000',
`ip4` char(15) NOT NULL COMMENT 'Gateway IP',
`wug_id` varchar(12) DEFAULT NULL COMMENT 'Weather Underground Station ID',
`wug_sec` varchar(12) DEFAULT NULL COMMENT 'Weather Underground security',
`last_hist_addr` char(4) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1 COMMENT='Weather Station identification' AUTO_INCREMENT=57 ;
-- --------------------------------------------------------
--
-- Stand-in structure for view `v_packets_sensordatevalues`
--
CREATE TABLE IF NOT EXISTS `v_packets_sensordatevalues` (
`id` int(10) unsigned
,`timestamp` datetime
,`packettype` int(10) unsigned
,`stationid` int(10) unsigned
,`did` int(10) unsigned
,`date` datetime
,`prior_value` double
);
-- --------------------------------------------------------
--
-- Stand-in structure for view `v_packets_sensorvalues`
--
CREATE TABLE IF NOT EXISTS `v_packets_sensorvalues` (
`id` int(10) unsigned
,`timestamp` datetime
,`packettype` int(10) unsigned
,`stationid` int(10) unsigned
,`sid` int(10) unsigned
,`value` double
);
-- --------------------------------------------------------
--
-- Structure for view `historyvalues`
--
DROP TABLE IF EXISTS `historyvalues`;
CREATE ALGORITHM=UNDEFINED DEFINER=`admin`@`localhost` SQL SECURITY INVOKER VIEW `historyvalues` AS select `P`.`id` AS `id`,`P`.`timestamp` AS `timestamp`,`P`.`packettype` AS `packettype`,`P`.`stationid` AS `stationid`,`S`.`sid` AS `sid`,`S`.`value` AS `value` from (`packets` `P` join `sensorvalues` `S` on((`P`.`id` = `S`.`id`))) where (`P`.`packettype` = 9) order by `P`.`id` desc;
-- --------------------------------------------------------
--
-- Structure for view `v_packets_sensordatevalues`
--
DROP TABLE IF EXISTS `v_packets_sensordatevalues`;
CREATE ALGORITHM=UNDEFINED DEFINER=`admin`@`localhost` SQL SECURITY INVOKER VIEW `v_packets_sensordatevalues` AS select `P`.`id` AS `id`,`P`.`timestamp` AS `timestamp`,`P`.`packettype` AS `packettype`,`P`.`stationid` AS `stationid`,`S`.`did` AS `did`,`S`.`date` AS `date`,`S`.`prior_value` AS `prior_value` from (`packets` `P` join `sensordatevalues` `S` on((`P`.`id` = `S`.`pid`)));
-- --------------------------------------------------------
--
-- Structure for view `v_packets_sensorvalues`
--
DROP TABLE IF EXISTS `v_packets_sensorvalues`;
CREATE ALGORITHM=UNDEFINED DEFINER=`admin`@`localhost` SQL SECURITY INVOKER VIEW `v_packets_sensorvalues` AS select `P`.`id` AS `id`,`P`.`timestamp` AS `timestamp`,`P`.`packettype` AS `packettype`,`P`.`stationid` AS `stationid`,`S`.`sid` AS `sid`,`S`.`value` AS `value` from (`packets` `P` join `sensorvalues` `S` on((`P`.`id` = `S`.`id`)));
--
-- Constraints for dumped tables
--
--
-- Constraints for table `packetdump`
--
ALTER TABLE `packetdump`
ADD CONSTRAINT `c_packetdump_pid` FOREIGN KEY (`pid`) REFERENCES `packets` (`id`) ON DELETE CASCADE;
--
-- Constraints for table `sensorvalues`
--
ALTER TABLE `sensorvalues`
ADD CONSTRAINT `c_packets_sensorvalues` FOREIGN KEY (`id`) REFERENCES `packets` (`id`) ON DELETE CASCADE;
/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;