diff --git a/core/src/main/java/google/registry/reporting/icann/ActivityReportingQueryBuilder.java b/core/src/main/java/google/registry/reporting/icann/ActivityReportingQueryBuilder.java index cc6552c94..3cb44b2ad 100644 --- a/core/src/main/java/google/registry/reporting/icann/ActivityReportingQueryBuilder.java +++ b/core/src/main/java/google/registry/reporting/icann/ActivityReportingQueryBuilder.java @@ -14,8 +14,8 @@ package google.registry.reporting.icann; +import static google.registry.persistence.transaction.TransactionManagerFactory.tm; import static google.registry.reporting.icann.IcannReportingModule.DATASTORE_EXPORT_DATA_SET; -import static google.registry.reporting.icann.IcannReportingModule.ICANN_REPORTING_DATA_SET; import static google.registry.reporting.icann.QueryBuilderUtils.getQueryFromFile; import static google.registry.reporting.icann.QueryBuilderUtils.getTableName; @@ -38,6 +38,7 @@ public final class ActivityReportingQueryBuilder implements QueryBuilder { static final String EPP_METRICS = "epp_metrics"; static final String WHOIS_COUNTS = "whois_counts"; static final String ACTIVITY_REPORT_AGGREGATION = "activity_report_aggregation"; + final String BIGQUERY_DATA_SET = tm().isOfy() ? "icann_reporting" : "cloud_sql_icann_reporting"; @Inject @Config("projectId") @@ -53,7 +54,7 @@ public final class ActivityReportingQueryBuilder implements QueryBuilder { public String getReportQuery(YearMonth yearMonth) { return String.format( "#standardSQL\nSELECT * FROM `%s.%s.%s`", - projectId, ICANN_REPORTING_DATA_SET, getTableName(ACTIVITY_REPORT_AGGREGATION, yearMonth)); + projectId, BIGQUERY_DATA_SET, getTableName(ACTIVITY_REPORT_AGGREGATION, yearMonth)); } /** Sets the month we're doing activity reporting for, and returns the view query map. */ @@ -65,12 +66,20 @@ public final class ActivityReportingQueryBuilder implements QueryBuilder { LocalDate lastDayOfMonth = yearMonth.toLocalDate(1).plusMonths(1).minusDays(1); ImmutableMap.Builder queriesBuilder = ImmutableMap.builder(); - String operationalRegistrarsQuery = - SqlTemplate.create(getQueryFromFile("registrar_operating_status.sql")) - .put("PROJECT_ID", projectId) - .put("DATASTORE_EXPORT_DATA_SET", DATASTORE_EXPORT_DATA_SET) - .put("REGISTRAR_TABLE", "Registrar") - .build(); + String operationalRegistrarsQuery; + if (tm().isOfy()) { + operationalRegistrarsQuery = + SqlTemplate.create(getQueryFromFile("registrar_operating_status.sql")) + .put("PROJECT_ID", projectId) + .put("DATASTORE_EXPORT_DATA_SET", DATASTORE_EXPORT_DATA_SET) + .put("REGISTRAR_TABLE", "Registrar") + .build(); + } else { + operationalRegistrarsQuery = + SqlTemplate.create(getQueryFromFile("cloud_sql_registrar_operating_status.sql")) + .put("PROJECT_ID", projectId) + .build(); + } queriesBuilder.put( getTableName(REGISTRAR_OPERATING_STATUS, yearMonth), operationalRegistrarsQuery); @@ -93,7 +102,7 @@ public final class ActivityReportingQueryBuilder implements QueryBuilder { String eppQuery = SqlTemplate.create(getQueryFromFile("epp_metrics.sql")) .put("PROJECT_ID", projectId) - .put("ICANN_REPORTING_DATA_SET", ICANN_REPORTING_DATA_SET) + .put("ICANN_REPORTING_DATA_SET", BIGQUERY_DATA_SET) .put("MONTHLY_LOGS_TABLE", getTableName(MONTHLY_LOGS, yearMonth)) // All metadata logs for reporting come from google.registry.flows.FlowReporter. .put( @@ -105,25 +114,35 @@ public final class ActivityReportingQueryBuilder implements QueryBuilder { String whoisQuery = SqlTemplate.create(getQueryFromFile("whois_counts.sql")) .put("PROJECT_ID", projectId) - .put("ICANN_REPORTING_DATA_SET", ICANN_REPORTING_DATA_SET) + .put("ICANN_REPORTING_DATA_SET", BIGQUERY_DATA_SET) .put("MONTHLY_LOGS_TABLE", getTableName(MONTHLY_LOGS, yearMonth)) .build(); queriesBuilder.put(getTableName(WHOIS_COUNTS, yearMonth), whoisQuery); - String aggregateQuery = - SqlTemplate.create(getQueryFromFile("activity_report_aggregation.sql")) + SqlTemplate aggregateQuery = + SqlTemplate.create( + getQueryFromFile( + tm().isOfy() + ? "activity_report_aggregation.sql" + : "cloud_sql_activity_report_aggregation.sql")) .put("PROJECT_ID", projectId) - .put("ICANN_REPORTING_DATA_SET", ICANN_REPORTING_DATA_SET) .put( "REGISTRAR_OPERATING_STATUS_TABLE", getTableName(REGISTRAR_OPERATING_STATUS, yearMonth)) + .put("ICANN_REPORTING_DATA_SET", BIGQUERY_DATA_SET) .put("DNS_COUNTS_TABLE", getTableName(DNS_COUNTS, yearMonth)) .put("EPP_METRICS_TABLE", getTableName(EPP_METRICS, yearMonth)) - .put("WHOIS_COUNTS_TABLE", getTableName(WHOIS_COUNTS, yearMonth)) - .put("DATASTORE_EXPORT_DATA_SET", DATASTORE_EXPORT_DATA_SET) - .put("REGISTRY_TABLE", "Registry") - .build(); - queriesBuilder.put(getTableName(ACTIVITY_REPORT_AGGREGATION, yearMonth), aggregateQuery); + .put("WHOIS_COUNTS_TABLE", getTableName(WHOIS_COUNTS, yearMonth)); + + if (tm().isOfy()) { + aggregateQuery = + aggregateQuery + .put("REGISTRY_TABLE", "Registry") + .put("DATASTORE_EXPORT_DATA_SET", DATASTORE_EXPORT_DATA_SET); + } + + queriesBuilder.put( + getTableName(ACTIVITY_REPORT_AGGREGATION, yearMonth), aggregateQuery.build()); return queriesBuilder.build(); } diff --git a/core/src/main/java/google/registry/reporting/icann/IcannReportingModule.java b/core/src/main/java/google/registry/reporting/icann/IcannReportingModule.java index 22fdf013e..faf94f27c 100644 --- a/core/src/main/java/google/registry/reporting/icann/IcannReportingModule.java +++ b/core/src/main/java/google/registry/reporting/icann/IcannReportingModule.java @@ -14,6 +14,7 @@ package google.registry.reporting.icann; +import static google.registry.persistence.transaction.TransactionManagerFactory.tm; import static google.registry.request.RequestParameters.extractOptionalParameter; import static google.registry.request.RequestParameters.extractRequiredParameter; import static google.registry.request.RequestParameters.extractSetOfEnumParameters; @@ -41,7 +42,8 @@ public final class IcannReportingModule { static final String PARAM_SUBDIR = "subdir"; static final String PARAM_REPORT_TYPES = "reportTypes"; - static final String ICANN_REPORTING_DATA_SET = "icann_reporting"; + static final String ICANN_REPORTING_DATA_SET = + tm().isOfy() ? "icann_reporting" : "cloud_sql_icann_reporting"; static final String DATASTORE_EXPORT_DATA_SET = "latest_datastore_export"; static final String MANIFEST_FILE_NAME = "MANIFEST.txt"; diff --git a/core/src/main/java/google/registry/reporting/icann/sql/cloud_sql_activity_report_aggregation.sql b/core/src/main/java/google/registry/reporting/icann/sql/cloud_sql_activity_report_aggregation.sql new file mode 100644 index 000000000..ca1d59787 --- /dev/null +++ b/core/src/main/java/google/registry/reporting/icann/sql/cloud_sql_activity_report_aggregation.sql @@ -0,0 +1,103 @@ +#standardSQL + -- Copyright 2021 The Nomulus Authors. All Rights Reserved. + -- + -- Licensed under the Apache License, Version 2.0 (the "License"); + -- you may not use this file except in compliance with the License. + -- You may obtain a copy of the License at + -- + -- http://www.apache.org/licenses/LICENSE-2.0 + -- + -- Unless required by applicable law or agreed to in writing, software + -- distributed under the License is distributed on an "AS IS" BASIS, + -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + -- See the License for the specific language governing permissions and + -- limitations under the License. + + -- This query pulls from all intermediary tables to create the activity + -- report csv, via a table transpose and sum over all activity report fields. + +SELECT + RealTlds.tld AS tld, + SUM(IF(metricName = 'operational-registrars', count, 0)) AS operational_registrars, + -- We use the Centralized Zone Data Service. + "CZDS" AS zfa_passwords, + SUM(IF(metricName = 'whois-43-queries', count, 0)) AS whois_43_queries, + SUM(IF(metricName = 'web-whois-queries', count, 0)) AS web_whois_queries, + -- We don't support searchable WHOIS. + 0 AS searchable_whois_queries, + -- DNS queries for UDP/TCP are all assumed to be received/responded. + SUM(IF(metricName = 'dns-udp-queries', count, 0)) AS dns_udp_queries_received, + SUM(IF(metricName = 'dns-udp-queries', count, 0)) AS dns_udp_queries_responded, + SUM(IF(metricName = 'dns-tcp-queries', count, 0)) AS dns_tcp_queries_received, + SUM(IF(metricName = 'dns-tcp-queries', count, 0)) AS dns_tcp_queries_responded, + -- SRS metrics. + SUM(IF(metricName = 'srs-dom-check', count, 0)) AS srs_dom_check, + SUM(IF(metricName = 'srs-dom-create', count, 0)) AS srs_dom_create, + SUM(IF(metricName = 'srs-dom-delete', count, 0)) AS srs_dom_delete, + SUM(IF(metricName = 'srs-dom-info', count, 0)) AS srs_dom_info, + SUM(IF(metricName = 'srs-dom-renew', count, 0)) AS srs_dom_renew, + SUM(IF(metricName = 'srs-dom-rgp-restore-report', count, 0)) AS srs_dom_rgp_restore_report, + SUM(IF(metricName = 'srs-dom-rgp-restore-request', count, 0)) AS srs_dom_rgp_restore_request, + SUM(IF(metricName = 'srs-dom-transfer-approve', count, 0)) AS srs_dom_transfer_approve, + SUM(IF(metricName = 'srs-dom-transfer-cancel', count, 0)) AS srs_dom_transfer_cancel, + SUM(IF(metricName = 'srs-dom-transfer-query', count, 0)) AS srs_dom_transfer_query, + SUM(IF(metricName = 'srs-dom-transfer-reject', count, 0)) AS srs_dom_transfer_reject, + SUM(IF(metricName = 'srs-dom-transfer-request', count, 0)) AS srs_dom_transfer_request, + SUM(IF(metricName = 'srs-dom-update', count, 0)) AS srs_dom_update, + SUM(IF(metricName = 'srs-host-check', count, 0)) AS srs_host_check, + SUM(IF(metricName = 'srs-host-create', count, 0)) AS srs_host_create, + SUM(IF(metricName = 'srs-host-delete', count, 0)) AS srs_host_delete, + SUM(IF(metricName = 'srs-host-info', count, 0)) AS srs_host_info, + SUM(IF(metricName = 'srs-host-update', count, 0)) AS srs_host_update, + SUM(IF(metricName = 'srs-cont-check', count, 0)) AS srs_cont_check, + SUM(IF(metricName = 'srs-cont-create', count, 0)) AS srs_cont_create, + SUM(IF(metricName = 'srs-cont-delete', count, 0)) AS srs_cont_delete, + SUM(IF(metricName = 'srs-cont-info', count, 0)) AS srs_cont_info, + SUM(IF(metricName = 'srs-cont-transfer-approve', count, 0)) AS srs_cont_transfer_approve, + SUM(IF(metricName = 'srs-cont-transfer-cancel', count, 0)) AS srs_cont_transfer_cancel, + SUM(IF(metricName = 'srs-cont-transfer-query', count, 0)) AS srs_cont_transfer_query, + SUM(IF(metricName = 'srs-cont-transfer-reject', count, 0)) AS srs_cont_transfer_reject, + SUM(IF(metricName = 'srs-cont-transfer-request', count, 0)) AS srs_cont_transfer_request, + SUM(IF(metricName = 'srs-cont-update', count, 0)) AS srs_cont_update + -- Cross join a list of all TLDs against TLD-specific metrics and then + -- filter so that only metrics with that TLD or a NULL TLD are counted + -- towards a given TLD. +FROM + EXTERNAL_QUERY("projects/%PROJECT_ID%/locations/us/connections/%PROJECT_ID%-sql", + '''SELECT + "tld_name" AS tld + FROM ( + SELECT + "tld_name" + FROM + "Tld" AS t + WHERE t.tld_type='REAL' + ) AS "RealTlds";''') AS RealTlds +CROSS JOIN( + SELECT + tld, + metricName, + count + FROM + ( + -- BEGIN INTERMEDIARY DATA SOURCES -- + -- Dummy data source to ensure all TLDs appear in report, even if + -- they have no recorded metrics for the month. + SELECT STRING(NULL) AS tld, STRING(NULL) AS metricName, 0 as count + UNION ALL + SELECT * FROM + `%PROJECT_ID%.%ICANN_REPORTING_DATA_SET%.%REGISTRAR_OPERATING_STATUS_TABLE%` + UNION ALL + SELECT * FROM + `%PROJECT_ID%.%ICANN_REPORTING_DATA_SET%.%DNS_COUNTS_TABLE%` + UNION ALL + SELECT * FROM + `%PROJECT_ID%.%ICANN_REPORTING_DATA_SET%.%EPP_METRICS_TABLE%` + UNION ALL + SELECT * FROM + `%PROJECT_ID%.%ICANN_REPORTING_DATA_SET%.%WHOIS_COUNTS_TABLE%` + -- END INTERMEDIARY DATA SOURCES -- + )) AS TldMetrics +WHERE RealTlds.tld = TldMetrics.tld OR TldMetrics.tld IS NULL +GROUP BY tld +ORDER BY tld diff --git a/core/src/main/java/google/registry/reporting/icann/sql/cloud_sql_registrar_operating_status.sql b/core/src/main/java/google/registry/reporting/icann/sql/cloud_sql_registrar_operating_status.sql new file mode 100644 index 000000000..d3a107a0f --- /dev/null +++ b/core/src/main/java/google/registry/reporting/icann/sql/cloud_sql_registrar_operating_status.sql @@ -0,0 +1,31 @@ +#standardSQL + -- Copyright 2021 The Nomulus Authors. All Rights Reserved. + -- + -- Licensed under the Apache License, Version 2.0 (the "License"); + -- you may not use this file except in compliance with the License. + -- You may obtain a copy of the License at + -- + -- http://www.apache.org/licenses/LICENSE-2.0 + -- + -- Unless required by applicable law or agreed to in writing, software + -- distributed under the License is distributed on an "AS IS" BASIS, + -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + -- See the License for the specific language governing permissions and + -- limitations under the License. + + -- Query that counts the number of real registrars in system. + +SELECT + -- Applies to all TLDs, hence the 'null' magic value. + STRING(NULL) AS tld, + 'operational-registrars' AS metricName, + count +FROM + EXTERNAL_QUERY("projects/%PROJECT_ID%/locations/us/connections/%PROJECT_ID%-sql", + '''SELECT + COUNT("registrar_name") AS count + FROM + "Registrar" AS r + WHERE + r.type='REAL' OR r.type='INTERNAL' ;''') +GROUP BY count diff --git a/core/src/test/java/google/registry/reporting/icann/ActivityReportingQueryBuilderTest.java b/core/src/test/java/google/registry/reporting/icann/ActivityReportingQueryBuilderTest.java index 679174291..95a55b823 100644 --- a/core/src/test/java/google/registry/reporting/icann/ActivityReportingQueryBuilderTest.java +++ b/core/src/test/java/google/registry/reporting/icann/ActivityReportingQueryBuilderTest.java @@ -18,12 +18,25 @@ import static com.google.common.truth.Truth.assertThat; import com.google.common.collect.ImmutableList; import com.google.common.collect.ImmutableMap; +import google.registry.testing.AppEngineExtension; +import google.registry.testing.DualDatabaseTest; +import google.registry.testing.TestOfyOnly; +import google.registry.testing.TestSqlOnly; import org.joda.time.YearMonth; -import org.junit.jupiter.api.Test; +import org.junit.jupiter.api.extension.RegisterExtension; /** Unit tests for {@link ActivityReportingQueryBuilder}. */ +@DualDatabaseTest class ActivityReportingQueryBuilderTest { + @RegisterExtension + public final AppEngineExtension appEngine = + AppEngineExtension.builder() + .withDatastoreAndCloudSql() + .withLocalModules() + .withTaskQueue() + .build(); + private final YearMonth yearMonth = new YearMonth(2017, 9); private ActivityReportingQueryBuilder getQueryBuilder() { @@ -35,8 +48,8 @@ class ActivityReportingQueryBuilderTest { return queryBuilder; } - @Test - void testAggregateQueryMatch() { + @TestOfyOnly + void testAggregateQueryMatch_datastore() { ActivityReportingQueryBuilder queryBuilder = getQueryBuilder(); assertThat(queryBuilder.getReportQuery(yearMonth)) .isEqualTo( @@ -44,8 +57,18 @@ class ActivityReportingQueryBuilderTest { + "`domain-registry-alpha.icann_reporting.activity_report_aggregation_201709`"); } - @Test - void testIntermediaryQueryMatch() { + @TestSqlOnly + void testAggregateQueryMatch_cloud_sql() { + ActivityReportingQueryBuilder queryBuilder = getQueryBuilder(); + assertThat(queryBuilder.getReportQuery(yearMonth)) + .isEqualTo( + "#standardSQL\n" + + "SELECT * FROM " + + "`domain-registry-alpha.cloud_sql_icann_reporting.activity_report_aggregation_201709`"); + } + + @TestOfyOnly + void testIntermediaryQueryMatch_datastore() { ImmutableList expectedQueryNames = ImmutableList.of( ActivityReportingQueryBuilder.REGISTRAR_OPERATING_STATUS, @@ -64,4 +87,25 @@ class ActivityReportingQueryBuilderTest { .isEqualTo(ReportingTestData.loadFile(testFilename)); } } + + @TestSqlOnly + void testIntermediaryQueryMatch_cloud_sql() { + ImmutableList expectedQueryNames = + ImmutableList.of( + ActivityReportingQueryBuilder.REGISTRAR_OPERATING_STATUS, + ActivityReportingQueryBuilder.MONTHLY_LOGS, + ActivityReportingQueryBuilder.DNS_COUNTS, + ActivityReportingQueryBuilder.EPP_METRICS, + ActivityReportingQueryBuilder.WHOIS_COUNTS, + ActivityReportingQueryBuilder.ACTIVITY_REPORT_AGGREGATION); + + ActivityReportingQueryBuilder queryBuilder = getQueryBuilder(); + ImmutableMap actualQueries = queryBuilder.getViewQueryMap(yearMonth); + for (String queryName : expectedQueryNames) { + String actualTableName = String.format("%s_201709", queryName); + String testFilename = String.format("%s_test_cloud_sql.sql", queryName); + assertThat(actualQueries.get(actualTableName)) + .isEqualTo(ReportingTestData.loadFile(testFilename)); + } + } } diff --git a/core/src/test/resources/google/registry/reporting/icann/activity_report_aggregation_test_cloud_sql.sql b/core/src/test/resources/google/registry/reporting/icann/activity_report_aggregation_test_cloud_sql.sql new file mode 100644 index 000000000..f1340963c --- /dev/null +++ b/core/src/test/resources/google/registry/reporting/icann/activity_report_aggregation_test_cloud_sql.sql @@ -0,0 +1,103 @@ +#standardSQL + -- Copyright 2021 The Nomulus Authors. All Rights Reserved. + -- + -- Licensed under the Apache License, Version 2.0 (the "License"); + -- you may not use this file except in compliance with the License. + -- You may obtain a copy of the License at + -- + -- http://www.apache.org/licenses/LICENSE-2.0 + -- + -- Unless required by applicable law or agreed to in writing, software + -- distributed under the License is distributed on an "AS IS" BASIS, + -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + -- See the License for the specific language governing permissions and + -- limitations under the License. + + -- This query pulls from all intermediary tables to create the activity + -- report csv, via a table transpose and sum over all activity report fields. + +SELECT + RealTlds.tld AS tld, + SUM(IF(metricName = 'operational-registrars', count, 0)) AS operational_registrars, + -- We use the Centralized Zone Data Service. + "CZDS" AS zfa_passwords, + SUM(IF(metricName = 'whois-43-queries', count, 0)) AS whois_43_queries, + SUM(IF(metricName = 'web-whois-queries', count, 0)) AS web_whois_queries, + -- We don't support searchable WHOIS. + 0 AS searchable_whois_queries, + -- DNS queries for UDP/TCP are all assumed to be received/responded. + SUM(IF(metricName = 'dns-udp-queries', count, 0)) AS dns_udp_queries_received, + SUM(IF(metricName = 'dns-udp-queries', count, 0)) AS dns_udp_queries_responded, + SUM(IF(metricName = 'dns-tcp-queries', count, 0)) AS dns_tcp_queries_received, + SUM(IF(metricName = 'dns-tcp-queries', count, 0)) AS dns_tcp_queries_responded, + -- SRS metrics. + SUM(IF(metricName = 'srs-dom-check', count, 0)) AS srs_dom_check, + SUM(IF(metricName = 'srs-dom-create', count, 0)) AS srs_dom_create, + SUM(IF(metricName = 'srs-dom-delete', count, 0)) AS srs_dom_delete, + SUM(IF(metricName = 'srs-dom-info', count, 0)) AS srs_dom_info, + SUM(IF(metricName = 'srs-dom-renew', count, 0)) AS srs_dom_renew, + SUM(IF(metricName = 'srs-dom-rgp-restore-report', count, 0)) AS srs_dom_rgp_restore_report, + SUM(IF(metricName = 'srs-dom-rgp-restore-request', count, 0)) AS srs_dom_rgp_restore_request, + SUM(IF(metricName = 'srs-dom-transfer-approve', count, 0)) AS srs_dom_transfer_approve, + SUM(IF(metricName = 'srs-dom-transfer-cancel', count, 0)) AS srs_dom_transfer_cancel, + SUM(IF(metricName = 'srs-dom-transfer-query', count, 0)) AS srs_dom_transfer_query, + SUM(IF(metricName = 'srs-dom-transfer-reject', count, 0)) AS srs_dom_transfer_reject, + SUM(IF(metricName = 'srs-dom-transfer-request', count, 0)) AS srs_dom_transfer_request, + SUM(IF(metricName = 'srs-dom-update', count, 0)) AS srs_dom_update, + SUM(IF(metricName = 'srs-host-check', count, 0)) AS srs_host_check, + SUM(IF(metricName = 'srs-host-create', count, 0)) AS srs_host_create, + SUM(IF(metricName = 'srs-host-delete', count, 0)) AS srs_host_delete, + SUM(IF(metricName = 'srs-host-info', count, 0)) AS srs_host_info, + SUM(IF(metricName = 'srs-host-update', count, 0)) AS srs_host_update, + SUM(IF(metricName = 'srs-cont-check', count, 0)) AS srs_cont_check, + SUM(IF(metricName = 'srs-cont-create', count, 0)) AS srs_cont_create, + SUM(IF(metricName = 'srs-cont-delete', count, 0)) AS srs_cont_delete, + SUM(IF(metricName = 'srs-cont-info', count, 0)) AS srs_cont_info, + SUM(IF(metricName = 'srs-cont-transfer-approve', count, 0)) AS srs_cont_transfer_approve, + SUM(IF(metricName = 'srs-cont-transfer-cancel', count, 0)) AS srs_cont_transfer_cancel, + SUM(IF(metricName = 'srs-cont-transfer-query', count, 0)) AS srs_cont_transfer_query, + SUM(IF(metricName = 'srs-cont-transfer-reject', count, 0)) AS srs_cont_transfer_reject, + SUM(IF(metricName = 'srs-cont-transfer-request', count, 0)) AS srs_cont_transfer_request, + SUM(IF(metricName = 'srs-cont-update', count, 0)) AS srs_cont_update + -- Cross join a list of all TLDs against TLD-specific metrics and then + -- filter so that only metrics with that TLD or a NULL TLD are counted + -- towards a given TLD. +FROM + EXTERNAL_QUERY("projects/domain-registry-alpha/locations/us/connections/domain-registry-alpha-sql", + '''SELECT + "tld_name" AS tld + FROM ( + SELECT + "tld_name" + FROM + "Tld" AS t + WHERE t.tld_type='REAL' + ) AS "RealTlds";''') AS RealTlds +CROSS JOIN( + SELECT + tld, + metricName, + count + FROM + ( + -- BEGIN INTERMEDIARY DATA SOURCES -- + -- Dummy data source to ensure all TLDs appear in report, even if + -- they have no recorded metrics for the month. + SELECT STRING(NULL) AS tld, STRING(NULL) AS metricName, 0 as count + UNION ALL + SELECT * FROM + `domain-registry-alpha.cloud_sql_icann_reporting.registrar_operating_status_201709` + UNION ALL + SELECT * FROM + `domain-registry-alpha.cloud_sql_icann_reporting.dns_counts_201709` + UNION ALL + SELECT * FROM + `domain-registry-alpha.cloud_sql_icann_reporting.epp_metrics_201709` + UNION ALL + SELECT * FROM + `domain-registry-alpha.cloud_sql_icann_reporting.whois_counts_201709` + -- END INTERMEDIARY DATA SOURCES -- + )) AS TldMetrics +WHERE RealTlds.tld = TldMetrics.tld OR TldMetrics.tld IS NULL +GROUP BY tld +ORDER BY tld diff --git a/core/src/test/resources/google/registry/reporting/icann/dns_counts_test_cloud_sql.sql b/core/src/test/resources/google/registry/reporting/icann/dns_counts_test_cloud_sql.sql new file mode 100644 index 000000000..85293dbb3 --- /dev/null +++ b/core/src/test/resources/google/registry/reporting/icann/dns_counts_test_cloud_sql.sql @@ -0,0 +1,29 @@ +#standardSQL + -- Copyright 2017 The Nomulus Authors. All Rights Reserved. + -- + -- Licensed under the Apache License, Version 2.0 (the "License"); + -- you may not use this file except in compliance with the License. + -- You may obtain a copy of the License at + -- + -- http://www.apache.org/licenses/LICENSE-2.0 + -- + -- Unless required by applicable law or agreed to in writing, software + -- distributed under the License is distributed on an "AS IS" BASIS, + -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + -- See the License for the specific language governing permissions and + -- limitations under the License. + + -- Query for DNS metrics. + + -- You must configure this yourself to enable activity reporting, according + -- to whatever metrics your DNS provider makes available. We hope to make + -- this available in the open-source build in the near future. + +SELECT + STRING(NULL) AS tld, + metricName, + -1 AS count +FROM (( + SELECT 'dns-udp-queries' AS metricName) + UNION ALL + (SELECT 'dns-tcp-queries' AS metricName)) diff --git a/core/src/test/resources/google/registry/reporting/icann/epp_metrics_test_cloud_sql.sql b/core/src/test/resources/google/registry/reporting/icann/epp_metrics_test_cloud_sql.sql new file mode 100644 index 000000000..151cc1728 --- /dev/null +++ b/core/src/test/resources/google/registry/reporting/icann/epp_metrics_test_cloud_sql.sql @@ -0,0 +1,58 @@ +#standardSQL + -- Copyright 2017 The Nomulus Authors. All Rights Reserved. + -- + -- Licensed under the Apache License, Version 2.0 (the "License"); + -- you may not use this file except in compliance with the License. + -- You may obtain a copy of the License at + -- + -- http://www.apache.org/licenses/LICENSE-2.0 + -- + -- Unless required by applicable law or agreed to in writing, software + -- distributed under the License is distributed on an "AS IS" BASIS, + -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + -- See the License for the specific language governing permissions and + -- limitations under the License. + + -- Query FlowReporter JSON log messages and calculate SRS metrics. + + -- We use ugly regex's over the monthly appengine logs to determine how many + -- EPP requests we received for each command. For example: + -- {"commandType":"check"...,"targetIds":["ais.a.how"], + -- "tld":"","tlds":["a.how"],"icannActivityReportField":"srs-dom-check"} + +SELECT + -- Remove quotation marks from tld fields. + REGEXP_EXTRACT(tld, '^"(.*)"$') AS tld, + activityReportField AS metricName, + COUNT(*) AS count +FROM ( + SELECT + -- TODO(b/32486667): Replace with JSON.parse() UDF when available for views + SPLIT( + REGEXP_EXTRACT(JSON_EXTRACT(json, '$.tlds'), r'^\[(.*)\]$')) AS tlds, + JSON_EXTRACT_SCALAR(json, + '$.resourceType') AS resourceType, + JSON_EXTRACT_SCALAR(json, + '$.icannActivityReportField') AS activityReportField + FROM ( + SELECT + -- Extract the logged JSON payload. + REGEXP_EXTRACT(logMessage, r'FLOW-LOG-SIGNATURE-METADATA: (.*)\n?$') + AS json + FROM `domain-registry-alpha.cloud_sql_icann_reporting.monthly_logs_201709` AS logs + JOIN + UNNEST(logs.logMessage) AS logMessage + WHERE + STARTS_WITH(logMessage, "google.registry.flows.FlowReporter recordToLogs: FLOW-LOG-SIGNATURE-METADATA"))) AS regexes +JOIN + -- Unnest the JSON-parsed tlds. + UNNEST(regexes.tlds) AS tld +-- Exclude cases that can't be tabulated correctly, where activityReportField +-- is null/empty, or TLD is null/empty despite being a domain flow. +WHERE + activityReportField != '' + AND (tld != '' OR resourceType != 'domain') +GROUP BY + tld, metricName +ORDER BY + tld, metricName diff --git a/core/src/test/resources/google/registry/reporting/icann/monthly_logs_test_cloud_sql.sql b/core/src/test/resources/google/registry/reporting/icann/monthly_logs_test_cloud_sql.sql new file mode 100644 index 000000000..86660f304 --- /dev/null +++ b/core/src/test/resources/google/registry/reporting/icann/monthly_logs_test_cloud_sql.sql @@ -0,0 +1,30 @@ +#standardSQL + -- Copyright 2017 The Nomulus Authors. All Rights Reserved. + -- + -- Licensed under the Apache License, Version 2.0 (the "License"); + -- you may not use this file except in compliance with the License. + -- You may obtain a copy of the License at + -- + -- http://www.apache.org/licenses/LICENSE-2.0 + -- + -- Unless required by applicable law or agreed to in writing, software + -- distributed under the License is distributed on an "AS IS" BASIS, + -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + -- See the License for the specific language governing permissions and + -- limitations under the License. + + -- Query to fetch AppEngine request logs for the report month. + + -- START_OF_MONTH and END_OF_MONTH should be in YYYYMM01 format. + +SELECT + protoPayload.resource AS requestPath, + ARRAY( + SELECT + logMessage + FROM + UNNEST(protoPayload.line)) AS logMessage +FROM + `domain-registry-alpha.appengine_logs.appengine_googleapis_com_request_log_*` +WHERE + _TABLE_SUFFIX BETWEEN '20170901' AND '20170930' diff --git a/core/src/test/resources/google/registry/reporting/icann/registrar_operating_status_test_cloud_sql.sql b/core/src/test/resources/google/registry/reporting/icann/registrar_operating_status_test_cloud_sql.sql new file mode 100644 index 000000000..4fd39bcf1 --- /dev/null +++ b/core/src/test/resources/google/registry/reporting/icann/registrar_operating_status_test_cloud_sql.sql @@ -0,0 +1,31 @@ +#standardSQL + -- Copyright 2021 The Nomulus Authors. All Rights Reserved. + -- + -- Licensed under the Apache License, Version 2.0 (the "License"); + -- you may not use this file except in compliance with the License. + -- You may obtain a copy of the License at + -- + -- http://www.apache.org/licenses/LICENSE-2.0 + -- + -- Unless required by applicable law or agreed to in writing, software + -- distributed under the License is distributed on an "AS IS" BASIS, + -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + -- See the License for the specific language governing permissions and + -- limitations under the License. + + -- Query that counts the number of real registrars in system. + +SELECT + -- Applies to all TLDs, hence the 'null' magic value. + STRING(NULL) AS tld, + 'operational-registrars' AS metricName, + count +FROM + EXTERNAL_QUERY("projects/domain-registry-alpha/locations/us/connections/domain-registry-alpha-sql", + '''SELECT + COUNT("registrar_name") AS count + FROM + "Registrar" AS r + WHERE + r.type='REAL' OR r.type='INTERNAL' ;''') +GROUP BY count diff --git a/core/src/test/resources/google/registry/reporting/icann/whois_counts_test_cloud_sql.sql b/core/src/test/resources/google/registry/reporting/icann/whois_counts_test_cloud_sql.sql new file mode 100644 index 000000000..d79df769f --- /dev/null +++ b/core/src/test/resources/google/registry/reporting/icann/whois_counts_test_cloud_sql.sql @@ -0,0 +1,33 @@ +#standardSQL + -- Copyright 2017 The Nomulus Authors. All Rights Reserved. + -- + -- Licensed under the Apache License, Version 2.0 (the "License"); + -- you may not use this file except in compliance with the License. + -- You may obtain a copy of the License at + -- + -- http://www.apache.org/licenses/LICENSE-2.0 + -- + -- Unless required by applicable law or agreed to in writing, software + -- distributed under the License is distributed on an "AS IS" BASIS, + -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + -- See the License for the specific language governing permissions and + -- limitations under the License. + + -- Query for WHOIS metrics. + + -- This searches the monthly appengine logs for Whois requests, and + -- counts the number of hits via both endpoints (port 43 and the web). + +SELECT + STRING(NULL) AS tld, + CASE + WHEN requestPath = '/_dr/whois' THEN 'whois-43-queries' + WHEN SUBSTR(requestPath, 0, 7) = '/whois/' THEN 'web-whois-queries' + END AS metricName, + COUNT(requestPath) AS count +FROM + `domain-registry-alpha.cloud_sql_icann_reporting.monthly_logs_201709` +GROUP BY + metricName +HAVING + metricName IS NOT NULL