From 7ca49fbc2dd1f5590a610574fc8ba761521b6b5e Mon Sep 17 00:00:00 2001 From: Priit Tark Date: Thu, 2 Jul 2015 17:23:55 +0300 Subject: [PATCH] Update structure file --- .../20140730082358_add_reserved_domains.rb | 2 +- db/schema.rb | 39 +++- db/structure.sql | 206 +++++++++++++++++- 3 files changed, 236 insertions(+), 11 deletions(-) diff --git a/db/migrate/20140730082358_add_reserved_domains.rb b/db/migrate/20140730082358_add_reserved_domains.rb index f6afecd7b..26a2ea0de 100644 --- a/db/migrate/20140730082358_add_reserved_domains.rb +++ b/db/migrate/20140730082358_add_reserved_domains.rb @@ -2,7 +2,7 @@ class AddReservedDomains < ActiveRecord::Migration def up create_table :reserved_domains do |t| t.string :name - t.timestamps + t.timestamps null: false end domains = %w( diff --git a/db/schema.rb b/db/schema.rb index b83051936..19b75088b 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -11,7 +11,7 @@ # # It's strongly recommended that you check this file into your version control system. -ActiveRecord::Schema.define(version: 20150612123111) do +ActiveRecord::Schema.define(version: 20150701074344) do # These are extensions that must be enabled in order to support this database enable_extension "plpgsql" @@ -131,6 +131,14 @@ ActiveRecord::Schema.define(version: 20150612123111) do t.datetime "updated_at" end + create_table "blocked_domains", force: :cascade do |t| + t.string "names", array: true + t.datetime "created_at" + t.datetime "updated_at" + t.string "creator_str" + t.string "updator_str" + end + create_table "cached_nameservers", id: false, force: :cascade do |t| t.string "hostname", limit: 255 t.string "ipv4", limit: 255 @@ -521,6 +529,21 @@ ActiveRecord::Schema.define(version: 20150612123111) do add_index "log_bank_transactions", ["item_type", "item_id"], name: "index_log_bank_transactions_on_item_type_and_item_id", using: :btree add_index "log_bank_transactions", ["whodunnit"], name: "index_log_bank_transactions_on_whodunnit", using: :btree + create_table "log_blocked_domains", 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_blocked_domains", ["item_type", "item_id"], name: "index_log_blocked_domains_on_item_type_and_item_id", using: :btree + add_index "log_blocked_domains", ["whodunnit"], name: "index_log_blocked_domains_on_whodunnit", using: :btree + create_table "log_certificates", force: :cascade do |t| t.string "item_type", null: false t.integer "item_id", null: false @@ -909,14 +932,14 @@ ActiveRecord::Schema.define(version: 20150612123111) do end create_table "que_jobs", id: false, force: :cascade do |t| - t.integer "priority", limit: 2, default: 100, null: false - t.datetime "run_at", default: "now()", null: false - t.integer "job_id", limit: 8, default: "nextval('que_jobs_job_id_seq'::regclass)", null: false - t.text "job_class", null: false - t.json "args", default: [], null: false - t.integer "error_count", default: 0, null: false + t.integer "priority", limit: 2, default: 100, null: false + t.datetime "run_at", default: '2015-06-29 12:38:58', null: false + t.integer "job_id", limit: 8, default: 0, null: false + t.text "job_class", null: false + t.json "args", default: [], null: false + t.integer "error_count", default: 0, null: false t.text "last_error" - t.text "queue", default: "", null: false + t.text "queue", default: "", null: false end create_table "registrant_verifications", force: :cascade do |t| diff --git a/db/structure.sql b/db/structure.sql index f6f83d7f9..271e8d8ae 100644 --- a/db/structure.sql +++ b/db/structure.sql @@ -25,6 +25,167 @@ COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language'; SET search_path = public, pg_catalog; +-- +-- Name: generate_zonefile(character varying); Type: FUNCTION; Schema: public; Owner: - +-- + +CREATE FUNCTION generate_zonefile(i_origin character varying) RETURNS text + LANGUAGE plpgsql + AS $_$ + DECLARE + zone_header text := concat('$ORIGIN ', i_origin, '.'); + serial_num varchar; + include_filter varchar := ''; + exclude_filter varchar := ''; + tmp_var text; + ret text; + BEGIN + -- define filters + include_filter = '%.' || i_origin; + + -- for %.%.% + IF i_origin ~ '\.' THEN + exclude_filter := ''; + -- for %.% + ELSE + exclude_filter := '%.%.' || i_origin; + END IF; + + SELECT ROUND(extract(epoch from now() at time zone 'utc')) INTO serial_num; + + -- zonefile header + SELECT concat( + format('%-10s', '$ORIGIN .'), chr(10), + format('%-10s', '$TTL'), zf.ttl, chr(10), chr(10), + format('%-10s', i_origin || '.'), 'IN SOA ', zf.master_nameserver, '. ', zf.email, '. (', chr(10), + format('%-17s', ''), format('%-12s', serial_num), '; serial number', chr(10), + format('%-17s', ''), format('%-12s', zf.refresh), '; refresh, seconds', chr(10), + format('%-17s', ''), format('%-12s', zf.retry), '; retry, seconds', chr(10), + format('%-17s', ''), format('%-12s', zf.expire), '; expire, seconds', chr(10), + format('%-17s', ''), format('%-12s', zf.minimum_ttl), '; minimum TTL, seconds', chr(10), + format('%-17s', ''), ')' + ) FROM zonefile_settings zf WHERE i_origin = zf.origin INTO tmp_var; + + ret = concat(tmp_var, chr(10), chr(10)); + + -- ns records + SELECT array_to_string( + array( + SELECT concat(d.name_puny, '. IN NS ', ns.hostname, '.') + FROM domains d + JOIN nameservers ns ON ns.domain_id = d.id + WHERE d.name LIKE include_filter AND d.name NOT LIKE exclude_filter OR d.name = i_origin + ORDER BY d.name + ), + chr(10) + ) INTO tmp_var; + + ret := concat(ret, '; Zone NS Records', chr(10), tmp_var, chr(10), chr(10)); + + -- a glue records for origin nameservers + SELECT array_to_string( + array( + SELECT concat(ns.hostname, '. IN A ', ns.ipv4) + FROM nameservers ns + JOIN domains d ON d.id = ns.domain_id + WHERE d.name = i_origin + AND ns.hostname LIKE '%.' || d.name + AND ns.ipv4 IS NOT NULL AND ns.ipv4 <> '' + ), chr(10) + ) INTO tmp_var; + + ret := concat(ret, '; Zone A Records', chr(10), tmp_var); + + -- a glue records for other nameservers + SELECT array_to_string( + array( + SELECT concat(ns.hostname, '. IN A ', ns.ipv4) + FROM nameservers ns + JOIN domains d ON d.id = ns.domain_id + 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 NOT EXISTS ( -- filter out glue records that already appeared in origin glue recrods + SELECT 1 FROM nameservers nsi + JOIN domains di ON nsi.domain_id = di.id + WHERE di.name = i_origin + AND nsi.hostname = ns.hostname + ) + ), chr(10) + ) INTO tmp_var; + + -- TODO This is a possible subtitition to the previous query, stress testing is needed to see which is faster + + -- SELECT ns.* + -- FROM nameservers ns + -- JOIN domains d ON d.id = ns.domain_id + -- WHERE d.name LIKE '%ee' AND d.name NOT LIKE '%pri.ee' + -- AND ns.hostname LIKE '%.' || d.name + -- AND d.name <> 'ee' + -- AND ns.ipv4 IS NOT NULL AND ns.ipv4 <> '' + -- AND ns.hostname NOT IN ( + -- SELECT ns.hostname FROM domains d JOIN nameservers ns ON d.id = ns.domain_id WHERE d.name = 'ee' + -- ) + + ret := concat(ret, chr(10), tmp_var, chr(10), chr(10)); + + -- aaaa glue records for origin nameservers + SELECT array_to_string( + array( + SELECT concat(ns.hostname, '. IN AAAA ', ns.ipv6) + FROM nameservers ns + JOIN domains d ON d.id = ns.domain_id + WHERE d.name = i_origin + AND ns.hostname LIKE '%.' || d.name + AND ns.ipv6 IS NOT NULL AND ns.ipv6 <> '' + ), chr(10) + ) INTO tmp_var; + + ret := concat(ret, '; Zone AAAA Records', chr(10), tmp_var); + + -- aaaa glue records for other nameservers + SELECT array_to_string( + array( + SELECT concat(ns.hostname, '. IN AAAA ', ns.ipv6) + FROM nameservers ns + JOIN domains d ON d.id = ns.domain_id + 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 NOT EXISTS ( -- filter out glue records that already appeared in origin glue recrods + SELECT 1 FROM nameservers nsi + JOIN domains di ON nsi.domain_id = di.id + WHERE di.name = i_origin + AND nsi.hostname = ns.hostname + ) + ), chr(10) + ) INTO tmp_var; + + ret := concat(ret, chr(10), tmp_var, chr(10), chr(10)); + + -- ds records + 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, ' )' + ) + FROM domains d + JOIN dnskeys dk ON dk.domain_id = d.id + WHERE d.name LIKE include_filter AND d.name NOT LIKE exclude_filter AND dk.flags = 257 + ), + chr(10) + ) INTO tmp_var; + + ret := concat(ret, '; Zone DS Records', chr(10), tmp_var, chr(10)); + + RETURN ret; + END; + $_$; + + SET default_tablespace = ''; SET default_with_oids = false; @@ -2243,8 +2404,8 @@ ALTER SEQUENCE pricelists_id_seq OWNED BY pricelists.id; CREATE TABLE que_jobs ( priority smallint DEFAULT 100 NOT NULL, - run_at timestamp without time zone DEFAULT '2015-06-29 12:38:58.258132'::timestamp without time zone NOT NULL, - job_id bigint DEFAULT 0 NOT NULL, + run_at timestamp with time zone DEFAULT now() NOT NULL, + job_id bigint NOT NULL, job_class text NOT NULL, args json DEFAULT '[]'::json NOT NULL, error_count integer DEFAULT 0 NOT NULL, @@ -2253,6 +2414,32 @@ CREATE TABLE que_jobs ( ); +-- +-- Name: TABLE que_jobs; Type: COMMENT; Schema: public; Owner: - +-- + +COMMENT ON TABLE que_jobs IS '3'; + + +-- +-- Name: que_jobs_job_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + +CREATE SEQUENCE que_jobs_job_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +-- +-- Name: que_jobs_job_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: - +-- + +ALTER SEQUENCE que_jobs_job_id_seq OWNED BY que_jobs.job_id; + + -- -- Name: registrant_verifications; Type: TABLE; Schema: public; Owner: -; Tablespace: -- @@ -3008,6 +3195,13 @@ ALTER TABLE ONLY people ALTER COLUMN id SET DEFAULT nextval('people_id_seq'::reg ALTER TABLE ONLY pricelists ALTER COLUMN id SET DEFAULT nextval('pricelists_id_seq'::regclass); +-- +-- Name: job_id; Type: DEFAULT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY que_jobs ALTER COLUMN job_id SET DEFAULT nextval('que_jobs_job_id_seq'::regclass); + + -- -- Name: id; Type: DEFAULT; Schema: public; Owner: - -- @@ -3527,6 +3721,14 @@ ALTER TABLE ONLY pricelists ADD CONSTRAINT pricelists_pkey PRIMARY KEY (id); +-- +-- Name: que_jobs_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- + +ALTER TABLE ONLY que_jobs + ADD CONSTRAINT que_jobs_pkey PRIMARY KEY (queue, priority, run_at, job_id); + + -- -- Name: registrant_verifications_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: --