1# export-to-sqlite.py: export perf data to a sqlite3 database 2# Copyright (c) 2017, Intel Corporation. 3# 4# This program is free software; you can redistribute it and/or modify it 5# under the terms and conditions of the GNU General Public License, 6# version 2, as published by the Free Software Foundation. 7# 8# This program is distributed in the hope it will be useful, but WITHOUT 9# ANY WARRANTY; without even the implied warranty of MERCHANTABILITY or 10# FITNESS FOR A PARTICULAR PURPOSE. See the GNU General Public License for 11# more details. 12 13from __future__ import print_function 14 15import os 16import sys 17import struct 18import datetime 19 20# To use this script you will need to have installed package python-pyside which 21# provides LGPL-licensed Python bindings for Qt. You will also need the package 22# libqt4-sql-sqlite for Qt sqlite3 support. 23# 24# Examples of installing pyside: 25# 26# ubuntu: 27# 28# $ sudo apt-get install python-pyside.qtsql libqt4-sql-psql 29# 30# Alternately, to use Python3 and/or pyside 2, one of the following: 31# 32# $ sudo apt-get install python3-pyside.qtsql libqt4-sql-psql 33# $ sudo apt-get install python-pyside2.qtsql libqt5sql5-psql 34# $ sudo apt-get install python3-pyside2.qtsql libqt5sql5-psql 35# fedora: 36# 37# $ sudo yum install python-pyside 38# 39# Alternately, to use Python3 and/or pyside 2, one of the following: 40# $ sudo yum install python3-pyside 41# $ pip install --user PySide2 42# $ pip3 install --user PySide2 43# 44# An example of using this script with Intel PT: 45# 46# $ perf record -e intel_pt//u ls 47# $ perf script -s ~/libexec/perf-core/scripts/python/export-to-sqlite.py pt_example branches calls 48# 2017-07-31 14:26:07.326913 Creating database... 49# 2017-07-31 14:26:07.538097 Writing records... 50# 2017-07-31 14:26:09.889292 Adding indexes 51# 2017-07-31 14:26:09.958746 Done 52# 53# To browse the database, sqlite3 can be used e.g. 54# 55# $ sqlite3 pt_example 56# sqlite> .header on 57# sqlite> select * from samples_view where id < 10; 58# sqlite> .mode column 59# sqlite> select * from samples_view where id < 10; 60# sqlite> .tables 61# sqlite> .schema samples_view 62# sqlite> .quit 63# 64# An example of using the database is provided by the script 65# exported-sql-viewer.py. Refer to that script for details. 66# 67# The database structure is practically the same as created by the script 68# export-to-postgresql.py. Refer to that script for details. A notable 69# difference is the 'transaction' column of the 'samples' table which is 70# renamed 'transaction_' in sqlite because 'transaction' is a reserved word. 71 72pyside_version_1 = True 73if not "pyside-version-1" in sys.argv: 74 try: 75 from PySide2.QtSql import * 76 pyside_version_1 = False 77 except: 78 pass 79 80if pyside_version_1: 81 from PySide.QtSql import * 82 83sys.path.append(os.environ['PERF_EXEC_PATH'] + \ 84 '/scripts/python/Perf-Trace-Util/lib/Perf/Trace') 85 86# These perf imports are not used at present 87#from perf_trace_context import * 88#from Core import * 89 90perf_db_export_mode = True 91perf_db_export_calls = False 92perf_db_export_callchains = False 93 94def printerr(*args, **keyword_args): 95 print(*args, file=sys.stderr, **keyword_args) 96 97def printdate(*args, **kw_args): 98 print(datetime.datetime.today(), *args, sep=' ', **kw_args) 99 100def usage(): 101 printerr("Usage is: export-to-sqlite.py <database name> [<columns>] [<calls>] [<callchains>] [<pyside-version-1>]"); 102 printerr("where: columns 'all' or 'branches'"); 103 printerr(" calls 'calls' => create calls and call_paths table"); 104 printerr(" callchains 'callchains' => create call_paths table"); 105 printerr(" pyside-version-1 'pyside-version-1' => use pyside version 1"); 106 raise Exception("Too few or bad arguments") 107 108if (len(sys.argv) < 2): 109 usage() 110 111dbname = sys.argv[1] 112 113if (len(sys.argv) >= 3): 114 columns = sys.argv[2] 115else: 116 columns = "all" 117 118if columns not in ("all", "branches"): 119 usage() 120 121branches = (columns == "branches") 122 123for i in range(3,len(sys.argv)): 124 if (sys.argv[i] == "calls"): 125 perf_db_export_calls = True 126 elif (sys.argv[i] == "callchains"): 127 perf_db_export_callchains = True 128 elif (sys.argv[i] == "pyside-version-1"): 129 pass 130 else: 131 usage() 132 133def do_query(q, s): 134 if (q.exec_(s)): 135 return 136 raise Exception("Query failed: " + q.lastError().text()) 137 138def do_query_(q): 139 if (q.exec_()): 140 return 141 raise Exception("Query failed: " + q.lastError().text()) 142 143printdate("Creating database ...") 144 145db_exists = False 146try: 147 f = open(dbname) 148 f.close() 149 db_exists = True 150except: 151 pass 152 153if db_exists: 154 raise Exception(dbname + " already exists") 155 156db = QSqlDatabase.addDatabase('QSQLITE') 157db.setDatabaseName(dbname) 158db.open() 159 160query = QSqlQuery(db) 161 162do_query(query, 'PRAGMA journal_mode = OFF') 163do_query(query, 'BEGIN TRANSACTION') 164 165do_query(query, 'CREATE TABLE selected_events (' 166 'id integer NOT NULL PRIMARY KEY,' 167 'name varchar(80))') 168do_query(query, 'CREATE TABLE machines (' 169 'id integer NOT NULL PRIMARY KEY,' 170 'pid integer,' 171 'root_dir varchar(4096))') 172do_query(query, 'CREATE TABLE threads (' 173 'id integer NOT NULL PRIMARY KEY,' 174 'machine_id bigint,' 175 'process_id bigint,' 176 'pid integer,' 177 'tid integer)') 178do_query(query, 'CREATE TABLE comms (' 179 'id integer NOT NULL PRIMARY KEY,' 180 'comm varchar(16))') 181do_query(query, 'CREATE TABLE comm_threads (' 182 'id integer NOT NULL PRIMARY KEY,' 183 'comm_id bigint,' 184 'thread_id bigint)') 185do_query(query, 'CREATE TABLE dsos (' 186 'id integer NOT NULL PRIMARY KEY,' 187 'machine_id bigint,' 188 'short_name varchar(256),' 189 'long_name varchar(4096),' 190 'build_id varchar(64))') 191do_query(query, 'CREATE TABLE symbols (' 192 'id integer NOT NULL PRIMARY KEY,' 193 'dso_id bigint,' 194 'sym_start bigint,' 195 'sym_end bigint,' 196 'binding integer,' 197 'name varchar(2048))') 198do_query(query, 'CREATE TABLE branch_types (' 199 'id integer NOT NULL PRIMARY KEY,' 200 'name varchar(80))') 201 202if branches: 203 do_query(query, 'CREATE TABLE samples (' 204 'id integer NOT NULL PRIMARY KEY,' 205 'evsel_id bigint,' 206 'machine_id bigint,' 207 'thread_id bigint,' 208 'comm_id bigint,' 209 'dso_id bigint,' 210 'symbol_id bigint,' 211 'sym_offset bigint,' 212 'ip bigint,' 213 'time bigint,' 214 'cpu integer,' 215 'to_dso_id bigint,' 216 'to_symbol_id bigint,' 217 'to_sym_offset bigint,' 218 'to_ip bigint,' 219 'branch_type integer,' 220 'in_tx boolean,' 221 'call_path_id bigint,' 222 'insn_count bigint,' 223 'cyc_count bigint)') 224else: 225 do_query(query, 'CREATE TABLE samples (' 226 'id integer NOT NULL PRIMARY KEY,' 227 'evsel_id bigint,' 228 'machine_id bigint,' 229 'thread_id bigint,' 230 'comm_id bigint,' 231 'dso_id bigint,' 232 'symbol_id bigint,' 233 'sym_offset bigint,' 234 'ip bigint,' 235 'time bigint,' 236 'cpu integer,' 237 'to_dso_id bigint,' 238 'to_symbol_id bigint,' 239 'to_sym_offset bigint,' 240 'to_ip bigint,' 241 'period bigint,' 242 'weight bigint,' 243 'transaction_ bigint,' 244 'data_src bigint,' 245 'branch_type integer,' 246 'in_tx boolean,' 247 'call_path_id bigint,' 248 'insn_count bigint,' 249 'cyc_count bigint)') 250 251if perf_db_export_calls or perf_db_export_callchains: 252 do_query(query, 'CREATE TABLE call_paths (' 253 'id integer NOT NULL PRIMARY KEY,' 254 'parent_id bigint,' 255 'symbol_id bigint,' 256 'ip bigint)') 257if perf_db_export_calls: 258 do_query(query, 'CREATE TABLE calls (' 259 'id integer NOT NULL PRIMARY KEY,' 260 'thread_id bigint,' 261 'comm_id bigint,' 262 'call_path_id bigint,' 263 'call_time bigint,' 264 'return_time bigint,' 265 'branch_count bigint,' 266 'call_id bigint,' 267 'return_id bigint,' 268 'parent_call_path_id bigint,' 269 'flags integer,' 270 'parent_id bigint,' 271 'insn_count bigint,' 272 'cyc_count bigint)') 273 274# printf was added to sqlite in version 3.8.3 275sqlite_has_printf = False 276try: 277 do_query(query, 'SELECT printf("") FROM machines') 278 sqlite_has_printf = True 279except: 280 pass 281 282def emit_to_hex(x): 283 if sqlite_has_printf: 284 return 'printf("%x", ' + x + ')' 285 else: 286 return x 287 288do_query(query, 'CREATE VIEW machines_view AS ' 289 'SELECT ' 290 'id,' 291 'pid,' 292 'root_dir,' 293 'CASE WHEN id=0 THEN \'unknown\' WHEN pid=-1 THEN \'host\' ELSE \'guest\' END AS host_or_guest' 294 ' FROM machines') 295 296do_query(query, 'CREATE VIEW dsos_view AS ' 297 'SELECT ' 298 'id,' 299 'machine_id,' 300 '(SELECT host_or_guest FROM machines_view WHERE id = machine_id) AS host_or_guest,' 301 'short_name,' 302 'long_name,' 303 'build_id' 304 ' FROM dsos') 305 306do_query(query, 'CREATE VIEW symbols_view AS ' 307 'SELECT ' 308 'id,' 309 'name,' 310 '(SELECT short_name FROM dsos WHERE id=dso_id) AS dso,' 311 'dso_id,' 312 'sym_start,' 313 'sym_end,' 314 'CASE WHEN binding=0 THEN \'local\' WHEN binding=1 THEN \'global\' ELSE \'weak\' END AS binding' 315 ' FROM symbols') 316 317do_query(query, 'CREATE VIEW threads_view AS ' 318 'SELECT ' 319 'id,' 320 'machine_id,' 321 '(SELECT host_or_guest FROM machines_view WHERE id = machine_id) AS host_or_guest,' 322 'process_id,' 323 'pid,' 324 'tid' 325 ' FROM threads') 326 327do_query(query, 'CREATE VIEW comm_threads_view AS ' 328 'SELECT ' 329 'comm_id,' 330 '(SELECT comm FROM comms WHERE id = comm_id) AS command,' 331 'thread_id,' 332 '(SELECT pid FROM threads WHERE id = thread_id) AS pid,' 333 '(SELECT tid FROM threads WHERE id = thread_id) AS tid' 334 ' FROM comm_threads') 335 336if perf_db_export_calls or perf_db_export_callchains: 337 do_query(query, 'CREATE VIEW call_paths_view AS ' 338 'SELECT ' 339 'c.id,' 340 + emit_to_hex('c.ip') + ' AS ip,' 341 'c.symbol_id,' 342 '(SELECT name FROM symbols WHERE id = c.symbol_id) AS symbol,' 343 '(SELECT dso_id FROM symbols WHERE id = c.symbol_id) AS dso_id,' 344 '(SELECT dso FROM symbols_view WHERE id = c.symbol_id) AS dso_short_name,' 345 'c.parent_id,' 346 + emit_to_hex('p.ip') + ' AS parent_ip,' 347 'p.symbol_id AS parent_symbol_id,' 348 '(SELECT name FROM symbols WHERE id = p.symbol_id) AS parent_symbol,' 349 '(SELECT dso_id FROM symbols WHERE id = p.symbol_id) AS parent_dso_id,' 350 '(SELECT dso FROM symbols_view WHERE id = p.symbol_id) AS parent_dso_short_name' 351 ' FROM call_paths c INNER JOIN call_paths p ON p.id = c.parent_id') 352if perf_db_export_calls: 353 do_query(query, 'CREATE VIEW calls_view AS ' 354 'SELECT ' 355 'calls.id,' 356 'thread_id,' 357 '(SELECT pid FROM threads WHERE id = thread_id) AS pid,' 358 '(SELECT tid FROM threads WHERE id = thread_id) AS tid,' 359 '(SELECT comm FROM comms WHERE id = comm_id) AS command,' 360 'call_path_id,' 361 + emit_to_hex('ip') + ' AS ip,' 362 'symbol_id,' 363 '(SELECT name FROM symbols WHERE id = symbol_id) AS symbol,' 364 'call_time,' 365 'return_time,' 366 'return_time - call_time AS elapsed_time,' 367 'branch_count,' 368 'insn_count,' 369 'cyc_count,' 370 'CASE WHEN cyc_count=0 THEN CAST(0 AS FLOAT) ELSE ROUND(CAST(insn_count AS FLOAT) / cyc_count, 2) END AS IPC,' 371 'call_id,' 372 'return_id,' 373 'CASE WHEN flags=0 THEN \'\' WHEN flags=1 THEN \'no call\' WHEN flags=2 THEN \'no return\' WHEN flags=3 THEN \'no call/return\' WHEN flags=6 THEN \'jump\' ELSE flags END AS flags,' 374 'parent_call_path_id,' 375 'calls.parent_id' 376 ' FROM calls INNER JOIN call_paths ON call_paths.id = call_path_id') 377 378do_query(query, 'CREATE VIEW samples_view AS ' 379 'SELECT ' 380 'id,' 381 'time,' 382 'cpu,' 383 '(SELECT pid FROM threads WHERE id = thread_id) AS pid,' 384 '(SELECT tid FROM threads WHERE id = thread_id) AS tid,' 385 '(SELECT comm FROM comms WHERE id = comm_id) AS command,' 386 '(SELECT name FROM selected_events WHERE id = evsel_id) AS event,' 387 + emit_to_hex('ip') + ' AS ip_hex,' 388 '(SELECT name FROM symbols WHERE id = symbol_id) AS symbol,' 389 'sym_offset,' 390 '(SELECT short_name FROM dsos WHERE id = dso_id) AS dso_short_name,' 391 + emit_to_hex('to_ip') + ' AS to_ip_hex,' 392 '(SELECT name FROM symbols WHERE id = to_symbol_id) AS to_symbol,' 393 'to_sym_offset,' 394 '(SELECT short_name FROM dsos WHERE id = to_dso_id) AS to_dso_short_name,' 395 '(SELECT name FROM branch_types WHERE id = branch_type) AS branch_type_name,' 396 'in_tx,' 397 'insn_count,' 398 'cyc_count,' 399 'CASE WHEN cyc_count=0 THEN CAST(0 AS FLOAT) ELSE ROUND(CAST(insn_count AS FLOAT) / cyc_count, 2) END AS IPC' 400 ' FROM samples') 401 402do_query(query, 'END TRANSACTION') 403 404evsel_query = QSqlQuery(db) 405evsel_query.prepare("INSERT INTO selected_events VALUES (?, ?)") 406machine_query = QSqlQuery(db) 407machine_query.prepare("INSERT INTO machines VALUES (?, ?, ?)") 408thread_query = QSqlQuery(db) 409thread_query.prepare("INSERT INTO threads VALUES (?, ?, ?, ?, ?)") 410comm_query = QSqlQuery(db) 411comm_query.prepare("INSERT INTO comms VALUES (?, ?)") 412comm_thread_query = QSqlQuery(db) 413comm_thread_query.prepare("INSERT INTO comm_threads VALUES (?, ?, ?)") 414dso_query = QSqlQuery(db) 415dso_query.prepare("INSERT INTO dsos VALUES (?, ?, ?, ?, ?)") 416symbol_query = QSqlQuery(db) 417symbol_query.prepare("INSERT INTO symbols VALUES (?, ?, ?, ?, ?, ?)") 418branch_type_query = QSqlQuery(db) 419branch_type_query.prepare("INSERT INTO branch_types VALUES (?, ?)") 420sample_query = QSqlQuery(db) 421if branches: 422 sample_query.prepare("INSERT INTO samples VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)") 423else: 424 sample_query.prepare("INSERT INTO samples VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)") 425if perf_db_export_calls or perf_db_export_callchains: 426 call_path_query = QSqlQuery(db) 427 call_path_query.prepare("INSERT INTO call_paths VALUES (?, ?, ?, ?)") 428if perf_db_export_calls: 429 call_query = QSqlQuery(db) 430 call_query.prepare("INSERT INTO calls VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)") 431 432def trace_begin(): 433 printdate("Writing records...") 434 do_query(query, 'BEGIN TRANSACTION') 435 # id == 0 means unknown. It is easier to create records for them than replace the zeroes with NULLs 436 evsel_table(0, "unknown") 437 machine_table(0, 0, "unknown") 438 thread_table(0, 0, 0, -1, -1) 439 comm_table(0, "unknown") 440 dso_table(0, 0, "unknown", "unknown", "") 441 symbol_table(0, 0, 0, 0, 0, "unknown") 442 sample_table(0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0) 443 if perf_db_export_calls or perf_db_export_callchains: 444 call_path_table(0, 0, 0, 0) 445 call_return_table(0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0) 446 447unhandled_count = 0 448 449def trace_end(): 450 do_query(query, 'END TRANSACTION') 451 452 printdate("Adding indexes") 453 if perf_db_export_calls: 454 do_query(query, 'CREATE INDEX pcpid_idx ON calls (parent_call_path_id)') 455 do_query(query, 'CREATE INDEX pid_idx ON calls (parent_id)') 456 457 if (unhandled_count): 458 printdate("Warning: ", unhandled_count, " unhandled events") 459 printdate("Done") 460 461def trace_unhandled(event_name, context, event_fields_dict): 462 global unhandled_count 463 unhandled_count += 1 464 465def sched__sched_switch(*x): 466 pass 467 468def bind_exec(q, n, x): 469 for xx in x[0:n]: 470 q.addBindValue(str(xx)) 471 do_query_(q) 472 473def evsel_table(*x): 474 bind_exec(evsel_query, 2, x) 475 476def machine_table(*x): 477 bind_exec(machine_query, 3, x) 478 479def thread_table(*x): 480 bind_exec(thread_query, 5, x) 481 482def comm_table(*x): 483 bind_exec(comm_query, 2, x) 484 485def comm_thread_table(*x): 486 bind_exec(comm_thread_query, 3, x) 487 488def dso_table(*x): 489 bind_exec(dso_query, 5, x) 490 491def symbol_table(*x): 492 bind_exec(symbol_query, 6, x) 493 494def branch_type_table(*x): 495 bind_exec(branch_type_query, 2, x) 496 497def sample_table(*x): 498 if branches: 499 for xx in x[0:15]: 500 sample_query.addBindValue(str(xx)) 501 for xx in x[19:24]: 502 sample_query.addBindValue(str(xx)) 503 do_query_(sample_query) 504 else: 505 bind_exec(sample_query, 24, x) 506 507def call_path_table(*x): 508 bind_exec(call_path_query, 4, x) 509 510def call_return_table(*x): 511 bind_exec(call_query, 14, x) 512