diff --git a/java/google/registry/reporting/ActivityReportingQueryBuilder.java b/java/google/registry/reporting/ActivityReportingQueryBuilder.java index 729e39d16..2aeae3f0e 100644 --- a/java/google/registry/reporting/ActivityReportingQueryBuilder.java +++ b/java/google/registry/reporting/ActivityReportingQueryBuilder.java @@ -20,7 +20,7 @@ import google.registry.util.ResourceUtils; import google.registry.util.SqlTemplate; import java.io.IOException; import java.net.URL; -import org.joda.time.DateTime; +import org.joda.time.LocalDate; import org.joda.time.format.DateTimeFormat; import org.joda.time.format.DateTimeFormatter; @@ -30,28 +30,30 @@ import org.joda.time.format.DateTimeFormatter; public final class ActivityReportingQueryBuilder { // Names for intermediary tables for overall activity reporting query. - static final String ACTIVITY_REPORTING = "activity_reporting"; - static final String MONTHLY_LOGS = "monthly_logs"; + static final String ICANN_REPORTING_DATA_SET = "icann_reporting"; + static final String MONTHLY_LOGS_TABLE = "monthly_logs"; static final String REGISTRAR_OPERATING_STATUS = "registrar_operating_status"; static final String DNS_COUNTS = "dns_counts"; static final String EPP_METRICS = "epp_metrics"; static final String WHOIS_COUNTS = "whois_counts"; /** Sets the month we're doing activity reporting for, and initializes the query map. */ - static ImmutableMap getQueryMap(DateTime reportingMonth) throws IOException { - // Convert the DateTime reportingMonth into YYYY-MM-01 format for start and end of month - DateTimeFormatter formatter = DateTimeFormat.forPattern("YYYY-MM-01"); + static ImmutableMap getQueryMap( + LocalDate reportingMonth, String projectId) throws IOException { + // Convert reportingMonth into YYYYMM01 format for Bigquery table partition pattern-matching. + DateTimeFormatter formatter = DateTimeFormat.forPattern("YYYYMM01"); String startOfMonth = formatter.print(reportingMonth); String endOfMonth = formatter.print(reportingMonth.plusMonths(1)); - return createQueryMap(startOfMonth, endOfMonth); + return createQueryMap(startOfMonth, endOfMonth, projectId); } private static ImmutableMap createQueryMap( - String startOfMonth, String endOfMonth) throws IOException { + String startOfMonth, String endOfMonth, String projectId) throws IOException { ImmutableMap.Builder queriesBuilder = ImmutableMap.builder(); String operationalRegistrarsQuery = SqlTemplate.create(getQueryFromFile("registrar_operating_status.sql")) + .put("PROJECT_ID", projectId) .put("REGISTRAR_DATA_SET", "registrar_data") .put("REGISTRAR_STATUS_TABLE", "registrar_status") .build(); @@ -65,29 +67,33 @@ public final class ActivityReportingQueryBuilder { // The monthly logs query is a shared dependency for epp counts and whois metrics String monthlyLogsQuery = SqlTemplate.create(getQueryFromFile("monthly_logs.sql")) - .put("START_OF_MONTH", startOfMonth).put("END_OF_MONTH", endOfMonth) + .put("PROJECT_ID", projectId) .put("APPENGINE_LOGS_DATA_SET", "appengine_logs") .put("REQUEST_TABLE", "appengine_googleapis_com_request_log_") + .put("START_OF_MONTH", startOfMonth) + .put("END_OF_MONTH", endOfMonth) .build(); queriesBuilder.put("monthly_logs", monthlyLogsQuery); String eppQuery = SqlTemplate.create(getQueryFromFile("epp_metrics.sql")) - .put("MONTHLY_LOGS_DATA_SET", MONTHLY_LOGS) - .put("MONTHLY_LOGS_TABLE", MONTHLY_LOGS + "_table") + .put("PROJECT_ID", projectId) + .put("ICANN_REPORTING_DATA_SET", ICANN_REPORTING_DATA_SET) + .put("MONTHLY_LOGS_TABLE", MONTHLY_LOGS_TABLE) .build(); queriesBuilder.put(EPP_METRICS, eppQuery); String whoisQuery = SqlTemplate.create(getQueryFromFile("whois_counts.sql")) - .put("MONTHLY_LOGS_DATA_SET", MONTHLY_LOGS) - .put("MONTHLY_LOGS_TABLE", MONTHLY_LOGS + "_table") + .put("PROJECT_ID", projectId) + .put("ICANN_REPORTING_DATA_SET", MONTHLY_LOGS_TABLE) + .put("MONTHLY_LOGS_TABLE", MONTHLY_LOGS_TABLE) .build(); queriesBuilder.put(WHOIS_COUNTS, whoisQuery); String activityQuery = SqlTemplate.create(getQueryFromFile("activity_report_aggregation.sql")) - .put("ACTIVITY_REPORTING_DATA_SET", ACTIVITY_REPORTING) + .put("ICANN_REPORTING_DATA_SET", ICANN_REPORTING_DATA_SET) .put("REGISTRAR_OPERATING_STATUS_TABLE", REGISTRAR_OPERATING_STATUS) .put("DNS_COUNTS_TABLE", DNS_COUNTS) .put("EPP_METRICS_TABLE", EPP_METRICS) diff --git a/java/google/registry/reporting/sql/activity_report_aggregation.sql b/java/google/registry/reporting/sql/activity_report_aggregation.sql index 7a999a606..0182d4b64 100644 --- a/java/google/registry/reporting/sql/activity_report_aggregation.sql +++ b/java/google/registry/reporting/sql/activity_report_aggregation.sql @@ -11,8 +11,10 @@ -- 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 Tld.tld AS tld, SUM(IF(metricName = 'operational-registrars', count, 0)) AS operational_registrars, @@ -79,10 +81,10 @@ LEFT OUTER JOIN ( metricName, count FROM -- BEGIN INTERMEDIARY DATA SOURCES -- - [%ACTIVITY_REPORTING_DATA_SET%.%REGISTRAR_OPERATING_STATUS_TABLE%], - [%ACTIVITY_REPORTING_DATA_SET%.%DNS_COUNTS_TABLE%], - [%ACTIVITY_REPORTING_DATA_SET%.%EPP_METRICS_TABLE%], - [%ACTIVITY_REPORTING_DATA_SET%.%WHOIS_COUNTS_TABLE%], + [%ICANN_REPORTING_DATA_SET%.%REGISTRAR_OPERATING_STATUS_TABLE%], + [%ICANN_REPORTING_DATA_SET%.%DNS_COUNTS_TABLE%], + [%ICANN_REPORTING_DATA_SET%.%EPP_METRICS_TABLE%], + [%ICANN_REPORTING_DATA_SET%.%WHOIS_COUNTS_TABLE%], -- END INTERMEDIARY DATA SOURCES -- ) AS TldMetrics ON diff --git a/java/google/registry/reporting/sql/dns_counts.sql b/java/google/registry/reporting/sql/dns_counts.sql index e5e2ebbe3..123782f2f 100644 --- a/java/google/registry/reporting/sql/dns_counts.sql +++ b/java/google/registry/reporting/sql/dns_counts.sql @@ -14,20 +14,16 @@ -- Query for DNS metrics. - -- Our DNS provider exports logs for all queries received. However, these - -- tables only have a TTL of 7 days. We make daily exports of the data - -- relevant to us, which allows us to get the full month's UDP and TCP - -- queries when generating activity reports. + -- This is a no-op until after we transition to Google Cloud DNS, which + -- will likely export metrics via Stackdriver. SELECT -- DNS metrics apply to all tlds, which requires the 'null' magic value. STRING(NULL) AS tld, metricName, - -- TODO(b/63388735): Change this to actually query the DNS tables when ready. - -1 AS count, -FROM ( - SELECT - 'dns-udp-queries' AS metricName), - ( - SELECT - 'dns-tcp-queries' AS metricName) + -- TODO(b/63388735): Change this to actually query Google Cloud DNS when ready. + -1 AS count +FROM (( + SELECT 'dns-udp-queries' AS metricName) + UNION ALL + (SELECT 'dns-tcp-queries' AS metricName)) diff --git a/java/google/registry/reporting/sql/epp_metrics.sql b/java/google/registry/reporting/sql/epp_metrics.sql index 49b84948e..7786d7037 100644 --- a/java/google/registry/reporting/sql/epp_metrics.sql +++ b/java/google/registry/reporting/sql/epp_metrics.sql @@ -14,51 +14,44 @@ -- Query FlowReporter JSON log messages and calculate SRS metrics. - -- We use regex's over the monthly appengine logs to determine how many - -- EPP requests we received for each command. + -- 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 - tld, + -- Remove quotation marks from tld fields. + REGEXP_EXTRACT(tld, '^"(.*)"$') AS tld, activityReportField AS metricName, - -- Manual INTEGER cast to work around a BigQuery bug (b/14560012). - INTEGER(COUNT(*)) AS count, -FROM - -- Flatten the "tld" column (repeated) so that domain checks for names - -- across multiple TLDs are counted towards each checked TLD as though - -- there were one copy of this row per TLD (the effect of flattening). - FLATTEN(( + 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 - -- Use some ugly regex hackery to convert JSON list of strings into - -- repeated string values, since there's no built-in for this. - -- TODO(b/20829992): replace with "JSON.parse()" inside a JS UDF - -- once we can use GoogleSQL; example in b/37629674#comment2. - -- e.g. JSON:"{"commandType":"check"...,"targetIds":["ais.a.how"], - -- "tld":"","tlds":["a.how"],"icannActivityReportField":"srs-dom-check"} - REGEXP_EXTRACT( - SPLIT( - REGEXP_EXTRACT( - JSON_EXTRACT(json, '$.tlds'), - r'^\[(.*)\]$')), - '^"(.*)"$') AS tld, - -- TODO(b/XXX): remove rawTlds after June 2017 (see below). - JSON_EXTRACT_SCALAR(json, '$.resourceType') AS resourceType, - JSON_EXTRACT_SCALAR(json, '$.icannActivityReportField') - AS activityReportField, - FROM ( - SELECT - -- Extract JSON payload following log signature. - REGEXP_EXTRACT(logMessage, r'FLOW-LOG-SIGNATURE-METADATA: (.*)\n?$') - AS json, - FROM - [%MONTHLY_LOGS_DATA_SET%.%MONTHLY_LOGS_TABLE%] - WHERE logMessage CONTAINS 'FLOW-LOG-SIGNATURE-METADATA' - ) - ), - -- Second argument to flatten (see above). - tld) --- Exclude cases that can't be tabulated correctly - activity report field --- is null/empty, or the TLD is null/empty even though it's a domain flow. + -- Extract the logged JSON payload. + REGEXP_EXTRACT(logMessage, r'FLOW-LOG-SIGNATURE-METADATA: (.*)\n?$') + AS json + FROM `%PROJECT_ID%.%ICANN_REPORTING_DATA_SET%.%MONTHLY_LOGS_TABLE%` AS logs + JOIN + UNNEST(logs.logMessage) AS logMessage + WHERE + logMessage LIKE "%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 + activityReportField != '' + AND (tld != '' OR resourceType != 'domain') +GROUP BY + tld, metricName +ORDER BY + tld, metricName diff --git a/java/google/registry/reporting/sql/monthly_logs.sql b/java/google/registry/reporting/sql/monthly_logs.sql index 7298895de..a491c2375 100644 --- a/java/google/registry/reporting/sql/monthly_logs.sql +++ b/java/google/registry/reporting/sql/monthly_logs.sql @@ -14,15 +14,16 @@ -- Query to fetch AppEngine request logs for the report month. - -- START_OF_MONTH and END_OF_MONTH should be in YYYY-MM-01 format. + -- START_OF_MONTH and END_OF_MONTH should be in YYYYMM01 format. SELECT protoPayload.resource AS requestPath, - protoPayload.line.logMessage AS logMessage, + ARRAY( + SELECT + logMessage + FROM + UNNEST(protoPayload.line)) AS logMessage FROM - TABLE_DATE_RANGE_STRICT( - [%APPENGINE_LOGS_DATA_SET%.%REQUEST_TABLE%], - TIMESTAMP('%START_OF_MONTH%'), - -- End timestamp is inclusive, so subtract 1 day from the - -- timestamp representing the start of the next month. - DATE_ADD(TIMESTAMP('%END_OF_MONTH%'), -1, 'DAY')) + `%PROJECT_ID%.%APPENGINE_LOGS_DATA_SET%.%REQUEST_TABLE%*` +WHERE + _TABLE_SUFFIX BETWEEN '%START_OF_MONTH%' AND '%END_OF_MONTH%' diff --git a/java/google/registry/reporting/sql/registrar_operating_status.sql b/java/google/registry/reporting/sql/registrar_operating_status.sql index a0d434d9a..716df387a 100644 --- a/java/google/registry/reporting/sql/registrar_operating_status.sql +++ b/java/google/registry/reporting/sql/registrar_operating_status.sql @@ -26,7 +26,7 @@ SELECT THEN 'pre-ramp-up-registrars' -- The import process is imprecise; filter out invalid rows. ELSE 'not-applicable' END AS metricName, - INTEGER(COUNT(registrar_id)) AS count + COUNT(registrar_id) AS count FROM - [%REGISTRAR_DATA_SET%.%REGISTRAR_STATUS_TABLE%] + `%PROJECT_ID%.%REGISTRAR_DATA_SET%.%REGISTRAR_STATUS_TABLE%` GROUP BY metricName diff --git a/java/google/registry/reporting/sql/whois_counts.sql b/java/google/registry/reporting/sql/whois_counts.sql index cb37bcac5..dc1b57266 100644 --- a/java/google/registry/reporting/sql/whois_counts.sql +++ b/java/google/registry/reporting/sql/whois_counts.sql @@ -18,16 +18,15 @@ -- counts the number of hits via both endpoints (port 43 and the web). SELECT - -- Whois applies to all TLDs, hence the 'null' magic value. STRING(NULL) AS tld, - -- Whois queries over port 43 get forwarded by the proxy to /_dr/whois, - -- while web queries come in via /whois/. CASE WHEN requestPath = '/_dr/whois' THEN 'whois-43-queries' - WHEN LEFT(requestPath, 7) = '/whois/' THEN 'web-whois-queries' + WHEN SUBSTR(requestPath, 0, 7) = '/whois/' THEN 'web-whois-queries' END AS metricName, - INTEGER(COUNT(requestPath)) AS count, + COUNT(requestPath) AS count FROM - [%MONTHLY_LOGS_DATA_SET%.%MONTHLY_LOGS_TABLE%] -GROUP BY metricName -HAVING metricName IS NOT NULL + `%PROJECT_ID%.%ICANN_REPORTING_DATA_SET%.%MONTHLY_LOGS_TABLE%` +GROUP BY + metricName +HAVING + metricName IS NOT NULL diff --git a/javatests/google/registry/reporting/ActivityReportingQueryBuilderTest.java b/javatests/google/registry/reporting/ActivityReportingQueryBuilderTest.java index c0f374e52..31ff02e4f 100644 --- a/javatests/google/registry/reporting/ActivityReportingQueryBuilderTest.java +++ b/javatests/google/registry/reporting/ActivityReportingQueryBuilderTest.java @@ -19,7 +19,7 @@ import static com.google.common.truth.Truth.assertThat; import com.google.common.collect.ImmutableList; import com.google.common.collect.ImmutableMap; import java.io.IOException; -import org.joda.time.DateTime; +import org.joda.time.LocalDate; import org.junit.Test; import org.junit.runner.RunWith; import org.junit.runners.JUnit4; @@ -34,7 +34,7 @@ public class ActivityReportingQueryBuilderTest { ImmutableList.of( ActivityReportingQueryBuilder.REGISTRAR_OPERATING_STATUS, ActivityReportingQueryBuilder.DNS_COUNTS, - ActivityReportingQueryBuilder.MONTHLY_LOGS, + ActivityReportingQueryBuilder.MONTHLY_LOGS_TABLE, ActivityReportingQueryBuilder.EPP_METRICS, ActivityReportingQueryBuilder.WHOIS_COUNTS, "activity_report_aggregation"); @@ -46,7 +46,8 @@ public class ActivityReportingQueryBuilderTest { } ImmutableMap testQueries = testQueryBuilder.build(); ImmutableMap queries = - ActivityReportingQueryBuilder.getQueryMap(new DateTime(2017, 05, 15, 0, 0)); + ActivityReportingQueryBuilder.getQueryMap( + new LocalDate(2017, 05, 15), "domain-registry-alpha"); for (String query : queryNames) { assertThat(queries.get(query)).isEqualTo(testQueries.get(query)); } diff --git a/javatests/google/registry/reporting/testdata/activity_report_aggregation_test.sql b/javatests/google/registry/reporting/testdata/activity_report_aggregation_test.sql index 391bd3963..e0ffac326 100644 --- a/javatests/google/registry/reporting/testdata/activity_report_aggregation_test.sql +++ b/javatests/google/registry/reporting/testdata/activity_report_aggregation_test.sql @@ -11,8 +11,10 @@ -- 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 Tld.tld AS tld, SUM(IF(metricName = 'operational-registrars', count, 0)) AS operational_registrars, @@ -79,10 +81,10 @@ LEFT OUTER JOIN ( metricName, count FROM -- BEGIN INTERMEDIARY DATA SOURCES -- - [activity_reporting.registrar_operating_status], - [activity_reporting.dns_counts], - [activity_reporting.epp_metrics], - [activity_reporting.whois_counts], + [icann_reporting.registrar_operating_status], + [icann_reporting.dns_counts], + [icann_reporting.epp_metrics], + [icann_reporting.whois_counts], -- END INTERMEDIARY DATA SOURCES -- ) AS TldMetrics ON diff --git a/javatests/google/registry/reporting/testdata/dns_counts_test.sql b/javatests/google/registry/reporting/testdata/dns_counts_test.sql index e5e2ebbe3..123782f2f 100644 --- a/javatests/google/registry/reporting/testdata/dns_counts_test.sql +++ b/javatests/google/registry/reporting/testdata/dns_counts_test.sql @@ -14,20 +14,16 @@ -- Query for DNS metrics. - -- Our DNS provider exports logs for all queries received. However, these - -- tables only have a TTL of 7 days. We make daily exports of the data - -- relevant to us, which allows us to get the full month's UDP and TCP - -- queries when generating activity reports. + -- This is a no-op until after we transition to Google Cloud DNS, which + -- will likely export metrics via Stackdriver. SELECT -- DNS metrics apply to all tlds, which requires the 'null' magic value. STRING(NULL) AS tld, metricName, - -- TODO(b/63388735): Change this to actually query the DNS tables when ready. - -1 AS count, -FROM ( - SELECT - 'dns-udp-queries' AS metricName), - ( - SELECT - 'dns-tcp-queries' AS metricName) + -- TODO(b/63388735): Change this to actually query Google Cloud DNS when ready. + -1 AS count +FROM (( + SELECT 'dns-udp-queries' AS metricName) + UNION ALL + (SELECT 'dns-tcp-queries' AS metricName)) diff --git a/javatests/google/registry/reporting/testdata/epp_metrics_test.sql b/javatests/google/registry/reporting/testdata/epp_metrics_test.sql index d8d085349..e8d57eda2 100644 --- a/javatests/google/registry/reporting/testdata/epp_metrics_test.sql +++ b/javatests/google/registry/reporting/testdata/epp_metrics_test.sql @@ -14,51 +14,44 @@ -- Query FlowReporter JSON log messages and calculate SRS metrics. - -- We use regex's over the monthly appengine logs to determine how many - -- EPP requests we received for each command. + -- 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 - tld, + -- Remove quotation marks from tld fields. + REGEXP_EXTRACT(tld, '^"(.*)"$') AS tld, activityReportField AS metricName, - -- Manual INTEGER cast to work around a BigQuery bug (b/14560012). - INTEGER(COUNT(*)) AS count, -FROM - -- Flatten the "tld" column (repeated) so that domain checks for names - -- across multiple TLDs are counted towards each checked TLD as though - -- there were one copy of this row per TLD (the effect of flattening). - FLATTEN(( + 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 - -- Use some ugly regex hackery to convert JSON list of strings into - -- repeated string values, since there's no built-in for this. - -- TODO(b/20829992): replace with "JSON.parse()" inside a JS UDF - -- once we can use GoogleSQL; example in b/37629674#comment2. - -- e.g. JSON:"{"commandType":"check"...,"targetIds":["ais.a.how"], - -- "tld":"","tlds":["a.how"],"icannActivityReportField":"srs-dom-check"} - REGEXP_EXTRACT( - SPLIT( - REGEXP_EXTRACT( - JSON_EXTRACT(json, '$.tlds'), - r'^\[(.*)\]$')), - '^"(.*)"$') AS tld, - -- TODO(b/XXX): remove rawTlds after June 2017 (see below). - JSON_EXTRACT_SCALAR(json, '$.resourceType') AS resourceType, - JSON_EXTRACT_SCALAR(json, '$.icannActivityReportField') - AS activityReportField, - FROM ( - SELECT - -- Extract JSON payload following log signature. - REGEXP_EXTRACT(logMessage, r'FLOW-LOG-SIGNATURE-METADATA: (.*)\n?$') - AS json, - FROM - [monthly_logs.monthly_logs_table] - WHERE logMessage CONTAINS 'FLOW-LOG-SIGNATURE-METADATA' - ) - ), - -- Second argument to flatten (see above). - tld) --- Exclude cases that can't be tabulated correctly - activity report field --- is null/empty, or the TLD is null/empty even though it's a domain flow. + -- Extract the logged JSON payload. + REGEXP_EXTRACT(logMessage, r'FLOW-LOG-SIGNATURE-METADATA: (.*)\n?$') + AS json + FROM `domain-registry-alpha.icann_reporting.monthly_logs` AS logs + JOIN + UNNEST(logs.logMessage) AS logMessage + WHERE + logMessage LIKE "%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 + activityReportField != '' + AND (tld != '' OR resourceType != 'domain') +GROUP BY + tld, metricName +ORDER BY + tld, metricName diff --git a/javatests/google/registry/reporting/testdata/monthly_logs_test.sql b/javatests/google/registry/reporting/testdata/monthly_logs_test.sql index 2b1cd69f6..929270028 100644 --- a/javatests/google/registry/reporting/testdata/monthly_logs_test.sql +++ b/javatests/google/registry/reporting/testdata/monthly_logs_test.sql @@ -14,15 +14,16 @@ -- Query to fetch AppEngine request logs for the report month. - -- START_OF_MONTH and END_OF_MONTH should be in YYYY-MM-01 format. + -- START_OF_MONTH and END_OF_MONTH should be in YYYYMM01 format. SELECT protoPayload.resource AS requestPath, - protoPayload.line.logMessage AS logMessage, + ARRAY( + SELECT + logMessage + FROM + UNNEST(protoPayload.line)) AS logMessage FROM - TABLE_DATE_RANGE_STRICT( - [appengine_logs.appengine_googleapis_com_request_log_], - TIMESTAMP('2017-05-01'), - -- End timestamp is inclusive, so subtract 1 day from the - -- timestamp representing the start of the next month. - DATE_ADD(TIMESTAMP('2017-06-01'), -1, 'DAY')) + `domain-registry-alpha.appengine_logs.appengine_googleapis_com_request_log_*` +WHERE + _TABLE_SUFFIX BETWEEN '20170501' AND '20170601' diff --git a/javatests/google/registry/reporting/testdata/registrar_operating_status_test.sql b/javatests/google/registry/reporting/testdata/registrar_operating_status_test.sql index e55de2c5a..9fb50733c 100644 --- a/javatests/google/registry/reporting/testdata/registrar_operating_status_test.sql +++ b/javatests/google/registry/reporting/testdata/registrar_operating_status_test.sql @@ -26,7 +26,7 @@ SELECT THEN 'pre-ramp-up-registrars' -- The import process is imprecise; filter out invalid rows. ELSE 'not-applicable' END AS metricName, - INTEGER(COUNT(registrar_id)) AS count + COUNT(registrar_id) AS count FROM - [registrar_data.registrar_status] + `domain-registry-alpha.registrar_data.registrar_status` GROUP BY metricName diff --git a/javatests/google/registry/reporting/testdata/whois_counts_test.sql b/javatests/google/registry/reporting/testdata/whois_counts_test.sql index bd1b258ac..11d27db11 100644 --- a/javatests/google/registry/reporting/testdata/whois_counts_test.sql +++ b/javatests/google/registry/reporting/testdata/whois_counts_test.sql @@ -18,16 +18,15 @@ -- counts the number of hits via both endpoints (port 43 and the web). SELECT - -- Whois applies to all TLDs, hence the 'null' magic value. STRING(NULL) AS tld, - -- Whois queries over port 43 get forwarded by the proxy to /_dr/whois, - -- while web queries come in via /whois/. CASE WHEN requestPath = '/_dr/whois' THEN 'whois-43-queries' - WHEN LEFT(requestPath, 7) = '/whois/' THEN 'web-whois-queries' + WHEN SUBSTR(requestPath, 0, 7) = '/whois/' THEN 'web-whois-queries' END AS metricName, - INTEGER(COUNT(requestPath)) AS count, + COUNT(requestPath) AS count FROM - [monthly_logs.monthly_logs_table] -GROUP BY metricName -HAVING metricName IS NOT NULL + `domain-registry-alpha.monthly_logs.monthly_logs` +GROUP BY + metricName +HAVING + metricName IS NOT NULL