Skip to content
This repository has been archived by the owner on Jan 18, 2024. It is now read-only.

Improvements in RDS Schema #25

Merged
merged 17 commits into from
Apr 24, 2018
Merged
Show file tree
Hide file tree
Changes from 8 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 2 additions & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -2,3 +2,5 @@
\.vscode/

node_modules/
*.log
*.terraform
169 changes: 97 additions & 72 deletions code/sql/schema.sql
Original file line number Diff line number Diff line change
@@ -1,96 +1,121 @@
CREATE SCHEMA waze;

CREATE TABLE waze.data_files
(
"id" SERIAL PRIMARY KEY NOT NULL,
"start_time_millis" BIGINT NOT NULL,
"end_time_millis" BIGINT NOT NULL,
"start_time" TIMESTAMP,
"end_time" TIMESTAMP,
"date_created" TIMESTAMP,
"date_updated" TIMESTAMP,
"file_name" TEXT NOT NULL,
"json_hash" uuid NOT NULL,
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The hash we create will be SHA1 , so this probably needs to be a varchar(40)

UNIQUE ("start_time_millis", "json_hash")
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

My plan is to actually embed the start_time_millis into the hash, so we won't need a separate unique constraint

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yes agreed.

);

CREATE TABLE waze.jams
(
"id" BIGINT PRIMARY KEY NOT NULL,
"uuid" VARCHAR[500] NOT NULL,
"pub_millis" BIGINT NOT NULL,
"start_node" VARCHAR[500],
"end_node" VARCHAR[500],
"road_type" INTEGER,
"street" VARCHAR[500],
"city" VARCHAR[500],
"country" VARCHAR[500],
"delay" INTEGER,
"speed" float4,
"length" INTEGER,
"turn_type" VARCHAR[500],
"level" INTEGER,
"blocking_alert_id" VARCHAR[500]
"id" SERIAL PRIMARY KEY NOT NULL,
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Part of the hashing proposal was to have the primary key on each of alerts/jams/irregularities be the actual hash. So rather than having a serial id primary key we would have something like record_hash varchar(40)

"uuid" TEXT NOT NULL,
"pub_millis" BIGINT NOT NULL,
"pub_utc_date" TIMESTAMP,
"start_node" TEXT,
"end_node" TEXT,
"road_type" INTEGER,
"street" TEXT,
"city" TEXT,
"country" TEXT,
"delay" INTEGER,
"speed" float4,
"speed_kmh" float4,
"length" INTEGER,
"turn_type" TEXT,
"level" INTEGER,
"blocking_alert_id" TEXT,
"line" JSONB,
"datafile_id" BIGINT NOT NULL REFERENCES waze.data_files (id)
);

CREATE TABLE waze.alerts
CREATE TABLE waze.alerts
(
"id" BIGINT PRIMARY KEY NOT NULL,
"uuid" VARCHAR[500] NOT NULL,
"pub_millis" BIGINT NOT NULL,
"road_type" INTEGER,
"street" VARCHAR[500],
"city" VARCHAR[500],
"country" VARCHAR[500],
"magvar" INTEGER,
"reliability" INTEGER,
"report_description" VARCHAR[500],
"report_rating" INTEGER,
"type" VARCHAR[500],
"subtype" VARCHAR[500],
"report_by_municipality_user" BOOLEAN,
"thumbs_up" INTEGER,
"jam_id" VARCHAR[500] REFERENCES waze.jams (uuid),
"irregularity_id" VARCHAR[500] REFERENCES waze.irregularities (uuid)
"id" SERIAL PRIMARY KEY NOT NULL,
"uuid" TEXT NOT NULL,
"pub_millis" BIGINT NOT NULL,
"pub_utc_date" TIMESTAMP,
"road_type" INTEGER,
"location" JSONB,
"street" TEXT,
"city" TEXT,
"country" TEXT,
"magvar" INTEGER,
"reliability" INTEGER,
"report_description" TEXT,
"report_rating" INTEGER,
"confidence" INTEGER,
"type" TEXT,
"subtype" TEXT,
"report_by_municipality_user" BOOLEAN,
"thumbs_up" INTEGER,
"jam_uuid" TEXT,
"irregularity_uuid" TEXT,
"datafile_id" BIGINT NOT NULL REFERENCES waze.data_files (id)
);

CREATE TABLE waze.irregularities
CREATE TABLE waze.irregularities
(
"id" BIGINT PRIMARY KEY NOT NULL,
"uuid" VARCHAR[500] NOT NULL,
"detection_date_millis" BIGINT NOT NULL,
"detection_date" TIMESTAMP,
"update_date_millis" BIGINT NOT NULL,
"update_date" TIMESTAMP,
"street" VARCHAR[500],
"city" VARCHAR[500],
"country" VARCHAR[500],
"is_highway" BOOLEAN,
"speed" float4,
"regular_speed" float4,
"delay_seconds" INTEGER,
"seconds" INTEGER,
"length" INTEGER,
"trend" INTEGER,
"type" VARCHAR[500],
"severity" float4,
"jam_level" INTEGER,
"drivers_count" INTEGER,
"alerts_count" INTEGER,
"n_thumbs_up" INTEGER,
"n_comments" INTEGER,
"n_images" INTEGER
"id" SERIAL PRIMARY KEY NOT NULL,
"uuid" TEXT NOT NULL,
"detection_date_millis" BIGINT NOT NULL,
"detection_date" TEXT,
"detection_utc_date" TIMESTAMP,
"update_date_millis" BIGINT NOT NULL,
"update_date" TEXT,
"update_utc_date" TIMESTAMP,
"street" TEXT,
"city" TEXT,
"country" TEXT,
"is_highway" BOOLEAN,
"speed" float4,
"regular_speed" float4,
"delay_seconds" INTEGER,
"seconds" INTEGER,
"length" INTEGER,
"trend" INTEGER,
"type" TEXT,
"severity" float4,
"jam_level" INTEGER,
"drivers_count" INTEGER,
"alerts_count" INTEGER,
"n_thumbs_up" INTEGER,
"n_comments" INTEGER,
"n_images" INTEGER,
"line" JSONB,
"datafile_id" BIGINT NOT NULL REFERENCES waze.data_files (id)
);


CREATE TABLE waze.coordinates
(
"id" BIGINT PRIMARY KEY NOT NULL,
"latitude" float8 NOT NULL,
"longitude" float8 NOT NULL,
"order" INTEGER NOT NULL,
"jam_id" BIGINT REFERENCES waze.jams (id),
"irregularity_id" BIGINT REFERENCES waze.irregularities (id),
"alert_id" BIGINT REFERENCES waze.alerts (id)
"id" SERIAL PRIMARY KEY NOT NULL,
"latitude" float8 NOT NULL,
"longitude" float8 NOT NULL,
"order" INTEGER NOT NULL,
"jam_id" BIGINT REFERENCES waze.jams (id),
"irregularity_id" BIGINT REFERENCES waze.irregularities (id),
"alert_id" BIGINT REFERENCES waze.alerts (id)
);

CREATE TABLE waze.roads
(
"id" INTEGER PRIMARY KEY NOT NULL,
"value" INTEGER NOT NULL,
"name" VARCHAR[100] NOT NULL
"id" SERIAL PRIMARY KEY NOT NULL,
"value" INTEGER NOT NULL,
"name" VARCHAR[100] NOT NULL
);

CREATE TABLE waze.alert_types
(
"id" BIGINT PRIMARY KEY NOT NULL,
"type" VARCHAR[500] NOT NULL,
"subtype" VARCHAR[500]
"id" SERIAL PRIMARY KEY NOT NULL,
"type" TEXT NOT NULL,
"subtype" TEXT
);