Skip to content

Commit

Permalink
Merge pull request #1277 from selenamarie/bug826564-exploitability-sql
Browse files Browse the repository at this point in the history
bug 826564 Add exploitability to reports_clean
  • Loading branch information
jezdez committed Jun 6, 2013
2 parents 291bc4f + d882f55 commit d1dd6df
Show file tree
Hide file tree
Showing 6 changed files with 199 additions and 5 deletions.
89 changes: 89 additions & 0 deletions alembic/versions/9798b1cc04_bug_826564_add_explo.py
@@ -0,0 +1,89 @@
"""bug 826564 - add exploitability to reports_clean
Revision ID: 9798b1cc04
Revises: 3805e9f77df4
Create Date: 2013-06-05 13:20:25.116074
"""

# revision identifiers, used by Alembic.
revision = '9798b1cc04'
down_revision = '3805e9f77df4'

import os
import sqlalchemy as sa
from alembic import op
from sqlalchemy.dialects import postgresql
from sqlalchemy import types
from sqlalchemy.sql import table, column
from sqlalchemy.dialects import postgresql

class CITEXT(types.UserDefinedType):
name = 'citext'

def get_col_spec(self):
return 'CITEXT'

def bind_processor(self, dialect):
def process(value):
return value
return process

def result_processor(self, dialect, coltype):
def process(value):
return value
return process

def __repr__(self):
return "citext"

class JSON(types.UserDefinedType):
name = 'json'

def get_col_spec(self):
return 'JSON'

def bind_processor(self, dialect):
def process(value):
return value
return process

def result_processor(self, dialect, coltype):
def process(value):
return value
return process

def __repr__(self):
return "json"

def upgrade():
op.create_table(u'exploitability_reports',
sa.Column(u'signature_id', sa.INTEGER(), nullable=False),
sa.Column(u'report_date', sa.DATE(), nullable=False),
sa.Column(u'null_count', sa.INTEGER(), server_default='0', nullable=False),
sa.Column(u'none_count', sa.INTEGER(), server_default='0', nullable=False),
sa.Column(u'low_count', sa.INTEGER(), server_default='0', nullable=False),
sa.Column(u'medium_count', sa.INTEGER(), server_default='0', nullable=False),
sa.Column(u'high_count', sa.INTEGER(), server_default='0', nullable=False),
sa.ForeignKeyConstraint(['signature_id'], [u'signatures.signature_id'], ),
sa.PrimaryKeyConstraint()
)
# We can probably get away with just applying this to the parent table
# If there are performance problems on stage, break this out and apply to all
# child partitions first, then reports_clean last.
op.add_column(u'reports_clean', sa.Column(u'exploitability', sa.TEXT(), nullable=True))
app_path=os.getcwd()
procs = [
'001_update_reports_clean.sql'
, 'update_exploitability.sql'
, 'backfill_exploitability.sql'
]
for myfile in [app_path + '/socorro/external/postgresql/raw_sql/procs/' + line for line in procs]:
proc = open(myfile, 'r').read()
op.execute(proc)

def downgrade():
op.drop_column(u'reports_clean', u'exploitability')
op.drop_table(u'exploitability_reports')
# Not rolling back 001_update_reports_clean.sql...
# if rolling back, need to pull out the old version and apply manually
10 changes: 10 additions & 0 deletions socorro/cron/jobs/matviews.py
Expand Up @@ -180,3 +180,13 @@ def run(self, connection, date):
start_time += datetime.timedelta(minutes=30)
end_time = start_time + datetime.timedelta(hours=1)
self.run_proc(connection, [start_time, end_time])


class ExploitabilityCronApp(_MatViewBackfillBase):
proc_name = 'update_exploitability'
app_name = 'exploitability-matview'
depends_on = (
'tcbs-matview',
'build-adu-matview',
'reports-clean'
)
17 changes: 17 additions & 0 deletions socorro/external/postgresql/models.py
Expand Up @@ -250,6 +250,22 @@ class Extension(DeclarativeBase):

__mapper_args__ = {"primary_key":(report_id, date_processed, extension_key, extension_id, extension_version)}

class ExploitabilityReport(DeclarativeBase):
__tablename__ = 'exploitability_reports'

#column definitions
signature_id = Column(u'signature_id', INTEGER(), ForeignKey('signatures.signature_id'), nullable=False)
report_date = Column(u'report_date', DATE(), nullable=False)
null_count = Column(u'null_count', INTEGER(), nullable=False, server_default=text('0'))
none_count = Column(u'none_count', INTEGER(), nullable=False, server_default=text('0'))
low_count = Column(u'low_count', INTEGER(), nullable=False, server_default=text('0'))
medium_count = Column(u'medium_count', INTEGER(), nullable=False, server_default=text('0'))
high_count = Column(u'high_count', INTEGER(), nullable=False, server_default=text('0'))

exploitable_signature_idx = Index('exploitable_signature_date_idx', signature_id, report_date, unique=True)

__mapper_args__ = {"primary_key":(signature_id, report_date)}

class PluginsReport(DeclarativeBase):
__tablename__ = 'plugins_reports'

Expand Down Expand Up @@ -1111,6 +1127,7 @@ class ReportsClean(DeclarativeBase):
signature_id = Column(u'signature_id', INTEGER(), nullable=False)
uptime = Column(u'uptime', INTERVAL())
uuid = Column(u'uuid', TEXT(), primary_key=True, nullable=False)
exploitability = Column(u'exploitability', TEXT())

#relationship definitions

Expand Down
Expand Up @@ -66,7 +66,8 @@ as select uuid,
email, user_comments, url, app_notes,
release_channel, hangid as hang_id,
cpu_name as architecture,
get_cores(cpu_info) as cores
get_cores(cpu_info) as cores,
exploitability
from reports
where date_processed >= fromtime and date_processed < ( fromtime + fortime )
and completed_datetime is not null;
Expand Down Expand Up @@ -185,7 +186,8 @@ release_channel citext,
duplicate_of text,
domain_id int,
architecture citext,
cores int
cores int,
exploitability text
) on commit drop ;

-- populate the new buffer with uuid, date_processed,
Expand Down Expand Up @@ -218,7 +220,8 @@ SELECT new_reports.uuid,
reports_duplicates.duplicate_of,
domains.domain_id,
architecture,
cores
cores,
exploitability
FROM new_reports
LEFT OUTER JOIN release_channel_matches ON new_reports.release_channel ILIKE release_channel_matches.match_string
LEFT OUTER JOIN signatures ON new_reports.signature = signatures.signature
Expand Down Expand Up @@ -333,12 +336,12 @@ EXECUTE 'INSERT INTO ' || rc_part || '
build, signature_id, install_age, uptime,
reason_id, address_id, os_name, os_version_id,
hang_id, flash_version_id, process_type, release_channel,
duplicate_of, domain_id, architecture, cores )
duplicate_of, domain_id, architecture, cores, exploitability )
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,
duplicate_of, domain_id, architecture, cores
duplicate_of, domain_id, architecture, cores, exploitability
FROM reports_clean_buffer;';

IF analyze_it THEN
Expand Down
@@ -0,0 +1,15 @@
CREATE OR REPLACE FUNCTION backfill_exploitability(updateday date) RETURNS boolean
LANGUAGE plpgsql
AS $$
BEGIN
-- stored procudure to delete and replace one day of
-- product_adu, optionally only for a specific product
-- intended to be called by backfill_matviews

DELETE FROM exploitability_reports
WHERE report_date = updateday;

PERFORM update_exploitability(updateday, false);

RETURN TRUE;
END; $$;
@@ -0,0 +1,60 @@
CREATE OR REPLACE FUNCTION update_exploitability(updateday date, checkdata boolean DEFAULT true, check_period interval DEFAULT '01:00:00'::interval) RETURNS boolean
LANGUAGE plpgsql
SET client_min_messages TO 'ERROR'
AS $$
BEGIN
-- Populate a daily matview which reports on the exploitability of Top Crashers each day
-- depends on tcbs and signatures

-- check if we've been run
IF checkdata THEN
PERFORM 1 FROM exploitability_reports WHERE report_date = updateday LIMIT 1;
IF FOUND THEN
RAISE INFO 'exploitability_reports has already been run for %.',updateday;
END IF;
END IF;

-- check if reports_clean is complete
IF NOT reports_clean_done(updateday, check_period) THEN
IF checkdata THEN
RAISE NOTICE 'Reports_clean has not been updated to the end of %',updateday;
RETURN FALSE;
ELSE
RETURN FALSE;
END IF;
END IF;

-- check if tcbs is updated
PERFORM 1
FROM tcbs
WHERE tcbs.report_date = updateday
LIMIT 1;

IF NOT FOUND THEN
IF checkdata THEN
RAISE NOTICE 'TCBS has not been updated to the end of %',updateday;
RETURN FALSE;
ELSE
RAISE NOTICE 'TCBS has not been updated, skipping.';
RETURN TRUE;
END IF;
END IF;


INSERT INTO exploitability_reports (
signature_id, report_date, null_count, none_count, low_count, medium_count, high_count)
select s.signature_id,
r.date_processed::date,
count(CASE WHEN r.exploitability is NULL THEN 1 ELSE 0 END) as count_null,
count(CASE WHEN r.exploitability = 'none' THEN 1 ELSE 0 END) as count_none,
count(CASE WHEN r.exploitability = 'low' THEN 1 ELSE 0 END) as count_low,
count(CASE WHEN r.exploitability = 'medium' THEN 1 ELSE 0 END) as count_medium,
count(CASE WHEN r.exploitability = 'high' THEN 1 ELSE 0 END) as count_high
FROM
signatures s JOIN reports_clean r ON r.signature_id = s.signature_id
WHERE s.signature_id IN (select signature_id from tcbs where utc_day_is(tcbs.report_date, updateday))
AND utc_day_is(r.date_processed, updateday)
GROUP BY s.signature_id, r.date_processed::date;

RETURN TRUE;
END; $$;

0 comments on commit d1dd6df

Please sign in to comment.