Skip to content

Commit

Permalink
Merge pull request #1441 from selenamarie/bug853452-devices-sigsum
Browse files Browse the repository at this point in the history
Fixes bug 853452 Adds signature summary for Android Devices
  • Loading branch information
selenamarie committed Aug 27, 2013
2 parents 877d003 + 8f8f3d8 commit 16a97bc
Show file tree
Hide file tree
Showing 9 changed files with 228 additions and 7 deletions.
83 changes: 83 additions & 0 deletions alembic/versions/49bf379b5a8_bug_853452_android_d.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,83 @@
"""bug 853452 android devices
Revision ID: 49bf379b5a8
Revises: 35604f61bc24
Create Date: 2013-08-26 13:51:45.423498
"""

# revision identifiers, used by Alembic.
revision = '49bf379b5a8'
down_revision = '35604f61bc24'

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


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

def get_col_spec(self):
return 'CITEXT'

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

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

def __repr__(self):
return "citext"

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

def get_col_spec(self):
return 'JSON'

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

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

def __repr__(self):
return "json"

def upgrade():
### commands auto generated by Alembic - please adjust! ###
op.create_table(u'signature_summary_device',
sa.Column(u'report_date', sa.DATE(), nullable=False),
sa.Column(u'signature_id', sa.INTEGER(), nullable=False),
sa.Column(u'android_device_id', sa.INTEGER(), nullable=False),
sa.Column(u'report_count', sa.INTEGER(), nullable=False),
sa.PrimaryKeyConstraint(u'report_date', u'signature_id', u'android_device_id')
)
op.create_table(u'android_devices',
sa.Column(u'android_device_id', sa.INTEGER(), nullable=False),
sa.Column(u'android_cpu_abi', sa.TEXT(), nullable=True),
sa.Column(u'android_manufacturer', sa.TEXT(), nullable=True),
sa.Column(u'android_model', sa.TEXT(), nullable=True),
sa.Column(u'android_version', sa.TEXT(), nullable=True),
sa.PrimaryKeyConstraint(u'android_device_id')
)
app_path=os.getcwd()
procs = [
'update_signature_summary.sql'
, 'backfill_android_devices.sql'
, 'update_android_devices.sql'
]
for myfile in [app_path + '/socorro/external/postgresql/raw_sql/procs/' + line for line in procs]:
with open(myfile, 'r') as file:
op.execute(file.read())


def downgrade():
### commands auto generated by Alembic - please adjust! ###
op.drop_table(u'android_devices')
op.drop_table(u'signature_summary_device')
### end Alembic commands ###
1 change: 1 addition & 0 deletions socorro/cron/crontabber.py
Original file line number Diff line number Diff line change
Expand Up @@ -48,6 +48,7 @@
socorro.cron.jobs.matviews.TCBSBuildCronApp|1d|10:00
socorro.cron.jobs.matviews.ExplosivenessCronApp|1d|10:00
socorro.cron.jobs.matviews.SignatureSummaryCronApp|1d|10:00
socorro.cron.jobs.matviews.AndroidDevicesCronApp|1d|10:00
socorro.cron.jobs.ftpscraper.FTPScraperCronApp|1h
socorro.cron.jobs.automatic_emails.AutomaticEmailsCronApp|1h
socorro.cron.jobs.suspicious_crashes.SuspiciousCrashesApp|1d
Expand Down
6 changes: 6 additions & 0 deletions socorro/cron/jobs/matviews.py
Original file line number Diff line number Diff line change
Expand Up @@ -199,3 +199,9 @@ class SignatureSummaryCronApp(_MatViewBackfillBase):
'reports-clean',
'product-versions-matview'
)


class AndroidDevicesCronApp(_MatViewBackfillBase):
proc_name = 'update_android_devices'
app_name = 'android-devices-matview'
# Depends on raw_crashes being populated, but no jobs
24 changes: 19 additions & 5 deletions socorro/external/postgresql/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -9,13 +9,9 @@
from __future__ import unicode_literals

from sqlalchemy import Column, ForeignKey, Index, text, Integer
from sqlalchemy import create_engine
from sqlalchemy import event
from sqlalchemy.ext import compiler
from sqlalchemy.ext.declarative import declarative_base
from sqlalchemy.orm import relationship, sessionmaker
from sqlalchemy.schema import DDLElement
from sqlalchemy.sql import table
from sqlalchemy.orm import relationship
import sqlalchemy.types as types

try:
Expand Down Expand Up @@ -1101,6 +1097,15 @@ class SignatureProductsRollup(DeclarativeBase):
signatures = relationship('Signature', primaryjoin='SignatureProductsRollup.signature_id==Signature.signature_id')


class AndroidDevice(DeclarativeBase):
__tablename__ = 'android_devices'

android_device_id = Column(u'android_device_id', INTEGER(), primary_key=True, nullable=False)
android_cpu_abi = Column(u'android_cpu_abi', TEXT())
android_manufacturer = Column(u'android_manufacturer', TEXT())
android_model = Column(u'android_model', TEXT())
android_version = Column(u'android_version', TEXT())

class SignatureSummaryArchitecture(DeclarativeBase):
__tablename__ = 'signature_summary_architecture'

Expand All @@ -1113,6 +1118,15 @@ class SignatureSummaryArchitecture(DeclarativeBase):
report_count = Column(u'report_count', INTEGER(), nullable=False)


class SignatureSummaryDevice(DeclarativeBase):
__tablename__ = 'signature_summary_device'

report_date = Column(u'report_date', DATE(), primary_key=True, nullable=False, index=True)
signature_id = Column(u'signature_id', INTEGER(), primary_key=True, nullable=False)
android_device_id = Column(u'android_device_id', INTEGER(), primary_key=True, nullable=False)
report_count = Column(u'report_count', INTEGER(), nullable=False)


class SignatureSummaryFlashVersion(DeclarativeBase):
__tablename__ = 'signature_summary_flash_version'

Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
CREATE OR REPLACE FUNCTION backfill_android_devices(updateday date) RETURNS boolean
LANGUAGE plpgsql
AS $$
BEGIN
-- stored procudure to re-run android_devices
-- intended to be called by backfill_matviews

PERFORM update_android_devices(updateday, false);

RETURN TRUE;
END; $$;

Original file line number Diff line number Diff line change
Expand Up @@ -81,6 +81,9 @@ WHILE thisday <= lastday LOOP
PERFORM backfill_nightly_builds(thisday);
RAISE INFO 'exploitability';
PERFORM backfill_exploitability(thisday);
RAISE INFO 'android_devices';
PERFORM backfill_android_devices(thisday);
RAISE INFO 'signature summary';
PERFORM backfill_signature_summary(thisday);

thisday := thisday + 1;
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,66 @@
CREATE OR REPLACE FUNCTION update_android_devices(updateday date, checkdata boolean DEFAULT true) RETURNS boolean
LANGUAGE plpgsql
SET "TimeZone" TO 'UTC'
AS $$
BEGIN

CREATE TEMPORARY TABLE new_android_devices
AS
SELECT DISTINCT
json_object_field_text(raw_crash, 'Android_CPU_ABI') as android_cpu_abi
, json_object_field_text(raw_crash, 'Android_Manufacturer') as android_manufacturer
, json_object_field_text(raw_crash, 'Android_Model') as android_model
, json_object_field_text(raw_crash, 'Android_Version') as android_version
FROM raw_crashes
WHERE
date_processed >= updateday
AND date_processed <= (updateday + 1)
GROUP BY
android_cpu_abi
, android_manufacturer
, android_model
, android_version
;

PERFORM 1 FROM new_android_devices;
IF NOT FOUND THEN
IF checkdata THEN
RAISE NOTICE 'no new android devices found in raw_crashes for date %',updateday;
RETURN FALSE;
END IF;
END IF;

ANALYZE new_android_devices;

-- update android_devices

INSERT INTO android_devices (
android_cpu_abi
, android_manufacturer
, android_model
, android_version
)
SELECT
new_android_devices.android_cpu_abi
, new_android_devices.android_manufacturer
, new_android_devices.android_model
, new_android_devices.android_version
FROM new_android_devices
LEFT OUTER JOIN android_devices
ON new_android_devices.android_cpu_abi = android_devices.android_cpu_abi
AND new_android_devices.android_manufacturer = android_devices.android_manufacturer
AND new_android_devices.android_model = android_devices.android_model
AND new_android_devices.android_version = android_devices.android_version
GROUP BY
new_android_devices.android_cpu_abi
, new_android_devices.android_manufacturer
, new_android_devices.android_model
, new_android_devices.android_version
;

DROP TABLE new_android_devices;

RETURN True;

END;
$$;
Original file line number Diff line number Diff line change
Expand Up @@ -207,6 +207,41 @@ GROUP BY
flash_version, signature_id, product_versions.product_name, product_versions.product_version_id, product_versions.version_string, report_date
;

INSERT into signature_summary_device (
report_date
, signature_id
, android_device_id
, report_count
)
WITH android_info AS (
SELECT
reports_clean.signature_id as signature_id
, json_object_field_text(raw_crash, 'Android_CPU_ABI') as android_cpu_abi
, json_object_field_text(raw_crash, 'Android_Manufacturer') as android_manufacturer
, json_object_field_text(raw_crash, 'Android_Model') as android_model
, json_object_field_text(raw_crash, 'Android_Version') as android_version
FROM raw_crashes
JOIN reports_clean ON raw_crashes.uuid::text = reports_clean.uuid
WHERE
raw_crashes.date_processed::date = updateday
AND reports_clean.date_processed::date = updateday
)
SELECT
updateday as report_date
, signature_id
, android_device_id
, count(android_device_id) as report_count
FROM
android_info
JOIN android_devices ON
android_info.android_cpu_abi = android_devices.android_cpu_abi
AND android_info.android_manufacturer = android_devices.android_manufacturer
AND android_info.android_model = android_devices.android_model
AND android_info.android_version = android_devices.android_version
GROUP BY
report_date, signature_id, android_device_id
;

RETURN TRUE;

END;
Expand Down
5 changes: 3 additions & 2 deletions socorro/external/postgresql/setupdb_app.py
Original file line number Diff line number Diff line change
Expand Up @@ -11,8 +11,6 @@
import sys
from glob import glob
import os
import psycopg2
import psycopg2.extensions
from psycopg2 import ProgrammingError
import re
import logging
Expand All @@ -23,10 +21,13 @@
from sqlalchemy import exc
from alembic.config import Config
from alembic import command
from sqlalchemy import create_engine
from sqlalchemy.orm import sessionmaker

from configman import Namespace
from socorro.external.postgresql.models import *


class PostgreSQLAlchemyManager(object):
"""
Connection management for PostgreSQL using SQLAlchemy
Expand Down

0 comments on commit 16a97bc

Please sign in to comment.