Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Browse files

Add stability report source data for analytics users. Fixes bug # 768…

…059. Fix permissions for analyst user for new matviews. Add new doc page for analyst user access, including docs for new function.
  • Loading branch information...
commit da28509508c1a485d634e62595bcea1628ce043b 1 parent ad44540
@jberkus authored
View
3  docs/database.rst
@@ -6,7 +6,7 @@ PostgreSQL Database
===================
.. toctree::
- :maxdepth: 1
+ :maxdepth: 0
databasetablesbysource
databasetabledesc
@@ -14,5 +14,6 @@ PostgreSQL Database
databaseadminfunctions
databasedatetimefunctions
databasemiscfunctions
+ databaseanalystfunctions
databasescripts
populatepostgres
View
104 docs/databaseananalystfunctions.txt
@@ -0,0 +1,104 @@
+.. index:: database
+
+.. _databaseanalystfunctions-chapter:
+
+Database Analyst Functions and Views Reference
+==============================================
+
+This doc covers views and functions which are designed for direct use
+by analyst and metrics teams pulling data straight from the database.
+
+product_crash_ratio (view)
+---------------------------
+
+Dynamic VIEW which shows crashes, ADU, adjusted crashes, and the crash/100ADU ratio, for each product and versions. Recommended for backing graphs and similar.
+
+product_os_crash_ratio (view)
+-----------------------------
+
+Dynamic VIEW which shows crashes, ADU, adjusted crashes, and the crash/100ADU ratio for each product, OS and version. Recommended for backing graphs and similar.
+
+stability_report (function)
+---------------------------
+
+Purpose: supplies crash count data in a variety of configurable groupings to allow
+ crash-kill staff to populate the daily or weekly stability reports.
+
+Called By: Crash-Kill stability report generator, daily or weekly.
+
+::
+
+ stability_report(
+ start_date DATE,
+ end_date DATE,
+ products ARRAY of TEXT default EMPTY
+ groups ARRAY of TEXT default 'product'
+ )
+
+ RETURNS TABLE
+ report_date : UTC day of crash report
+ product : product name
+ channel : release channel
+ version : full version string, e.g. "17.0b2"
+ os_name : long name of the OS, eg. "Windows"
+ crash_type : crash type from the Crashes-by-User UI
+ report_count : adjusted report count
+ adu : active daily installs
+ crash_hadu : crashes per 100 active daily installs
+
+Parameters:
+
+start_date
+ UTC date of first crash report, inclusive
+end_date
+ UTC date of last crash report, inclusive
+products
+ array of products to filter by. Default is not to filter by product.
+groups
+ array of columns to group by (in addition to report_date). Default is to
+ group by product name only. Available columns for grouping are: product,
+ channel, version, os_name, crash_type. The order in which you list the columns
+ is also the order in which they will be sorted.
+
+Usage examples:
+
+Return crash totals from October 11 to October 12, inclusive, grouped by product for
+all products:
+
+::
+
+ SELECT * FROM stability_report('2012-10-11','2012-10-12');
+
+Get crash totals for all products on October 12, not grouped by product.
+The '{}' notation indicates a deliberately empty array:
+
+::
+
+ SELECT * FROM stability_report( start_date := '2012-10-12', end_date := '2012-10-12',
+ groups := '{}');
+
+
+Get crash totals from October 11 to 12 for Firefox and FennecAndroid,
+grouped by product, channel and version, sorted by product, then channel, then version.
+
+::
+
+ SELECT * FROM stability_report('2012-10-11','2012-10-12',
+ ARRAY['Firefox','FennecAndroid'],ARRAY['product','channel','version']);
+
+Get crash totals from October 11 to 12 for Firefox and Thunderbird,
+grouped by product and os_name, sorted by os_name, then product.
+
+::
+
+ SELECT * FROM stability_report('2012-10-11','2012-10-12',
+ ARRAY['Firefox','Thunderbird'],ARRAY['os_name','product']);
+
+
+Notes:
+* report_count is the adjusted report count, which means Firefox release
+ versions are multiplied by 10 to compensate for throttling.
+* rapid betas, when they come in the future, will be reported as the same "version" for all beta releases.
+* except for report_date, any column which is not grouped on will also be blank.
+* this pulls from crashes_by_user, which stops aggregating crashes for products released more than two years ago.
+* crash_hadu for "Unknown" OS is unreasonably large. This is a known issue due to underlying data issues.
View
20 sql/upgrade/24.0/README.rst
@@ -0,0 +1,20 @@
+.. This Source Code Form is subject to the terms of the Mozilla Public
+.. License, v. 2.0. If a copy of the MPL was not distributed with this
+.. file, You can obtain one at http://mozilla.org/MPL/2.0/.
+
+24.0 Database Updates
+=====================
+
+This batch makes the following database changes:
+
+bug #768059
+ provide new data access for Crashkill to do stability reports.
+ also fix permissions on some new matviews for their access.
+
+...
+
+The above changes should take only a few minutes to deploy.
+This upgrade does not require a downtime.
+
+However, after applying the update, you will need to do a backfill
+of the product_adu and crashes_by_user views, probably back 4 weeks.
View
12 sql/upgrade/24.0/analyst_grants.sql
@@ -0,0 +1,12 @@
+\set ON_ERROR_STOP 1
+
+-- fix permissions for analyst on new matviews
+
+GRANT SELECT ON crashes_by_user TO analyst;
+GRANT SELECT ON crashes_by_user_build TO analyst;
+GRANT SELECT ON crashes_by_user_view TO analyst;
+GRANT SELECT ON crashes_by_user_build_view TO analyst;
+GRANT SELECT ON home_page_graph TO analyst;
+GRANT SELECT ON home_page_graph_view TO analyst;
+GRANT SELECT ON home_page_graph_build TO analyst;
+GRANT SELECT ON home_page_graph_build_view TO analyst;
View
71 sql/upgrade/24.0/stability_report.sql
@@ -1,20 +1,25 @@
\set ON_ERROR_STOP 1
+
+CREATE TYPE stability_report AS (
+ report_date DATE,
+ product CITEXT,
+ channel CITEXT,
+ version CITEXT,
+ os_name CITEXT,
+ crash_type CITEXT,
+ report_count INT,
+ adu INT,
+ crash_hadu NUMERIC
+);
+
CREATE OR REPLACE FUNCTION stability_report(
start_date DATE,
end_date DATE,
products TEXT[] default '{}',
- groups TEXT[] default ARRAY['product'] ,
- OUT report_date DATE,
- OUT product CITEXT,
- OUT channel CITEXT,
- OUT version TEXT,
- OUT os_name CITEXT,
- OUT crash_type CITEXT,
- OUT report_count INT,
- OUT adu INT,
- OUT crash_hadu NUMERIC
+ groups TEXT[] default ARRAY['product']
)
+RETURNS SETOF stability_report
LANGUAGE plpgsql
AS $f$
DECLARE prod_clause TEXT := '';
@@ -31,7 +36,7 @@ BEGIN
-- available grouping levels, in correct order
std_groups := ARRAY [ 'product','channel','version','os_name','crash_type' ];
std_cols := ARRAY [ 'product_versions.product_name','product_versions.build_type',
- 'product_versions.version', 'os_names.os_name', 'crash_types.crash_type' ];
+ 'product_versions.version_string', 'os_names.os_name', 'crash_types.crash_type' ];
-- check products list
IF products <> '{}' THEN
@@ -58,30 +63,31 @@ IF groups <> '{}' THEN
RAISE EXCEPTION 'Grouping level % is invalid.', bad_val;
ELSE
group_clause := ', ' || array_to_string(groups, ', ');
- -- loop through grouping clauses IN ORDER to make sure
- -- that we correctly populate the SELECT and JOIN clauses
- FOR sgroup IN SELECT i FROM generate_series(1,array_upper(std_groups,1)) as gs(i) LOOP
-
- IF std_groups[sgroup] = ANY ( groups ) THEN
- select_clause := select_clause ||
- ', ' || std_cols[sgroup] || ' AS '
- || std_groups[sgroup];
-
- -- add join clauses
-
- IF std_groups[sgroup] = 'os_name' THEN
- join_clause := join_clause || ' JOIN os_names USING ( os_short_name ) ';
- ELSIF std_groups[sgroup] = 'crash_type' THEN
- join_clause := join_clause || ' JOIN crash_types USING ( crash_type_id ) ';
- END IF;
- ELSE
- select_clause := select_clause ||
- ', ''''::CITEXT AS ' || std_groups[sgroup];
- END IF;
- END LOOP;
END IF;
END IF;
+-- loop through grouping clauses IN ORDER to make sure
+-- that we correctly populate the SELECT and JOIN clauses
+FOR sgroup IN SELECT i FROM generate_series(1,array_upper(std_groups,1)) as gs(i) LOOP
+
+ IF std_groups[sgroup] = ANY ( groups ) THEN
+ select_clause := select_clause ||
+ ', ' || std_cols[sgroup] || ' AS '
+ || std_groups[sgroup];
+
+ -- add join clauses
+
+ IF std_groups[sgroup] = 'os_name' THEN
+ join_clause := join_clause || ' JOIN os_names USING ( os_short_name ) ';
+ ELSIF std_groups[sgroup] = 'crash_type' THEN
+ join_clause := join_clause || ' JOIN crash_types USING ( crash_type_id ) ';
+ END IF;
+ ELSE
+ select_clause := select_clause ||
+ ', ''''::CITEXT AS ' || std_groups[sgroup];
+ END IF;
+END LOOP;
+
repquery := 'SELECT report_date ' || select_clause
|| ', sum(report_count*throttle)::int AS report_count,
sum(adu)::int AS adu,
@@ -108,3 +114,4 @@ END; $f$;
+
View
12 sql/upgrade/24.0/update_adu.sql
@@ -2,8 +2,13 @@
-- function
+BEGIN;
+
+DROP FUNCTION IF EXISTS update_adu ( date, boolean );
+
CREATE OR REPLACE FUNCTION update_adu (
- updateday date, checkdata boolean default true, check_period interval )
+ updateday date, checkdata boolean default true,
+ check_period interval default '1 hour')
RETURNS BOOLEAN
LANGUAGE plpgsql
SET work_mem = '512MB'
@@ -140,8 +145,10 @@ GROUP BY product_version_id, os;
RETURN TRUE;
END; $f$;
+DROP FUNCTION IF EXISTS backfill_adu ( date );
+
CREATE OR REPLACE FUNCTION backfill_adu (
- updateday date )
+ updateday date, check_period interval default '1 hour' )
RETURNS BOOLEAN
LANGUAGE plpgsql
AS $f$
@@ -158,6 +165,7 @@ PERFORM update_adu(updateday, false);
RETURN TRUE;
END; $f$;
+END;
View
33 sql/upgrade/24.0/upgrade.sh
@@ -0,0 +1,33 @@
+#!/bin/bash
+# This Source Code Form is subject to the terms of the Mozilla Public
+# License, v. 2.0. If a copy of the MPL was not distributed with this
+# file, You can obtain one at http://mozilla.org/MPL/2.0/.
+
+#please see README
+
+set -e
+
+CURDIR=$(dirname $0)
+DBNAME=$1
+: ${DBNAME:="breakpad"}
+VERSION=24.0
+
+echo '*********************************************************'
+echo 'fix permissions for user analyst on new matviews'
+echo 'no bug'
+psql -f ${CURDIR}/analyst_grants.sql $DBNAME
+
+echo '*********************************************************'
+echo 'provide data source for stability report for direct'
+echo 'access by analytics users.'
+echo 'bug 768059'
+psql -f ${CURDIR}/update_adu.sql $DBNAME
+psql -f ${CURDIR}/update_crashes_by_user.sql $DBNAME
+psql -f ${CURDIR}/stability_report.sql $DBNAME
+
+#change version in DB
+psql -c "SELECT update_socorro_db_version( '$VERSION' )" $DBNAME
+
+echo "$VERSION upgrade done"
+
+exit 0
Please sign in to comment.
Something went wrong with that request. Please try again.