blob: aa040d6661733135115b37c0e657848290fe7259 [file] [log] [blame]
Mitja Nikolaus6a679132018-08-30 14:35:29 +02001"""SQL queries for getting device statistics."""
2
Dirk Vogt0e565a72017-10-09 15:14:21 +02003from django.conf import settings
4
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +02005
Dirk Vogt62ff7f22017-05-04 16:07:21 +02006def execute_device_update_history_query(cursor, params):
Mitja Nikolaus6a679132018-08-30 14:35:29 +02007 """Query the device update history."""
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +02008 if (
9 settings.DATABASES["default"]["ENGINE"]
10 == "django.db.backends.postgresql_psycopg2"
11 ):
Dirk Vogt0e565a72017-10-09 15:14:21 +020012 return psql_execute_device_update_history_query(cursor, params)
13 else:
14 return sqlite_execute_device_update_history_query(cursor, params)
15
16
17def execute_device_report_history(cursor, params):
Mitja Nikolaus6a679132018-08-30 14:35:29 +020018 """Query the device report history."""
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +020019 if (
20 settings.DATABASES["default"]["ENGINE"]
21 == "django.db.backends.postgresql_psycopg2"
22 ):
Dirk Vogt0e565a72017-10-09 15:14:21 +020023 return psql_execute_device_report_history(cursor, params)
24 else:
25 return sqlite_execute_device_report_history(cursor, params)
26
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +020027
Dirk Vogt0e565a72017-10-09 15:14:21 +020028def sqlite_execute_device_update_history_query(cursor, params):
Mitja Nikolaus6a679132018-08-30 14:35:29 +020029 """Execute SQLite query for getting the device update history."""
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +020030 query = """
Dirk Vogta10db9d2017-05-05 09:08:45 +020031 SELECT
Dirk Vogt62ff7f22017-05-04 16:07:21 +020032 min(crashreports_heartbeat.date) as update_date,
Dirk Vogta10db9d2017-05-05 09:08:45 +020033 build_fingerprint,
34 ( select count(crashreports_crashreport.id) from crashreports_crashreport
35 where boot_reason in ("UNKNOWN", "keyboard power on")
36 and crashreports_device.id == crashreports_crashreport.device_id
37 and crashreports_crashreport.build_fingerprint == crashreports_heartbeat.build_fingerprint ) as prob_crashes,
38 ( select count(crashreports_crashreport.id) from crashreports_crashreport
39 where boot_reason in ("RTC alarm")
40 and crashreports_device.id == crashreports_crashreport.device_id
Dirk Vogt38f606c2017-12-05 15:30:27 +010041 and crashreports_crashreport.build_fingerprint == crashreports_heartbeat.build_fingerprint ) as smpl,
Dirk Vogta10db9d2017-05-05 09:08:45 +020042 ( select count(crashreports_crashreport.id) from crashreports_crashreport
43 where boot_reason not in ("UNKNOWN", "keyboard power on", "RTC alarm")
44 and crashreports_device.id == crashreports_crashreport.device_id
45 and crashreports_crashreport.build_fingerprint == crashreports_heartbeat.build_fingerprint ) as other,
46 count(crashreports_heartbeat.id) as heartbeats
47 FROM
Dirk Vogt62ff7f22017-05-04 16:07:21 +020048 crashreports_device
Dirk Vogta10db9d2017-05-05 09:08:45 +020049 JOIN
50 crashreports_heartbeat
51 ON
52 crashreports_device.id == crashreports_heartbeat.device_id
53 where
Dirk Vogt62ff7f22017-05-04 16:07:21 +020054 crashreports_device.uuid=%s
55 group by build_fingerprint;
Mitja Nikolaus21075cf2018-08-30 16:53:21 +020056 """ # noqa: E501
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +020057 uuid = params.get("uuid", "18f530d7-e9c3-4dcf-adba-3dddcd7d3155")
Dirk Vogt62ff7f22017-05-04 16:07:21 +020058 param_array = [uuid]
59 cursor.execute(query, param_array)
60
61
Dirk Vogt0e565a72017-10-09 15:14:21 +020062def psql_execute_device_update_history_query(cursor, params):
Mitja Nikolaus6a679132018-08-30 14:35:29 +020063 """Execute PostgreSQL query for getting the device update history."""
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +020064 query = """
Dirk Vogt0e565a72017-10-09 15:14:21 +020065 SELECT
66 min(crashreports_heartbeat.date) as update_date,
67 build_fingerprint,
Dirk Vogt38f606c2017-12-05 15:30:27 +010068 max(crashreports_device.id),
Dirk Vogt0e565a72017-10-09 15:14:21 +020069 ( select count(crashreports_crashreport.id) from crashreports_crashreport
70 where boot_reason in ('UNKNOWN', 'keyboard power on')
Dirk Vogt38f606c2017-12-05 15:30:27 +010071 and max(crashreports_device.id) = crashreports_crashreport.device_id
Dirk Vogt0e565a72017-10-09 15:14:21 +020072 and crashreports_crashreport.build_fingerprint = crashreports_heartbeat.build_fingerprint ) as prob_crashes,
73 ( select count(crashreports_crashreport.id) from crashreports_crashreport
74 where boot_reason in ('RTC alarm')
Dirk Vogt38f606c2017-12-05 15:30:27 +010075 and max(crashreports_device.id) = crashreports_crashreport.device_id
76 and crashreports_crashreport.build_fingerprint = crashreports_heartbeat.build_fingerprint ) as smpl,
Dirk Vogt0e565a72017-10-09 15:14:21 +020077 ( select count(crashreports_crashreport.id) from crashreports_crashreport
78 where boot_reason not in ('UNKNOWN', 'keyboard power on', 'RTC alarm')
Dirk Vogt38f606c2017-12-05 15:30:27 +010079 and max(crashreports_device.id) = crashreports_crashreport.device_id
Dirk Vogt0e565a72017-10-09 15:14:21 +020080 and crashreports_crashreport.build_fingerprint = crashreports_heartbeat.build_fingerprint ) as other,
81 count(crashreports_heartbeat.id) as heartbeats
82 FROM
83 crashreports_device
84 JOIN
85 crashreports_heartbeat
86 ON
87 crashreports_device.id = crashreports_heartbeat.device_id
88 where
89 crashreports_device.uuid=%s
90 group by build_fingerprint;
Mitja Nikolaus21075cf2018-08-30 16:53:21 +020091 """ # noqa: E501
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +020092 uuid = params.get("uuid", "18f530d7-e9c3-4dcf-adba-3dddcd7d3155")
Dirk Vogt0e565a72017-10-09 15:14:21 +020093 param_array = [uuid]
94 cursor.execute(query, param_array)
95
96
97def sqlite_execute_device_report_history(cursor, params):
Mitja Nikolaus6a679132018-08-30 14:35:29 +020098 """Execute SQLite query for getting the device report history."""
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +020099 query = """
Dirk Vogt62ff7f22017-05-04 16:07:21 +0200100 SELECT
Dirk Vogta10db9d2017-05-05 09:08:45 +0200101 strftime("%%Y-%%m-%%d",crashreports_heartbeat.date) as date,
Dirk Vogt62ff7f22017-05-04 16:07:21 +0200102 count(crashreports_heartbeat.id) as heartbeats,
103 (
Dirk Vogta10db9d2017-05-05 09:08:45 +0200104 select count(id) from crashreports_crashreport
105 where
106 boot_reason in ("RTC alarm")
Dirk Vogt62ff7f22017-05-04 16:07:21 +0200107 and strftime("%%Y-%%m-%%d",crashreports_crashreport.date) == strftime("%%Y-%%m-%%d",crashreports_heartbeat.date)
108 and crashreports_device.id == crashreports_crashreport.device_id
109 ) as smpl,
110 (
Dirk Vogta10db9d2017-05-05 09:08:45 +0200111 select count(id) from crashreports_crashreport
112 where
113 boot_reason in ("UNKNOWN", "keyboard power on")
Dirk Vogt62ff7f22017-05-04 16:07:21 +0200114 and strftime("%%Y-%%m-%%d",crashreports_crashreport.date) == strftime("%%Y-%%m-%%d",crashreports_heartbeat.date)
115 and crashreports_device.id == crashreports_crashreport.device_id
116 ) as prob_crashes,
117 (
Dirk Vogta10db9d2017-05-05 09:08:45 +0200118 select count(id) from crashreports_crashreport
119 where
120 boot_reason not in ("RTC alarm", "UNKNOWN", "keyboard power on")
Dirk Vogt62ff7f22017-05-04 16:07:21 +0200121 and strftime("%%Y-%%m-%%d",crashreports_crashreport.date) == strftime("%%Y-%%m-%%d",crashreports_heartbeat.date)
122 and crashreports_device.id == crashreports_crashreport.device_id
123 ) as other
Dirk Vogta10db9d2017-05-05 09:08:45 +0200124 from crashreports_device
125 join
126 crashreports_heartbeat on crashreports_device.id == crashreports_heartbeat.device_id
127 where
Dirk Vogt62ff7f22017-05-04 16:07:21 +0200128 crashreports_device.uuid = %s
129 group by date;
Mitja Nikolaus21075cf2018-08-30 16:53:21 +0200130 """ # noqa: E501
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +0200131 uuid = params.get("uuid", "18f530d7-e9c3-4dcf-adba-3dddcd7d3155")
Dirk Vogt62ff7f22017-05-04 16:07:21 +0200132 param_array = [uuid]
133 cursor.execute(query, param_array)
Dirk Vogt0e565a72017-10-09 15:14:21 +0200134
135
136def psql_execute_device_report_history(cursor, params):
Mitja Nikolaus6a679132018-08-30 14:35:29 +0200137 """Execute Postgresql query for getting the device report history."""
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +0200138 query = """
Dirk Vogt0e565a72017-10-09 15:14:21 +0200139 SELECT
140 crashreports_heartbeat.date::date as date,
141 count(crashreports_heartbeat.id) as heartbeats,
142 count(crashreports_crashreport.id) filter (where crashreports_crashreport.boot_reason in ('RTC alarm')) as SMPL,
143 count(crashreports_crashreport.id) filter (where crashreports_crashreport.boot_reason in ('UNKNOWN', 'keyboard power on')) as prob_crashes,
144 count(crashreports_crashreport.id) filter (where crashreports_crashreport.boot_reason not in ('RTC alarm', 'UNKNOWN', 'keyboard power on')) as other
145 from crashreports_device
146 join crashreports_heartbeat on crashreports_device.id = crashreports_heartbeat.device_id
147 left join crashreports_crashreport on crashreports_device.id = crashreports_crashreport.device_id and crashreports_heartbeat.date::date = crashreports_crashreport.date::date
148 where
Dirk Vogt1e8eb122017-12-06 10:56:37 +0100149 crashreports_device.uuid = %s group by crashreports_heartbeat.date, crashreports_device.id;
Mitja Nikolaus21075cf2018-08-30 16:53:21 +0200150 """ # noqa: E501
Mitja Nikolauscb50f2c2018-08-24 13:54:48 +0200151 uuid = params.get("uuid", "18f530d7-e9c3-4dcf-adba-3dddcd7d3155")
Dirk Vogt0e565a72017-10-09 15:14:21 +0200152 param_array = [uuid]
153 cursor.execute(query, param_array)