From a3f9c73d9401c0737d924927cb6b99d541b78e15 Mon Sep 17 00:00:00 2001 From: Chris Veilleux Date: Fri, 8 Feb 2019 13:14:33 -0600 Subject: [PATCH] moved all mycroft database DDL and scripts from the devops repository to this one. --- db/mycroft/account_schema/create_schema.sql | 3 + .../account_schema/data/subscription.sql | 6 + db/mycroft/account_schema/grants.sql | 4 + db/mycroft/account_schema/tables/account.sql | 6 + .../tables/account_agreement.sql | 8 + .../tables/account_subscription.sql | 9 + .../account_schema/tables/agreement.sql | 8 + .../account_schema/tables/refresh_token.sql | 6 + .../account_schema/tables/subscription.sql | 6 + db/mycroft/create_db.sql | 1 + db/mycroft/create_extensions.sql | 2 + db/mycroft/create_roles.sql | 4 + db/mycroft/device_schema/create_schema.sql | 7 + .../device_schema/data/text_to_speech.sql | 7 + db/mycroft/device_schema/grants.sql | 4 + .../tables/account_preferences.sql | 11 + db/mycroft/device_schema/tables/category.sql | 6 + db/mycroft/device_schema/tables/device.sql | 15 + .../device_schema/tables/device_skill.sql | 12 + db/mycroft/device_schema/tables/location.sql | 8 + .../device_schema/tables/skill_setting.sql | 7 + .../device_schema/tables/text_to_speech.sql | 6 + db/mycroft/device_schema/tables/wake_word.sql | 7 + .../tables/wake_word_settings.sql | 11 + db/mycroft/drop_db.sql | 1 + db/mycroft/drop_extensions.sql | 2 + db/mycroft/drop_roles.sql | 3 + db/mycroft/skill_schema/create_schema.sql | 7 + db/mycroft/skill_schema/grants.sql | 4 + db/mycroft/skill_schema/tables/activation.sql | 6 + db/mycroft/skill_schema/tables/branch.sql | 13 + db/mycroft/skill_schema/tables/category.sql | 6 + db/mycroft/skill_schema/tables/credit.sql | 7 + .../skill_schema/tables/oauth_credential.sql | 12 + .../skill_schema/tables/oauth_token.sql | 7 + db/mycroft/skill_schema/tables/platform.sql | 6 + db/mycroft/skill_schema/tables/setting.sql | 14 + .../skill_schema/tables/setting_section.sql | 8 + .../skill_schema/tables/setting_version.sql | 6 + db/mycroft/skill_schema/tables/skill.sql | 5 + db/mycroft/skill_schema/tables/tag.sql | 6 + db/mycroft/types/cateogory_enum.sql | 11 + db/mycroft/types/date_format_enum.sql | 1 + db/mycroft/types/measurement_system_enum.sql | 1 + db/mycroft/types/time_format_enum.sql | 1 + db/mycroft/types/tts_engine_enum.sql | 1 + db/scripts/__init__.py | 0 db/scripts/bootstrap_mycroft_db.py | 175 +++++++ db/scripts/neo4j-postgres.py | 428 ++++++++++++++++++ db/scripts/queries.cypher | 35 ++ 50 files changed, 930 insertions(+) create mode 100644 db/mycroft/account_schema/create_schema.sql create mode 100644 db/mycroft/account_schema/data/subscription.sql create mode 100644 db/mycroft/account_schema/grants.sql create mode 100644 db/mycroft/account_schema/tables/account.sql create mode 100644 db/mycroft/account_schema/tables/account_agreement.sql create mode 100644 db/mycroft/account_schema/tables/account_subscription.sql create mode 100644 db/mycroft/account_schema/tables/agreement.sql create mode 100644 db/mycroft/account_schema/tables/refresh_token.sql create mode 100644 db/mycroft/account_schema/tables/subscription.sql create mode 100644 db/mycroft/create_db.sql create mode 100644 db/mycroft/create_extensions.sql create mode 100644 db/mycroft/create_roles.sql create mode 100644 db/mycroft/device_schema/create_schema.sql create mode 100644 db/mycroft/device_schema/data/text_to_speech.sql create mode 100644 db/mycroft/device_schema/grants.sql create mode 100644 db/mycroft/device_schema/tables/account_preferences.sql create mode 100644 db/mycroft/device_schema/tables/category.sql create mode 100644 db/mycroft/device_schema/tables/device.sql create mode 100644 db/mycroft/device_schema/tables/device_skill.sql create mode 100644 db/mycroft/device_schema/tables/location.sql create mode 100644 db/mycroft/device_schema/tables/skill_setting.sql create mode 100644 db/mycroft/device_schema/tables/text_to_speech.sql create mode 100644 db/mycroft/device_schema/tables/wake_word.sql create mode 100644 db/mycroft/device_schema/tables/wake_word_settings.sql create mode 100644 db/mycroft/drop_db.sql create mode 100644 db/mycroft/drop_extensions.sql create mode 100644 db/mycroft/drop_roles.sql create mode 100644 db/mycroft/skill_schema/create_schema.sql create mode 100644 db/mycroft/skill_schema/grants.sql create mode 100644 db/mycroft/skill_schema/tables/activation.sql create mode 100644 db/mycroft/skill_schema/tables/branch.sql create mode 100644 db/mycroft/skill_schema/tables/category.sql create mode 100644 db/mycroft/skill_schema/tables/credit.sql create mode 100644 db/mycroft/skill_schema/tables/oauth_credential.sql create mode 100644 db/mycroft/skill_schema/tables/oauth_token.sql create mode 100644 db/mycroft/skill_schema/tables/platform.sql create mode 100644 db/mycroft/skill_schema/tables/setting.sql create mode 100644 db/mycroft/skill_schema/tables/setting_section.sql create mode 100644 db/mycroft/skill_schema/tables/setting_version.sql create mode 100644 db/mycroft/skill_schema/tables/skill.sql create mode 100644 db/mycroft/skill_schema/tables/tag.sql create mode 100644 db/mycroft/types/cateogory_enum.sql create mode 100644 db/mycroft/types/date_format_enum.sql create mode 100644 db/mycroft/types/measurement_system_enum.sql create mode 100644 db/mycroft/types/time_format_enum.sql create mode 100644 db/mycroft/types/tts_engine_enum.sql create mode 100644 db/scripts/__init__.py create mode 100644 db/scripts/bootstrap_mycroft_db.py create mode 100644 db/scripts/neo4j-postgres.py create mode 100644 db/scripts/queries.cypher diff --git a/db/mycroft/account_schema/create_schema.sql b/db/mycroft/account_schema/create_schema.sql new file mode 100644 index 00000000..99fc4d78 --- /dev/null +++ b/db/mycroft/account_schema/create_schema.sql @@ -0,0 +1,3 @@ +-- create the schema that will be used to store user data +-- took out the "e" in "user" because "user" is a Postgres keyword +CREATE SCHEMA account; diff --git a/db/mycroft/account_schema/data/subscription.sql b/db/mycroft/account_schema/data/subscription.sql new file mode 100644 index 00000000..504e87a9 --- /dev/null +++ b/db/mycroft/account_schema/data/subscription.sql @@ -0,0 +1,6 @@ +INSERT INTO + account.subscription (subscription, rate, rate_period) +VALUES + ('monthly supporter', 1.99, 'month'), + ('yearly supporter', 19.99, 'year') +; \ No newline at end of file diff --git a/db/mycroft/account_schema/grants.sql b/db/mycroft/account_schema/grants.sql new file mode 100644 index 00000000..7ecbcf97 --- /dev/null +++ b/db/mycroft/account_schema/grants.sql @@ -0,0 +1,4 @@ +GRANT USAGE ON SCHEMA account TO selene_crud; +GRANT USAGE ON SCHEMA account to selene_view; +GRANT SELECT ON ALL TABLES IN SCHEMA account TO selene_crud, selene_view; +GRANT INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA account TO selene_crud; diff --git a/db/mycroft/account_schema/tables/account.sql b/db/mycroft/account_schema/tables/account.sql new file mode 100644 index 00000000..525f32a0 --- /dev/null +++ b/db/mycroft/account_schema/tables/account.sql @@ -0,0 +1,6 @@ +CREATE TABLE account.account ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + email_address text NOT NULL UNIQUE, + username text NOT NULL UNIQUE, + password text +); diff --git a/db/mycroft/account_schema/tables/account_agreement.sql b/db/mycroft/account_schema/tables/account_agreement.sql new file mode 100644 index 00000000..6ce17517 --- /dev/null +++ b/db/mycroft/account_schema/tables/account_agreement.sql @@ -0,0 +1,8 @@ +CREATE TABLE account.account_agreement ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + account_id uuid NOT NULL REFERENCES account.account ON DELETE CASCADE, + agreement_id uuid NOT NULL REFERENCES account.agreement, + agreement_ts_range tsrange NOT NULL, + EXCLUDE USING gist (account_id WITH =, agreement_ts_range with &&), + UNIQUE (account_id, agreement_id, agreement_ts_range) +); diff --git a/db/mycroft/account_schema/tables/account_subscription.sql b/db/mycroft/account_schema/tables/account_subscription.sql new file mode 100644 index 00000000..a2261cef --- /dev/null +++ b/db/mycroft/account_schema/tables/account_subscription.sql @@ -0,0 +1,9 @@ +CREATE TABLE account.account_subscription ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + account_id uuid NOT NULL REFERENCES account.account ON DELETE CASCADE, + subscription_id uuid NOT NULL REFERENCES account.subscription, + subscription_ts_range tsrange NOT NULL, + stripe_customer_id text NOT NULL, + EXCLUDE USING gist (account_id WITH =, subscription_ts_range with &&), + UNIQUE (account_id, subscription_id, subscription_ts_range) +) diff --git a/db/mycroft/account_schema/tables/agreement.sql b/db/mycroft/account_schema/tables/agreement.sql new file mode 100644 index 00000000..45e30e40 --- /dev/null +++ b/db/mycroft/account_schema/tables/agreement.sql @@ -0,0 +1,8 @@ +CREATE TABLE account.agreement ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + agreement text NOT NULL, + version text NOT NULL, + effective_dt date NOT NULL, + content oid NOT NULL, + UNIQUE (agreement, version) +); diff --git a/db/mycroft/account_schema/tables/refresh_token.sql b/db/mycroft/account_schema/tables/refresh_token.sql new file mode 100644 index 00000000..454b7f7d --- /dev/null +++ b/db/mycroft/account_schema/tables/refresh_token.sql @@ -0,0 +1,6 @@ +CREATE TABLE account.refresh_token ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + account_id uuid NOT NULL REFERENCES account.account ON DELETE CASCADE, + refresh_token text, + UNIQUE (account_id, refresh_token) +); diff --git a/db/mycroft/account_schema/tables/subscription.sql b/db/mycroft/account_schema/tables/subscription.sql new file mode 100644 index 00000000..9596cce0 --- /dev/null +++ b/db/mycroft/account_schema/tables/subscription.sql @@ -0,0 +1,6 @@ +CREATE TABLE account.subscription ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + subscription text NOT NULL UNIQUE, + rate numeric NOT NULL, + rate_period text NOT NULL +); diff --git a/db/mycroft/create_db.sql b/db/mycroft/create_db.sql new file mode 100644 index 00000000..57d30ab7 --- /dev/null +++ b/db/mycroft/create_db.sql @@ -0,0 +1 @@ +CREATE DATABASE mycroft; diff --git a/db/mycroft/create_extensions.sql b/db/mycroft/create_extensions.sql new file mode 100644 index 00000000..6ffe1bfa --- /dev/null +++ b/db/mycroft/create_extensions.sql @@ -0,0 +1,2 @@ +CREATE EXTENSION pgcrypto; +CREATE EXTENSION btree_gist; \ No newline at end of file diff --git a/db/mycroft/create_roles.sql b/db/mycroft/create_roles.sql new file mode 100644 index 00000000..2182753e --- /dev/null +++ b/db/mycroft/create_roles.sql @@ -0,0 +1,4 @@ +-- create the roles that will be used by selene applications +CREATE ROLE selene WITH NOLOGIN; +CREATE ROLE selene_crud WITH LOGIN ENCRYPTED PASSWORD 'crud' IN GROUP selene; +CREATE ROLE selene_view WITH LOGIN ENCRYPTED PASSWORD 'view' IN GROUP selene; \ No newline at end of file diff --git a/db/mycroft/device_schema/create_schema.sql b/db/mycroft/device_schema/create_schema.sql new file mode 100644 index 00000000..0c04e39e --- /dev/null +++ b/db/mycroft/device_schema/create_schema.sql @@ -0,0 +1,7 @@ +-- create the schema that will be used to store user data +-- took out the "e" in "user" because "user" is a Postgres keyword +CREATE SCHEMA device; +GRANT USAGE ON SCHEMA device TO selene_crud; +GRANT USAGE ON SCHEMA device to selene_view; +GRANT SELECT ON ALL TABLES IN SCHEMA device TO selene_crud, selene_view; +GRANT INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA device TO selene_crud; diff --git a/db/mycroft/device_schema/data/text_to_speech.sql b/db/mycroft/device_schema/data/text_to_speech.sql new file mode 100644 index 00000000..734af636 --- /dev/null +++ b/db/mycroft/device_schema/data/text_to_speech.sql @@ -0,0 +1,7 @@ +INSERT INTO + device.text_to_speech (setting_name, display_name, engine) +VALUES + ('ap', 'British Male (default)', 'mimic'), + ('amy', 'American Female', 'mimic'), + ('kusal', 'American Male', 'mimic'), + ('google', 'Google Free Voice', 'google') diff --git a/db/mycroft/device_schema/grants.sql b/db/mycroft/device_schema/grants.sql new file mode 100644 index 00000000..1dc42e88 --- /dev/null +++ b/db/mycroft/device_schema/grants.sql @@ -0,0 +1,4 @@ +GRANT USAGE ON SCHEMA device TO selene_crud; +GRANT USAGE ON SCHEMA device to selene_view; +GRANT SELECT ON ALL TABLES IN SCHEMA device TO selene_crud, selene_view; +GRANT INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA device TO selene_crud; diff --git a/db/mycroft/device_schema/tables/account_preferences.sql b/db/mycroft/device_schema/tables/account_preferences.sql new file mode 100644 index 00000000..45e551b8 --- /dev/null +++ b/db/mycroft/device_schema/tables/account_preferences.sql @@ -0,0 +1,11 @@ +-- Account level preferences that pertain to device function. +CREATE TABLE device.account_preferences ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + account_id uuid REFERENCES account.account ON DELETE CASCADE, + date_format date_format_enum NOT NULL DEFAULT 'MM/DD/YYYY', + time_format time_format_enum NOT NULL DEFAULT '12 Hour', + measurement_system measurement_system_enum NOT NULL DEFAULT 'Imperial', + wake_word_id uuid NOT NULL REFERENCES device.wake_word, + text_to_speech_id uuid NOT NULL REFERENCES device.text_to_speech, + location_id uuid REFERENCES device.location +); diff --git a/db/mycroft/device_schema/tables/category.sql b/db/mycroft/device_schema/tables/category.sql new file mode 100644 index 00000000..bf2d8208 --- /dev/null +++ b/db/mycroft/device_schema/tables/category.sql @@ -0,0 +1,6 @@ +CREATE TABLE device.category ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + account_id uuid NOT NULL REFERENCES account.account ON DELETE CASCADE, + category text, + UNIQUE (account_id, category) +); diff --git a/db/mycroft/device_schema/tables/device.sql b/db/mycroft/device_schema/tables/device.sql new file mode 100644 index 00000000..e47d1e93 --- /dev/null +++ b/db/mycroft/device_schema/tables/device.sql @@ -0,0 +1,15 @@ +CREATE TABLE device.device ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + account_id uuid NOT NULL REFERENCES account.account ON DELETE CASCADE , + name text NOT NULL, + platform text NOT NULL DEFAULT 'unknown', + enclosure_version text NOT NULL DEFAULT 'unknown', + core_version text NOT NULL DEFAULT 'unknown', + wake_word_id uuid NOT NULL REFERENCES device.wake_word, + text_to_speech_id uuid NOT NULL REFERENCES device.text_to_speech, + category_id uuid REFERENCES device.category, + location_id uuid REFERENCES device.location, + placement text, + last_contact_ts timestamp, + UNIQUE (account_id, category_id, name) +); diff --git a/db/mycroft/device_schema/tables/device_skill.sql b/db/mycroft/device_schema/tables/device_skill.sql new file mode 100644 index 00000000..b61fa8b6 --- /dev/null +++ b/db/mycroft/device_schema/tables/device_skill.sql @@ -0,0 +1,12 @@ +CREATE TABLE device.device_skill ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + device_id uuid NOT NULL REFERENCES device.device ON DELETE CASCADE, + skill_id uuid NOT NULL REFERENCES skill.skill, + install_method text NOT NULL DEFAULT 'msm', + install_status text NOT NULL DEFAULT 'installed', + install_failure_reason text, + install_ts timestamp, + update_ts timestamp, + beta boolean NOT NULL DEFAULT FALSE, + UNIQUE (device_id, skill_id) +); diff --git a/db/mycroft/device_schema/tables/location.sql b/db/mycroft/device_schema/tables/location.sql new file mode 100644 index 00000000..0bcdd48a --- /dev/null +++ b/db/mycroft/device_schema/tables/location.sql @@ -0,0 +1,8 @@ +CREATE TABLE device.location ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + account_id uuid NOT NULL REFERENCES account.account ON DELETE CASCADE, + country text NOT NULL, + postal_code text NOT NULL, + time_zone text, + UNIQUE (account_id, country, postal_code) +); diff --git a/db/mycroft/device_schema/tables/skill_setting.sql b/db/mycroft/device_schema/tables/skill_setting.sql new file mode 100644 index 00000000..3cda9241 --- /dev/null +++ b/db/mycroft/device_schema/tables/skill_setting.sql @@ -0,0 +1,7 @@ +CREATE TABLE device.skill_setting ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + device_skill_id uuid NOT NULL REFERENCES device.device_skill ON DELETE CASCADE, + setting_id uuid NOT NULL REFERENCES skill.setting, + value text NOT NULL, + UNIQUE (device_skill_id, setting_id) +); diff --git a/db/mycroft/device_schema/tables/text_to_speech.sql b/db/mycroft/device_schema/tables/text_to_speech.sql new file mode 100644 index 00000000..ef108462 --- /dev/null +++ b/db/mycroft/device_schema/tables/text_to_speech.sql @@ -0,0 +1,6 @@ +CREATE TABLE device.text_to_speech ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + setting_name text NOT NULL UNIQUE, + display_name text NOT NULL, + engine tts_engine_enum NOT NULL +); diff --git a/db/mycroft/device_schema/tables/wake_word.sql b/db/mycroft/device_schema/tables/wake_word.sql new file mode 100644 index 00000000..0a31fac4 --- /dev/null +++ b/db/mycroft/device_schema/tables/wake_word.sql @@ -0,0 +1,7 @@ +CREATE TABLE device.wake_word ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + wake_word text NOT NULL, + account_id uuid REFERENCES account.account ON DELETE CASCADE, + engine text NOT NULL, + UNIQUE (account_id, wake_word) +); diff --git a/db/mycroft/device_schema/tables/wake_word_settings.sql b/db/mycroft/device_schema/tables/wake_word_settings.sql new file mode 100644 index 00000000..937286e8 --- /dev/null +++ b/db/mycroft/device_schema/tables/wake_word_settings.sql @@ -0,0 +1,11 @@ +-- Settings for wake words using the Pocketsphinx engine +CREATE TABLE device.wake_word_settings ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + wake_word_id uuid UNIQUE REFERENCES device.wake_word ON DELETE CASCADE, + sample_rate integer, + channels integer, + pronunciation text, + threshold text, + threshold_multiplier numeric, + dynamic_energy_ratio numeric +); diff --git a/db/mycroft/drop_db.sql b/db/mycroft/drop_db.sql new file mode 100644 index 00000000..7e2e5d37 --- /dev/null +++ b/db/mycroft/drop_db.sql @@ -0,0 +1 @@ +DROP DATABASE IF EXISTS mycroft; diff --git a/db/mycroft/drop_extensions.sql b/db/mycroft/drop_extensions.sql new file mode 100644 index 00000000..d915bc6d --- /dev/null +++ b/db/mycroft/drop_extensions.sql @@ -0,0 +1,2 @@ +DROP EXTENSION IF EXISTS pgcrypto; +DROP EXTENSION IF EXISTS btree_gist; \ No newline at end of file diff --git a/db/mycroft/drop_roles.sql b/db/mycroft/drop_roles.sql new file mode 100644 index 00000000..7407a9ee --- /dev/null +++ b/db/mycroft/drop_roles.sql @@ -0,0 +1,3 @@ +DROP ROLE IF EXISTS selene_crud; +DROP ROLE IF EXISTS selene_view; +DROP ROLE IF EXISTS selene; \ No newline at end of file diff --git a/db/mycroft/skill_schema/create_schema.sql b/db/mycroft/skill_schema/create_schema.sql new file mode 100644 index 00000000..12d982f6 --- /dev/null +++ b/db/mycroft/skill_schema/create_schema.sql @@ -0,0 +1,7 @@ +-- create the schema that will be used to store user data +-- took out the "e" in "user" because "user" is a Postgres keyword +CREATE SCHEMA skill; +GRANT USAGE ON SCHEMA skill TO selene_crud; +GRANT USAGE ON SCHEMA skill to selene_view; +GRANT SELECT ON ALL TABLES IN SCHEMA skill TO selene_crud, selene_view; +GRANT INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA skill TO selene_crud; diff --git a/db/mycroft/skill_schema/grants.sql b/db/mycroft/skill_schema/grants.sql new file mode 100644 index 00000000..2d7a658c --- /dev/null +++ b/db/mycroft/skill_schema/grants.sql @@ -0,0 +1,4 @@ +GRANT USAGE ON SCHEMA skill TO selene_crud; +GRANT USAGE ON SCHEMA skill to selene_view; +GRANT SELECT ON ALL TABLES IN SCHEMA skill TO selene_crud, selene_view; +GRANT INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA skill TO selene_crud; diff --git a/db/mycroft/skill_schema/tables/activation.sql b/db/mycroft/skill_schema/tables/activation.sql new file mode 100644 index 00000000..8b89a0e9 --- /dev/null +++ b/db/mycroft/skill_schema/tables/activation.sql @@ -0,0 +1,6 @@ +CREATE TABLE skill.activation ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + skill_id uuid NOT NULL REFERENCES skill.skill, + activation text NOT NULL, + UNIQUE (skill_id, activation) +); diff --git a/db/mycroft/skill_schema/tables/branch.sql b/db/mycroft/skill_schema/tables/branch.sql new file mode 100644 index 00000000..3832c622 --- /dev/null +++ b/db/mycroft/skill_schema/tables/branch.sql @@ -0,0 +1,13 @@ +CREATE TABLE skill.branch ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + skill_id uuid NOT NULL REFERENCES skill.skill, + repository_name text NOT NULL, + branch text NOT NULL, + display_name text, + short_description text, + long_description text, + icon_name text, + icon_color text, + icon_image_url text, + UNIQUE (repository_name, branch) +); diff --git a/db/mycroft/skill_schema/tables/category.sql b/db/mycroft/skill_schema/tables/category.sql new file mode 100644 index 00000000..6865a3c2 --- /dev/null +++ b/db/mycroft/skill_schema/tables/category.sql @@ -0,0 +1,6 @@ +CREATE TABLE skill.category ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + skill_id uuid NOT NULL REFERENCES skill.skill, + category category_enum NOT NULL, + UNIQUE (skill_id, category) +); diff --git a/db/mycroft/skill_schema/tables/credit.sql b/db/mycroft/skill_schema/tables/credit.sql new file mode 100644 index 00000000..acaf55c4 --- /dev/null +++ b/db/mycroft/skill_schema/tables/credit.sql @@ -0,0 +1,7 @@ +CREATE TABLE skill.credit ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + skill_id uuid NOT NULL REFERENCES skill.skill, + github_id text NOT NULL, + github_name text NOT NULL, + UNIQUE (skill_id, github_id) +); diff --git a/db/mycroft/skill_schema/tables/oauth_credential.sql b/db/mycroft/skill_schema/tables/oauth_credential.sql new file mode 100644 index 00000000..55ca60f6 --- /dev/null +++ b/db/mycroft/skill_schema/tables/oauth_credential.sql @@ -0,0 +1,12 @@ +CREATE TABLE skill.oauth_credential ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + developer_id uuid NOT NULL REFERENCES account.account, + application_name text NOT NULL, + oauth_client_id text NOT NULL, + oauth_client_secret text NOT NULL, + oauth_scope text NOT NULL, + token_uri text NOT NULL, + auth_uri text NOT NULL, + revoke_uri text NOT NULL, + UNIQUE (developer_id, application_name) +) \ No newline at end of file diff --git a/db/mycroft/skill_schema/tables/oauth_token.sql b/db/mycroft/skill_schema/tables/oauth_token.sql new file mode 100644 index 00000000..c46c8e41 --- /dev/null +++ b/db/mycroft/skill_schema/tables/oauth_token.sql @@ -0,0 +1,7 @@ +CREATE TABLE skill.oauth_token ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + oauth_credential_id uuid NOT NULL REFERENCES skill.oauth_credential, + account_id uuid NOT NULL REFERENCES account.account, + token json NOT NULL, + UNIQUE (oauth_credential_id, account_id) +) \ No newline at end of file diff --git a/db/mycroft/skill_schema/tables/platform.sql b/db/mycroft/skill_schema/tables/platform.sql new file mode 100644 index 00000000..a41f8be1 --- /dev/null +++ b/db/mycroft/skill_schema/tables/platform.sql @@ -0,0 +1,6 @@ +CREATE TABLE skill.platform ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + skill_id uuid NOT NULL REFERENCES skill.skill, + platform text NOT NULL, + UNIQUE (skill_id, platform) +); diff --git a/db/mycroft/skill_schema/tables/setting.sql b/db/mycroft/skill_schema/tables/setting.sql new file mode 100644 index 00000000..0ed0dfe0 --- /dev/null +++ b/db/mycroft/skill_schema/tables/setting.sql @@ -0,0 +1,14 @@ +CREATE TABLE skill.setting ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + setting_section_id uuid NOT NULL REFERENCES skill.setting_section, + setting text NOT NULL, + setting_type text NOT NULL, + hint text, + label text, + placeholder text, + options text, + default_value text, + hidden boolean NOT NULL, + display_order integer NOT NULL, + UNIQUE (setting_section_id, setting) +); diff --git a/db/mycroft/skill_schema/tables/setting_section.sql b/db/mycroft/skill_schema/tables/setting_section.sql new file mode 100644 index 00000000..fc052e59 --- /dev/null +++ b/db/mycroft/skill_schema/tables/setting_section.sql @@ -0,0 +1,8 @@ +CREATE TABLE skill.setting_section ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + skill_version_id uuid NOT NULL REFERENCES skill.setting_version, + section text NOT NULL, + description text, + display_order integer NOT NULL, + UNIQUE (skill_version_id, section) +); diff --git a/db/mycroft/skill_schema/tables/setting_version.sql b/db/mycroft/skill_schema/tables/setting_version.sql new file mode 100644 index 00000000..4f91bee7 --- /dev/null +++ b/db/mycroft/skill_schema/tables/setting_version.sql @@ -0,0 +1,6 @@ +CREATE TABLE skill.setting_version ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + skill_id uuid NOT NULL REFERENCES skill.skill, + version_hash text NOT NULL, + UNIQUE (skill_id, version_hash) +) \ No newline at end of file diff --git a/db/mycroft/skill_schema/tables/skill.sql b/db/mycroft/skill_schema/tables/skill.sql new file mode 100644 index 00000000..6a203552 --- /dev/null +++ b/db/mycroft/skill_schema/tables/skill.sql @@ -0,0 +1,5 @@ +CREATE TABLE skill.skill ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + name text NOT NULL, + url text +); diff --git a/db/mycroft/skill_schema/tables/tag.sql b/db/mycroft/skill_schema/tables/tag.sql new file mode 100644 index 00000000..4850de3b --- /dev/null +++ b/db/mycroft/skill_schema/tables/tag.sql @@ -0,0 +1,6 @@ +CREATE TABLE skill.tag ( + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), + skill_id uuid NOT NULL REFERENCES skill.skill, + tag text NOT NULL, + UNIQUE (skill_id, tag) +); diff --git a/db/mycroft/types/cateogory_enum.sql b/db/mycroft/types/cateogory_enum.sql new file mode 100644 index 00000000..dd028015 --- /dev/null +++ b/db/mycroft/types/cateogory_enum.sql @@ -0,0 +1,11 @@ +CREATE TYPE category_enum AS ENUM ( + 'Daily', + 'Configuration', + 'Entertainment', + 'Information', + 'IoT', + 'Music and Audio', + 'Media', + 'Productivity', + 'Transport' +); \ No newline at end of file diff --git a/db/mycroft/types/date_format_enum.sql b/db/mycroft/types/date_format_enum.sql new file mode 100644 index 00000000..3a953422 --- /dev/null +++ b/db/mycroft/types/date_format_enum.sql @@ -0,0 +1 @@ +CREATE TYPE date_format_enum AS ENUM ('DD/MM/YYYY', 'MM/DD/YYYY'); \ No newline at end of file diff --git a/db/mycroft/types/measurement_system_enum.sql b/db/mycroft/types/measurement_system_enum.sql new file mode 100644 index 00000000..226e2877 --- /dev/null +++ b/db/mycroft/types/measurement_system_enum.sql @@ -0,0 +1 @@ +CREATE TYPE measurement_system_enum AS ENUM ('Imperial', 'Metric'); \ No newline at end of file diff --git a/db/mycroft/types/time_format_enum.sql b/db/mycroft/types/time_format_enum.sql new file mode 100644 index 00000000..84fb58d7 --- /dev/null +++ b/db/mycroft/types/time_format_enum.sql @@ -0,0 +1 @@ +CREATE TYPE time_format_enum AS ENUM ('12 Hour', '24 Hour'); \ No newline at end of file diff --git a/db/mycroft/types/tts_engine_enum.sql b/db/mycroft/types/tts_engine_enum.sql new file mode 100644 index 00000000..cd2766a6 --- /dev/null +++ b/db/mycroft/types/tts_engine_enum.sql @@ -0,0 +1 @@ +CREATE TYPE tts_engine_enum AS ENUM ('google', 'mimic'); \ No newline at end of file diff --git a/db/scripts/__init__.py b/db/scripts/__init__.py new file mode 100644 index 00000000..e69de29b diff --git a/db/scripts/bootstrap_mycroft_db.py b/db/scripts/bootstrap_mycroft_db.py new file mode 100644 index 00000000..50e126d5 --- /dev/null +++ b/db/scripts/bootstrap_mycroft_db.py @@ -0,0 +1,175 @@ +from glob import glob +from os import path + +from psycopg2 import connect + +MYCROFT_DB_DIR = '/Users/chrisveilleux/Mycroft/github/devops/db/mycroft' +SCHEMAS = ('account', 'skill', 'device') +DB_DESTROY_FILES = ('drop_db.sql', 'drop_roles.sql') +DB_CREATE_FILES = ('create_db.sql', 'create_roles.sql') +ACCOUNT_TABLE_ORDER = ( + 'account', + 'refresh_token', + 'agreement', + 'account_agreement', + 'subscription', + 'account_subscription', +) +SKILL_TABLE_ORDER = ( + 'skill', + 'branch', + 'activation', + 'category', + 'credit', + 'platform', + 'setting_version', + 'setting_section', + 'setting', + 'tag', + 'oauth_credential', + 'oauth_token' +) +DEVICE_TABLE_ORDER = ( + 'category', + 'location', + 'text_to_speech', + 'wake_word', + 'wake_word_settings', + 'account_preferences', + 'device', + 'device_skill', + 'skill_setting' +) + +schema_directory = '{}_schema' + + +def get_sql_from_file(file_path: str) -> str: + with open(path.join(MYCROFT_DB_DIR, file_path)) as sql_file: + sql = sql_file.read() + + return sql + + +class PostgresDB(object): + def __init__(self, dbname, user): + self.db = connect(dbname=dbname, user=user) + self.db.autocommit = True + + def close_db(self): + self.db.close() + + def execute_sql(self, sql: str): + cursor = self.db.cursor() + cursor.execute(sql) + + +postgres_db = PostgresDB(dbname='postgres', user='chrisveilleux') + +# Destroy any objects we will be creating later. +for db_destroy_file in DB_DESTROY_FILES: + postgres_db.execute_sql( + get_sql_from_file(db_destroy_file) + ) + +# Create the extensions, mycroft database, and selene roles +for db_setup_file in DB_CREATE_FILES: + postgres_db.execute_sql( + get_sql_from_file(db_setup_file) + ) + +postgres_db.close_db() + +mycroft_db = PostgresDB(dbname='mycroft', user='chrisveilleux') + +mycroft_db.execute_sql( + get_sql_from_file(path.join('create_extensions.sql')) +) + +# Create user-defined data types +type_directory = path.join(MYCROFT_DB_DIR, 'types') +for type_file in glob(type_directory + '/*.sql'): + mycroft_db.execute_sql( + get_sql_from_file(path.join(type_directory, type_file)) + ) + +# Create the schemas and grant access +for schema in SCHEMAS: + mycroft_db.execute_sql( + get_sql_from_file(schema + '_schema/create_schema.sql') + ) + +# Create the account schema tables first as other schemas have tables with +# foreign keys to these tables. +for table in ACCOUNT_TABLE_ORDER: + create_table_file = path.join( + 'account_schema', + 'tables', + table + '.sql' + ) + mycroft_db.execute_sql( + get_sql_from_file(create_table_file) + ) + insert_rows_file = path.join( + 'account_schema', + 'data', + table + '.sql' + ) + try: + mycroft_db.execute_sql( + get_sql_from_file(insert_rows_file) + ) + except FileNotFoundError: + pass + +# Create the account schema tables first as other schemas have tables with +# foreign keys to these tables. +for table in SKILL_TABLE_ORDER: + create_table_file = path.join( + 'skill_schema', + 'tables', + table + '.sql' + ) + mycroft_db.execute_sql( + get_sql_from_file(create_table_file) + ) + insert_rows_file = path.join( + 'skill_schema', + 'data', + table + '.sql' + ) + try: + mycroft_db.execute_sql( + get_sql_from_file(insert_rows_file) + ) + except FileNotFoundError: + pass + +# Create the account schema tables first as other schemas have tables with +# foreign keys to these tables. +for table in DEVICE_TABLE_ORDER: + create_table_file = path.join( + 'device_schema', + 'tables', + table + '.sql' + ) + mycroft_db.execute_sql( + get_sql_from_file(create_table_file) + ) + insert_rows_file = path.join( + 'device_schema', + 'data', + table + '.sql' + ) + try: + mycroft_db.execute_sql( + get_sql_from_file(insert_rows_file) + ) + except FileNotFoundError: + pass + +# Grant access to schemas and tables +for schema in SCHEMAS: + mycroft_db.execute_sql( + get_sql_from_file(schema + '_schema/grants.sql') + ) diff --git a/db/scripts/neo4j-postgres.py b/db/scripts/neo4j-postgres.py new file mode 100644 index 00000000..dfe244bc --- /dev/null +++ b/db/scripts/neo4j-postgres.py @@ -0,0 +1,428 @@ +import csv +import datetime + +from psycopg2 import connect +import uuid + +users = {} +user_settings = {} +subscription = {} +devices = {} +user_devices = {} +skills = {} +skill_sections = {} +skill_fields = {} +skill_field_values = {} +device_to_skill = {} +skill_to_section = {} +section_to_field = {} +device_to_field = {} + + +def load_csv(): + with open('users.csv') as user_csv: + user_reader = csv.reader(user_csv) + next(user_reader, None) + for row in user_reader: + # email, password + users[row[0]] = {} + users[row[0]]['email'] = row[1] + users[row[0]]['password'] = row[2] + + with open('user_settings.csv') as user_setting_csv: + user_setting_reader = csv.reader(user_setting_csv) + next(user_setting_reader, None) + for row in user_setting_reader: + user_settings[row[0]] = {} + user_settings[row[0]]['date_format'] = row[1] + user_settings[row[0]]['time_format'] = row[2] + user_settings[row[0]]['measurement_system'] = row[3] + user_settings[row[0]]['tts_type'] = row[4] + user_settings[row[0]]['tts_voice'] = row[5] + user_settings[row[0]]['wake_word'] = row[6] + user_settings[row[0]]['sample_rate'] = row[7] + user_settings[row[0]]['channels'] = row[8] + user_settings[row[0]]['pronunciation'] = row[9] + user_settings[row[0]]['threshold'] = row[10] + user_settings[row[0]]['threshold_multiplier'] = row[11] + user_settings[row[0]]['dynamic_energy_ratio'] = row[12] + + with open('subscription.csv') as subscription_csv: + subscription_reader = csv.reader(subscription_csv) + next(subscription_reader, None) + for row in subscription_reader: + subscription[row[0]] = {} + subscription[row[0]]['stripe_customer_id'] = row[1] + subscription[row[0]]['last_payment_ts'] = row[2] + subscription[row[0]]['type'] = row[3] + + with open('devices.csv') as devices_csv: + devices_reader = csv.reader(devices_csv) + next(devices_reader, None) + for row in devices_reader: + devices[row[0]] = {} + user_uuid = row[1] + devices[row[0]]['user_uuid'] = row[1] + devices[row[0]]['name'] = row[2] + devices[row[0]]['description'] = row[3], + devices[row[0]]['platform'] = row[4], + devices[row[0]]['enclosure_version'] = row[5] + devices[row[0]]['core_version'] = row[6] + + if user_uuid in user_devices: + user_devices[user_uuid].append((row[0], row[2])) + else: + user_devices[user_uuid] = [(row[0], row[2])] + + with open('skill.csv') as skill_csv: + skill_reader = csv.reader(skill_csv) + next(skill_reader, None) + for row in skill_reader: + skill = row[0] + skills[skill] = {} + dev_uuid = row[1] + skills[skill]['device_uuid'] = dev_uuid + skills[skill]['name'] = row[2] + skills[skill]['description'] = row[3] + skills[skill]['identifier'] = row[4] + if dev_uuid in device_to_skill: + device_to_skill[dev_uuid].add(skill) + else: + device_to_skill[dev_uuid] = {skill} + + with open('skill_section.csv') as skill_section_csv: + skill_section_reader = csv.reader(skill_section_csv) + next(skill_section_reader, None) + for row in skill_section_reader: + section_uuid = row[0] + skill_sections[section_uuid] = {} + skill_uuid = row[1] + skill_sections[section_uuid]['skill_uuid'] = skill_uuid + skill_sections[section_uuid]['section'] = row[2] + skill_sections[section_uuid]['display_order'] = row[3] + if skill_uuid in skill_to_section: + skill_to_section[skill_uuid].add(section_uuid) + else: + skill_to_section[skill_uuid] = {section_uuid} + + with open('skill_fields.csv') as skill_fields_csv: + skill_fields_reader = csv.reader(skill_fields_csv) + next(skill_fields_reader, None) + for row in skill_fields_reader: + field_uuid = row[0] + skill_fields[field_uuid] = {} + section_uuid = row[1] + skill_fields[field_uuid]['section_uuid'] = section_uuid + skill_fields[field_uuid]['name'] = row[2] + skill_fields[field_uuid]['type'] = row[3] + skill_fields[field_uuid]['label'] = row[4] + skill_fields[field_uuid]['hint'] = row[5] + skill_fields[field_uuid]['placeholder'] = row[6] + skill_fields[field_uuid]['hide'] = row[7] + skill_fields[field_uuid]['options'] = row[8] + skill_fields[field_uuid]['order'] = row[9] + if section_uuid in section_to_field: + section_to_field[section_uuid].add(field_uuid) + else: + section_to_field[section_uuid] = {field_uuid} + + with open('skill_fields_values.csv') as skill_field_values_csv: + skill_field_values_reader = csv.reader(skill_field_values_csv) + next(skill_field_values_reader, None) + for row in skill_field_values_reader: + field_uuid = row[0] + skill_field_values[field_uuid] = {} + skill_field_values[field_uuid]['skill_uuid'] = row[1] + device_uuid = row[2] + skill_field_values[field_uuid]['device_uuid'] = device_uuid + skill_field_values[field_uuid]['field_value'] = row[3] + if device_uuid in device_to_field: + device_to_field[device_uuid].add(field_uuid) + else: + device_to_field[device_uuid] = {field_uuid} + + +def parse_user_setting(user_uuid) -> (str, str, str, str): + if user_uuid in user_settings: + user_setting = user_settings[user_uuid] + date_format = user_setting['date_format'] + if date_format == 'DMY': + date_format = 'DD/MM/YYYY' + else: + date_format = 'MM/DD/YYYY' + time_format = user_setting['time_format'] + if time_format == 'full': + time_format = '24 Hour' + else: + time_format = '12 Hour' + measurement_system = user_setting['measurement_system'] + if measurement_system == 'metric': + measurement_system = 'Metric' + elif measurement_system == 'imperial': + measurement_system = 'Imperial' + wake_word = user_setting['wake_word'] + tts_type = user_setting['tts_type'] + tts_voice = user_setting['tts_voice'] + if tts_type == 'MimicSetting': + if tts_voice == 'ap': + tts = 'ap' + elif tts_voice == 'trinity': + tts = 'amy' + else: + tts = 'ap' + elif tts_type == 'Mimic2Setting': + tts = 'kusal' + elif tts_type == 'GoogleTTSSetting': + tts = 'google' + else: + tts = 'ap' + sample_rate = user_setting['sample_rate'] + channels = user_setting['channels'] + pronunciation = user_setting['pronunciation'] + threshold = user_setting['threshold'] + threshold_multiplier = user_setting['threshold_multiplier'] + dynamic_energy_ratio = user_setting['dynamic_energy_ratio'] + return date_format, time_format, measurement_system, tts, wake_word, sample_rate, channels, pronunciation, threshold, threshold_multiplier, dynamic_energy_ratio + else: + return 'MM/DD/YYYY', '12 Hour', 'Imperial', 'ap', 'Hey Mycroft', '16000', '1', 'HH EY . M AY K R AO F T', '1e-90', '1.0', '1.5' + + +def format_date(value): + value = int(value) + value = datetime.datetime.fromtimestamp(value//1000) + return f'{value:%Y-%m-%d}' + + +def format_timestamp(value): + value = int(value) + value = datetime.datetime.fromtimestamp(value//1000) + return f'{value:%Y-%m-%d %H:%M:%S}' + + +def parse_subscription(user_uuid): + if user_uuid in subscription: + subscr = subscription[user_uuid] + stripe_customer_id = subscr['stripe_customer_id'] + start = format_timestamp(subscr['last_payment_ts']) + subscription_ts_range = '[{},)'.format(start) + subscription_type = subscr['type'] + if subscription_type == 'MonthlyAccount': + subscription_type = 'month' + elif subscription_type == 'YearlyAccount': + subscription_type = 'year' + return subscription_ts_range, stripe_customer_id, subscription_type + else: + return '', '', '' + + +db = connect(dbname='mycroft', user='postgres', host='127.0.0.1') +db.autocommit = True + +subscription_uuids = {} + + +def get_subscription_uuid(subs): + if subs in subscription_uuids: + return subscription_uuids[subs] + else: + cursor = db.cursor() + cursor.execute(f'select id from account.subscription s where s.rate_period = \'{subs}\'') + result = cursor.fetchone() + subscription_uuids[subs] = result + return result + + +tts_uuids = {} + + +def get_tts_uuid(tts): + if tts in tts_uuids: + return tts_uuids[tts] + else: + cursor = db.cursor() + cursor.execute(f'select id from device.text_to_speech s where s.setting_name = \'{tts}\'') + result = cursor.fetchone() + tts_uuids[tts] = result + return result + + +def create_account(user_uuid): + user = users[user_uuid] + email = user['email'] + password = user['password'] + date_format, time_format, measurement_system, tts, wake_word, sample_rate, channels, pronunciation, threshold, threshold_multiplier, dynamic_energy_ratio = parse_user_setting(user_uuid) + subscription_ts_range, stripe_customer_id, subscription_type = parse_subscription(user_uuid) + cursor = db.cursor() + + query = 'insert into account.account(' \ + 'id, ' \ + 'email_address, ' \ + 'password) ' \ + 'values (%s, %s, %s)' + params = (user_uuid, email, password) + cursor.execute(query, params) + + wake_word_id = str(uuid.uuid4()) + user['wake_word_id'] = wake_word_id + query = 'insert into device.wake_word (' \ + 'id,' \ + 'wake_word,' \ + 'account_id)' \ + 'values (%s, %s, %s)' + params = (wake_word_id, wake_word, user_uuid) + cursor.execute(query, params) + + text_to_speech_id = get_tts_uuid(tts) + user['text_to_speech_id'] = text_to_speech_id + + query = 'insert into device.account_preferences(' \ + 'account_id, ' \ + 'date_format, ' \ + 'time_format, ' \ + 'measurement_system,' \ + 'wake_word_id,' \ + 'text_to_speech_id)' \ + 'values (%s, %s, %s, %s, %s, %s)' + params = (user_uuid, date_format, time_format, measurement_system, wake_word_id, text_to_speech_id) + cursor.execute(query, params) + + if subscription_ts_range != '': + subscription_uuid = get_subscription_uuid(subscription_type) + query = 'insert into account.account_subscription(' \ + 'account_id, ' \ + 'subscription_id, ' \ + 'subscription_ts_range, ' \ + 'stripe_customer_id) ' \ + 'values (%s, %s, %s, %s)' + params = (user_uuid, subscription_uuid, subscription_ts_range, stripe_customer_id) + cursor.execute(query, params) + + query = 'insert into device.wake_word_settings(' \ + 'wake_word_id,' \ + 'sample_rate,' \ + 'channels,' \ + 'pronunciation,' \ + 'threshold,' \ + 'threshold_multiplier,' \ + 'dynamic_energy_ratio)' \ + 'values (%s, %s, %s, %s, %s, %s, %s)' + params = (wake_word_id, sample_rate, channels, pronunciation, threshold, threshold_multiplier, dynamic_energy_ratio) + cursor.execute(query, params) + +load_csv() + +for account in users: + print('Creating user {}'.format(account)) + create_account(account) + + +def create_device(device_uuid, category): + print('Creating device {} with category {}'.format(device_uuid, category)) + device = devices[device_uuid] + account_id = device['user_uuid'] + device_name = device['name'] + description = device['description'] + platform = device['platform'] + enclosure_version = device['enclosure_version'] + core_version = device['core_version'] + + wake_word_id = users[account_id]['wake_word_id'] + text_to_speech_id = users[account_id]['text_to_speech_id'] + + cursor = db.cursor() + query = 'select cat.id from device.category cat left join account.account acc on cat.account_id = acc.id where acc.id = %s and cat.category = %s' + params = (account_id, category) + cursor.execute(query, params) + category_id = cursor.fetchone() + if category_id is None: + query = 'insert into device.category(id, account_id, category) values (%s, %s, %s)' + category_id = str(uuid.uuid4()) + params = (category_id, account_id, category) + cursor.execute(query, params) + + query = 'insert into device.device(' \ + 'id, ' \ + 'account_id, ' \ + 'name, ' \ + 'category_id,' \ + 'placement,' \ + 'platform,' \ + 'enclosure_version,' \ + 'core_version,' \ + 'wake_word_id,' \ + 'text_to_speech_id) ' \ + 'values (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s)' + params = (device_uuid, account_id, device_name, category_id, description, platform, enclosure_version, core_version, wake_word_id, text_to_speech_id) + cursor.execute(query, params) + + +def create_device_skills(device_uuid): + cursor = db.cursor() + if device_uuid in device_to_skill: + for skill_uuid in device_to_skill[device_uuid]: + skill = skills[skill_uuid] + version_hash = skill['identifier'] + skill_name = skill['name'] + print('Creating skill with id {}'.format(skill_uuid)) + query = 'insert into skill.skill(id, name) values (%s, %s)' + params = (skill_uuid, skill_name) + cursor.execute(query, params) + + skill_version_id = str(uuid.uuid4()) + query = 'insert into skill.setting_version(id, skill_id, version_hash) values (%s, %s, %s)' + params = (skill_version_id, skill_uuid, version_hash) + cursor.execute(query, params) + + device_skill_id = str(uuid.uuid4()) + query = 'insert into device.device_skill (id, device_id, skill_id) values (%s, %s, %s)' + params = (device_skill_id, device_uuid, skill_uuid) + cursor.execute(query, params) + for section_uuid in skill_to_section[skill_uuid]: + print('Creating section with id {}'.format(section_uuid)) + query = 'insert into skill.setting_section(id, skill_version_id, section, display_order) values (%s, %s, %s, %s)' + section = skill_sections[section_uuid] + section_name = section['section'] + display_order = section['display_order'] + params = (section_uuid, skill_version_id, section_name, display_order) + cursor.execute(query, params) + for field_uuid in section_to_field[section_uuid]: + print('Creating field with id {}'.format(field_uuid)) + query = 'insert into skill.setting(id, setting_section_id, setting, setting_type, hint, label, placeholder, hidden, options, display_order) values (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s)' + field = skill_fields[field_uuid] + setting = field['name'] + setting_type = field['type'] + hint = field['hint'] + label = field['label'] + placeholder = field['placeholder'] + hidden = field['hide'] + options = field['options'] + display_order = field['order'] + params = (field_uuid, section_uuid, setting, setting_type, hint, label, placeholder, hidden == 'true', options, display_order) + cursor.execute(query, params) + + field_value = skill_field_values[field_uuid]['field_value'] + query = 'insert into device.skill_setting(device_skill_id, setting_id, value) values (%s, %s, %s)' + params = (device_skill_id, field_uuid, field_value) + cursor.execute(query, params) + + +def create_devices(): + for user in user_devices: + if user in users: + category = {} + for device_uuid, name in user_devices[user]: + if name in category: + category[name].append(device_uuid) + else: + category[name] = [device_uuid] + print('User {} Categories: {}'.format(user, category)) + for name in category: + group = 1 + for device_uuid in category[name]: + create_device(device_uuid, 'Group {}'.format(group)) + create_device_skills(device_uuid) + group += 1 + + +create_devices() + diff --git a/db/scripts/queries.cypher b/db/scripts/queries.cypher new file mode 100644 index 00000000..fe90122b --- /dev/null +++ b/db/scripts/queries.cypher @@ -0,0 +1,35 @@ +users.csv +match (n:User) return n.uuid, n.email, n.password + +subscription.csv +match (n) where ((n:MonthlyAccount) or (n:YearlyAccount)) and n.expiratesAt is not null set n.expiresAt = n.expiratesAt + +match (n:User)-[:ACCOUNT]->(acc) +where not (acc:FreeAccount) +return n.uuid, acc.customerId, acc.lastPayment, labels(acc)[0] + +user_location.csv +match (n:User)-[:LIVES_AT]->()-[:COORDINATE]->(coord) return n.uuid, coord.latitude, coord.longitude + +user_setting.csv +match (n:User)-[:SETTING]->(setting)-[:TTS_SETTING]->(tts:Active), (setting)-[:LISTENER_SETTING]->(listener) +with filter(l in labels(tts) where l <> 'Active') as s, n, tts, setting, listener +return n.uuid, setting.dateFormat, setting.timeFormat, setting.systemUnit, s[0], tts.voice, listener.wakeWord, listener.sampleRate, listener.channels, listener.phonemes, listener.threshold, listener.multiplier, listener.energyRatio + +device.csv +match (user:User)-[:DEVICE]->(n:Device) return n.uuid, user.uuid, n.name, n.description, n.platform, n.enclosureVersion, n.coreVersion + +devices_location.csv +match (n:Device)-[:PLACED_AT]->()-[:COORDINATE]->(coord) return n.uuid, coord.latitude, coord.longitude + +skill.csv +match (n:Skill) return n.uuid, n.name, n.description, n.identifier + +skill_section.csv +match (skill:Skill)-[:METADATA]->()-[:SECTION]->(section) return section.uuid, skill.uuid, section.name, section.order order by skill.uuid + +skill_fields.csv +match (section:SkillMetadataSection)-[:FIELD]->(field:SkillMetadataField) return field.uuid, section.uuid, field.name, field.type, field.label, field.hint, field.placeholder, field.hide, field.options, field.order + +skill_fields_values.csv +match (device:Device)-[:SKILL_MAPPING]->(map:SkillMetadataMapping)-[r:SKILL_FIELD_VALUE]->(field:SkillMetadataField), (map)-[:SKILL]->(skill:Skill) return field.uuid, skill.uuid, device.uuid, r.value \ No newline at end of file