mirror of
https://github.com/google/nomulus.git
synced 2025-05-13 07:57:13 +02:00
Prepare ICANN reporting for production
This originally started as a small change, but quickly grew into a major refactor as I realized the original parameter structure wasn't conducive to a cron task and manual re-runs. The changes are as follows: 1. Adds DNS metrics to activity reports, thanks to Nick's work with the Zoneman Dremel -> #plx workflow. 2. Surrounds registrar names in transactions reports with quotes, to escape possible commas. 3. Factors out the report generation logic into IcannReportingStager. 4. Assigns default values to the three main parameters - yearMonth defaults to the previous month - subdir defaults to "icann/monthly/yearMonth", i.e. "gs://domain-registry-reporting/icann/monthly/yyyy-MM" - reportType defaults to both reports 5. Adds "Total" row generation logic to transactions reports - This was a previously overlooked requirement. 6. Adds "MANIFEST.txt" generation and upload logic. - The MANIFEST lists out which files need to be uploaded in the subdirectory. 7. Increases urlfetch timeout from 5s to 10s in backend tasks. - Backend tasks should be more latency tolerant anyway, and this reduces the number of incorrect timeouts we see for services like Bigquery which might take some time to respond. TESTED=Extensive testing in alpha, and ran FOSS test. TODO: send out an e-mail for report generation and upload, and add reporting to cron.xml ------------- Created by MOE: https://github.com/google/moe MOE_MIGRATED_REVID=172738344
This commit is contained in:
parent
06f0ec4f2f
commit
f1c76d035f
39 changed files with 1092 additions and 589 deletions
|
@ -19,8 +19,6 @@
|
|||
SELECT
|
||||
RealTlds.tld AS tld,
|
||||
SUM(IF(metricName = 'operational-registrars', count, 0)) AS operational_registrars,
|
||||
SUM(IF(metricName = 'ramp-up-registrars', count, 0)) AS ramp_up_registrars,
|
||||
SUM(IF(metricName = 'pre-ramp-up-registrars', count, 0)) AS pre_ramp_up_registrars,
|
||||
-- We use the Centralized Zone Data Service.
|
||||
"CZDS" AS zfa_passwords,
|
||||
SUM(IF(metricName = 'whois-43-queries', count, 0)) AS whois_43_queries,
|
||||
|
@ -65,7 +63,7 @@ SELECT
|
|||
-- filter so that only metrics with that TLD or a NULL TLD are counted
|
||||
-- towards a given TLD.
|
||||
FROM (
|
||||
SELECT tldStr as tld
|
||||
SELECT tldStr AS tld
|
||||
FROM `%PROJECT_ID%.%DATASTORE_EXPORT_DATA_SET%.%REGISTRY_TABLE%`
|
||||
WHERE tldType = 'REAL'
|
||||
) as RealTlds
|
||||
|
|
|
@ -15,14 +15,13 @@
|
|||
|
||||
-- Query for DNS metrics.
|
||||
|
||||
-- This is a no-op until after we transition to Google Cloud DNS, which
|
||||
-- will likely export metrics via Stackdriver.
|
||||
-- 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
|
||||
-- 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 Google Cloud DNS when ready.
|
||||
-1 AS count
|
||||
FROM ((
|
||||
SELECT 'dns-udp-queries' AS metricName)
|
||||
|
|
|
@ -26,5 +26,5 @@ FROM
|
|||
UNNEST(allowedTlds) as allowed_tlds
|
||||
WHERE (type = 'REAL' OR type = 'INTERNAL')
|
||||
-- Filter out prober data
|
||||
AND NOT ENDS_WITH(allowed_tlds, "test")
|
||||
AND NOT ENDS_WITH(allowed_tlds, ".test")
|
||||
ORDER BY tld, registrarName
|
||||
|
|
|
@ -23,5 +23,5 @@ SELECT
|
|||
FROM
|
||||
`%PROJECT_ID%.%DATASTORE_EXPORT_DATA_SET%.%REGISTRAR_TABLE%`
|
||||
WHERE
|
||||
type = 'REAL'
|
||||
(type = 'REAL' OR type = 'INTERNAL')
|
||||
GROUP BY metricName
|
||||
|
|
|
@ -32,7 +32,7 @@ JOIN
|
|||
ON
|
||||
currentSponsorClientId = registrar_table.__key__.name
|
||||
WHERE
|
||||
domain_table._d = "DomainResource"
|
||||
AND (registrar_table.type = "REAL" OR registrar_table.type = "INTERNAL")
|
||||
domain_table._d = 'DomainResource'
|
||||
AND (registrar_table.type = 'REAL' OR registrar_table.type = 'INTERNAL')
|
||||
GROUP BY tld, registrarName
|
||||
ORDER BY tld, registrarName
|
||||
|
|
|
@ -65,8 +65,6 @@ FROM (
|
|||
WHERE reportingTime
|
||||
BETWEEN TIMESTAMP('%EARLIEST_REPORT_TIME%')
|
||||
AND TIMESTAMP('%LATEST_REPORT_TIME%')
|
||||
-- Ignore prober data
|
||||
AND NOT ENDS_WITH(tld, "test")
|
||||
GROUP BY
|
||||
tld,
|
||||
clientId,
|
||||
|
|
|
@ -20,7 +20,8 @@
|
|||
|
||||
SELECT
|
||||
registrars.tld as tld,
|
||||
registrars.registrar_name as registrar_name,
|
||||
-- Surround registrar names with quotes to handle names containing a comma.
|
||||
FORMAT("\"%s\"", registrars.registrar_name) as registrar_name,
|
||||
registrars.iana_id as iana_id,
|
||||
SUM(IF(metrics.metricName = 'TOTAL_DOMAINS', metrics.metricValue, 0)) AS total_domains,
|
||||
SUM(IF(metrics.metricName = 'TOTAL_NAMESERVERS', metrics.metricValue, 0)) AS total_nameservers,
|
||||
|
@ -62,9 +63,16 @@ SELECT
|
|||
0 AS agp_exemptions_granted,
|
||||
0 AS agp_exempted_domains,
|
||||
SUM(IF(metrics.metricName = 'ATTEMPTED_ADDS', metrics.metricValue, 0)) AS attempted_adds
|
||||
FROM (
|
||||
SELECT *
|
||||
FROM `%PROJECT_ID%.%ICANN_REPORTING_DATA_SET%.%REGISTRAR_IANA_ID_TABLE%`) AS registrars
|
||||
FROM
|
||||
-- Only produce reports for real TLDs
|
||||
(SELECT tldStr AS tld
|
||||
FROM `%PROJECT_ID%.%DATASTORE_EXPORT_DATA_SET%.%REGISTRY_TABLE%`
|
||||
WHERE tldType = 'REAL') AS registries
|
||||
JOIN
|
||||
(SELECT *
|
||||
FROM `%PROJECT_ID%.%ICANN_REPORTING_DATA_SET%.%REGISTRAR_IANA_ID_TABLE%`)
|
||||
AS registrars
|
||||
ON registries.tld = registrars.tld
|
||||
-- We LEFT JOIN to produce reports even if the registrar made no transactions
|
||||
LEFT OUTER JOIN (
|
||||
-- Gather all intermediary data views
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue