Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

Modified matviews for backfilling old releases to support Paula's rep…

…orts.
  • Loading branch information...
commit 90ec7206d349fabc5987da364e80a9841f6f9bfe 1 parent 3388e0c
@jberkus authored
View
164 sql/upgrade/24.0/update_adu.sql
@@ -0,0 +1,164 @@
+\set ON_ERROR_STOP 1
+
+-- function
+
+CREATE OR REPLACE FUNCTION update_adu (
+ updateday date, checkdata boolean default true, check_period interval )
+RETURNS BOOLEAN
+LANGUAGE plpgsql
+SET work_mem = '512MB'
+SET temp_buffers = '512MB'
+AS $f$
+BEGIN
+-- daily batch update procedure to update the
+-- adu-product matview, used to power graphs
+-- gets its data from raw_adu, which is populated
+-- daily by metrics
+-- note that check_period is accepted for this proc, but ignored.
+
+-- check if raw_adu has been updated. otherwise, abort.
+PERFORM 1 FROM raw_adu
+WHERE "date" = updateday
+LIMIT 1;
+
+IF NOT FOUND THEN
+ IF checkdata THEN
+ RAISE EXCEPTION 'raw_adu not updated for %',updateday;
+ ELSE
+ RETURN FALSE;
+ END IF;
+END IF;
+
+-- check if ADU has already been run for the date
+PERFORM 1 FROM product_adu
+WHERE adu_date = updateday LIMIT 1;
+IF FOUND THEN
+ IF checkdata THEN
+ RAISE NOTICE 'update_adu has already been run for %', updateday;
+ END IF;
+ RETURN FALSE;
+END IF;
+
+-- insert releases
+-- note that we're now matching against product_guids were we can
+-- and that we need to strip the {} out of the guids
+
+INSERT INTO product_adu ( product_version_id, os_name,
+ adu_date, adu_count )
+SELECT product_version_id, coalesce(os_name,'Unknown') as os,
+ updateday,
+ coalesce(sum(adu_count), 0)
+FROM product_versions
+ LEFT OUTER JOIN (
+ SELECT COALESCE(prodmap.product_name, raw_adu.product_name)::citext
+ as product_name, raw_adu.product_version::citext as product_version,
+ raw_adu.build_channel::citext as build_channel,
+ raw_adu.adu_count,
+ os_name_matches.os_name
+ FROM raw_adu
+ LEFT OUTER JOIN product_productid_map as prodmap
+ ON raw_adu.product_guid = btrim(prodmap.productid, '{}')
+ LEFT OUTER JOIN os_name_matches
+ ON raw_adu.product_os_platform ILIKE os_name_matches.match_string
+ WHERE raw_adu.date = updateday
+ ) as prod_adu
+ ON product_versions.product_name = prod_adu.product_name
+ AND product_versions.version_string = prod_adu.product_version
+ AND product_versions.build_type = prod_adu.build_channel
+WHERE product_versions.build_type IN ('release','nightly','aurora')
+ AND product_versions.build_date >= ( current_date - interval '2 years' )
+GROUP BY product_version_id, os;
+
+-- insert ESRs
+-- need a separate query here because the ESR version number doesn't match
+
+INSERT INTO product_adu ( product_version_id, os_name,
+ adu_date, adu_count )
+SELECT product_version_id, coalesce(os_name,'Unknown') as os,
+ updateday,
+ coalesce(sum(adu_count), 0)
+FROM product_versions
+ LEFT OUTER JOIN (
+ SELECT COALESCE(prodmap.product_name, raw_adu.product_name)::citext
+ as product_name, raw_adu.product_version::citext as product_version,
+ raw_adu.build_channel::citext as build_channel,
+ raw_adu.adu_count,
+ os_name_matches.os_name
+ FROM raw_adu
+ LEFT OUTER JOIN product_productid_map as prodmap
+ ON raw_adu.product_guid = btrim(prodmap.productid, '{}')
+ LEFT OUTER JOIN os_name_matches
+ ON raw_adu.product_os_platform ILIKE os_name_matches.match_string
+ WHERE raw_adu.date = updateday
+ and raw_adu.build_channel ILIKE 'esr'
+ ) as prod_adu
+ ON product_versions.product_name = prod_adu.product_name
+ AND product_versions.version_string
+ = ( prod_adu.product_version || 'esr' )
+ AND product_versions.build_type = prod_adu.build_channel
+WHERE product_versions.build_type = 'ESR'
+ AND product_versions.build_date >= ( current_date - interval '2 years' )
+GROUP BY product_version_id, os;
+
+-- insert betas
+
+INSERT INTO product_adu ( product_version_id, os_name,
+ adu_date, adu_count )
+SELECT product_version_id, coalesce(os_name,'Unknown') as os,
+ updateday,
+ coalesce(sum(adu_count), 0)
+FROM product_versions
+ JOIN products USING ( product_name )
+ LEFT OUTER JOIN (
+ SELECT COALESCE(prodmap.product_name, raw_adu.product_name)::citext
+ as product_name, raw_adu.product_version::citext as product_version,
+ raw_adu.build_channel::citext as build_channel,
+ raw_adu.adu_count,
+ os_name_matches.os_name,
+ build_numeric(raw_adu.build) as build_id
+ FROM raw_adu
+ LEFT OUTER JOIN product_productid_map as prodmap
+ ON raw_adu.product_guid = btrim(prodmap.productid, '{}')
+ LEFT OUTER JOIN os_name_matches
+ ON raw_adu.product_os_platform ILIKE os_name_matches.match_string
+ WHERE raw_adu.date = updateday
+ AND raw_adu.build_channel = 'beta'
+ ) as prod_adu
+ ON product_versions.product_name = prod_adu.product_name
+ AND product_versions.release_version = prod_adu.product_version
+ AND product_versions.build_type = prod_adu.build_channel
+WHERE product_versions.build_type = 'Beta'
+ AND EXISTS ( SELECT 1
+ FROM product_version_builds
+ WHERE product_versions.product_version_id = product_version_builds.product_version_id
+ AND product_version_builds.build_id = prod_adu.build_id
+ )
+ AND product_versions.build_date >= ( current_date - interval '2 years' )
+GROUP BY product_version_id, os;
+
+
+RETURN TRUE;
+END; $f$;
+
+CREATE OR REPLACE FUNCTION backfill_adu (
+ updateday date )
+RETURNS BOOLEAN
+LANGUAGE plpgsql
+AS $f$
+BEGIN
+-- stored procudure to delete and replace one day of
+-- product_adu, optionally only for a specific product
+-- intended to be called by backfill_matviews
+
+DELETE FROM product_adu
+WHERE adu_date = updateday;
+
+PERFORM update_adu(updateday, false);
+
+RETURN TRUE;
+END; $f$;
+
+
+
+
+
View
119 sql/upgrade/24.0/update_crashes_by_user.sql
@@ -0,0 +1,119 @@
+\set ON_ERROR_STOP 1
+
+-- daily update function
+CREATE OR REPLACE FUNCTION update_crashes_by_user (
+ updateday DATE,
+ checkdata BOOLEAN default TRUE,
+ check_period INTERVAL default interval '1 hour' )
+RETURNS BOOLEAN
+LANGUAGE plpgsql
+SET work_mem = '512MB'
+SET temp_buffers = '512MB'
+SET client_min_messages = 'ERROR'
+AS $f$
+BEGIN
+-- this function populates a daily matview
+-- for general statistics of crashes by user
+-- depends on the new reports_clean
+
+-- check if we've been run
+IF checkdata THEN
+ PERFORM 1 FROM crashes_by_user
+ WHERE report_date = updateday
+ LIMIT 1;
+ IF FOUND THEN
+ RAISE NOTICE 'crashes_by_user has already been run for %.',updateday;
+ RETURN FALSE;
+ END IF;
+END IF;
+
+-- check if reports_clean is complete
+IF NOT reports_clean_done(updateday, check_period) THEN
+ IF checkdata THEN
+ RAISE EXCEPTION 'Reports_clean has not been updated to the end of %',updateday;
+ ELSE
+ RETURN FALSE;
+ END IF;
+END IF;
+
+-- check for product_adu
+
+PERFORM 1 FROM product_adu
+WHERE adu_date = updateday
+LIMIT 1;
+IF NOT FOUND THEN
+ IF checkdata THEN
+ RAISE EXCEPTION 'product_adu has not been updated for %', updateday;
+ ELSE
+ RETURN FALSE;
+ END IF;
+END IF;
+
+-- now insert the new records
+INSERT INTO crashes_by_user
+ ( product_version_id, report_date,
+ report_count, adu,
+ os_short_name, crash_type_id )
+SELECT product_version_id, updateday,
+ coalesce(report_count,0), coalesce(adu_sum, 0),
+ os_short_name, crash_type_id
+FROM ( select product_versions.product_version_id,
+ count(reports_clean.uuid) as report_count,
+ os_names.os_name, os_short_name, crash_type_id
+ FROM product_versions
+ CROSS JOIN crash_types
+ CROSS JOIN os_names
+ LEFT OUTER JOIN reports_clean ON
+ product_versions.product_version_id = reports_clean.product_version_id
+ and utc_day_is(date_processed, updateday)
+ AND reports_clean.process_type = crash_types.process_type
+ AND ( reports_clean.hang_id IS NOT NULL ) = crash_types.has_hang_id
+ AND reports_clean.os_name = os_names.os_name
+ WHERE product_versions.build_date >= ( current_date - interval '2 years' )
+ GROUP BY product_versions.product_version_id,
+ os_names.os_name, os_short_name, crash_type_id
+ ) as count_reports
+ JOIN
+ ( select product_version_id,
+ sum(adu_count) as adu_sum,
+ os_name
+ from product_adu
+ where adu_date = updateday
+ group by product_version_id, os_name ) as sum_adu
+ USING ( product_version_id, os_name )
+ORDER BY product_version_id;
+
+-- insert records for the rapid beta parent entries
+INSERT INTO crashes_by_user
+ ( product_version_id, report_date,
+ report_count, adu,
+ os_short_name, crash_type_id )
+SELECT product_versions.rapid_beta_id, updateday,
+ sum(report_count), sum(adu),
+ os_short_name, crash_type_id
+FROM crashes_by_user
+ JOIN product_versions USING ( product_version_id )
+WHERE rapid_beta_id IS NOT NULL
+ AND report_date = updateday
+GROUP BY rapid_beta_id, os_short_name, crash_type_id;
+
+RETURN TRUE;
+END; $f$;
+
+-- now create a backfill function
+-- so that we can backfill missing data
+CREATE OR REPLACE FUNCTION backfill_crashes_by_user(
+ updateday DATE, check_period INTERVAL DEFAULT INTERVAL '1 hour' )
+RETURNS BOOLEAN
+LANGUAGE plpgsql AS
+$f$
+BEGIN
+
+DELETE FROM crashes_by_user WHERE report_date = updateday;
+PERFORM update_crashes_by_user(updateday, false, check_period);
+
+RETURN TRUE;
+END; $f$;
+
+
+
Please sign in to comment.
Something went wrong with that request. Please try again.