From 6be09329d76ac410a1c66f0c5d6c272baa45c5c0 Mon Sep 17 00:00:00 2001 From: Vladimir Krylov Date: Tue, 5 Jan 2016 15:03:29 +0200 Subject: [PATCH] Story#108091488 - add index to reserved domains --- ...6_name_and_password_for_reserved_domain.rb | 1 + db/schema-read-only.rb | 57 ++--- db/structure.sql | 219 ++++++++++++------ 3 files changed, 167 insertions(+), 110 deletions(-) diff --git a/db/migrate/20151202123506_name_and_password_for_reserved_domain.rb b/db/migrate/20151202123506_name_and_password_for_reserved_domain.rb index 1176ee255..3e4f16500 100644 --- a/db/migrate/20151202123506_name_and_password_for_reserved_domain.rb +++ b/db/migrate/20151202123506_name_and_password_for_reserved_domain.rb @@ -2,6 +2,7 @@ class NameAndPasswordForReservedDomain < ActiveRecord::Migration def up add_column :reserved_domains, :name, :string add_column :reserved_domains, :password, :string + add_index :reserved_domains, :name ReservedDomain.find_each do |domain| names = domain.names diff --git a/db/schema-read-only.rb b/db/schema-read-only.rb index b362619b0..6cb666e3b 100644 --- a/db/schema-read-only.rb +++ b/db/schema-read-only.rb @@ -11,7 +11,7 @@ # # It's strongly recommended that you check this file into your version control system. -ActiveRecord::Schema.define(version: 20151029152638) do +ActiveRecord::Schema.define(version: 20151202123506) do # These are extensions that must be enabled in order to support this database enable_extension "plpgsql" @@ -240,19 +240,20 @@ ActiveRecord::Schema.define(version: 20151029152638) do end create_table "dnskeys", force: :cascade do |t| - t.integer "domain_id" - t.integer "flags" - t.integer "protocol" - t.integer "alg" - t.text "public_key" - t.integer "delegation_signer_id" - t.string "ds_key_tag" - t.integer "ds_alg" - t.integer "ds_digest_type" - t.string "ds_digest" - t.string "creator_str" - t.string "updator_str" - t.integer "legacy_domain_id" + t.integer "domain_id" + t.integer "flags" + t.integer "protocol" + t.integer "alg" + t.text "public_key" + t.integer "delegation_signer_id" + t.string "ds_key_tag" + t.integer "ds_alg" + t.integer "ds_digest_type" + t.string "ds_digest" + t.string "creator_str" + t.string "updator_str" + t.integer "legacy_domain_id" + t.datetime "updated_at" end add_index "dnskeys", ["delegation_signer_id"], name: "index_dnskeys_on_delegation_signer_id", using: :btree @@ -336,6 +337,7 @@ ActiveRecord::Schema.define(version: 20151029152638) do end add_index "domains", ["delete_at"], name: "index_domains_on_delete_at", using: :btree + add_index "domains", ["name"], name: "index_domains_on_name", unique: true, using: :btree add_index "domains", ["outzone_at"], name: "index_domains_on_outzone_at", using: :btree add_index "domains", ["registrant_id"], name: "index_domains_on_registrant_id", using: :btree add_index "domains", ["registrant_verification_asked_at"], name: "index_domains_on_registrant_verification_asked_at", using: :btree @@ -442,9 +444,7 @@ ActiveRecord::Schema.define(version: 20151029152638) do t.integer "documentable_id" t.string "documentable_type" t.datetime "created_at" - t.datetime "updated_at" t.string "creator_str" - t.string "updator_str" t.string "path" end @@ -739,21 +739,6 @@ ActiveRecord::Schema.define(version: 20151029152638) do add_index "log_keyrelays", ["item_type", "item_id"], name: "index_log_keyrelays_on_item_type_and_item_id", using: :btree add_index "log_keyrelays", ["whodunnit"], name: "index_log_keyrelays_on_whodunnit", using: :btree - create_table "log_legal_documents", force: :cascade do |t| - t.string "item_type", null: false - t.integer "item_id", null: false - t.string "event", null: false - t.string "whodunnit" - t.json "object" - t.json "object_changes" - t.datetime "created_at" - t.string "session" - t.json "children" - end - - add_index "log_legal_documents", ["item_type", "item_id"], name: "index_log_legal_documents_on_item_type_and_item_id", using: :btree - add_index "log_legal_documents", ["whodunnit"], name: "index_log_legal_documents_on_whodunnit", using: :btree - create_table "log_messages", force: :cascade do |t| t.string "item_type", null: false t.integer "item_id", null: false @@ -910,10 +895,10 @@ ActiveRecord::Schema.define(version: 20151029152638) do create_table "nameservers", force: :cascade do |t| t.string "hostname" - t.string "ipv4" + t.string "ipv4", array: true t.datetime "created_at" t.datetime "updated_at" - t.string "ipv6" + t.string "ipv6", array: true t.integer "domain_id" t.string "creator_str" t.string "updator_str" @@ -1011,9 +996,13 @@ ActiveRecord::Schema.define(version: 20151029152638) do t.datetime "updated_at" t.string "creator_str" t.string "updator_str" - t.hstore "names" + t.integer "legacy_id" + t.string "name" + t.string "password" end + add_index "reserved_domains", ["name"], name: "index_reserved_domains_on_name", using: :btree + create_table "settings", force: :cascade do |t| t.string "var", null: false t.text "value" diff --git a/db/structure.sql b/db/structure.sql index b2480a04e..c4ede9569 100644 --- a/db/structure.sql +++ b/db/structure.sql @@ -39,6 +39,106 @@ COMMENT ON EXTENSION hstore IS 'data type for storing sets of (key, value) pairs SET search_path = public, pg_catalog; +-- +-- Name: fill_ident_country(); Type: FUNCTION; Schema: public; Owner: - +-- + +CREATE FUNCTION fill_ident_country() RETURNS boolean + LANGUAGE plpgsql + AS $_$ + DECLARE + changed BOOLEAN; + multiplier INT []; + multiplier2 INT []; + multiplier3 INT []; + multiplier4 INT []; + r RECORD; + control TEXT; + total INT; + i INT; + mod INT; + counter INT; + BEGIN + + multiplier := ARRAY [1, 2, 3, 4, 5, 6, 7, 8, 9, 1]; + multiplier2 := ARRAY [3, 4, 5, 6, 7, 8, 9, 1, 2, 3]; + multiplier3 := ARRAY [1, 2, 3, 4, 5, 6, 7]; + multiplier4 := ARRAY [3, 4, 5, 6, 7, 8, 9]; + + FOR r IN SELECT id, ident FROM contacts WHERE ident_type = 'priv' AND ident_country_code IS NULL + LOOP + IF (length(r.ident) = 11 AND (r.ident ~ '^[0-9]+$') AND (substring(r.ident, 1, 1) = '3' OR substring(r.ident, 1, 1) = '4' OR substring(r.ident, 1, 1) = '5' OR substring(r.ident, 1, 1) = '6')) + THEN + total := 0; + counter := 1; + FOREACH i IN ARRAY multiplier + LOOP + total := (total + (i * to_number(substring(r.ident, counter, 1), '9'))); + counter := (counter + 1); + END LOOP; + mod := (total % 11); + counter := 1; + IF (mod >= 10) + THEN + total = 0; + FOREACH i IN ARRAY multiplier2 + LOOP + total := (total + (i * to_number(substring(r.ident, counter, 1), '9'))); + counter := (counter + 1); + END LOOP; + mod := (total % 11); + END IF; + IF (mod = 10) + THEN + mod := 0; + END IF; + IF (substring(r.ident, 11, 1) = to_char(mod, 'FM999MI')) + THEN + UPDATE contacts SET ident_country_code = 'EE' WHERE id = r.id; + END IF; + total := 0; + END IF; + END LOOP; + + FOR r IN SELECT id, ident FROM contacts WHERE ident_type = 'org' AND ident_country_code IS NULL + LOOP + IF (length(r.ident) = 8 AND (r.ident ~ '^[0-9]+$') AND (substring(r.ident, 1, 1) = '1' OR substring(r.ident, 1, 1) = '8' OR substring(r.ident, 1, 1) = '9')) + THEN + total := 0; + counter := 1; + FOREACH i IN ARRAY multiplier3 + LOOP + total := (total + (i * to_number(substring(r.ident, counter, 1), '9'))); + counter := (counter + 1); + END LOOP; + mod := total % 11; + total := 0; + counter := 1; + IF (mod >= 10) + THEN + total = 0; + FOREACH i IN ARRAY multiplier4 + LOOP + total := (total + (i * to_number(substring(r.ident, counter, 1), '9'))); + counter := (counter + 1); + END LOOP; + mod := (total % 11); + END IF; + IF (mod = 10) + THEN + mod := 0; + END IF; + IF (substring(r.ident, 8, 1) = to_char(mod, 'FM999MI')) + THEN + UPDATE contacts SET ident_country_code = 'EE' WHERE id = r.id; + END IF; + END IF; + END LOOP; + RETURN changed; + END; + $_$; + + -- -- Name: generate_zonefile(character varying); Type: FUNCTION; Schema: public; Owner: - -- @@ -114,7 +214,7 @@ CREATE FUNCTION generate_zonefile(i_origin character varying) RETURNS text WHERE d.name LIKE include_filter AND d.name NOT LIKE exclude_filter AND ns.hostname LIKE '%.' || d.name AND d.name <> i_origin - AND ns.ipv4 IS NOT NULL AND ns.ipv4 <> '' + AND ns.ipv4 IS NOT NULL AND ns.ipv4 <> '{}' AND NOT ('{serverHold,clientHold}' && d.statuses) ), chr(10) ) INTO tmp_var; @@ -134,7 +234,7 @@ CREATE FUNCTION generate_zonefile(i_origin character varying) RETURNS text WHERE d.name LIKE include_filter AND d.name NOT LIKE exclude_filter AND ns.hostname LIKE '%.' || d.name AND d.name <> i_origin - AND ns.ipv6 IS NOT NULL AND ns.ipv6 <> '' + AND ns.ipv6 IS NOT NULL AND ns.ipv6 <> '{}' AND NOT ('{serverHold,clientHold}' && d.statuses) ), chr(10) ) INTO tmp_var; @@ -145,8 +245,8 @@ CREATE FUNCTION generate_zonefile(i_origin character varying) RETURNS text SELECT array_to_string( array( SELECT concat( - d.name_puny, '. IN DS ', dk.ds_key_tag, ' ', - dk.ds_alg, ' ', dk.ds_digest_type, ' ( ', dk.ds_digest, ' )' + d.name_puny, '. 3600 IN DS ', dk.ds_key_tag, ' ', + dk.ds_alg, ' ', dk.ds_digest_type, ' ', dk.ds_digest ) FROM domains d JOIN dnskeys dk ON dk.domain_id = d.id @@ -745,7 +845,8 @@ CREATE TABLE dnskeys ( ds_digest character varying, creator_str character varying, updator_str character varying, - legacy_domain_id integer + legacy_domain_id integer, + updated_at timestamp without time zone ); @@ -1130,9 +1231,7 @@ CREATE TABLE legal_documents ( documentable_id integer, documentable_type character varying, created_at timestamp without time zone, - updated_at timestamp without time zone, creator_str character varying, - updator_str character varying, path character varying ); @@ -1863,43 +1962,6 @@ CREATE SEQUENCE log_keyrelays_id_seq ALTER SEQUENCE log_keyrelays_id_seq OWNED BY log_keyrelays.id; --- --- Name: log_legal_documents; Type: TABLE; Schema: public; Owner: -; Tablespace: --- - -CREATE TABLE log_legal_documents ( - id integer NOT NULL, - item_type character varying NOT NULL, - item_id integer NOT NULL, - event character varying NOT NULL, - whodunnit character varying, - object json, - object_changes json, - created_at timestamp without time zone, - session character varying, - children json -); - - --- --- Name: log_legal_documents_id_seq; Type: SEQUENCE; Schema: public; Owner: - --- - -CREATE SEQUENCE log_legal_documents_id_seq - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; - - --- --- Name: log_legal_documents_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: - --- - -ALTER SEQUENCE log_legal_documents_id_seq OWNED BY log_legal_documents.id; - - -- -- Name: log_messages; Type: TABLE; Schema: public; Owner: -; Tablespace: -- @@ -2313,10 +2375,10 @@ ALTER SEQUENCE messages_id_seq OWNED BY messages.id; CREATE TABLE nameservers ( id integer NOT NULL, hostname character varying, - ipv4 character varying, + ipv4 character varying[], created_at timestamp without time zone, updated_at timestamp without time zone, - ipv6 character varying, + ipv6 character varying[], domain_id integer, creator_str character varying, updator_str character varying, @@ -2560,7 +2622,9 @@ CREATE TABLE reserved_domains ( updated_at timestamp without time zone, creator_str character varying, updator_str character varying, - names hstore + legacy_id integer, + name character varying, + password character varying ); @@ -3126,13 +3190,6 @@ ALTER TABLE ONLY log_invoices ALTER COLUMN id SET DEFAULT nextval('log_invoices_ ALTER TABLE ONLY log_keyrelays ALTER COLUMN id SET DEFAULT nextval('log_keyrelays_id_seq'::regclass); --- --- Name: id; Type: DEFAULT; Schema: public; Owner: - --- - -ALTER TABLE ONLY log_legal_documents ALTER COLUMN id SET DEFAULT nextval('log_legal_documents_id_seq'::regclass); - - -- -- Name: id; Type: DEFAULT; Schema: public; Owner: - -- @@ -3645,14 +3702,6 @@ ALTER TABLE ONLY log_keyrelays ADD CONSTRAINT log_keyrelays_pkey PRIMARY KEY (id); --- --- Name: log_legal_documents_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: --- - -ALTER TABLE ONLY log_legal_documents - ADD CONSTRAINT log_legal_documents_pkey PRIMARY KEY (id); - - -- -- Name: log_messages_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: -- @@ -3985,6 +4034,13 @@ CREATE INDEX index_domain_transfers_on_domain_id ON domain_transfers USING btree CREATE INDEX index_domains_on_delete_at ON domains USING btree (delete_at); +-- +-- Name: index_domains_on_name; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + +CREATE UNIQUE INDEX index_domains_on_name ON domains USING btree (name); + + -- -- Name: index_domains_on_outzone_at; Type: INDEX; Schema: public; Owner: -; Tablespace: -- @@ -4349,20 +4405,6 @@ CREATE INDEX index_log_keyrelays_on_item_type_and_item_id ON log_keyrelays USING CREATE INDEX index_log_keyrelays_on_whodunnit ON log_keyrelays USING btree (whodunnit); --- --- Name: index_log_legal_documents_on_item_type_and_item_id; Type: INDEX; Schema: public; Owner: -; Tablespace: --- - -CREATE INDEX index_log_legal_documents_on_item_type_and_item_id ON log_legal_documents USING btree (item_type, item_id); - - --- --- Name: index_log_legal_documents_on_whodunnit; Type: INDEX; Schema: public; Owner: -; Tablespace: --- - -CREATE INDEX index_log_legal_documents_on_whodunnit ON log_legal_documents USING btree (whodunnit); - - -- -- Name: index_log_messages_on_item_type_and_item_id; Type: INDEX; Schema: public; Owner: -; Tablespace: -- @@ -4510,6 +4552,13 @@ CREATE INDEX index_registrant_verifications_on_domain_id ON registrant_verificat CREATE INDEX index_registrars_on_code ON registrars USING btree (code); +-- +-- Name: index_reserved_domains_on_name; Type: INDEX; Schema: public; Owner: -; Tablespace: +-- + +CREATE INDEX index_reserved_domains_on_name ON reserved_domains USING btree (name); + + -- -- Name: index_settings_on_thing_type_and_thing_id_and_var; Type: INDEX; Schema: public; Owner: -; Tablespace: -- @@ -4947,5 +4996,23 @@ INSERT INTO schema_migrations (version) VALUES ('20150921110152'); INSERT INTO schema_migrations (version) VALUES ('20150921111842'); +INSERT INTO schema_migrations (version) VALUES ('20151028183132'); + INSERT INTO schema_migrations (version) VALUES ('20151029152638'); +INSERT INTO schema_migrations (version) VALUES ('20151112160452'); + +INSERT INTO schema_migrations (version) VALUES ('20151117081204'); + +INSERT INTO schema_migrations (version) VALUES ('20151120090455'); + +INSERT INTO schema_migrations (version) VALUES ('20151124200353'); + +INSERT INTO schema_migrations (version) VALUES ('20151125155601'); + +INSERT INTO schema_migrations (version) VALUES ('20151127091716'); + +INSERT INTO schema_migrations (version) VALUES ('20151130175654'); + +INSERT INTO schema_migrations (version) VALUES ('20151202123506'); +