From d31f7b6b2669e4793db4bc6ea1ab7c6bc6392e44 Mon Sep 17 00:00:00 2001 From: Josh Berkus Date: Fri, 22 Jun 2012 16:23:06 -0700 Subject: [PATCH] Fixed 14.0 schema.sql. Also dropped the plperl requirement from setupdb_app.py. --- socorro/external/postgresql/setupdb_app.py | 4 - sql/schema.sql | 1371 +++++++++++++++----- 2 files changed, 1065 insertions(+), 310 deletions(-) diff --git a/socorro/external/postgresql/setupdb_app.py b/socorro/external/postgresql/setupdb_app.py index 4b85710ed7..1b2e8f02c5 100755 --- a/socorro/external/postgresql/setupdb_app.py +++ b/socorro/external/postgresql/setupdb_app.py @@ -154,10 +154,6 @@ def main(self): with open('sql/roles.sql') as f: db.execute(f.read()) - for lang in ['plpgsql', 'plperl']: - db.execute('CREATE LANGUAGE "%s"' % lang, - ['language "%s" already exists' % lang]) - if not self.no_schema: with open('sql/schema.sql') as f: db.execute(f.read(), ['schema "pgx_diag" already exists']) diff --git a/sql/schema.sql b/sql/schema.sql index c753aeecd7..85be358350 100644 --- a/sql/schema.sql +++ b/sql/schema.sql @@ -154,11 +154,11 @@ IF defaultval <> '' THEN END IF; -- check if the column already exists. -PERFORM 1 +PERFORM 1 FROM information_schema.columns WHERE table_name = tablename AND column_name = columnname; - + IF FOUND THEN RETURN FALSE; END IF; @@ -210,7 +210,7 @@ PERFORM validate_lookup('products','product_name',product,'product'); --validate channel PERFORM validate_lookup('release_channels','release_channel',release_channel,'release channel'); --validate build -IF NOT ( build_date(build_id) BETWEEN '2005-01-01' +IF NOT ( build_date(build_id) BETWEEN '2005-01-01' AND (current_date + INTERVAL '1 month') ) THEN RAISE EXCEPTION 'invalid buildid'; END IF; @@ -220,7 +220,7 @@ END IF; INSERT INTO releases_raw ( product_name, version, platform, build_id, build_type, beta_number, repository ) -VALUES ( product, version, platform, build_id, +VALUES ( product, version, platform, build_id, release_channel, beta_number, repository ); --call update_products, if desired @@ -289,18 +289,18 @@ END IF; END IF; -- now add it - + INSERT INTO productdims ( product, version, branch, release, version_sort ) VALUES ( product_name, new_version, '2.2', release_type, old_version_sort(new_version) ) RETURNING id INTO new_id; - + INSERT INTO product_visibility ( productdims_id, start_date, end_date, featured, throttle ) VALUES ( new_id, release_date, last_date, is_featured, 100 ); - + RETURN TRUE; - + END; $$; @@ -335,7 +335,7 @@ BEGIN -- product_adu, optionally only for a specific product -- intended to be called by backfill_matviews -DELETE FROM product_adu +DELETE FROM product_adu WHERE adu_date = updateday; PERFORM update_adu(updateday); @@ -368,16 +368,16 @@ this_time := start_date + interval '1 hour'; while this_time <= end_date loop dups_found := backfill_reports_duplicates( this_time - INTERVAL '1 hour', this_time); - + RAISE INFO '% duplicates found for %',dups_found,this_time; this_time := this_time + interval '30 minutes'; - + -- analyze once per day, just to avoid bad query plans IF extract('hour' FROM this_time) = 2 THEN analyze reports_duplicates; END IF; - + truncate new_reports_duplicates; end loop; @@ -500,14 +500,14 @@ END IF; -- set optional end date IF lastday IS NULL or lastday = current_date THEN - last_rc := date_trunc('hour', now()) - INTERVAL '3 hours'; -ELSE + last_rc := date_trunc('hour', now()) - INTERVAL '3 hours'; +ELSE last_rc := ( lastday + 1 ) AT TIME ZONE 'UTC'; END IF; -- check if lastday is after we have ADU; -- if so, adjust lastday -SELECT max("date") +SELECT max("date") INTO last_adu FROM raw_adu; @@ -515,7 +515,7 @@ IF lastday > last_adu THEN RAISE INFO 'last day of backfill period is after final day of ADU. adjusting last day to %',last_adu; lastday := last_adu; END IF; - + -- fill in products PERFORM update_product_versions(); @@ -619,7 +619,7 @@ begin order by relname desc limit 1; raise info 'updating %',reppartition; - + EXECUTE 'UPDATE ' || reppartition || ' SET release_channel = back_one_day.release_channel FROM back_one_day WHERE back_one_day.uuid = ' || reppartition || '.uuid;'; @@ -668,7 +668,7 @@ begin order by relname desc limit 1; raise info 'updating %',reppartition; - + EXECUTE 'UPDATE ' || reppartition || ' SET release_channel = back_one_day.release_channel FROM back_one_day WHERE back_one_day.uuid = ' || reppartition || '.uuid;'; @@ -717,33 +717,33 @@ BEGIN IF ( COALESCE(end_time, now()) - begin_time ) > interval '15 hours' THEN cyclesize := '6 hours'; END IF; - + IF stop_time IS NULL THEN -- if no end time supplied, then default to three hours ago -- on the hour stop_time := ( date_trunc('hour', now()) - interval '3 hours' ); END IF; - + WHILE cur_time < stop_time LOOP IF cur_time + cyclesize > stop_time THEN cyclesize = stop_time - cur_time; END IF; - + RAISE INFO 'backfilling % of reports_clean starting at %',cyclesize,cur_time; - - DELETE FROM reports_clean - WHERE date_processed >= cur_time + + DELETE FROM reports_clean + WHERE date_processed >= cur_time AND date_processed < ( cur_time + cyclesize ); - + DELETE FROM reports_user_info - WHERE date_processed >= cur_time + WHERE date_processed >= cur_time AND date_processed < ( cur_time + cyclesize ); - + PERFORM update_reports_clean( cur_time, cyclesize, false ); - + cur_time := cur_time + cyclesize; END LOOP; - + RETURN TRUE; END;$$; @@ -772,7 +772,7 @@ select follower.uuid as uuid, leader.uuid as duplicate_of, follower.date_processed from -( +( select uuid, install_age, uptime, @@ -800,29 +800,29 @@ select uuid, from reports where date_processed BETWEEN start_time AND end_time ) as follower -JOIN +JOIN ( select uuid, install_age, uptime, client_crash_date FROM reports where date_processed BETWEEN start_time AND end_time ) as leader ON follower.leader_uuid = leader.uuid -WHERE ( same_time_fuzzy(leader.client_crash_date, follower.client_crash_date, - leader.uptime, follower.uptime) - OR follower.uptime < 60 +WHERE ( same_time_fuzzy(leader.client_crash_date, follower.client_crash_date, + leader.uptime, follower.uptime) + OR follower.uptime < 60 ) AND - same_time_fuzzy(leader.client_crash_date, follower.client_crash_date, + same_time_fuzzy(leader.client_crash_date, follower.client_crash_date, leader.install_age, follower.install_age) AND follower.uuid <> leader.uuid; - + -- insert a copy of the leaders - + insert into new_reports_duplicates select uuid, uuid, date_processed from reports -where uuid IN ( select duplicate_of +where uuid IN ( select duplicate_of from new_reports_duplicates ) and date_processed BETWEEN start_time AND end_time; - + analyze new_reports_duplicates; select count(*) into new_dups from new_reports_duplicates; @@ -830,7 +830,7 @@ select count(*) into new_dups from new_reports_duplicates; -- insert new duplicates into permanent table insert into reports_duplicates (uuid, duplicate_of, date_processed ) -select new_reports_duplicates.* +select new_reports_duplicates.* from new_reports_duplicates left outer join reports_duplicates USING (uuid) where reports_duplicates.uuid IS NULL; @@ -862,9 +862,9 @@ WHILE thisdate <= enddate LOOP PERFORM update_os_signature_counts(thisdate, false); PERFORM update_product_signature_counts(thisdate, false); PERFORM update_uptime_signature_counts(thisdate, false); - + thisdate := thisdate + 1; - + END LOOP; RETURN TRUE; @@ -945,12 +945,12 @@ FOR thistable IN SELECT * FROM unnest(tables) LOOP SELECT count(*) INTO partcount FROM pg_stat_user_tables -WHERE relname LIKE ( thistable || '_%' ) +WHERE relname LIKE ( thistable || '_%' ) AND relname > ( thistable || '_' || cur_partition ); --RAISE INFO '% : %',thistable,partcount; -IF partcount < numpartitions OR partcount IS NULL THEN +IF partcount < numpartitions OR partcount IS NULL THEN result := result + 1; msg := msg || ' ' || thistable; END IF; @@ -1177,7 +1177,7 @@ DECLARE dex INT := 1; scripts TEXT[] := '{}'; indexname TEXT; BEGIN --- this function allows you to send a create table script to the backend +-- this function allows you to send a create table script to the backend -- multiple times without erroring. it checks if the table is already -- there and also optionally sets the ownership -- this version of the function also creates indexes from a list of fields @@ -1192,23 +1192,23 @@ BEGIN dex := dex + 1; END LOOP; END IF; - + IF tableowner <> '' THEN EXECUTE 'ALTER TABLE ' || tablename || ' OWNER TO ' || tableowner; END IF; - + dex := 1; - + WHILE indexes[dex] IS NOT NULL LOOP indexname := replace( indexes[dex], ',', '_' ); indexname := replace ( indexname, ' ', '' ); - EXECUTE 'CREATE INDEX ' || tablename || '_' || indexname || + EXECUTE 'CREATE INDEX ' || tablename || '_' || indexname || ' ON ' || tablename || '(' || indexes[dex] || ')'; dex := dex + 1; END LOOP; - + EXECUTE 'ANALYZE ' || tablename; - + RETURN TRUE; END; $$; @@ -1236,54 +1236,54 @@ BEGIN -- supports date, timestamp, timestamptz/utc through the various options thispart := tablename || '_' || to_char(theweek, 'YYYYMMDD'); - + PERFORM 1 FROM pg_stat_user_tables WHERE relname = thispart; IF FOUND THEN RETURN TRUE; END IF; - + IF is_utc THEN timetype := ' TIMESTAMP'; zonestring := ' AT TIME ZONE UTC '; END IF; - - EXECUTE 'CREATE TABLE ' || thispart || ' ( CONSTRAINT ' || thispart - || '_date_check CHECK ( ' || partcol || ' BETWEEN ' + + EXECUTE 'CREATE TABLE ' || thispart || ' ( CONSTRAINT ' || thispart + || '_date_check CHECK ( ' || partcol || ' BETWEEN ' || timetype || ' ' || quote_literal(to_char(theweek, 'YYYY-MM-DD')) - || ' AND ' || timetype || ' ' + || ' AND ' || timetype || ' ' || quote_literal(to_char(theweek + 7, 'YYYY-MM-DD')) || ' ) ) INHERITS ( ' || tablename || ');'; - + IF tableowner <> '' THEN EXECUTE 'ALTER TABLE ' || thispart || ' OWNER TO ' || tableowner; END IF; - + dex := 1; WHILE uniques[dex] IS NOT NULL LOOP EXECUTE 'CREATE UNIQUE INDEX ' || thispart || '_' - || regexp_replace(uniques[dex], $$[,\s]+$$, '_', 'g') + || regexp_replace(uniques[dex], $$[,\s]+$$, '_', 'g') || ' ON ' || thispart || '(' || uniques[dex] || ')'; dex := dex + 1; END LOOP; - + dex := 1; WHILE indexes[dex] IS NOT NULL LOOP - EXECUTE 'CREATE INDEX ' || thispart || '_' - || regexp_replace(indexes[dex], $$[,\s]+$$, '_', 'g') + EXECUTE 'CREATE INDEX ' || thispart || '_' + || regexp_replace(indexes[dex], $$[,\s]+$$, '_', 'g') || ' ON ' || thispart || '(' || indexes[dex] || ')'; dex := dex + 1; END LOOP; - + dex := 1; WHILE fkeys[dex] IS NOT NULL LOOP fkstring := regexp_replace(fkeys[dex], 'WEEKNUM', to_char(theweek, 'YYYYMMDD'), 'g'); - EXECUTE 'ALTER TABLE ' || thispart || ' ADD CONSTRAINT ' + EXECUTE 'ALTER TABLE ' || thispart || ' ADD CONSTRAINT ' || thispart || '_fk_' || dex || ' FOREIGN KEY ' || fkstring || ' ON DELETE CASCADE ON UPDATE CASCADE'; dex := dex + 1; END LOOP; - + RETURN TRUE; END; $_$; @@ -1316,10 +1316,10 @@ CREATE FUNCTION crontabber_timestamp() RETURNS trigger LANGUAGE plpgsql AS $$ BEGIN - + NEW.last_updated = now(); RETURN NEW; - + END; $$; @@ -1356,15 +1356,15 @@ DECLARE tabname TEXT; listnames TEXT; BEGIN listnames := $q$SELECT relname FROM pg_stat_user_tables - WHERE relname LIKE '$q$ || mastername || $q$_%' - AND relname < '$q$ || mastername || '_' + WHERE relname LIKE '$q$ || mastername || $q$_%' + AND relname < '$q$ || mastername || '_' || to_char(cutoffdate, 'YYYYMMDD') || $q$'$q$; IF try_lock_table(mastername,'ACCESS EXCLUSIVE') THEN FOR tabname IN EXECUTE listnames LOOP - + EXECUTE 'DROP TABLE ' || tabname; - + END LOOP; ELSE RAISE EXCEPTION 'Unable to lock table plugin_reports; try again later'; @@ -1406,7 +1406,7 @@ UPDATE product_versions SET featured_version = false WHERE featured_version AND product_name = product AND NOT ( version_string = ANY( featured_versions ) ); - + --feature new versions UPDATE product_versions SET featured_version = true WHERE version_string = ANY ( featured_versions ) @@ -1484,7 +1484,7 @@ ELSE IF which_t = 'new' THEN -- note that changes to the product name or version will be ignored -- only changes to featured and visibility dates will be taken - + -- first we're going to log this since we've had some issues -- and we want to track updates INSERT INTO product_info_changelog ( @@ -1493,13 +1493,13 @@ ELSE SELECT prod_id, user_name, now(), row( build_date, sunset_date, featured_version, throttle )::product_info_change, - row( begin_visibility, end_visibility, + row( begin_visibility, end_visibility, is_featured, crash_throttle/100 )::product_info_change FROM product_versions JOIN product_release_channels ON product_versions.product_name = product_release_channels.product_name AND product_versions.build_type = product_release_channels.release_channel WHERE product_version_id = prod_id; - + -- then update UPDATE product_versions SET featured_version = is_featured, @@ -1560,7 +1560,7 @@ ALTER FUNCTION public.get_cores(cpudetails text) OWNER TO postgres; CREATE FUNCTION get_product_version_ids(product citext, VARIADIC versions citext[]) RETURNS integer[] LANGUAGE sql AS $_$ -SELECT array_agg(product_version_id) +SELECT array_agg(product_version_id) FROM product_versions WHERE product_name = $1 AND version_string = ANY ( $2 ); @@ -1598,8 +1598,8 @@ CASE WHEN tablename = 'reports' THEN curdate:= now() - INTERVAL '3 days'; EXECUTE 'SELECT max(date_processed) FROM reports - WHERE date_processed > ' || - quote_literal(to_char(curdate, 'YYYY-MM-DD')) + WHERE date_processed > ' || + quote_literal(to_char(curdate, 'YYYY-MM-DD')) || ' and date_processed < ' || quote_literal(to_char(curdate + INTERVAL '4 days','YYYY-MM-DD')) INTO resdate; @@ -1638,7 +1638,7 @@ declare arewelogging boolean; begin SELECT log_jobs INTO arewelogging FROM priorityjobs_logging_switch; -IF arewelogging THEN +IF arewelogging THEN INSERT INTO priorityjobs_log VALUES ( NEW.uuid ); END IF; RETURN NEW; @@ -1719,7 +1719,7 @@ SELECT to_char( matched[1]::int, 'FM000' ) ELSE 'z' END || '000' FROM ( SELECT regexp_matches($1, -$x$^(\d+)[^\d]*\.(\d+)([a-z]?)[^\.]*(?:\.(\d+))?([a-z]?).*$$x$) as matched) as match +$x$^(\d+)[^\d]*\.(\d+)([a-z]?)[^\.]*(?:\.(\d+))?([a-z]?).*$$x$) as matched) as match LIMIT 1; $_$; @@ -1773,7 +1773,7 @@ BEGIN -- work for the database and more foolproof. UPDATE productdims SET sort_key = new_sort -FROM ( SELECT product, version, +FROM ( SELECT product, version, row_number() over ( partition by product order by sec1_num1 ASC NULLS FIRST, sec1_string1 ASC NULLS LAST, @@ -1920,31 +1920,30 @@ $_$; ALTER FUNCTION public.replace(citext, citext, citext) OWNER TO postgres; -- --- Name: reports_clean_done(date, interval); Type: FUNCTION; Schema: public; Owner: breakpad_rw +-- Name: reports_clean_done(date); Type: FUNCTION; Schema: public; Owner: postgres -- -CREATE FUNCTION reports_clean_done(updateday date, check_period interval DEFAULT '01:00:00'::interval) RETURNS boolean +CREATE FUNCTION reports_clean_done(updateday date) RETURNS boolean LANGUAGE plpgsql AS $$ -- this function checks that reports_clean has been updated -- all the way to the last hour of the UTC day BEGIN -PERFORM 1 - FROM reports_clean - WHERE date_processed BETWEEN ( ( updateday::timestamp at time zone 'utc' ) - + ( interval '24 hours' - check_period ) ) - AND ( ( updateday::timestamp at time zone 'utc' ) + interval '1 day' ) - LIMIT 1; +PERFORM 1 + FROM reports_clean + WHERE date_processed BETWEEN ( ( updateday::timestamp at time zone 'utc' ) + interval '23 hours' ) + AND ( ( updateday::timestamp at time zone 'utc' ) + interval '1 day' ) + LIMIT 1; IF FOUND THEN - RETURN TRUE; + RETURN TRUE; ELSE - RETURN FALSE; + RETURN FALSE; END IF; END; $$; -ALTER FUNCTION public.reports_clean_done(updateday date, check_period interval) OWNER TO breakpad_rw; +ALTER FUNCTION public.reports_clean_done(updateday date) OWNER TO postgres; -- -- Name: reports_clean_weekly_partition(timestamp with time zone, text); Type: FUNCTION; Schema: public; Owner: postgres @@ -1967,14 +1966,14 @@ begin this_part := which_table || '_' || to_char(date_trunc('week', this_date), 'YYYYMMDD'); begin_week := to_char(date_trunc('week', this_date), 'YYYY-MM-DD'); end_week := to_char(date_trunc('week', this_date) + interval '1 week', 'YYYY-MM-DD'); - + PERFORM 1 FROM pg_stat_user_tables WHERE relname = this_part; IF FOUND THEN RETURN this_part; END IF; - + EXECUTE 'CREATE TABLE ' || this_part || $$ ( CONSTRAINT date_processed_week CHECK ( date_processed >= '$$ || begin_week || $$'::timestamp AT TIME ZONE 'UTC' AND date_processed < '$$ || end_week || $$'::timestamp AT TIME ZONE 'UTC' ) ) @@ -1983,29 +1982,29 @@ begin IF which_table = 'reports_clean' THEN - rc_indexes := ARRAY[ 'date_processed', 'product_version_id', 'os_name', 'os_version_id', + rc_indexes := ARRAY[ 'date_processed', 'product_version_id', 'os_name', 'os_version_id', 'signature_id', 'address_id', 'flash_version_id', 'hang_id', 'process_type', 'release_channel', 'domain_id' ]; - - EXECUTE 'CREATE INDEX ' || this_part || '_sig_prod_date ON ' || this_part + + EXECUTE 'CREATE INDEX ' || this_part || '_sig_prod_date ON ' || this_part || '( signature_id, product_version_id, date_processed )'; - - EXECUTE 'CREATE INDEX ' || this_part || '_arch_cores ON ' || this_part + + EXECUTE 'CREATE INDEX ' || this_part || '_arch_cores ON ' || this_part || '( architecture, cores )'; - + ELSEIF which_table = 'reports_user_info' THEN - + rc_indexes := '{}'; - + END IF; - + WHILE rc_indexes[dex] IS NOT NULL LOOP EXECUTE 'CREATE INDEX ' || this_part || '_' || rc_indexes[dex] || ' ON ' || this_part || '(' || rc_indexes[dex] || ');'; dex := dex + 1; END LOOP; - + EXECUTE 'ALTER TABLE ' || this_part || ' OWNER TO breakpad_rw'; - + RETURN this_part; end;$_$; @@ -2032,7 +2031,7 @@ WHEN $4 IS NULL THEN ELSE ( extract ('epoch' from ( $2 - $1 ) ) - - ( $4 - $3 ) + ( $4 - $3 ) ) BETWEEN -60 AND 60 END; $_$; @@ -2178,21 +2177,6 @@ CREATE FUNCTION texticregexne(citext, text) RETURNS boolean ALTER FUNCTION public.texticregexne(citext, text) OWNER TO postgres; --- --- Name: to_major_version(text); Type: FUNCTION; Schema: public; Owner: breakpad_rw --- - -CREATE FUNCTION to_major_version(version text) RETURNS major_version - LANGUAGE sql IMMUTABLE - AS $_$ --- turns a version string into a major version --- i.e. "6.0a2" into "6.0" -SELECT substring($1 from $x$^(\d+\.\d+)$x$)::major_version; -$_$; - - -ALTER FUNCTION public.to_major_version(version text) OWNER TO breakpad_rw; - -- -- Name: transform_rules_insert_order(); Type: FUNCTION; Schema: public; Owner: postgres -- @@ -2206,21 +2190,21 @@ DECLARE order_num INT; BEGIN IF NEW.rule_order IS NULL or NEW.rule_order = 0 THEN -- no order supplied, add the rule to the end - SELECT max(rule_order) + SELECT max(rule_order) INTO order_num FROM transform_rules WHERE category = NEW.category; - + NEW.rule_order := COALESCE(order_num, 0) + 1; ELSE -- check if there's already a gap there - PERFORM rule_order + PERFORM rule_order FROM transform_rules WHERE category = NEW.category AND rule_order = NEW.rule_order; -- if not, then bump up IF FOUND THEN - UPDATE transform_rules + UPDATE transform_rules SET rule_order = rule_order + 1 WHERE category = NEW.category AND rule_order = NEW.rule_order; @@ -2243,18 +2227,18 @@ CREATE FUNCTION transform_rules_update_order() RETURNS trigger AS $$ BEGIN -- if we've changed the order number, or category reorder - IF NEW.rule_order <> OLD.rule_order + IF NEW.rule_order <> OLD.rule_order OR NEW.category <> OLD.category THEN - + -- insert a new gap UPDATE transform_rules SET rule_order = rule_order + 1 WHERE category = NEW.category AND rule_order = NEW.rule_order AND transform_rule_id <> NEW.transform_rule_id; - - END IF; - + + END IF; + RETURN NEW; END; $$; @@ -2313,7 +2297,7 @@ ALTER FUNCTION public.try_lock_table(tabname text, mode text, attempts integer) CREATE FUNCTION tstz_between(tstz timestamp with time zone, bdate date, fdate date) RETURNS boolean LANGUAGE sql IMMUTABLE AS $_$ -SELECT $1 >= ( $2::timestamp AT TIME ZONE 'UTC' ) +SELECT $1 >= ( $2::timestamp AT TIME ZONE 'UTC' ) AND $1 < ( ( $3 + 1 )::timestamp AT TIME ZONE 'UTC' ); $_$; @@ -2352,7 +2336,7 @@ END IF; IF checkdata THEN PERFORM 1 FROM product_adu WHERE adu_date = updateday LIMIT 1; - + IF FOUND THEN RAISE EXCEPTION 'update_adu has already been run for %', updateday; END IF; @@ -2368,14 +2352,14 @@ SELECT product_version_id, coalesce(os_name,'Unknown') as os, updateday, coalesce(sum(adu_count), 0) FROM product_versions - LEFT OUTER JOIN ( + 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 + 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 @@ -2383,7 +2367,7 @@ FROM product_versions ) 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 + AND product_versions.build_type = prod_adu.build_channel WHERE updateday BETWEEN build_date AND ( sunset_date + 1 ) AND product_versions.build_type IN ('release','nightly','aurora') GROUP BY product_version_id, os; @@ -2397,14 +2381,14 @@ SELECT product_version_id, coalesce(os_name,'Unknown') as os, updateday, coalesce(sum(adu_count), 0) FROM product_versions - LEFT OUTER JOIN ( + 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 + 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 @@ -2412,9 +2396,9 @@ FROM product_versions and raw_adu.build_channel ILIKE 'esr' ) as prod_adu ON product_versions.product_name = prod_adu.product_name - AND product_versions.version_string + AND product_versions.version_string = ( prod_adu.product_version || 'esr' ) - AND product_versions.build_type = prod_adu.build_channel + AND product_versions.build_type = prod_adu.build_channel WHERE updateday BETWEEN build_date AND ( sunset_date + 1 ) AND product_versions.build_type = 'ESR' GROUP BY product_version_id, os; @@ -2428,15 +2412,15 @@ SELECT product_version_id, coalesce(os_name,'Unknown') as os, updateday, coalesce(sum(adu_count), 0) FROM product_versions - LEFT OUTER JOIN ( + 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 + 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 @@ -2445,7 +2429,7 @@ FROM product_versions ) 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 + AND product_versions.build_type = prod_adu.build_channel WHERE updateday BETWEEN build_date AND ( sunset_date + 1 ) AND product_versions.build_type = 'Beta' AND EXISTS ( SELECT 1 @@ -2538,14 +2522,14 @@ ANALYZE uuid_repid; INSERT INTO correlation_addons ( correlation_id, addon_key, addon_version, crash_count ) SELECT correlation_id, extension_id, extension_version, count(*) -FROM correlations - JOIN reports_clean +FROM correlations + JOIN reports_clean USING ( product_version_id, os_name, reason_id, signature_id ) - JOIN uuid_repid + JOIN uuid_repid USING ( uuid ) - JOIN extensions + JOIN extensions USING ( report_id ) - JOIN product_versions + JOIN product_versions USING ( product_version_id ) WHERE utc_day_is(reports_clean.date_processed, updateday) AND utc_day_is(extensions.date_processed, updateday) @@ -2558,10 +2542,10 @@ ANALYZE correlation_addons; INSERT INTO correlation_cores ( correlation_id, architecture, cores, crash_count ) SELECT correlation_id, architecture, cores, count(*) -FROM correlations - JOIN reports_clean +FROM correlations + JOIN reports_clean USING ( product_version_id, os_name, reason_id, signature_id ) - JOIN product_versions + JOIN product_versions USING ( product_version_id ) WHERE utc_day_is(reports_clean.date_processed, updateday) AND updateday BETWEEN build_date AND sunset_date @@ -2650,7 +2634,7 @@ GROUP BY subr.prod_id, subr.os_short_name; -- insert crash counts for new products INSERT INTO daily_crashes (count, report_type, productdims_id, os_short_name, adu_day) SELECT COUNT(*) as count, daily_crash_code(process_type, hang_id) as crash_code, - product_version_id, + product_version_id, initcap(os_short_name), updateday FROM reports_clean JOIN product_versions USING (product_version_id) @@ -2661,7 +2645,7 @@ GROUP BY product_version_id, crash_code, os_short_name; -- insert normalized hangs for new products INSERT INTO daily_crashes (count, report_type, productdims_id, os_short_name, adu_day) -SELECT count(DISTINCT hang_id) as count, 'H', +SELECT count(DISTINCT hang_id) as count, 'H', product_version_id, initcap(os_short_name), updateday FROM product_versions @@ -2691,9 +2675,9 @@ CREATE FUNCTION update_explosiveness(updateday date, checkdata boolean DEFAULT t SET client_min_messages TO 'ERROR' AS $$ -- set stats parameters per Kairo -DECLARE +DECLARE -- minimum crashes/mil.adu to show up - minrate INT := 10; + minrate INT := 10; -- minimum comparitor figures if there are no -- or very few proir crashes to smooth curves -- mostly corresponds to Kairo "clampperadu" @@ -2735,7 +2719,7 @@ IF NOT FOUND THEN END IF; END IF; --- compute dates +-- compute dates -- note that dates are inclusive -- last date of measured period mes_edate := updateday; @@ -2752,7 +2736,7 @@ comp_bdate := mes_edate - 9; -- day, including zeroes CREATE TEMPORARY TABLE crash_madu ON COMMIT DROP -AS +AS WITH crashdates AS ( SELECT report_date::DATE as report_date FROM generate_series(comp_bdate, mes_edate, INTERVAL '1 day') @@ -2765,7 +2749,7 @@ adusum AS ( FROM product_adu WHERE adu_date BETWEEN comp_bdate and mes_edate AND adu_count > 0 - GROUP BY adu_date, product_version_id + GROUP BY adu_date, product_version_id ), reportsum AS ( SELECT report_date, sum(report_count) as report_count, @@ -2776,7 +2760,7 @@ reportsum AS ( ), crash_madu_raw AS ( SELECT ( report_count * 1000000::numeric ) / adu_count AS crash_madu, - reportsum.product_version_id, reportsum.signature_id, + reportsum.product_version_id, reportsum.signature_id, report_date, mindivisor FROM adusum JOIN reportsum ON adu_date = report_date @@ -2786,7 +2770,7 @@ product_sigs AS ( SELECT DISTINCT product_version_id, signature_id FROM crash_madu_raw ) -SELECT crashdates.report_date, +SELECT crashdates.report_date, coalesce(crash_madu, 0) as crash_madu, product_sigs.product_version_id, product_sigs.signature_id, COALESCE(crash_madu_raw.mindivisor, 0) as mindivisor @@ -2838,8 +2822,8 @@ GROUP BY product_version_id, signature_id; -- create oneday temp table CREATE TEMPORARY TABLE explosive_oneday ON COMMIT DROP -AS -WITH sum1day AS ( +AS +WITH sum1day AS ( SELECT product_version_id, signature_id, crash_madu as sum1day, mindivisor FROM crash_madu @@ -2857,24 +2841,24 @@ agg9day AS ( SELECT sum1day.signature_id, sum1day.product_version_id , round ( - ( sum1day.sum1day - coalesce(agg9day.avg9day,0) ) + ( sum1day.sum1day - coalesce(agg9day.avg9day,0) ) / GREATEST ( agg9day.max9day - agg9day.avg9day, sum1day.mindivisor ) , 2 ) as explosive_1day, round(sum1day,2) as oneday_rate -FROM sum1day +FROM sum1day LEFT OUTER JOIN agg9day USING ( signature_id, product_version_id ) WHERE sum1day.sum1day IS NOT NULL; - + ANALYZE explosive_oneday; -- create threeday temp table CREATE TEMPORARY TABLE explosive_threeday ON COMMIT DROP AS -WITH avg3day AS ( - SELECT product_version_id, signature_id, +WITH avg3day AS ( + SELECT product_version_id, signature_id, AVG(crash_madu) as avg3day, AVG(mindivisor) as mindivisor FROM crash_madu @@ -2893,38 +2877,38 @@ agg7day AS ( SELECT avg3day.signature_id, avg3day.product_version_id , round ( - ( avg3day - coalesce(avg7day,0) ) + ( avg3day - coalesce(avg7day,0) ) / GREATEST ( sdv7day, avg3day.mindivisor ) , 2 ) as explosive_3day, round(avg3day, 2) as threeday_rate -FROM avg3day LEFT OUTER JOIN agg7day +FROM avg3day LEFT OUTER JOIN agg7day USING ( signature_id, product_version_id ); - + ANALYZE explosive_threeday; - + -- truncate explosiveness DELETE FROM explosiveness; -- merge the two tables and insert INSERT INTO explosiveness ( - last_date, signature_id, product_version_id, - oneday, threeday, + last_date, signature_id, product_version_id, + oneday, threeday, day0, day1, day2, day3, day4, day5, day6, day7, day8, day9) -SELECT updateday, signature_id, product_version_id, +SELECT updateday, signature_id, product_version_id, explosive_1day, explosive_3day, day0, day1, day2, day3, day4, day5, day6, day7, day8, day9 -FROM crash_xtab +FROM crash_xtab LEFT OUTER JOIN explosive_oneday USING ( signature_id, product_version_id ) LEFT OUTER JOIN explosive_threeday USING ( signature_id, product_version_id ) WHERE explosive_1day IS NOT NULL or explosive_3day IS NOT NULL ORDER BY product_version_id; - + RETURN TRUE; END; $$; @@ -2975,7 +2959,7 @@ END IF; -- insert data -- note that we need to group on the plugin here and -- take min() of all of the browser crash data. this is a sloppy --- approach but works because the only reason for more than one +-- approach but works because the only reason for more than one -- browser crash in a hang group is duplicate crash data INSERT INTO daily_hangs ( uuid, plugin_uuid, report_date, product_version_id, browser_signature_id, plugin_signature_id, @@ -2989,7 +2973,7 @@ SELECT plugin.signature_id AS plugin_signature_id, plugin.hang_id, plugin.flash_version_id, - nullif(array_agg(browser.duplicate_of) + nullif(array_agg(browser.duplicate_of) || COALESCE(ARRAY[plugin.duplicate_of], '{}'),'{NULL}'), min(browser_info.url) FROM reports_clean AS browser @@ -3006,7 +2990,7 @@ WHERE sig_browser.signature LIKE 'hang | %' AND utc_day_is(browser_info.date_processed, updateday) GROUP BY plugin.uuid, plugin.signature_id, plugin.hang_id, plugin.flash_version_id, plugin.duplicate_of; - + ANALYZE daily_hangs; RETURN TRUE; END;$$; @@ -3029,10 +3013,10 @@ begin ELSE table_name := column_name || 's'; END IF; - + insert_query := ' insert into ' || table_name || ' ( ' || column_name || ', first_seen ) - select newrecords.* from ( + select newrecords.* from ( select ' || column_name || '::citext as col, min(date_processed) as first_report from new_reports @@ -3040,9 +3024,9 @@ begin left join ' || table_name || ' as lookuplist on newrecords.col = lookuplist.' || column_name || ' where lookuplist.' || column_name || ' IS NULL;'; - + execute insert_query; - + RETURN true; end; $$; @@ -3089,19 +3073,19 @@ END IF; INSERT INTO nightly_builds ( product_version_id, build_date, report_date, days_out, report_count ) -SELECT product_version_id, - build_date(reports_clean.build) as build_date, +SELECT product_version_id, + build_date(reports_clean.build) as build_date, date_processed::date as report_date, - date_processed::date + date_processed::date - build_date(reports_clean.build) as days_out, count(*) FROM reports_clean join product_versions using (product_version_id) join product_version_builds using (product_version_id) -WHERE +WHERE reports_clean.build = product_version_builds.build_id and reports_clean.release_channel IN ( 'nightly', 'aurora' ) - and date_processed::date + and date_processed::date - build_date(reports_clean.build) <= 14 and tstz_between(date_processed, build_date, sunset_date) and utc_day_is(date_processed,updateday) @@ -3427,7 +3411,7 @@ END IF; -- create temporary table with totals from reports_clean -CREATE TEMPORARY TABLE prod_sig_counts +CREATE TEMPORARY TABLE prod_sig_counts AS SELECT product_version_id, signature_id, count(*) as report_count FROM reports_clean WHERE utc_day_is(date_processed, updateday) @@ -3442,11 +3426,11 @@ INSERT INTO rank_compare ( product_version_id, signature_id, rank_days, report_count, - total_reports, + total_reports, rank_report_count, percent_of_total) SELECT product_version_id, signature_id, - 1, + 1, report_count, total_count, count_rank, @@ -3455,7 +3439,7 @@ FROM ( SELECT product_version_id, signature_id, report_count, sum(report_count) over (partition by product_version_id) as total_count, - dense_rank() over (partition by product_version_id + dense_rank() over (partition by product_version_id order by report_count desc) as count_rank FROM prod_sig_counts ) as initrank; @@ -3487,15 +3471,15 @@ begin -- VERSION: 6 --- accepts a timestamptz, so be careful that the calling script is sending +-- accepts a timestamptz, so be careful that the calling script is sending -- something appropriate -- since we do allow dynamic timestamps, check if we split over a week -- boundary. if so, call self recursively for the first half of the period -IF ( week_begins_utc(fromtime) <> +IF ( week_begins_utc(fromtime) <> week_begins_utc( fromtime + fortime - interval '1 second' ) ) THEN - PERFORM update_reports_clean( fromtime, + PERFORM update_reports_clean( fromtime, ( week_begins_utc( fromtime + fortime ) - fromtime ), checkdata ); newfortime := ( fromtime + fortime ) - week_begins_utc( fromtime + fortime ); fromtime := week_begins_utc( fromtime + fortime ); @@ -3520,8 +3504,8 @@ END IF; create temporary table new_reports on commit drop -as select uuid, - date_processed, +as select uuid, + date_processed, client_crash_date, uptime, install_age, @@ -3543,7 +3527,7 @@ as select uuid, from reports where date_processed >= fromtime and date_processed < ( fromtime + fortime ) and completed_datetime is not null; - + -- check for no data PERFORM 1 FROM new_reports @@ -3556,7 +3540,7 @@ IF NOT FOUND THEN RETURN TRUE; END IF; END IF; - + create index new_reports_uuid on new_reports(uuid); create index new_reports_signature on new_reports(signature); create index new_reports_address on new_reports(address); @@ -3565,7 +3549,7 @@ create index new_reports_reason on new_reports(reason); analyze new_reports; -- trim reports_bad to 2 days of data -DELETE FROM reports_bad +DELETE FROM reports_bad WHERE date_processed < ( now() - interval '2 days' ); -- delete any reports which were already processed @@ -3576,7 +3560,7 @@ and reports_clean.date_processed between ( fromtime - interval '1 day' ) and ( fromtime + fortime + interval '1 day' ); -- RULE: strip leading "0.0.0 Linux" from Linux version strings -UPDATE new_reports +UPDATE new_reports SET os_version = regexp_replace(os_version, $x$[0\.]+\s+Linux\s+$x$, '') WHERE os_version LIKE '%0.0.0%' AND os_name ILIKE 'Linux%'; @@ -3584,8 +3568,8 @@ WHERE os_version LIKE '%0.0.0%' -- insert signatures into signature list insert into signatures ( signature, first_report, first_build ) select newsigs.* from ( - select signature::citext as signature, - min(date_processed) as first_report, + select signature::citext as signature, + min(date_processed) as first_report, min(build_numeric(build)) as first_build from new_reports group by signature::citext ) as newsigs @@ -3629,7 +3613,7 @@ build numeric, signature_id int, install_age interval, uptime interval, -reason_id int, +reason_id int, address_id int, os_name citext, os_version_id int, @@ -3657,7 +3641,7 @@ cores int -- channel match list INSERT INTO reports_clean_buffer -SELECT new_reports.uuid, +SELECT new_reports.uuid, new_reports.date_processed, client_crash_date, 0, @@ -3688,12 +3672,12 @@ LEFT OUTER JOIN domains ON new_reports.domain = domains.domain ORDER BY new_reports.uuid; ANALYZE reports_clean_buffer; - + -- populate product_version -- RULE: populate releases/aurora/nightlies based on matching product name -- and version with release_version - + UPDATE reports_clean_buffer SET product_version_id = product_versions.product_version_id FROM product_versions, new_reports @@ -3705,7 +3689,7 @@ WHERE reports_clean_buffer.uuid = new_reports.uuid -- RULE: populate betas based on matching product_name, version with -- release_version, and build number. - + UPDATE reports_clean_buffer SET product_version_id = product_versions.product_version_id FROM product_versions JOIN product_version_builds USING (product_version_id), new_reports @@ -3724,7 +3708,7 @@ UPDATE reports_clean_buffer SET os_name = os_name_matches.os_name FROM new_reports, os_name_matches WHERE reports_clean_buffer.uuid = new_reports.uuid AND new_reports.os_name ILIKE os_name_matches.match_string; - + -- RULE: if os_name isn't recognized, set major and minor versions to 0. UPDATE reports_clean_buffer SET os_name = 'Unknown', major_version = 0, minor_version = 0 @@ -3732,7 +3716,7 @@ WHERE os_name IS NULL OR os_name NOT IN ( SELECT os_name FROM os_names ); -- RULE: set minor_version based on parsing the os_version string -- for a second decimal between 0 and 1000 if os_name is not Unknown -UPDATE reports_clean_buffer +UPDATE reports_clean_buffer SET minor_version = substring(os_version from $x$^\d+\.(\d+)$x$)::int FROM new_reports WHERE new_reports.uuid = reports_clean_buffer.uuid @@ -3740,10 +3724,10 @@ WHERE new_reports.uuid = reports_clean_buffer.uuid and substring(os_version from $x$^(\d+)$x$)::numeric < 1000 and substring(os_version from $x$^\d+\.(\d+)$x$)::numeric < 1000 and reports_clean_buffer.os_name <> 'Unknown'; - + -- RULE: set major_version based on parsing the os_vesion string -- for a number between 0 and 1000, but there's no minor version -UPDATE reports_clean_buffer +UPDATE reports_clean_buffer SET major_version = substring(os_version from $x$^(\d+)$x$)::int FROM new_reports WHERE new_reports.uuid = reports_clean_buffer.uuid @@ -3758,23 +3742,23 @@ FROM os_versions WHERE reports_clean_buffer.os_name = os_versions.os_name AND reports_clean_buffer.major_version = os_versions.major_version AND reports_clean_buffer.minor_version = os_versions.minor_version; - + -- copy to reports_bad and delete bad reports --- RULE: currently we purge reports which have any of the following +-- RULE: currently we purge reports which have any of the following -- missing or invalid: product_version, release_channel, os_name INSERT INTO reports_bad ( uuid, date_processed ) -SELECT uuid, date_processed +SELECT uuid, date_processed FROM reports_clean_buffer WHERE product_version_id = 0 OR release_channel IS NULL OR signature_id IS NULL; - + DELETE FROM reports_clean_buffer WHERE product_version_id = 0 OR release_channel IS NULL OR signature_id IS NULL; - + -- check if the right reports_clean partition exists, or create it rc_part := reports_clean_weekly_partition(fromtime, 'reports_clean'); @@ -3786,15 +3770,15 @@ rui_part := reports_clean_weekly_partition(fromtime, 'reports_user_info'); -- copy to reports_clean EXECUTE 'INSERT INTO ' || rc_part || ' - ( uuid, date_processed, client_crash_date, product_version_id, + ( uuid, date_processed, client_crash_date, product_version_id, build, signature_id, install_age, uptime, reason_id, address_id, os_name, os_version_id, -hang_id, flash_version_id, process_type, release_channel, +hang_id, flash_version_id, process_type, release_channel, duplicate_of, domain_id, architecture, cores ) -SELECT uuid, date_processed, client_crash_date, product_version_id, +SELECT uuid, date_processed, client_crash_date, product_version_id, build, signature_id, install_age, uptime, reason_id, address_id, os_name, os_version_id, -hang_id, flash_version_id, process_type, release_channel, +hang_id, flash_version_id, process_type, release_channel, duplicate_of, domain_id, architecture, cores FROM reports_clean_buffer;'; @@ -3809,7 +3793,7 @@ SELECT new_reports.uuid, new_reports.date_processed, FROM new_reports JOIN reports_clean_buffer USING ( uuid ) WHERE email <> '' OR user_comments <> '' OR url <> '' OR app_notes <> '';$$; - + EXECUTE 'ANALYZE ' || rui_part; -- exit @@ -3920,7 +3904,7 @@ select count(*) into new_dups from new_reports_duplicates; insert into reports_duplicates (uuid, duplicate_of, date_processed ) select new_reports_duplicates.* from new_reports_duplicates - left outer join reports_duplicates + left outer join reports_duplicates ON new_reports_duplicates.uuid = reports_duplicates.uuid AND reports_duplicates.date_processed > ( start_time - INTERVAL '1 day' ) AND reports_duplicates.date_processed < ( end_time + INTERVAL '1 day' ) @@ -3955,9 +3939,9 @@ BEGIN create temporary table new_signatures on commit drop as -select coalesce(signature,'') as signature, - product::citext as product, - version::citext as version, +select coalesce(signature,'') as signature, + product::citext as product, + version::citext as version, build, NULL::INT as product_version_id, min(date_processed) as first_report from reports @@ -4063,16 +4047,16 @@ BEGIN SELECT current_version = newversion INTO rerun FROM socorro_db_version; - + IF rerun THEN RAISE NOTICE 'This database is already set to version %. If you have deliberately rerun the upgrade scripts, then this is as expected. If not, then there is something wrong.',newversion; ELSE UPDATE socorro_db_version SET current_version = newversion; END IF; - + INSERT INTO socorro_db_version_history ( version, upgraded_on, backfill_to ) VALUES ( newversion, now(), backfilldate ); - + RETURN true; END; $$; @@ -4201,10 +4185,10 @@ BEGIN EXECUTE 'SELECT 1 FROM ' || ltable || ' WHERE ' || lcol || ' = ' || quote_literal(lval) INTO nrows; - + IF nrows > 0 THEN RETURN true; - ELSE + ELSE RAISE EXCEPTION '% is not a valid %',lval,lmessage; END IF; END; @@ -4222,7 +4206,7 @@ CREATE FUNCTION version_matches_channel(version text, channel citext) RETURNS bo AS $_$ SELECT CASE WHEN $1 ILIKE '%a1' AND $2 ILIKE 'nightly%' THEN TRUE -WHEN $1 ILIKE '%a2' AND $2 = 'aurora' +WHEN $1 ILIKE '%a2' AND $2 = 'aurora' THEN TRUE WHEN $1 ILIKE '%esr' AND $2 IN ( 'release', 'esr' ) THEN TRUE @@ -4248,7 +4232,7 @@ BEGIN -- regexp the version number into tokens vne := regexp_matches( version, $x$^(\d+)\.(\d+)([a-zA-Z]*)(\d*)(?:\.(\d+))?(?:([a-zA-Z]+)(\d*))?.*$$x$ ); - + -- bump betas after the 3rd digit back vne[3] := coalesce(nullif(vne[3],''),vne[6]); vne[4] := coalesce(nullif(vne[4],''),vne[7]); @@ -4258,13 +4242,13 @@ BEGIN vne[3] := 'b'; vne[4] := beta_no::TEXT; END IF; - + --handle final betas IF version LIKE '%(beta)%' THEN vne[3] := 'b'; vne[4] := '99'; END IF; - + --handle release channels CASE channel WHEN 'nightly' THEN @@ -4285,21 +4269,21 @@ BEGIN ELSE NULL; END CASE; - + -- fix character otherwise IF vne[3] = 'esr' THEN vne[3] := 'x'; ELSE vne[3] := COALESCE(nullif(vne[3],''),'r'); END IF; - + --assemble string - sortstring := version_sort_digit(vne[1]) - || version_sort_digit(vne[2]) - || version_sort_digit(vne[5]) + sortstring := version_sort_digit(vne[1]) + || version_sort_digit(vne[2]) + || version_sort_digit(vne[5]) || vne[3] || version_sort_digit(vne[4]) ; - + RETURN sortstring; END;$_$; @@ -4373,7 +4357,7 @@ SELECT s1n1,s1s1,s1n2,s1s2, s2n1,s2s1,s2n2,s2s2, s3n1,s3s1,s3n2,s3s2, ext -INTO +INTO NEW.sec1_num1,NEW.sec1_string1,NEW.sec1_num2,NEW.sec1_string2, NEW.sec2_num1,NEW.sec2_string1,NEW.sec2_num2,NEW.sec2_string2, NEW.sec3_num1,NEW.sec3_string1,NEW.sec3_num2,NEW.sec3_string2, @@ -4574,7 +4558,7 @@ CREATE FUNCTION weekly_report_partitions(numweeks integer DEFAULT 2, targetdate -- reports -- designed to be called as a cronjob once a week -- controlled by the data in the reports_partition_info table -DECLARE +DECLARE thisweek DATE; dex INT := 1; weeknum INT := 0; @@ -4582,12 +4566,12 @@ DECLARE BEGIN targetdate := COALESCE(targetdate, now()); thisweek := date_trunc('week', targetdate)::date; - + WHILE weeknum <= numweeks LOOP FOR tabinfo IN SELECT * FROM report_partition_info ORDER BY build_order LOOP - - PERFORM create_weekly_partition ( + + PERFORM create_weekly_partition ( tablename := tabinfo.table_name, theweek := thisweek, uniques := tabinfo.keys, @@ -4602,7 +4586,7 @@ BEGIN END LOOP; RETURN TRUE; - + END; $$; @@ -5177,6 +5161,19 @@ ALTER TABLE public.addresses_address_id_seq OWNER TO breakpad_rw; ALTER SEQUENCE addresses_address_id_seq OWNED BY addresses.address_id; +-- +-- Name: alexa_topsites; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE alexa_topsites ( + domain text NOT NULL, + rank integer DEFAULT 10000, + last_updated timestamp without time zone DEFAULT now() NOT NULL +); + + +ALTER TABLE public.alexa_topsites OWNER TO breakpad_rw; + -- -- Name: bloat; Type: VIEW; Schema: public; Owner: postgres -- @@ -5187,6 +5184,75 @@ CREATE VIEW bloat AS ALTER TABLE public.bloat OWNER TO postgres; +-- +-- Name: product_versions; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE product_versions ( + product_version_id integer NOT NULL, + product_name citext NOT NULL, + major_version major_version NOT NULL, + release_version citext NOT NULL, + version_string citext NOT NULL, + beta_number integer, + version_sort text DEFAULT 0 NOT NULL, + build_date date NOT NULL, + sunset_date date NOT NULL, + featured_version boolean DEFAULT false NOT NULL, + build_type citext DEFAULT 'release'::citext NOT NULL +); + + +ALTER TABLE public.product_versions OWNER TO breakpad_rw; + +-- +-- Name: productdims_id_seq1; Type: SEQUENCE; Schema: public; Owner: breakpad_rw +-- + +CREATE SEQUENCE productdims_id_seq1 + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +ALTER TABLE public.productdims_id_seq1 OWNER TO breakpad_rw; + +-- +-- Name: productdims_id_seq1; Type: SEQUENCE OWNED BY; Schema: public; Owner: breakpad_rw +-- + +ALTER SEQUENCE productdims_id_seq1 OWNED BY product_versions.product_version_id; + + +-- +-- Name: productdims; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE productdims ( + id integer DEFAULT nextval('productdims_id_seq1'::regclass) NOT NULL, + product citext NOT NULL, + version citext NOT NULL, + branch text NOT NULL, + release release_enum, + sort_key integer, + version_sort text +); + + +ALTER TABLE public.productdims OWNER TO breakpad_rw; + +-- +-- Name: branches; Type: VIEW; Schema: public; Owner: breakpad_rw +-- + +CREATE VIEW branches AS + SELECT productdims.product, productdims.version, productdims.branch FROM productdims; + + +ALTER TABLE public.branches OWNER TO breakpad_rw; + -- -- Name: bug_associations; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -5213,6 +5279,25 @@ CREATE TABLE bugs ( ALTER TABLE public.bugs OWNER TO breakpad_rw; +-- +-- Name: builds; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE builds ( + product citext, + version citext, + platform citext, + buildid bigint, + platform_changeset text, + filename text, + date timestamp without time zone DEFAULT now(), + app_changeset_1 text, + app_changeset_2 text +); + + +ALTER TABLE public.builds OWNER TO breakpad_rw; + -- -- Name: correlation_addons; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -5416,25 +5501,20 @@ CREATE TABLE product_release_channels ( ALTER TABLE public.product_release_channels OWNER TO breakpad_rw; -- --- Name: product_versions; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- Name: product_visibility; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- -CREATE TABLE product_versions ( - product_version_id integer NOT NULL, - product_name citext NOT NULL, - major_version major_version NOT NULL, - release_version citext NOT NULL, - version_string citext NOT NULL, - beta_number integer, - version_sort text DEFAULT 0 NOT NULL, - build_date date NOT NULL, - sunset_date date NOT NULL, - featured_version boolean DEFAULT false NOT NULL, - build_type citext DEFAULT 'release'::citext NOT NULL +CREATE TABLE product_visibility ( + productdims_id integer NOT NULL, + start_date timestamp without time zone, + end_date timestamp without time zone, + ignore boolean DEFAULT false, + featured boolean DEFAULT false, + throttle numeric(5,2) DEFAULT 0.00 ); -ALTER TABLE public.product_versions OWNER TO breakpad_rw; +ALTER TABLE public.product_visibility OWNER TO breakpad_rw; -- -- Name: products; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: @@ -5444,13 +5524,24 @@ CREATE TABLE products ( product_name citext NOT NULL, sort smallint DEFAULT 0 NOT NULL, rapid_release_version major_version, - release_name citext NOT NULL, - rapid_beta_version major_version + release_name citext NOT NULL ); ALTER TABLE public.products OWNER TO breakpad_rw; +-- +-- Name: release_build_type_map; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE release_build_type_map ( + release release_enum NOT NULL, + build_type citext NOT NULL +); + + +ALTER TABLE public.release_build_type_map OWNER TO breakpad_rw; + -- -- Name: release_channels; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -5468,7 +5559,7 @@ ALTER TABLE public.release_channels OWNER TO breakpad_rw; -- CREATE VIEW product_info AS - SELECT product_versions.product_version_id, product_versions.product_name, product_versions.version_string, 'new'::text AS which_table, product_versions.build_date AS start_date, product_versions.sunset_date AS end_date, product_versions.featured_version AS is_featured, product_versions.build_type, ((product_release_channels.throttle * (100)::numeric))::numeric(5,2) AS throttle, product_versions.version_sort, products.sort AS product_sort, release_channels.sort AS channel_sort, ((product_versions.build_type = ANY (ARRAY['Aurora'::citext, 'Nightly'::citext])) OR ((product_versions.build_type = 'Beta'::citext) AND (major_version_sort((product_versions.major_version)::text) <= major_version_sort((products.rapid_beta_version)::text)))) AS has_builds FROM (((product_versions 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 products ON ((product_versions.product_name = products.product_name))) JOIN release_channels ON ((product_versions.build_type = release_channels.release_channel))) ORDER BY product_versions.product_name, product_versions.version_string; + SELECT product_versions.product_version_id, product_versions.product_name, product_versions.version_string, 'new'::text AS which_table, product_versions.build_date AS start_date, product_versions.sunset_date AS end_date, product_versions.featured_version AS is_featured, product_versions.build_type, ((product_release_channels.throttle * (100)::numeric))::numeric(5,2) AS throttle, product_versions.version_sort, products.sort AS product_sort, release_channels.sort AS channel_sort FROM (((product_versions 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 products ON ((product_versions.product_name = products.product_name))) JOIN release_channels ON ((product_versions.build_type = release_channels.release_channel))) UNION ALL SELECT productdims.id AS product_version_id, productdims.product AS product_name, productdims.version AS version_string, 'old'::text AS which_table, product_visibility.start_date, product_visibility.end_date, product_visibility.featured AS is_featured, release_build_type_map.build_type, product_visibility.throttle, productdims.version_sort, products.sort AS product_sort, release_channels.sort AS channel_sort FROM (((((productdims JOIN product_visibility ON ((productdims.id = product_visibility.productdims_id))) JOIN release_build_type_map ON ((productdims.release = release_build_type_map.release))) JOIN products ON ((productdims.product = products.product_name))) LEFT JOIN product_versions ON (((productdims.product = product_versions.product_name) AND ((productdims.version = product_versions.release_version) OR (productdims.version = product_versions.version_string))))) JOIN release_channels ON ((release_build_type_map.build_type = release_channels.release_channel))) WHERE (product_versions.product_name IS NULL) ORDER BY 2, 3; ALTER TABLE public.product_info OWNER TO breakpad_rw; @@ -5483,16 +5574,6 @@ CREATE VIEW default_versions AS ALTER TABLE public.default_versions OWNER TO breakpad_rw; --- --- Name: default_versions_builds; Type: VIEW; Schema: public; Owner: breakpad_rw --- - -CREATE VIEW default_versions_builds AS - SELECT count_versions.product_name, count_versions.version_string, count_versions.product_version_id FROM (SELECT product_info.product_name, product_info.version_string, product_info.product_version_id, row_number() OVER (PARTITION BY product_info.product_name ORDER BY ((('now'::text)::date >= product_info.start_date) AND (('now'::text)::date <= product_info.end_date)) DESC, product_info.is_featured DESC, product_info.channel_sort DESC) AS sort_count FROM product_info WHERE product_info.has_builds) count_versions WHERE (count_versions.sort_count = 1); - - -ALTER TABLE public.default_versions_builds OWNER TO breakpad_rw; - -- -- Name: domains; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -5835,6 +5916,40 @@ ALTER TABLE public.os_versions_os_version_id_seq OWNER TO breakpad_rw; ALTER SEQUENCE os_versions_os_version_id_seq OWNED BY os_versions.os_version_id; +-- +-- Name: osdims; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE osdims ( + id integer NOT NULL, + os_name character varying(100), + os_version character varying(100) +); + + +ALTER TABLE public.osdims OWNER TO breakpad_rw; + +-- +-- Name: osdims_id_seq; Type: SEQUENCE; Schema: public; Owner: breakpad_rw +-- + +CREATE SEQUENCE osdims_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +ALTER TABLE public.osdims_id_seq OWNER TO breakpad_rw; + +-- +-- Name: osdims_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: breakpad_rw +-- + +ALTER SEQUENCE osdims_id_seq OWNED BY osdims.id; + + -- -- Name: performance_check_1; Type: VIEW; Schema: public; Owner: ganglia -- @@ -6021,7 +6136,7 @@ ALTER TABLE public.product_productid_map OWNER TO breakpad_rw; -- CREATE VIEW product_selector AS - SELECT product_versions.product_name, product_versions.version_string, 'new'::text AS which_table, product_versions.version_sort FROM product_versions WHERE (now() <= product_versions.sunset_date) ORDER BY product_versions.product_name, product_versions.version_string; + SELECT product_versions.product_name, product_versions.version_string, 'new'::text AS which_table, product_versions.version_sort FROM product_versions WHERE (now() <= product_versions.sunset_date) UNION ALL SELECT productdims.product AS product_name, productdims.version AS version_string, 'old'::text AS which_table, productdims.version_sort FROM ((productdims JOIN product_visibility ON ((productdims.id = product_visibility.productdims_id))) LEFT JOIN product_versions ON (((productdims.product = product_versions.product_name) AND ((productdims.version = product_versions.release_version) OR (productdims.version = product_versions.version_string))))) WHERE ((product_versions.product_name IS NULL) AND ((now() >= product_visibility.start_date) AND (now() <= (product_visibility.end_date + '1 day'::interval)))) ORDER BY 1, 2; ALTER TABLE public.product_selector OWNER TO breakpad_rw; @@ -6041,25 +6156,30 @@ CREATE TABLE product_version_builds ( ALTER TABLE public.product_version_builds OWNER TO breakpad_rw; -- --- Name: productdims_id_seq1; Type: SEQUENCE; Schema: public; Owner: breakpad_rw +-- Name: productdims_version_sort; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- -CREATE SEQUENCE productdims_id_seq1 - START WITH 1 - INCREMENT BY 1 - NO MINVALUE - NO MAXVALUE - CACHE 1; +CREATE TABLE productdims_version_sort ( + id integer NOT NULL, + product citext NOT NULL, + version citext NOT NULL, + sec1_num1 integer, + sec1_string1 text, + sec1_num2 integer, + sec1_string2 text, + sec2_num1 integer, + sec2_string1 text, + sec2_num2 integer, + sec2_string2 text, + sec3_num1 integer, + sec3_string1 text, + sec3_num2 integer, + sec3_string2 text, + extra text +); -ALTER TABLE public.productdims_id_seq1 OWNER TO breakpad_rw; - --- --- Name: productdims_id_seq1; Type: SEQUENCE OWNED BY; Schema: public; Owner: breakpad_rw --- - -ALTER SEQUENCE productdims_id_seq1 OWNED BY product_versions.product_version_id; - +ALTER TABLE public.productdims_version_sort OWNER TO breakpad_rw; -- -- Name: rank_compare; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: @@ -6385,6 +6505,19 @@ CREATE TABLE sessions ( ALTER TABLE public.sessions OWNER TO breakpad_rw; +-- +-- Name: signature_bugs_rollup; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE signature_bugs_rollup ( + signature_id integer NOT NULL, + bug_count integer DEFAULT 0 NOT NULL, + bug_list integer[] DEFAULT '{}'::integer[] NOT NULL +); + + +ALTER TABLE public.signature_bugs_rollup OWNER TO breakpad_rw; + -- -- Name: signature_products; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -6494,6 +6627,98 @@ CREATE TABLE tcbs ( ALTER TABLE public.tcbs OWNER TO breakpad_rw; +-- +-- Name: top_crashes_by_signature; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE top_crashes_by_signature ( + id integer NOT NULL, + count integer, + uptime real, + signature text, + productdims_id integer, + osdims_id integer, + window_end timestamp without time zone, + window_size interval, + hang_count integer, + plugin_count integer +); + + +ALTER TABLE public.top_crashes_by_signature OWNER TO breakpad_rw; + +-- +-- Name: top_crashes_by_signature_id_seq; Type: SEQUENCE; Schema: public; Owner: breakpad_rw +-- + +CREATE SEQUENCE top_crashes_by_signature_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +ALTER TABLE public.top_crashes_by_signature_id_seq OWNER TO breakpad_rw; + +-- +-- Name: top_crashes_by_signature_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: breakpad_rw +-- + +ALTER SEQUENCE top_crashes_by_signature_id_seq OWNED BY top_crashes_by_signature.id; + + +-- +-- Name: top_crashes_by_url; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE top_crashes_by_url ( + id integer NOT NULL, + count integer, + urldims_id integer, + productdims_id integer, + osdims_id integer, + window_end timestamp without time zone, + window_size interval +); + + +ALTER TABLE public.top_crashes_by_url OWNER TO breakpad_rw; + +-- +-- Name: top_crashes_by_url_id_seq; Type: SEQUENCE; Schema: public; Owner: breakpad_rw +-- + +CREATE SEQUENCE top_crashes_by_url_id_seq + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +ALTER TABLE public.top_crashes_by_url_id_seq OWNER TO breakpad_rw; + +-- +-- Name: top_crashes_by_url_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: breakpad_rw +-- + +ALTER SEQUENCE top_crashes_by_url_id_seq OWNED BY top_crashes_by_url.id; + + +-- +-- Name: top_crashes_by_url_signature; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE top_crashes_by_url_signature ( + top_crashes_by_url_id integer NOT NULL, + signature text NOT NULL, + count integer +); + + +ALTER TABLE public.top_crashes_by_url_signature OWNER TO breakpad_rw; + -- -- Name: transform_rules; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -6570,6 +6795,40 @@ ALTER TABLE public.uptime_levels_uptime_level_seq OWNER TO breakpad_rw; ALTER SEQUENCE uptime_levels_uptime_level_seq OWNED BY uptime_levels.uptime_level; +-- +-- Name: urldims; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE TABLE urldims ( + id integer NOT NULL, + domain text NOT NULL, + url text NOT NULL +); + + +ALTER TABLE public.urldims OWNER TO breakpad_rw; + +-- +-- Name: urldims_id_seq1; Type: SEQUENCE; Schema: public; Owner: breakpad_rw +-- + +CREATE SEQUENCE urldims_id_seq1 + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +ALTER TABLE public.urldims_id_seq1 OWNER TO breakpad_rw; + +-- +-- Name: urldims_id_seq1; Type: SEQUENCE OWNED BY; Schema: public; Owner: breakpad_rw +-- + +ALTER SEQUENCE urldims_id_seq1 OWNED BY urldims.id; + + -- -- Name: windows_versions; Type: TABLE; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -6646,6 +6905,13 @@ ALTER TABLE ONLY jobs ALTER COLUMN id SET DEFAULT nextval('jobs_id_seq'::regclas ALTER TABLE ONLY os_versions ALTER COLUMN os_version_id SET DEFAULT nextval('os_versions_os_version_id_seq'::regclass); +-- +-- Name: id; Type: DEFAULT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY osdims ALTER COLUMN id SET DEFAULT nextval('osdims_id_seq'::regclass); + + -- -- Name: id; Type: DEFAULT; Schema: public; Owner: breakpad_rw -- @@ -6695,6 +6961,20 @@ ALTER TABLE ONLY server_status ALTER COLUMN id SET DEFAULT nextval('server_statu ALTER TABLE ONLY signatures ALTER COLUMN signature_id SET DEFAULT nextval('signatures_signature_id_seq'::regclass); +-- +-- Name: id; Type: DEFAULT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY top_crashes_by_signature ALTER COLUMN id SET DEFAULT nextval('top_crashes_by_signature_id_seq'::regclass); + + +-- +-- Name: id; Type: DEFAULT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY top_crashes_by_url ALTER COLUMN id SET DEFAULT nextval('top_crashes_by_url_id_seq'::regclass); + + -- -- Name: transform_rule_id; Type: DEFAULT; Schema: public; Owner: breakpad_rw -- @@ -6709,6 +6989,13 @@ ALTER TABLE ONLY transform_rules ALTER COLUMN transform_rule_id SET DEFAULT next ALTER TABLE ONLY uptime_levels ALTER COLUMN uptime_level SET DEFAULT nextval('uptime_levels_uptime_level_seq'::regclass); +-- +-- Name: id; Type: DEFAULT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY urldims ALTER COLUMN id SET DEFAULT nextval('urldims_id_seq1'::regclass); + + -- -- Name: addresses_address_key; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -6725,6 +7012,14 @@ ALTER TABLE ONLY addresses ADD CONSTRAINT addresses_pkey PRIMARY KEY (address_id); +-- +-- Name: alexa_topsites_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY alexa_topsites + ADD CONSTRAINT alexa_topsites_pkey PRIMARY KEY (domain); + + -- -- Name: bug_associations_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -6965,6 +7260,14 @@ ALTER TABLE ONLY os_versions ADD CONSTRAINT os_versions_pkey PRIMARY KEY (os_version_id); +-- +-- Name: osdims_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY osdims + ADD CONSTRAINT osdims_pkey PRIMARY KEY (id); + + -- -- Name: plugins_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7061,6 +7364,38 @@ ALTER TABLE ONLY product_versions ADD CONSTRAINT product_versions_pkey PRIMARY KEY (product_version_id); +-- +-- Name: product_visibility_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY product_visibility + ADD CONSTRAINT product_visibility_pkey PRIMARY KEY (productdims_id); + + +-- +-- Name: productdims_pkey1; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY productdims + ADD CONSTRAINT productdims_pkey1 PRIMARY KEY (id); + + +-- +-- Name: productdims_version_sort_id_key; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY productdims_version_sort + ADD CONSTRAINT productdims_version_sort_id_key UNIQUE (id); + + +-- +-- Name: productdims_version_sort_key; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY productdims_version_sort + ADD CONSTRAINT productdims_version_sort_key PRIMARY KEY (product, version); + + -- -- Name: productid_map_key2; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7101,6 +7436,14 @@ ALTER TABLE ONLY reasons ADD CONSTRAINT reasons_reason_key UNIQUE (reason); +-- +-- Name: release_build_type_map_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY release_build_type_map + ADD CONSTRAINT release_build_type_map_pkey PRIMARY KEY (release); + + -- -- Name: release_channel_matches_key; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7181,6 +7524,14 @@ ALTER TABLE ONLY sessions ADD CONSTRAINT session_id_pkey PRIMARY KEY (session_id); +-- +-- Name: signature_bugs_rollup_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY signature_bugs_rollup + ADD CONSTRAINT signature_bugs_rollup_pkey PRIMARY KEY (signature_id); + + -- -- Name: signature_products_key; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7247,6 +7598,30 @@ ALTER TABLE ONLY tcbs ADD CONSTRAINT tcbs_key PRIMARY KEY (signature_id, report_date, product_version_id, process_type, release_channel); +-- +-- Name: top_crashes_by_signature2_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY top_crashes_by_signature + ADD CONSTRAINT top_crashes_by_signature2_pkey PRIMARY KEY (id); + + +-- +-- Name: top_crashes_by_url2_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY top_crashes_by_url + ADD CONSTRAINT top_crashes_by_url2_pkey PRIMARY KEY (id); + + +-- +-- Name: top_crashes_by_url_signature2_pkey; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY top_crashes_by_url_signature + ADD CONSTRAINT top_crashes_by_url_signature2_pkey PRIMARY KEY (top_crashes_by_url_id, signature); + + -- -- Name: transform_rules_key; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7279,6 +7654,14 @@ ALTER TABLE ONLY uptime_levels ADD CONSTRAINT uptime_levels_uptime_string_key UNIQUE (uptime_string); +-- +-- Name: urldims_pkey1; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +ALTER TABLE ONLY urldims + ADD CONSTRAINT urldims_pkey1 PRIMARY KEY (id); + + -- -- Name: windows_version_key; Type: CONSTRAINT; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7287,6 +7670,13 @@ ALTER TABLE ONLY windows_versions ADD CONSTRAINT windows_version_key UNIQUE (major_version, minor_version); +-- +-- Name: builds_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE UNIQUE INDEX builds_key ON builds USING btree (product, version, platform, buildid); + + -- -- Name: crontabber_state_one_row; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7401,6 +7791,13 @@ ALTER TABLE jobs CLUSTER ON jobs_owner_starteddatetime_key; CREATE INDEX nightly_builds_product_version_id_report_date ON nightly_builds USING btree (product_version_id, report_date); +-- +-- Name: osdims_name_version_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX osdims_name_version_key ON osdims USING btree (os_name, os_version); + + -- -- Name: product_version_unique_beta; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7429,6 +7826,34 @@ CREATE INDEX product_versions_product_name ON product_versions USING btree (prod CREATE INDEX product_versions_version_sort ON product_versions USING btree (version_sort); +-- +-- Name: product_visibility_end_date; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX product_visibility_end_date ON product_visibility USING btree (end_date); + + +-- +-- Name: product_visibility_start_date; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX product_visibility_start_date ON product_visibility USING btree (start_date); + + +-- +-- Name: productdims_product_version_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE UNIQUE INDEX productdims_product_version_key ON productdims USING btree (product, version); + + +-- +-- Name: productdims_sort_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX productdims_sort_key ON productdims USING btree (product, sort_key); + + -- -- Name: rank_compare_product_version_id_rank_report_count; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: -- @@ -7499,6 +7924,76 @@ CREATE INDEX tcbs_report_date ON tcbs USING btree (report_date); CREATE INDEX tcbs_signature ON tcbs USING btree (signature_id); +-- +-- Name: top_crashes_by_signature2_osdims_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_signature2_osdims_key ON top_crashes_by_signature USING btree (osdims_id); + + +-- +-- Name: top_crashes_by_signature2_productdims_window_end_idx; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_signature2_productdims_window_end_idx ON top_crashes_by_signature USING btree (productdims_id, window_end DESC); + + +-- +-- Name: top_crashes_by_signature2_signature_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_signature2_signature_key ON top_crashes_by_signature USING btree (signature); + + +-- +-- Name: top_crashes_by_signature2_window_end_productdims_id_idx; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_signature2_window_end_productdims_id_idx ON top_crashes_by_signature USING btree (window_end DESC, productdims_id); + + +-- +-- Name: top_crashes_by_url2_count_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_url2_count_key ON top_crashes_by_url USING btree (count); + + +-- +-- Name: top_crashes_by_url2_osdims_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_url2_osdims_key ON top_crashes_by_url USING btree (osdims_id); + + +-- +-- Name: top_crashes_by_url2_productdims_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_url2_productdims_key ON top_crashes_by_url USING btree (productdims_id); + + +-- +-- Name: top_crashes_by_url2_urldims_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_url2_urldims_key ON top_crashes_by_url USING btree (urldims_id); + + +-- +-- Name: top_crashes_by_url2_window_end_window_size_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE INDEX top_crashes_by_url2_window_end_window_size_key ON top_crashes_by_url USING btree (window_end, window_size); + + +-- +-- Name: urldims_url_domain_key; Type: INDEX; Schema: public; Owner: breakpad_rw; Tablespace: +-- + +CREATE UNIQUE INDEX urldims_url_domain_key ON urldims USING btree (url, domain); + + -- -- Name: crontabber_nodelete; Type: TRIGGER; Schema: public; Owner: breakpad_rw -- @@ -7534,6 +8029,27 @@ CREATE TRIGGER transform_rules_insert_order BEFORE INSERT ON transform_rules FOR CREATE TRIGGER transform_rules_update_order AFTER UPDATE OF rule_order, category ON transform_rules FOR EACH ROW EXECUTE PROCEDURE transform_rules_update_order(); +-- +-- Name: version_sort_trigger; Type: TRIGGER; Schema: public; Owner: breakpad_rw +-- + +CREATE TRIGGER version_sort_trigger BEFORE INSERT OR UPDATE ON productdims FOR EACH ROW EXECUTE PROCEDURE version_sort_trigger(); + + +-- +-- Name: version_sort_update_trigger_after; Type: TRIGGER; Schema: public; Owner: breakpad_rw +-- + +CREATE TRIGGER version_sort_update_trigger_after AFTER UPDATE ON productdims_version_sort FOR EACH ROW EXECUTE PROCEDURE version_sort_update_trigger_after(); + + +-- +-- Name: version_sort_update_trigger_before; Type: TRIGGER; Schema: public; Owner: breakpad_rw +-- + +CREATE TRIGGER version_sort_update_trigger_before BEFORE UPDATE ON productdims_version_sort FOR EACH ROW EXECUTE PROCEDURE version_sort_update_trigger_before(); + + -- -- Name: bug_associations_bugs_fk; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw -- @@ -7646,6 +8162,30 @@ ALTER TABLE ONLY product_versions ADD CONSTRAINT product_versions_product_name_fkey FOREIGN KEY (product_name) REFERENCES products(product_name); +-- +-- Name: product_visibility_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY product_visibility + ADD CONSTRAINT product_visibility_id_fkey FOREIGN KEY (productdims_id) REFERENCES productdims(id) ON DELETE CASCADE; + + +-- +-- Name: productdims_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY top_crashes_by_signature + ADD CONSTRAINT productdims_id_fkey FOREIGN KEY (productdims_id) REFERENCES productdims(id) ON DELETE CASCADE; + + +-- +-- Name: productdims_product_version_fkey; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY productdims_version_sort + ADD CONSTRAINT productdims_product_version_fkey FOREIGN KEY (product, version) REFERENCES productdims(product, version) ON UPDATE CASCADE ON DELETE CASCADE; + + -- -- Name: release_channel_matches_release_channel_fkey; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw -- @@ -7654,6 +8194,14 @@ ALTER TABLE ONLY release_channel_matches ADD CONSTRAINT release_channel_matches_release_channel_fkey FOREIGN KEY (release_channel) REFERENCES release_channels(release_channel); +-- +-- Name: signature_bugs_rollup_signature_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY signature_bugs_rollup + ADD CONSTRAINT signature_bugs_rollup_signature_id_fkey FOREIGN KEY (signature_id) REFERENCES signatures(signature_id); + + -- -- Name: signature_products_rollup_product_name_fkey; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw -- @@ -7694,6 +8242,22 @@ ALTER TABLE ONLY tcbs ADD CONSTRAINT tcbs_signature_id_fkey FOREIGN KEY (signature_id) REFERENCES signatures(signature_id); +-- +-- Name: top_crashes_by_url_productdims_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY top_crashes_by_url + ADD CONSTRAINT top_crashes_by_url_productdims_id_fkey FOREIGN KEY (productdims_id) REFERENCES productdims(id) ON DELETE CASCADE; + + +-- +-- Name: top_crashes_by_url_signature_fkey; Type: FK CONSTRAINT; Schema: public; Owner: breakpad_rw +-- + +ALTER TABLE ONLY top_crashes_by_url_signature + ADD CONSTRAINT top_crashes_by_url_signature_fkey FOREIGN KEY (top_crashes_by_url_id) REFERENCES top_crashes_by_url(id) ON DELETE CASCADE; + + -- -- Name: public; Type: ACL; Schema: -; Owner: breakpad_rw -- @@ -7729,6 +8293,18 @@ GRANT ALL ON TABLE addresses TO monitor; GRANT SELECT ON TABLE addresses TO analyst; +-- +-- Name: alexa_topsites; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE alexa_topsites FROM PUBLIC; +REVOKE ALL ON TABLE alexa_topsites FROM breakpad_rw; +GRANT ALL ON TABLE alexa_topsites TO breakpad_rw; +GRANT SELECT ON TABLE alexa_topsites TO monitoring; +GRANT SELECT ON TABLE alexa_topsites TO breakpad_ro; +GRANT SELECT ON TABLE alexa_topsites TO breakpad; + + -- -- Name: bloat; Type: ACL; Schema: public; Owner: postgres -- @@ -7742,6 +8318,52 @@ GRANT SELECT ON TABLE bloat TO breakpad; GRANT SELECT,INSERT,DELETE,UPDATE ON TABLE bloat TO breakpad_rw; +-- +-- Name: product_versions; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE product_versions FROM PUBLIC; +REVOKE ALL ON TABLE product_versions FROM breakpad_rw; +GRANT ALL ON TABLE product_versions TO breakpad_rw; +GRANT SELECT ON TABLE product_versions TO breakpad_ro; +GRANT SELECT ON TABLE product_versions TO breakpad; +GRANT ALL ON TABLE product_versions TO monitor; +GRANT SELECT ON TABLE product_versions TO analyst; + + +-- +-- Name: productdims_id_seq1; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON SEQUENCE productdims_id_seq1 FROM PUBLIC; +REVOKE ALL ON SEQUENCE productdims_id_seq1 FROM breakpad_rw; +GRANT ALL ON SEQUENCE productdims_id_seq1 TO breakpad_rw; +GRANT SELECT ON SEQUENCE productdims_id_seq1 TO breakpad; + + +-- +-- Name: productdims; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE productdims FROM PUBLIC; +REVOKE ALL ON TABLE productdims FROM breakpad_rw; +GRANT ALL ON TABLE productdims TO breakpad_rw; +GRANT SELECT ON TABLE productdims TO monitoring; +GRANT SELECT ON TABLE productdims TO breakpad_ro; +GRANT SELECT ON TABLE productdims TO breakpad; + + +-- +-- Name: branches; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE branches FROM PUBLIC; +REVOKE ALL ON TABLE branches FROM breakpad_rw; +GRANT ALL ON TABLE branches TO breakpad_rw; +GRANT SELECT ON TABLE branches TO breakpad_ro; +GRANT SELECT ON TABLE branches TO breakpad; + + -- -- Name: bug_associations; Type: ACL; Schema: public; Owner: breakpad_rw -- @@ -7768,6 +8390,18 @@ GRANT SELECT ON TABLE bugs TO breakpad; GRANT SELECT ON TABLE bugs TO analyst; +-- +-- Name: builds; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE builds FROM PUBLIC; +REVOKE ALL ON TABLE builds FROM breakpad_rw; +GRANT ALL ON TABLE builds TO breakpad_rw; +GRANT SELECT ON TABLE builds TO monitoring; +GRANT SELECT ON TABLE builds TO breakpad_ro; +GRANT SELECT ON TABLE builds TO breakpad; + + -- -- Name: correlation_addons; Type: ACL; Schema: public; Owner: breakpad_rw -- @@ -7917,16 +8551,15 @@ GRANT SELECT ON TABLE product_release_channels TO analyst; -- --- Name: product_versions; Type: ACL; Schema: public; Owner: breakpad_rw +-- Name: product_visibility; Type: ACL; Schema: public; Owner: breakpad_rw -- -REVOKE ALL ON TABLE product_versions FROM PUBLIC; -REVOKE ALL ON TABLE product_versions FROM breakpad_rw; -GRANT ALL ON TABLE product_versions TO breakpad_rw; -GRANT SELECT ON TABLE product_versions TO breakpad_ro; -GRANT SELECT ON TABLE product_versions TO breakpad; -GRANT ALL ON TABLE product_versions TO monitor; -GRANT SELECT ON TABLE product_versions TO analyst; +REVOKE ALL ON TABLE product_visibility FROM PUBLIC; +REVOKE ALL ON TABLE product_visibility FROM breakpad_rw; +GRANT ALL ON TABLE product_visibility TO breakpad_rw; +GRANT SELECT ON TABLE product_visibility TO monitoring; +GRANT SELECT ON TABLE product_visibility TO breakpad_ro; +GRANT SELECT ON TABLE product_visibility TO breakpad; -- @@ -7942,6 +8575,18 @@ GRANT ALL ON TABLE products TO monitor; GRANT SELECT ON TABLE products TO analyst; +-- +-- Name: release_build_type_map; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE release_build_type_map FROM PUBLIC; +REVOKE ALL ON TABLE release_build_type_map FROM breakpad_rw; +GRANT ALL ON TABLE release_build_type_map TO breakpad_rw; +GRANT SELECT ON TABLE release_build_type_map TO breakpad_ro; +GRANT SELECT ON TABLE release_build_type_map TO breakpad; +GRANT ALL ON TABLE release_build_type_map TO monitor; + + -- -- Name: release_channels; Type: ACL; Schema: public; Owner: breakpad_rw -- @@ -8170,6 +8815,28 @@ GRANT ALL ON SEQUENCE os_versions_os_version_id_seq TO breakpad_rw; GRANT SELECT ON SEQUENCE os_versions_os_version_id_seq TO breakpad; +-- +-- Name: osdims; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE osdims FROM PUBLIC; +REVOKE ALL ON TABLE osdims FROM breakpad_rw; +GRANT ALL ON TABLE osdims TO breakpad_rw; +GRANT SELECT ON TABLE osdims TO monitoring; +GRANT SELECT ON TABLE osdims TO breakpad_ro; +GRANT SELECT ON TABLE osdims TO breakpad; + + +-- +-- Name: osdims_id_seq; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON SEQUENCE osdims_id_seq FROM PUBLIC; +REVOKE ALL ON SEQUENCE osdims_id_seq FROM breakpad_rw; +GRANT ALL ON SEQUENCE osdims_id_seq TO breakpad_rw; +GRANT SELECT ON SEQUENCE osdims_id_seq TO breakpad; + + -- -- Name: performance_check_1; Type: ACL; Schema: public; Owner: ganglia -- @@ -8343,13 +9010,14 @@ GRANT SELECT ON TABLE product_version_builds TO analyst; -- --- Name: productdims_id_seq1; Type: ACL; Schema: public; Owner: breakpad_rw +-- Name: productdims_version_sort; Type: ACL; Schema: public; Owner: breakpad_rw -- -REVOKE ALL ON SEQUENCE productdims_id_seq1 FROM PUBLIC; -REVOKE ALL ON SEQUENCE productdims_id_seq1 FROM breakpad_rw; -GRANT ALL ON SEQUENCE productdims_id_seq1 TO breakpad_rw; -GRANT SELECT ON SEQUENCE productdims_id_seq1 TO breakpad; +REVOKE ALL ON TABLE productdims_version_sort FROM PUBLIC; +REVOKE ALL ON TABLE productdims_version_sort FROM breakpad_rw; +GRANT ALL ON TABLE productdims_version_sort TO breakpad_rw; +GRANT SELECT ON TABLE productdims_version_sort TO breakpad_ro; +GRANT SELECT ON TABLE productdims_version_sort TO breakpad; -- @@ -8899,6 +9567,19 @@ GRANT SELECT ON TABLE sessions TO breakpad_ro; GRANT SELECT ON TABLE sessions TO breakpad; +-- +-- Name: signature_bugs_rollup; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE signature_bugs_rollup FROM PUBLIC; +REVOKE ALL ON TABLE signature_bugs_rollup FROM breakpad_rw; +GRANT ALL ON TABLE signature_bugs_rollup TO breakpad_rw; +GRANT SELECT ON TABLE signature_bugs_rollup TO breakpad_ro; +GRANT SELECT ON TABLE signature_bugs_rollup TO breakpad; +GRANT ALL ON TABLE signature_bugs_rollup TO monitor; +GRANT SELECT ON TABLE signature_bugs_rollup TO analyst; + + -- -- Name: signature_products; Type: ACL; Schema: public; Owner: breakpad_rw -- @@ -8986,6 +9667,62 @@ GRANT ALL ON TABLE tcbs TO monitor; GRANT SELECT ON TABLE tcbs TO analyst; +-- +-- Name: top_crashes_by_signature; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE top_crashes_by_signature FROM PUBLIC; +REVOKE ALL ON TABLE top_crashes_by_signature FROM breakpad_rw; +GRANT ALL ON TABLE top_crashes_by_signature TO breakpad_rw; +GRANT SELECT ON TABLE top_crashes_by_signature TO monitoring; +GRANT SELECT ON TABLE top_crashes_by_signature TO breakpad_ro; +GRANT SELECT ON TABLE top_crashes_by_signature TO breakpad; + + +-- +-- Name: top_crashes_by_signature_id_seq; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON SEQUENCE top_crashes_by_signature_id_seq FROM PUBLIC; +REVOKE ALL ON SEQUENCE top_crashes_by_signature_id_seq FROM breakpad_rw; +GRANT ALL ON SEQUENCE top_crashes_by_signature_id_seq TO breakpad_rw; +GRANT SELECT ON SEQUENCE top_crashes_by_signature_id_seq TO breakpad; + + +-- +-- Name: top_crashes_by_url; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE top_crashes_by_url FROM PUBLIC; +REVOKE ALL ON TABLE top_crashes_by_url FROM breakpad_rw; +GRANT ALL ON TABLE top_crashes_by_url TO breakpad_rw; +GRANT SELECT ON TABLE top_crashes_by_url TO monitoring; +GRANT SELECT ON TABLE top_crashes_by_url TO breakpad_ro; +GRANT SELECT ON TABLE top_crashes_by_url TO breakpad; + + +-- +-- Name: top_crashes_by_url_id_seq; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON SEQUENCE top_crashes_by_url_id_seq FROM PUBLIC; +REVOKE ALL ON SEQUENCE top_crashes_by_url_id_seq FROM breakpad_rw; +GRANT ALL ON SEQUENCE top_crashes_by_url_id_seq TO breakpad_rw; +GRANT SELECT ON SEQUENCE top_crashes_by_url_id_seq TO breakpad; + + +-- +-- Name: top_crashes_by_url_signature; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE top_crashes_by_url_signature FROM PUBLIC; +REVOKE ALL ON TABLE top_crashes_by_url_signature FROM breakpad_rw; +GRANT ALL ON TABLE top_crashes_by_url_signature TO breakpad_rw; +GRANT SELECT ON TABLE top_crashes_by_url_signature TO monitoring; +GRANT SELECT ON TABLE top_crashes_by_url_signature TO breakpad_ro; +GRANT SELECT ON TABLE top_crashes_by_url_signature TO breakpad; + + -- -- Name: transform_rules; Type: ACL; Schema: public; Owner: breakpad_rw -- @@ -9011,6 +9748,28 @@ GRANT ALL ON TABLE uptime_levels TO monitor; GRANT SELECT ON TABLE uptime_levels TO analyst; +-- +-- Name: urldims; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON TABLE urldims FROM PUBLIC; +REVOKE ALL ON TABLE urldims FROM breakpad_rw; +GRANT ALL ON TABLE urldims TO breakpad_rw; +GRANT SELECT ON TABLE urldims TO monitoring; +GRANT SELECT ON TABLE urldims TO breakpad_ro; +GRANT SELECT ON TABLE urldims TO breakpad; + + +-- +-- Name: urldims_id_seq1; Type: ACL; Schema: public; Owner: breakpad_rw +-- + +REVOKE ALL ON SEQUENCE urldims_id_seq1 FROM PUBLIC; +REVOKE ALL ON SEQUENCE urldims_id_seq1 FROM breakpad_rw; +GRANT ALL ON SEQUENCE urldims_id_seq1 TO breakpad_rw; +GRANT SELECT ON SEQUENCE urldims_id_seq1 TO breakpad; + + -- -- Name: windows_versions; Type: ACL; Schema: public; Owner: breakpad_rw --