Add django user to roles.sql #844

Closed
wants to merge 6 commits into
from
+845 −6
Split
View
@@ -6,13 +6,14 @@ PostgreSQL Database
===================
.. toctree::
- :maxdepth: 1
+ :maxdepth: 0
databasetablesbysource
databasetabledesc
creatingmatviews
databaseadminfunctions
databasedatetimefunctions
databasemiscfunctions
+ databaseanalystfunctions
databasescripts
populatepostgres
@@ -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,14 +20,14 @@ BEGIN
someroles := ARRAY['analyst','breakpad','breakpad_ro','breakpad_rw',
'breakpad_metrics','processor','monitor','monitoring',
- 'nagiosdaemon','ganglia','replicator'];
-
-rolepass := ARRAY['breakpad_ro','breakpad_rw','processor','monitor'];
+ 'nagiosdaemon','ganglia','replicator','django'];
+
+rolepass := ARRAY['breakpad_ro','breakpad_rw','processor','monitor','django'];
WHILE iter <= array_upper(someroles, 1) LOOP
PERFORM 1 FROM information_schema.enabled_roles
WHERE role_name = someroles[iter];
-
+
IF NOT FOUND THEN
EXECUTE 'CREATE ROLE ' || someroles[iter] ||
' WITH NOSUPERUSER INHERIT NOCREATEROLE NOCREATEDB LOGIN;';
@@ -37,7 +37,7 @@ WHILE iter <= array_upper(someroles, 1) LOOP
END IF;
END IF;
iter := iter + 1;
-
+
END LOOP;
END;$d$;
@@ -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.
@@ -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;
@@ -0,0 +1,117 @@
+\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']
+)
+RETURNS SETOF stability_report
+LANGUAGE plpgsql
+AS $f$
+DECLARE prod_clause TEXT := '';
+ group_clause TEXT := '';
+ select_clause TEXT := '';
+ join_clause TEXT := '';
+ std_groups TEXT[];
+ std_cols TEXT[];
+ bad_val TEXT;
+ sgroup INT;
+ repquery TEXT;
+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_string', 'os_names.os_name', 'crash_types.crash_type' ];
+
+-- check products list
+IF products <> '{}' THEN
+ SELECT prods.product
+ INTO bad_val
+ FROM unnest(products) AS prods(product)
+ WHERE prods.product NOT IN ( SELECT product_name FROM products );
+ IF bad_val <> '' THEN
+ RAISE EXCEPTION 'Product % does not exist.', bad_val;
+ ELSE
+ prod_clause := ' AND product_versions.product_name IN ( '''
+ || array_to_string(products, ''', ''' ) || ''' ) ';
+ END IF;
+END IF;
+
+-- check groups list
+IF groups <> '{}' THEN
+ bad_val := '';
+ SELECT groupies.groupy
+ INTO bad_val
+ FROM unnest(groups) as groupies(groupy)
+ WHERE groupy != ALL ( std_groups );
+ IF bad_val <> '' THEN
+ RAISE EXCEPTION 'Grouping level % is invalid.', bad_val;
+ ELSE
+ group_clause := ', ' || array_to_string(groups, ', ');
+ 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,
+ crash_hadu(sum(report_count*throttle)::bigint,sum(adu)) AS crash_hadu
+ FROM crashes_by_user
+ JOIN product_versions USING ( product_version_id )
+ JOIN product_release_channels ON
+ product_versions.product_name = product_release_channels.product_name
+ AND product_versions.build_type = product_release_channels.release_channel '
+ || join_clause
+ || ' WHERE report_date >= ' || quote_literal(to_char(start_date,'YYYY-MM-DD'))
+ || ' AND report_date <= ' || quote_literal(to_char(start_date,'YYYY-MM-DD'))
+ || prod_clause
+ || ' GROUP BY report_date ' || group_clause
+ || ' ORDER BY report_date ' || group_clause;
+
+RETURN QUERY EXECUTE repquery;
+RETURN;
+
+END; $f$;
+
+
+
+
+
+
+
Oops, something went wrong.