Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Print DB schema #83

Open
wants to merge 1 commit into
base: feature/add-unit-test-suite
Choose a base branch
from

Conversation

calufa
Copy link
Contributor

@calufa calufa commented Feb 10, 2022

TODO:

  • Add ./db-schema.sh to print the current DB schema
  • Update README to include instructions on how to run ./db-schema.sh
  • Remove devops/all.sql file

@netlify
Copy link

netlify bot commented Feb 10, 2022

✔️ Deploy Preview for vlab-research canceled.

🔨 Explore the source changes: 6c2be65

🔍 Inspect the deploy log: https://app.netlify.com/sites/vlab-research/deploys/620575be7cfb580008f6bc79

@calufa calufa changed the base branch from main to feature/add-unit-test-suite February 10, 2022 20:29
@calufa calufa force-pushed the feature/dump-db-schema branch 2 times, most recently from e8baa32 to be1007e Compare February 10, 2022 21:20
@calufa
Copy link
Contributor Author

calufa commented Feb 10, 2022

This is the output after running ./db-schema.sh:

CREATE TABLE users (
	id UUID NOT NULL DEFAULT gen_random_uuid(),
	email VARCHAR NOT NULL,
	CONSTRAINT "primary" PRIMARY KEY (id ASC),
	UNIQUE INDEX users_email_key (email ASC),
	FAMILY "primary" (id, email)
);

CREATE TABLE campaigns (
	id UUID NOT NULL DEFAULT gen_random_uuid(),
	userid UUID NOT NULL,
	created TIMESTAMPTZ NOT NULL DEFAULT current_timestamp():::TIMESTAMPTZ,
	name VARCHAR NOT NULL,
	active BOOL NOT NULL DEFAULT true,
	CONSTRAINT "primary" PRIMARY KEY (id ASC),
	UNIQUE INDEX campaigns_userid_name_key (userid ASC, name ASC),
	FAMILY "primary" (id, userid, created, name, active)
);

CREATE TABLE adopt_reports (
	campaignid UUID NOT NULL,
	created TIMESTAMPTZ NOT NULL DEFAULT current_timestamp():::TIMESTAMPTZ,
	report_type VARCHAR NOT NULL,
	details JSONB NOT NULL,
	INDEX adopt_reports_auto_index_fk_campaignid_ref_campaigns (campaignid ASC),
	FAMILY "primary" (campaignid, created, report_type, details, rowid)
);

CREATE TABLE campaign_confs (
	campaignid UUID NOT NULL,
	created TIMESTAMPTZ NOT NULL DEFAULT current_timestamp():::TIMESTAMPTZ,
	conf_type VARCHAR NOT NULL,
	entity_name VARCHAR NULL,
	conf JSONB NOT NULL,
	INDEX campaign_confs_campaignid_conf_type_created_idx (campaignid ASC, conf_type ASC, created DESC) STORING (entity_name, conf),
	FAMILY "primary" (campaignid, created, conf_type, entity_name, conf, rowid)
);

CREATE TABLE credentials (
	userid UUID NOT NULL,
	entity VARCHAR NOT NULL,
	key VARCHAR NOT NULL,
	created TIMESTAMPTZ NOT NULL DEFAULT current_timestamp():::TIMESTAMPTZ,
	details JSONB NOT NULL,
	facebook_page_id VARCHAR NULL AS (CASE WHEN entity = 'facebook_page' THEN details->>'id' ELSE NULL END) STORED,
	UNIQUE INDEX credentials_entity_key_key (entity ASC, key ASC),
	INDEX credentials_userid_entity_key_created_idx (userid ASC, entity ASC, key ASC, created DESC) STORING (details),
	UNIQUE INDEX unique_facebook_page (facebook_page_id ASC),
	INDEX credentials_facebook_page_id_idx (facebook_page_id ASC) STORING (details, key, userid),
	FAMILY "primary" (userid, entity, key, created, details, rowid, facebook_page_id)
);

CREATE TABLE messages (
	id INT8 NULL,
	content VARCHAR NOT NULL,
	userid VARCHAR NOT NULL,
	"timestamp" TIMESTAMPTZ NOT NULL,
	hsh INT8 NOT NULL AS (fnv64a(content)) STORED,
	CONSTRAINT "primary" PRIMARY KEY (hsh ASC, userid ASC),
	INDEX messages_userid_idx (userid ASC) STORING (content, "timestamp"),
	INDEX messages_userid_timestamp_idx (userid ASC, "timestamp" ASC) STORING (content),
	INDEX messages_timestamp_idx ("timestamp" DESC) STORING (content),
	FAMILY "primary" (id, content, userid, "timestamp", hsh)
);

CREATE TABLE surveys (
	id UUID NOT NULL DEFAULT gen_random_uuid(),
	created TIMESTAMPTZ NOT NULL,
	formid VARCHAR NOT NULL,
	form VARCHAR NOT NULL,
	messages VARCHAR NULL,
	shortcode VARCHAR NOT NULL,
	title VARCHAR NOT NULL,
	userid UUID NOT NULL,
	form_json JSONB NULL AS (form::JSONB) STORED,
	messages_json JSONB NULL AS (messages::JSONB) STORED,
	has_followup BOOL NULL AS ((messages::JSONB->>'label.buttonHint.default') IS NOT NULL) STORED,
	metadata JSONB NOT NULL DEFAULT '{}':::JSONB,
	survey_name VARCHAR NOT NULL DEFAULT 'default':::STRING,
	translation_conf JSONB NOT NULL DEFAULT '{}':::JSONB,
	CONSTRAINT "primary" PRIMARY KEY (id ASC),
	INDEX surveys_auto_index_fk_userid_ref_users (userid ASC),
	INDEX surveys_shortcode_userid_created_idx (shortcode ASC, userid ASC, created DESC) STORING (formid, form, messages, title, form_json),
	INDEX surveys_has_followup_shortcode_userid_created_idx (has_followup ASC, shortcode ASC, userid ASC, created DESC),
	FAMILY "primary" (id, created, formid, form, messages, shortcode, title, userid, form_json, messages_json, has_followup, metadata, survey_name, translation_conf)
);

CREATE TABLE responses (
	parent_surveyid UUID NULL,
	parent_shortcode VARCHAR NOT NULL,
	surveyid UUID NOT NULL,
	shortcode VARCHAR NOT NULL,
	flowid INT8 NOT NULL,
	userid VARCHAR NOT NULL,
	question_ref VARCHAR NOT NULL,
	question_idx INT8 NOT NULL,
	question_text VARCHAR NOT NULL,
	response VARCHAR NOT NULL,
	seed INT8 NOT NULL,
	"timestamp" TIMESTAMPTZ NOT NULL,
	metadata JSONB NULL,
	pageid VARCHAR NULL,
	clusterid VARCHAR NULL AS (metadata->>'clusterid') STORED,
	translated_response VARCHAR NULL,
	CONSTRAINT "primary" PRIMARY KEY (userid ASC, "timestamp" ASC, question_ref ASC),
	INDEX responses_auto_index_fk_parent_surveyid_ref_surveys (parent_surveyid ASC),
	INDEX responses_auto_index_fk_surveyid_ref_surveys (surveyid ASC),
	INVERTED INDEX responses_metadata_idx (metadata),
	INDEX responses_shortcode_question_ref_response_clusterid_timestamp_idx (shortcode ASC, question_ref ASC, response ASC, clusterid ASC, "timestamp" ASC),
	INDEX responses_surveyid_userid_timestamp_question_ref_idx (surveyid ASC, userid ASC, "timestamp" ASC, question_ref ASC) STORING (parent_surveyid, parent_shortcode, shortcode, flowid, question_idx, question_text, response, seed, metadata, pageid, clusterid, translated_response),
	FAMILY "primary" (parent_surveyid, parent_shortcode, surveyid, shortcode, flowid, userid, question_ref, question_idx, question_text, response, seed, "timestamp", metadata, pageid, clusterid, translated_response)
);

CREATE TABLE states (
	userid VARCHAR NOT NULL,
	pageid VARCHAR NOT NULL,
	updated TIMESTAMPTZ NOT NULL,
	current_state VARCHAR NOT NULL,
	state_json JSONB NOT NULL,
	fb_error_code VARCHAR NULL AS ((state_json->'error')->>'code') STORED,
	current_form VARCHAR NULL AS ((state_json->'forms')->>-1) STORED,
	previous_is_followup BOOL NULL AS (((state_json->'previousOutput')->>'followUp') IS NOT NULL) STORED,
	previous_with_token BOOL NULL AS (((state_json->'previousOutput')->>'token') IS NOT NULL) STORED,
	form_start_time TIMESTAMPTZ NULL AS (ceiling(((state_json->'md')->>'startTime')::INT8 / 1000)::INT8::TIMESTAMPTZ) STORED,
	error_tag VARCHAR NULL AS ((state_json->'error')->>'tag') STORED,
	stuck_on_question VARCHAR NULL AS (CASE WHEN ((((state_json->'qa')->-1)->>0) = (((state_json->'qa')->-2)->>0)) AND ((((state_json->'qa')->-2)->>0) = (((state_json->'qa')->-3)->>0)) THEN ((state_json->'qa')->-1)->>0 ELSE NULL END) STORED,
	timeout_date TIMESTAMPTZ NULL AS (CASE WHEN (((state_json->'wait')->>'type') = 'timeout') AND ((((state_json->'wait')->'value')->>'type') = 'absolute') THEN (((state_json->'wait')->'value')->>'timeout')::TIMESTAMPTZ WHEN (((state_json->'wait')->>'type') = 'timeout') AND ((((state_json->'wait')->'value')->>'type') = 'relative') THEN (ceiling((state_json->>'waitStart')::INT8 / 1000)::INT8::TIMESTAMPTZ + (((state_json->'wait')->'value')->>'timeout')::INTERVAL) WHEN ((state_json->'wait')->>'type') = 'timeout' THEN (ceiling((state_json->>'waitStart')::INT8 / 1000)::INT8::TIMESTAMPTZ + ((state_json->'wait')->>'value')::INTERVAL) ELSE NULL END) STORED,
	next_retry TIMESTAMP NULL AS ((floor(((power(2, (CASE WHEN json_array_length(state_json->'retries') <= 16 THEN json_array_length(state_json->'retries') ELSE 16 END)) * 60000) + ((state_json->'retries')->>-1)::INT8)::INT8) / 1000)::INT8::TIMESTAMP) STORED,
	CONSTRAINT "primary" PRIMARY KEY (userid ASC, pageid ASC),
	INDEX states_current_state_updated_idx (current_state ASC, updated ASC),
	INDEX states_auto_index_fk_pageid_ref_facebook_pages (pageid ASC),
	INDEX states_current_state_fb_error_code_idx (current_state ASC, fb_error_code ASC) STORING (state_json),
	INVERTED INDEX states_state_json_idx (state_json),
	INDEX states_current_state_current_form_updated_idx (current_state ASC, current_form ASC, updated ASC),
	INDEX states_previous_with_token_previous_is_followup_form_start_time_current_state_updated_idx (previous_with_token ASC, previous_is_followup ASC, form_start_time ASC, current_state ASC, updated ASC) STORING (state_json),
	INDEX states_error_tag_current_state_current_form_updated_idx (error_tag ASC, current_state ASC, current_form ASC, updated ASC),
	INDEX states_stuck_on_question_current_state_current_form_updated_idx (stuck_on_question ASC, current_state ASC, current_form ASC, updated ASC),
	INDEX states_current_state_timeout_date_idx (current_state ASC, timeout_date ASC) STORING (state_json),
	INDEX states_current_state_error_tag_updated_next_retry_idx (current_state ASC, error_tag ASC, updated ASC, next_retry ASC),
	INDEX states_current_state_fb_error_code_updated_next_retry_idx (current_state ASC, fb_error_code ASC, updated ASC, next_retry ASC),
	FAMILY "primary" (userid, pageid, updated, current_state, state_json, fb_error_code, current_form, previous_is_followup, previous_with_token, form_start_time, error_tag, stuck_on_question, timeout_date, next_retry),
	CONSTRAINT valid_state_json CHECK (state_json ? 'state')
);

ALTER TABLE campaigns ADD CONSTRAINT fk_userid_ref_users FOREIGN KEY (userid) REFERENCES users(id) ON DELETE CASCADE;
ALTER TABLE adopt_reports ADD CONSTRAINT fk_campaignid_ref_campaigns FOREIGN KEY (campaignid) REFERENCES campaigns(id) ON DELETE CASCADE;
ALTER TABLE campaign_confs ADD CONSTRAINT fk_campaignid_ref_campaigns FOREIGN KEY (campaignid) REFERENCES campaigns(id) ON DELETE CASCADE;
ALTER TABLE credentials ADD CONSTRAINT fk_userid_ref_users FOREIGN KEY (userid) REFERENCES users(id) ON DELETE CASCADE;
ALTER TABLE surveys ADD CONSTRAINT fk_userid_ref_users FOREIGN KEY (userid) REFERENCES users(id) ON DELETE CASCADE;
ALTER TABLE responses ADD CONSTRAINT fk_parent_surveyid_ref_surveys FOREIGN KEY (parent_surveyid) REFERENCES surveys(id);
ALTER TABLE responses ADD CONSTRAINT fk_surveyid_ref_surveys FOREIGN KEY (surveyid) REFERENCES surveys(id);
ALTER TABLE states ADD CONSTRAINT fk_facebook_page_id FOREIGN KEY (pageid) REFERENCES credentials(facebook_page_id) ON DELETE CASCADE;

-- Validate foreign key constraints. These can fail if there was unvalidated data during the dump.
ALTER TABLE campaigns VALIDATE CONSTRAINT fk_userid_ref_users;
ALTER TABLE adopt_reports VALIDATE CONSTRAINT fk_campaignid_ref_campaigns;
ALTER TABLE campaign_confs VALIDATE CONSTRAINT fk_campaignid_ref_campaigns;
ALTER TABLE credentials VALIDATE CONSTRAINT fk_userid_ref_users;
ALTER TABLE surveys VALIDATE CONSTRAINT fk_userid_ref_users;
ALTER TABLE responses VALIDATE CONSTRAINT fk_parent_surveyid_ref_surveys;
ALTER TABLE responses VALIDATE CONSTRAINT fk_surveyid_ref_surveys;
ALTER TABLE states VALIDATE CONSTRAINT fk_facebook_page_id;

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

1 participant