diff --git a/db/migrate/20170422130054_update_generate_zonefile_sql.rb b/db/migrate/20170422130054_update_generate_zonefile_sql.rb new file mode 100644 index 000000000..d20257f31 --- /dev/null +++ b/db/migrate/20170422130054_update_generate_zonefile_sql.rb @@ -0,0 +1,124 @@ +class UpdateGenerateZonefileSql < ActiveRecord::Migration + def change + execute <<-SQL + CREATE OR REPLACE 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)); + + -- origin ns records + SELECT ns_records FROM zonefile_settings zf WHERE i_origin = zf.origin INTO tmp_var; + ret := concat(ret, '; Zone NS Records', chr(10), tmp_var, chr(10)); + + -- ns records + SELECT array_to_string( + array( + SELECT concat(d.name_puny, '. IN NS ', coalesce(ns.hostname_puny, 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 + AND NOT ('{serverHold,clientHold,inactive}' && d.statuses) + ORDER BY d.name + ), + chr(10) + ) INTO tmp_var; + + ret := concat(ret, tmp_var, chr(10), chr(10)); + + -- origin a glue records + SELECT a_records FROM zonefile_settings zf WHERE i_origin = zf.origin INTO tmp_var; + ret := concat(ret, '; Zone A Records', chr(10), tmp_var, chr(10)); + + -- a glue records for other nameservers + SELECT array_to_string( + array( + SELECT concat(coalesce(ns.hostname_puny, ns.hostname), '. IN A ', unnest(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 ('{serverHold,clientHold,inactive}' && d.statuses) + ), chr(10) + ) INTO tmp_var; + + ret := concat(ret, tmp_var, chr(10), chr(10)); + + -- origin aaaa glue records + SELECT a4_records FROM zonefile_settings zf WHERE i_origin = zf.origin INTO tmp_var; + ret := concat(ret, '; Zone AAAA Records', chr(10), tmp_var, chr(10)); + + -- aaaa glue records for other nameservers + SELECT array_to_string( + array( + SELECT concat(coalesce(ns.hostname_puny, ns.hostname), '. IN AAAA ', unnest(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 ('{serverHold,clientHold,inactive}' && d.statuses) + ), chr(10) + ) INTO tmp_var; + + ret := concat(ret, tmp_var, chr(10), chr(10)); + + -- ds records + SELECT array_to_string( + array( + SELECT concat( + 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 + WHERE d.name LIKE include_filter AND d.name NOT LIKE exclude_filter AND dk.flags = 257 + AND NOT ('{serverHold,clientHold,inactive}' && d.statuses) + ), + chr(10) + ) INTO tmp_var; + + ret := concat(ret, '; Zone DS Records', chr(10), tmp_var, chr(10)); + + RETURN ret; + END; + $_$; + SQL + end +end diff --git a/db/schema-read-only.rb b/db/schema-read-only.rb index 11fdff432..3e4245111 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: 20170420125200) do +ActiveRecord::Schema.define(version: 20170422130054) do # These are extensions that must be enabled in order to support this database enable_extension "plpgsql" diff --git a/db/structure.sql b/db/structure.sql index 37dadaf65..49656326c 100644 --- a/db/structure.sql +++ b/db/structure.sql @@ -167,7 +167,7 @@ CREATE FUNCTION generate_zonefile(i_origin character varying) RETURNS text exclude_filter varchar := ''; tmp_var text; ret text; - BEGIN + BEGIN -- define filters include_filter = '%.' || i_origin; @@ -203,7 +203,7 @@ CREATE FUNCTION generate_zonefile(i_origin character varying) RETURNS text -- ns records SELECT array_to_string( array( - SELECT concat(d.name_puny, '. IN NS ', ns.hostname, '.') + SELECT concat(d.name_puny, '. IN NS ', coalesce(ns.hostname_puny, 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 @@ -222,7 +222,7 @@ CREATE FUNCTION generate_zonefile(i_origin character varying) RETURNS text -- a glue records for other nameservers SELECT array_to_string( array( - SELECT concat(ns.hostname, '. IN A ', unnest(ns.ipv4)) + SELECT concat(coalesce(ns.hostname_puny, ns.hostname), '. IN A ', unnest(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 @@ -242,7 +242,7 @@ CREATE FUNCTION generate_zonefile(i_origin character varying) RETURNS text -- aaaa glue records for other nameservers SELECT array_to_string( array( - SELECT concat(ns.hostname, '. IN AAAA ', unnest(ns.ipv6)) + SELECT concat(coalesce(ns.hostname_puny, ns.hostname), '. IN AAAA ', unnest(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 @@ -2930,7 +2930,7 @@ ALTER SEQUENCE whois_records_id_seq OWNED BY whois_records.id; -- --- Name: zones; Type: TABLE; Schema: public; Owner: -; Tablespace: +-- Name: zones; Type: TABLE; Schema: public; Owner: -; Tablespace: -- CREATE TABLE zones ( @@ -3985,7 +3985,7 @@ ALTER TABLE ONLY whois_records -- --- Name: zones_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: +-- Name: zones_pkey; Type: CONSTRAINT; Schema: public; Owner: -; Tablespace: -- ALTER TABLE ONLY zones @@ -5217,3 +5217,5 @@ INSERT INTO schema_migrations (version) VALUES ('20170419120048'); INSERT INTO schema_migrations (version) VALUES ('20170420125200'); +INSERT INTO schema_migrations (version) VALUES ('20170422130054'); +