-
Notifications
You must be signed in to change notification settings - Fork 68
/
v4_schema.sql
166 lines (149 loc) · 7.8 KB
/
v4_schema.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
USE covid;
CREATE TABLE geo_dim (
`geo_key_id` BIGINT(20) UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
`geo_type` VARCHAR(12) NOT NULL,
`geo_value` VARCHAR(12) NOT NULL,
UNIQUE INDEX `geo_dim_index` (`geo_type`, `geo_value`)
) ENGINE=InnoDB;
CREATE TABLE signal_dim (
`signal_key_id` BIGINT(20) UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
`source` VARCHAR(32) NOT NULL,
`signal` VARCHAR(64) NOT NULL,
UNIQUE INDEX `signal_dim_index` (`source`, `signal`)
) ENGINE=InnoDB;
CREATE TABLE strat_dim (
`strat_key_id` BIGINT(20) UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
`stratification_name` VARCHAR(64) NOT NULL UNIQUE,
`stratification_descr` VARCHAR(64) NOT NULL
) ENGINE=InnoDB;
INSERT INTO strat_dim VALUES (1, 'NO_STRATIFICATION', '');
CREATE TABLE epimetric_full (
`epimetric_id` BIGINT(20) UNSIGNED NOT NULL PRIMARY KEY,
`signal_key_id` BIGINT(20) UNSIGNED NOT NULL,
`geo_key_id` BIGINT(20) UNSIGNED NOT NULL,
`strat_key_id` BIGINT(20) UNSIGNED NOT NULL DEFAULT 1, -- TODO: for future use
`issue` INT(11) NOT NULL,
`data_as_of_dt` DATETIME(0), -- TODO: for future use ; also "as_of" is problematic and should be renamed
`time_type` VARCHAR(12) NOT NULL,
`time_value` INT(11) NOT NULL,
`reference_dt` DATETIME(0), -- TODO: for future use
`value` DOUBLE,
`stderr` DOUBLE,
`sample_size` DOUBLE,
`lag` INT(11) NOT NULL,
`value_updated_timestamp` INT(11) NOT NULL,
`computation_as_of_dt` DATETIME(0), -- TODO: for future use ; also "as_of" is problematic and should be renamed
`missing_value` INT(1) DEFAULT '0',
`missing_stderr` INT(1) DEFAULT '0',
`missing_sample_size` INT(1) DEFAULT '0',
UNIQUE INDEX `value_key_tig` (`signal_key_id`, `time_type`, `time_value`, `issue`, `geo_key_id`),
UNIQUE INDEX `value_key_tgi` (`signal_key_id`, `time_type`, `time_value`, `geo_key_id`, `issue`),
UNIQUE INDEX `value_key_itg` (`signal_key_id`, `issue`, `time_type`, `time_value`, `geo_key_id`),
UNIQUE INDEX `value_key_igt` (`signal_key_id`, `issue`, `geo_key_id`, `time_type`, `time_value`),
UNIQUE INDEX `value_key_git` (`signal_key_id`, `geo_key_id`, `issue`, `time_type`, `time_value`),
UNIQUE INDEX `value_key_gti` (`signal_key_id`, `geo_key_id`, `time_type`, `time_value`, `issue`)
) ENGINE=InnoDB;
CREATE TABLE epimetric_latest (
PRIMARY KEY (`epimetric_id`),
UNIQUE INDEX `value_key_tg` (`signal_key_id`, `time_type`, `time_value`, `geo_key_id`),
UNIQUE INDEX `value_key_gt` (`signal_key_id`, `geo_key_id`, `time_type`, `time_value`)
) ENGINE=InnoDB
SELECT * FROM epimetric_full;
-- NOTE: In production or any non-testing system that should maintain consistency,
-- **DO NOT** 'TRUNCATE' this table.
-- Doing so will function as a DROP/CREATE and reset the AUTO_INCREMENT counter for the `epimetric_id` field.
-- This field is used to populate the non-AUTO_INCREMENT fields of the same name in `epimetric_latest` and `epimetric_full`,
-- and resetting it will ultimately cause PK collisions.
-- To restore the counter, a row must be written with a `epimetric_id` value greater than the maximum
-- of its values in the other tables.
CREATE TABLE epimetric_load (
`epimetric_id` BIGINT(20) UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
`signal_key_id` BIGINT(20) UNSIGNED,
`geo_key_id` BIGINT(20) UNSIGNED,
`strat_key_id` BIGINT(20) UNSIGNED NOT NULL DEFAULT 1, -- TODO: for future use
`issue` INT(11) NOT NULL,
`data_as_of_dt` DATETIME(0), -- TODO: for future use ; also "as_of" is problematic and should be renamed
`source` VARCHAR(32) NOT NULL,
`signal` VARCHAR(64) NOT NULL,
`geo_type` VARCHAR(12) NOT NULL,
`geo_value` VARCHAR(12) NOT NULL,
`time_type` VARCHAR(12) NOT NULL,
`time_value` INT(11) NOT NULL,
`reference_dt` DATETIME(0), -- TODO: for future use
`value` DOUBLE,
`stderr` DOUBLE,
`sample_size` DOUBLE,
`lag` INT(11) NOT NULL,
`value_updated_timestamp` INT(11) NOT NULL,
`computation_as_of_dt` DATETIME(0), -- TODO: for future use ; also "as_of" is problematic and should be renamed
`is_latest_issue` BINARY(1) NOT NULL DEFAULT '0',
`missing_value` INT(1) DEFAULT '0',
`missing_stderr` INT(1) DEFAULT '0',
`missing_sample_size` INT(1) DEFAULT '0',
UNIQUE INDEX (`source`, `signal`, `time_type`, `geo_type`, `time_value`, `geo_value`, `issue`)
) ENGINE=InnoDB;
CREATE OR REPLACE VIEW epimetric_full_v AS
SELECT
0 AS `is_latest_issue`, -- provides column-compatibility to match `covidcast` table
-- ^ this value is essentially undefined in this view, the notion of a 'latest' issue is not encoded here and must be drawn from the 'latest' table or view or otherwise computed...
NULL AS `direction`, -- provides column-compatibility to match `covidcast` table
`t2`.`source` AS `source`,
`t2`.`signal` AS `signal`,
`t3`.`geo_type` AS `geo_type`,
`t3`.`geo_value` AS `geo_value`,
`t1`.`epimetric_id` AS `epimetric_id`,
`t1`.`strat_key_id` AS `strat_key_id`, -- TODO: for future use
`t1`.`issue` AS `issue`,
`t1`.`data_as_of_dt` AS `data_as_of_dt`, -- TODO: for future use ; also "as_of" is problematic and should be renamed
`t1`.`time_type` AS `time_type`,
`t1`.`time_value` AS `time_value`,
`t1`.`reference_dt` AS `reference_dt`, -- TODO: for future use
`t1`.`value` AS `value`,
`t1`.`stderr` AS `stderr`,
`t1`.`sample_size` AS `sample_size`,
`t1`.`lag` AS `lag`,
`t1`.`value_updated_timestamp` AS `value_updated_timestamp`,
`t1`.`computation_as_of_dt` AS `computation_as_of_dt`, -- TODO: for future use ; also "as_of" is problematic and should be renamed
`t1`.`missing_value` AS `missing_value`,
`t1`.`missing_stderr` AS `missing_stderr`,
`t1`.`missing_sample_size` AS `missing_sample_size`,
`t1`.`signal_key_id` AS `signal_key_id`,
`t1`.`geo_key_id` AS `geo_key_id`
FROM `epimetric_full` `t1`
JOIN `signal_dim` `t2` USING (`signal_key_id`)
JOIN `geo_dim` `t3` USING (`geo_key_id`);
CREATE OR REPLACE VIEW epimetric_latest_v AS
SELECT
1 AS `is_latest_issue`, -- provides column-compatibility to match `covidcast` table
NULL AS `direction`, -- provides column-compatibility to match `covidcast` table
`t2`.`source` AS `source`,
`t2`.`signal` AS `signal`,
`t3`.`geo_type` AS `geo_type`,
`t3`.`geo_value` AS `geo_value`,
`t1`.`epimetric_id` AS `epimetric_id`,
`t1`.`strat_key_id` AS `strat_key_id`, -- TODO: for future use
`t1`.`issue` AS `issue`,
`t1`.`data_as_of_dt` AS `data_as_of_dt`, -- TODO: for future use ; also "as_of" is problematic and should be renamed
`t1`.`time_type` AS `time_type`,
`t1`.`time_value` AS `time_value`,
`t1`.`reference_dt` AS `reference_dt`, -- TODO: for future use
`t1`.`value` AS `value`,
`t1`.`stderr` AS `stderr`,
`t1`.`sample_size` AS `sample_size`,
`t1`.`lag` AS `lag`,
`t1`.`value_updated_timestamp` AS `value_updated_timestamp`,
`t1`.`computation_as_of_dt` AS `computation_as_of_dt`, -- TODO: for future use ; also "as_of" is problematic and should be renamed
`t1`.`missing_value` AS `missing_value`,
`t1`.`missing_stderr` AS `missing_stderr`,
`t1`.`missing_sample_size` AS `missing_sample_size`,
`t1`.`signal_key_id` AS `signal_key_id`,
`t1`.`geo_key_id` AS `geo_key_id`
FROM `epimetric_latest` `t1`
JOIN `signal_dim` `t2` USING (`signal_key_id`)
JOIN `geo_dim` `t3` USING (`geo_key_id`);
CREATE TABLE `covidcast_meta_cache` (
`timestamp` int(11) NOT NULL,
`epidata` LONGTEXT NOT NULL,
PRIMARY KEY (`timestamp`)
) ENGINE=InnoDB;
INSERT INTO covidcast_meta_cache VALUES (0, '[]');