1# export-to-postgresql.py: export perf data to a postgresql database 2# Copyright (c) 2014, 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-psql for Qt postgresql support. 23# 24# The script assumes postgresql is running on the local machine and that the 25# user has postgresql permissions to create databases. Examples of installing 26# postgresql and adding such a user are: 27# 28# fedora: 29# 30# $ sudo yum install postgresql postgresql-server qt-postgresql 31# $ sudo su - postgres -c initdb 32# $ sudo service postgresql start 33# $ sudo su - postgres 34# $ createuser -s <your user id here> # Older versions may not support -s, in which case answer the prompt below: 35# Shall the new role be a superuser? (y/n) y 36# $ sudo yum install python-pyside 37# 38# Alternately, to use Python3 and/or pyside 2, one of the following: 39# $ sudo yum install python3-pyside 40# $ pip install --user PySide2 41# $ pip3 install --user PySide2 42# 43# ubuntu: 44# 45# $ sudo apt-get install postgresql 46# $ sudo su - postgres 47# $ createuser -s <your user id here> 48# $ sudo apt-get install python-pyside.qtsql libqt4-sql-psql 49# 50# Alternately, to use Python3 and/or pyside 2, one of the following: 51# 52# $ sudo apt-get install python3-pyside.qtsql libqt4-sql-psql 53# $ sudo apt-get install python-pyside2.qtsql libqt5sql5-psql 54# $ sudo apt-get install python3-pyside2.qtsql libqt5sql5-psql 55# 56# An example of using this script with Intel PT: 57# 58# $ perf record -e intel_pt//u ls 59# $ perf script -s ~/libexec/perf-core/scripts/python/export-to-postgresql.py pt_example branches calls 60# 2015-05-29 12:49:23.464364 Creating database... 61# 2015-05-29 12:49:26.281717 Writing to intermediate files... 62# 2015-05-29 12:49:27.190383 Copying to database... 63# 2015-05-29 12:49:28.140451 Removing intermediate files... 64# 2015-05-29 12:49:28.147451 Adding primary keys 65# 2015-05-29 12:49:28.655683 Adding foreign keys 66# 2015-05-29 12:49:29.365350 Done 67# 68# To browse the database, psql can be used e.g. 69# 70# $ psql pt_example 71# pt_example=# select * from samples_view where id < 100; 72# pt_example=# \d+ 73# pt_example=# \d+ samples_view 74# pt_example=# \q 75# 76# An example of using the database is provided by the script 77# exported-sql-viewer.py. Refer to that script for details. 78# 79# Tables: 80# 81# The tables largely correspond to perf tools' data structures. They are largely self-explanatory. 82# 83# samples 84# 85# 'samples' is the main table. It represents what instruction was executing at a point in time 86# when something (a selected event) happened. The memory address is the instruction pointer or 'ip'. 87# 88# calls 89# 90# 'calls' represents function calls and is related to 'samples' by 'call_id' and 'return_id'. 91# 'calls' is only created when the 'calls' option to this script is specified. 92# 93# call_paths 94# 95# 'call_paths' represents all the call stacks. Each 'call' has an associated record in 'call_paths'. 96# 'calls_paths' is only created when the 'calls' option to this script is specified. 97# 98# branch_types 99# 100# 'branch_types' provides descriptions for each type of branch. 101# 102# comm_threads 103# 104# 'comm_threads' shows how 'comms' relates to 'threads'. 105# 106# comms 107# 108# 'comms' contains a record for each 'comm' - the name given to the executable that is running. 109# 110# dsos 111# 112# 'dsos' contains a record for each executable file or library. 113# 114# machines 115# 116# 'machines' can be used to distinguish virtual machines if virtualization is supported. 117# 118# selected_events 119# 120# 'selected_events' contains a record for each kind of event that has been sampled. 121# 122# symbols 123# 124# 'symbols' contains a record for each symbol. Only symbols that have samples are present. 125# 126# threads 127# 128# 'threads' contains a record for each thread. 129# 130# Views: 131# 132# Most of the tables have views for more friendly display. The views are: 133# 134# calls_view 135# call_paths_view 136# comm_threads_view 137# dsos_view 138# machines_view 139# samples_view 140# symbols_view 141# threads_view 142# 143# More examples of browsing the database with psql: 144# Note that some of the examples are not the most optimal SQL query. 145# Note that call information is only available if the script's 'calls' option has been used. 146# 147# Top 10 function calls (not aggregated by symbol): 148# 149# SELECT * FROM calls_view ORDER BY elapsed_time DESC LIMIT 10; 150# 151# Top 10 function calls (aggregated by symbol): 152# 153# SELECT symbol_id,(SELECT name FROM symbols WHERE id = symbol_id) AS symbol, 154# SUM(elapsed_time) AS tot_elapsed_time,SUM(branch_count) AS tot_branch_count 155# FROM calls_view GROUP BY symbol_id ORDER BY tot_elapsed_time DESC LIMIT 10; 156# 157# Note that the branch count gives a rough estimation of cpu usage, so functions 158# that took a long time but have a relatively low branch count must have spent time 159# waiting. 160# 161# Find symbols by pattern matching on part of the name (e.g. names containing 'alloc'): 162# 163# SELECT * FROM symbols_view WHERE name LIKE '%alloc%'; 164# 165# Top 10 function calls for a specific symbol (e.g. whose symbol_id is 187): 166# 167# SELECT * FROM calls_view WHERE symbol_id = 187 ORDER BY elapsed_time DESC LIMIT 10; 168# 169# Show function calls made by function in the same context (i.e. same call path) (e.g. one with call_path_id 254): 170# 171# SELECT * FROM calls_view WHERE parent_call_path_id = 254; 172# 173# Show branches made during a function call (e.g. where call_id is 29357 and return_id is 29370 and tid is 29670) 174# 175# SELECT * FROM samples_view WHERE id >= 29357 AND id <= 29370 AND tid = 29670 AND event LIKE 'branches%'; 176# 177# Show transactions: 178# 179# SELECT * FROM samples_view WHERE event = 'transactions'; 180# 181# Note transaction start has 'in_tx' true whereas, transaction end has 'in_tx' false. 182# Transaction aborts have branch_type_name 'transaction abort' 183# 184# Show transaction aborts: 185# 186# SELECT * FROM samples_view WHERE event = 'transactions' AND branch_type_name = 'transaction abort'; 187# 188# To print a call stack requires walking the call_paths table. For example this python script: 189# #!/usr/bin/python2 190# 191# import sys 192# from PySide.QtSql import * 193# 194# if __name__ == '__main__': 195# if (len(sys.argv) < 3): 196# print >> sys.stderr, "Usage is: printcallstack.py <database name> <call_path_id>" 197# raise Exception("Too few arguments") 198# dbname = sys.argv[1] 199# call_path_id = sys.argv[2] 200# db = QSqlDatabase.addDatabase('QPSQL') 201# db.setDatabaseName(dbname) 202# if not db.open(): 203# raise Exception("Failed to open database " + dbname + " error: " + db.lastError().text()) 204# query = QSqlQuery(db) 205# print " id ip symbol_id symbol dso_id dso_short_name" 206# while call_path_id != 0 and call_path_id != 1: 207# ret = query.exec_('SELECT * FROM call_paths_view WHERE id = ' + str(call_path_id)) 208# if not ret: 209# raise Exception("Query failed: " + query.lastError().text()) 210# if not query.next(): 211# raise Exception("Query failed") 212# print "{0:>6} {1:>10} {2:>9} {3:<30} {4:>6} {5:<30}".format(query.value(0), query.value(1), query.value(2), query.value(3), query.value(4), query.value(5)) 213# call_path_id = query.value(6) 214 215pyside_version_1 = True 216if not "pyside-version-1" in sys.argv: 217 try: 218 from PySide2.QtSql import * 219 pyside_version_1 = False 220 except: 221 pass 222 223if pyside_version_1: 224 from PySide.QtSql import * 225 226if sys.version_info < (3, 0): 227 def toserverstr(str): 228 return str 229 def toclientstr(str): 230 return str 231else: 232 # Assume UTF-8 server_encoding and client_encoding 233 def toserverstr(str): 234 return bytes(str, "UTF_8") 235 def toclientstr(str): 236 return bytes(str, "UTF_8") 237 238# Need to access PostgreSQL C library directly to use COPY FROM STDIN 239from ctypes import * 240libpq = CDLL("libpq.so.5") 241PQconnectdb = libpq.PQconnectdb 242PQconnectdb.restype = c_void_p 243PQconnectdb.argtypes = [ c_char_p ] 244PQfinish = libpq.PQfinish 245PQfinish.argtypes = [ c_void_p ] 246PQstatus = libpq.PQstatus 247PQstatus.restype = c_int 248PQstatus.argtypes = [ c_void_p ] 249PQexec = libpq.PQexec 250PQexec.restype = c_void_p 251PQexec.argtypes = [ c_void_p, c_char_p ] 252PQresultStatus = libpq.PQresultStatus 253PQresultStatus.restype = c_int 254PQresultStatus.argtypes = [ c_void_p ] 255PQputCopyData = libpq.PQputCopyData 256PQputCopyData.restype = c_int 257PQputCopyData.argtypes = [ c_void_p, c_void_p, c_int ] 258PQputCopyEnd = libpq.PQputCopyEnd 259PQputCopyEnd.restype = c_int 260PQputCopyEnd.argtypes = [ c_void_p, c_void_p ] 261 262sys.path.append(os.environ['PERF_EXEC_PATH'] + \ 263 '/scripts/python/Perf-Trace-Util/lib/Perf/Trace') 264 265# These perf imports are not used at present 266#from perf_trace_context import * 267#from Core import * 268 269perf_db_export_mode = True 270perf_db_export_calls = False 271perf_db_export_callchains = False 272 273def printerr(*args, **kw_args): 274 print(*args, file=sys.stderr, **kw_args) 275 276def printdate(*args, **kw_args): 277 print(datetime.datetime.today(), *args, sep=' ', **kw_args) 278 279def usage(): 280 printerr("Usage is: export-to-postgresql.py <database name> [<columns>] [<calls>] [<callchains>] [<pyside-version-1>]"); 281 printerr("where: columns 'all' or 'branches'"); 282 printerr(" calls 'calls' => create calls and call_paths table"); 283 printerr(" callchains 'callchains' => create call_paths table"); 284 printerr(" pyside-version-1 'pyside-version-1' => use pyside version 1"); 285 raise Exception("Too few or bad arguments") 286 287if (len(sys.argv) < 2): 288 usage() 289 290dbname = sys.argv[1] 291 292if (len(sys.argv) >= 3): 293 columns = sys.argv[2] 294else: 295 columns = "all" 296 297if columns not in ("all", "branches"): 298 usage() 299 300branches = (columns == "branches") 301 302for i in range(3,len(sys.argv)): 303 if (sys.argv[i] == "calls"): 304 perf_db_export_calls = True 305 elif (sys.argv[i] == "callchains"): 306 perf_db_export_callchains = True 307 elif (sys.argv[i] == "pyside-version-1"): 308 pass 309 else: 310 usage() 311 312output_dir_name = os.getcwd() + "/" + dbname + "-perf-data" 313os.mkdir(output_dir_name) 314 315def do_query(q, s): 316 if (q.exec_(s)): 317 return 318 raise Exception("Query failed: " + q.lastError().text()) 319 320printdate("Creating database...") 321 322db = QSqlDatabase.addDatabase('QPSQL') 323query = QSqlQuery(db) 324db.setDatabaseName('postgres') 325db.open() 326try: 327 do_query(query, 'CREATE DATABASE ' + dbname) 328except: 329 os.rmdir(output_dir_name) 330 raise 331query.finish() 332query.clear() 333db.close() 334 335db.setDatabaseName(dbname) 336db.open() 337 338query = QSqlQuery(db) 339do_query(query, 'SET client_min_messages TO WARNING') 340 341do_query(query, 'CREATE TABLE selected_events (' 342 'id bigint NOT NULL,' 343 'name varchar(80))') 344do_query(query, 'CREATE TABLE machines (' 345 'id bigint NOT NULL,' 346 'pid integer,' 347 'root_dir varchar(4096))') 348do_query(query, 'CREATE TABLE threads (' 349 'id bigint NOT NULL,' 350 'machine_id bigint,' 351 'process_id bigint,' 352 'pid integer,' 353 'tid integer)') 354do_query(query, 'CREATE TABLE comms (' 355 'id bigint NOT NULL,' 356 'comm varchar(16),' 357 'c_thread_id bigint,' 358 'c_time bigint,' 359 'exec_flag boolean)') 360do_query(query, 'CREATE TABLE comm_threads (' 361 'id bigint NOT NULL,' 362 'comm_id bigint,' 363 'thread_id bigint)') 364do_query(query, 'CREATE TABLE dsos (' 365 'id bigint NOT NULL,' 366 'machine_id bigint,' 367 'short_name varchar(256),' 368 'long_name varchar(4096),' 369 'build_id varchar(64))') 370do_query(query, 'CREATE TABLE symbols (' 371 'id bigint NOT NULL,' 372 'dso_id bigint,' 373 'sym_start bigint,' 374 'sym_end bigint,' 375 'binding integer,' 376 'name varchar(2048))') 377do_query(query, 'CREATE TABLE branch_types (' 378 'id integer NOT NULL,' 379 'name varchar(80))') 380 381if branches: 382 do_query(query, 'CREATE TABLE samples (' 383 'id bigint NOT NULL,' 384 'evsel_id bigint,' 385 'machine_id bigint,' 386 'thread_id bigint,' 387 'comm_id bigint,' 388 'dso_id bigint,' 389 'symbol_id bigint,' 390 'sym_offset bigint,' 391 'ip bigint,' 392 'time bigint,' 393 'cpu integer,' 394 'to_dso_id bigint,' 395 'to_symbol_id bigint,' 396 'to_sym_offset bigint,' 397 'to_ip bigint,' 398 'branch_type integer,' 399 'in_tx boolean,' 400 'call_path_id bigint,' 401 'insn_count bigint,' 402 'cyc_count bigint)') 403else: 404 do_query(query, 'CREATE TABLE samples (' 405 'id bigint NOT NULL,' 406 'evsel_id bigint,' 407 'machine_id bigint,' 408 'thread_id bigint,' 409 'comm_id bigint,' 410 'dso_id bigint,' 411 'symbol_id bigint,' 412 'sym_offset bigint,' 413 'ip bigint,' 414 'time bigint,' 415 'cpu integer,' 416 'to_dso_id bigint,' 417 'to_symbol_id bigint,' 418 'to_sym_offset bigint,' 419 'to_ip bigint,' 420 'period bigint,' 421 'weight bigint,' 422 'transaction bigint,' 423 'data_src bigint,' 424 'branch_type integer,' 425 'in_tx boolean,' 426 'call_path_id bigint,' 427 'insn_count bigint,' 428 'cyc_count bigint)') 429 430if perf_db_export_calls or perf_db_export_callchains: 431 do_query(query, 'CREATE TABLE call_paths (' 432 'id bigint NOT NULL,' 433 'parent_id bigint,' 434 'symbol_id bigint,' 435 'ip bigint)') 436if perf_db_export_calls: 437 do_query(query, 'CREATE TABLE calls (' 438 'id bigint NOT NULL,' 439 'thread_id bigint,' 440 'comm_id bigint,' 441 'call_path_id bigint,' 442 'call_time bigint,' 443 'return_time bigint,' 444 'branch_count bigint,' 445 'call_id bigint,' 446 'return_id bigint,' 447 'parent_call_path_id bigint,' 448 'flags integer,' 449 'parent_id bigint,' 450 'insn_count bigint,' 451 'cyc_count bigint)') 452 453do_query(query, 'CREATE TABLE ptwrite (' 454 'id bigint NOT NULL,' 455 'payload bigint,' 456 'exact_ip boolean)') 457 458do_query(query, 'CREATE TABLE cbr (' 459 'id bigint NOT NULL,' 460 'cbr integer,' 461 'mhz integer,' 462 'percent integer)') 463 464do_query(query, 'CREATE TABLE mwait (' 465 'id bigint NOT NULL,' 466 'hints integer,' 467 'extensions integer)') 468 469do_query(query, 'CREATE TABLE pwre (' 470 'id bigint NOT NULL,' 471 'cstate integer,' 472 'subcstate integer,' 473 'hw boolean)') 474 475do_query(query, 'CREATE TABLE exstop (' 476 'id bigint NOT NULL,' 477 'exact_ip boolean)') 478 479do_query(query, 'CREATE TABLE pwrx (' 480 'id bigint NOT NULL,' 481 'deepest_cstate integer,' 482 'last_cstate integer,' 483 'wake_reason integer)') 484 485do_query(query, 'CREATE VIEW machines_view AS ' 486 'SELECT ' 487 'id,' 488 'pid,' 489 'root_dir,' 490 'CASE WHEN id=0 THEN \'unknown\' WHEN pid=-1 THEN \'host\' ELSE \'guest\' END AS host_or_guest' 491 ' FROM machines') 492 493do_query(query, 'CREATE VIEW dsos_view AS ' 494 'SELECT ' 495 'id,' 496 'machine_id,' 497 '(SELECT host_or_guest FROM machines_view WHERE id = machine_id) AS host_or_guest,' 498 'short_name,' 499 'long_name,' 500 'build_id' 501 ' FROM dsos') 502 503do_query(query, 'CREATE VIEW symbols_view AS ' 504 'SELECT ' 505 'id,' 506 'name,' 507 '(SELECT short_name FROM dsos WHERE id=dso_id) AS dso,' 508 'dso_id,' 509 'sym_start,' 510 'sym_end,' 511 'CASE WHEN binding=0 THEN \'local\' WHEN binding=1 THEN \'global\' ELSE \'weak\' END AS binding' 512 ' FROM symbols') 513 514do_query(query, 'CREATE VIEW threads_view AS ' 515 'SELECT ' 516 'id,' 517 'machine_id,' 518 '(SELECT host_or_guest FROM machines_view WHERE id = machine_id) AS host_or_guest,' 519 'process_id,' 520 'pid,' 521 'tid' 522 ' FROM threads') 523 524do_query(query, 'CREATE VIEW comm_threads_view AS ' 525 'SELECT ' 526 'comm_id,' 527 '(SELECT comm FROM comms WHERE id = comm_id) AS command,' 528 'thread_id,' 529 '(SELECT pid FROM threads WHERE id = thread_id) AS pid,' 530 '(SELECT tid FROM threads WHERE id = thread_id) AS tid' 531 ' FROM comm_threads') 532 533if perf_db_export_calls or perf_db_export_callchains: 534 do_query(query, 'CREATE VIEW call_paths_view AS ' 535 'SELECT ' 536 'c.id,' 537 'to_hex(c.ip) AS ip,' 538 'c.symbol_id,' 539 '(SELECT name FROM symbols WHERE id = c.symbol_id) AS symbol,' 540 '(SELECT dso_id FROM symbols WHERE id = c.symbol_id) AS dso_id,' 541 '(SELECT dso FROM symbols_view WHERE id = c.symbol_id) AS dso_short_name,' 542 'c.parent_id,' 543 'to_hex(p.ip) AS parent_ip,' 544 'p.symbol_id AS parent_symbol_id,' 545 '(SELECT name FROM symbols WHERE id = p.symbol_id) AS parent_symbol,' 546 '(SELECT dso_id FROM symbols WHERE id = p.symbol_id) AS parent_dso_id,' 547 '(SELECT dso FROM symbols_view WHERE id = p.symbol_id) AS parent_dso_short_name' 548 ' FROM call_paths c INNER JOIN call_paths p ON p.id = c.parent_id') 549if perf_db_export_calls: 550 do_query(query, 'CREATE VIEW calls_view AS ' 551 'SELECT ' 552 'calls.id,' 553 'thread_id,' 554 '(SELECT pid FROM threads WHERE id = thread_id) AS pid,' 555 '(SELECT tid FROM threads WHERE id = thread_id) AS tid,' 556 '(SELECT comm FROM comms WHERE id = comm_id) AS command,' 557 'call_path_id,' 558 'to_hex(ip) AS ip,' 559 'symbol_id,' 560 '(SELECT name FROM symbols WHERE id = symbol_id) AS symbol,' 561 'call_time,' 562 'return_time,' 563 'return_time - call_time AS elapsed_time,' 564 'branch_count,' 565 'insn_count,' 566 'cyc_count,' 567 'CASE WHEN cyc_count=0 THEN CAST(0 AS NUMERIC(20, 2)) ELSE CAST((CAST(insn_count AS FLOAT) / cyc_count) AS NUMERIC(20, 2)) END AS IPC,' 568 'call_id,' 569 'return_id,' 570 '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 CAST ( flags AS VARCHAR(6) ) END AS flags,' 571 'parent_call_path_id,' 572 'calls.parent_id' 573 ' FROM calls INNER JOIN call_paths ON call_paths.id = call_path_id') 574 575do_query(query, 'CREATE VIEW samples_view AS ' 576 'SELECT ' 577 'id,' 578 'time,' 579 'cpu,' 580 '(SELECT pid FROM threads WHERE id = thread_id) AS pid,' 581 '(SELECT tid FROM threads WHERE id = thread_id) AS tid,' 582 '(SELECT comm FROM comms WHERE id = comm_id) AS command,' 583 '(SELECT name FROM selected_events WHERE id = evsel_id) AS event,' 584 'to_hex(ip) AS ip_hex,' 585 '(SELECT name FROM symbols WHERE id = symbol_id) AS symbol,' 586 'sym_offset,' 587 '(SELECT short_name FROM dsos WHERE id = dso_id) AS dso_short_name,' 588 'to_hex(to_ip) AS to_ip_hex,' 589 '(SELECT name FROM symbols WHERE id = to_symbol_id) AS to_symbol,' 590 'to_sym_offset,' 591 '(SELECT short_name FROM dsos WHERE id = to_dso_id) AS to_dso_short_name,' 592 '(SELECT name FROM branch_types WHERE id = branch_type) AS branch_type_name,' 593 'in_tx,' 594 'insn_count,' 595 'cyc_count,' 596 'CASE WHEN cyc_count=0 THEN CAST(0 AS NUMERIC(20, 2)) ELSE CAST((CAST(insn_count AS FLOAT) / cyc_count) AS NUMERIC(20, 2)) END AS IPC' 597 ' FROM samples') 598 599do_query(query, 'CREATE VIEW ptwrite_view AS ' 600 'SELECT ' 601 'ptwrite.id,' 602 'time,' 603 'cpu,' 604 'to_hex(payload) AS payload_hex,' 605 'CASE WHEN exact_ip=FALSE THEN \'False\' ELSE \'True\' END AS exact_ip' 606 ' FROM ptwrite' 607 ' INNER JOIN samples ON samples.id = ptwrite.id') 608 609do_query(query, 'CREATE VIEW cbr_view AS ' 610 'SELECT ' 611 'cbr.id,' 612 'time,' 613 'cpu,' 614 'cbr,' 615 'mhz,' 616 'percent' 617 ' FROM cbr' 618 ' INNER JOIN samples ON samples.id = cbr.id') 619 620do_query(query, 'CREATE VIEW mwait_view AS ' 621 'SELECT ' 622 'mwait.id,' 623 'time,' 624 'cpu,' 625 'to_hex(hints) AS hints_hex,' 626 'to_hex(extensions) AS extensions_hex' 627 ' FROM mwait' 628 ' INNER JOIN samples ON samples.id = mwait.id') 629 630do_query(query, 'CREATE VIEW pwre_view AS ' 631 'SELECT ' 632 'pwre.id,' 633 'time,' 634 'cpu,' 635 'cstate,' 636 'subcstate,' 637 'CASE WHEN hw=FALSE THEN \'False\' ELSE \'True\' END AS hw' 638 ' FROM pwre' 639 ' INNER JOIN samples ON samples.id = pwre.id') 640 641do_query(query, 'CREATE VIEW exstop_view AS ' 642 'SELECT ' 643 'exstop.id,' 644 'time,' 645 'cpu,' 646 'CASE WHEN exact_ip=FALSE THEN \'False\' ELSE \'True\' END AS exact_ip' 647 ' FROM exstop' 648 ' INNER JOIN samples ON samples.id = exstop.id') 649 650do_query(query, 'CREATE VIEW pwrx_view AS ' 651 'SELECT ' 652 'pwrx.id,' 653 'time,' 654 'cpu,' 655 'deepest_cstate,' 656 'last_cstate,' 657 'CASE WHEN wake_reason=1 THEN \'Interrupt\'' 658 ' WHEN wake_reason=2 THEN \'Timer Deadline\'' 659 ' WHEN wake_reason=4 THEN \'Monitored Address\'' 660 ' WHEN wake_reason=8 THEN \'HW\'' 661 ' ELSE CAST ( wake_reason AS VARCHAR(2) )' 662 'END AS wake_reason' 663 ' FROM pwrx' 664 ' INNER JOIN samples ON samples.id = pwrx.id') 665 666do_query(query, 'CREATE VIEW power_events_view AS ' 667 'SELECT ' 668 'samples.id,' 669 'samples.time,' 670 'samples.cpu,' 671 'selected_events.name AS event,' 672 'FORMAT(\'%6s\', cbr.cbr) AS cbr,' 673 'FORMAT(\'%6s\', cbr.mhz) AS MHz,' 674 'FORMAT(\'%5s\', cbr.percent) AS percent,' 675 'to_hex(mwait.hints) AS hints_hex,' 676 'to_hex(mwait.extensions) AS extensions_hex,' 677 'FORMAT(\'%3s\', pwre.cstate) AS cstate,' 678 'FORMAT(\'%3s\', pwre.subcstate) AS subcstate,' 679 'CASE WHEN pwre.hw=FALSE THEN \'False\' WHEN pwre.hw=TRUE THEN \'True\' ELSE NULL END AS hw,' 680 'CASE WHEN exstop.exact_ip=FALSE THEN \'False\' WHEN exstop.exact_ip=TRUE THEN \'True\' ELSE NULL END AS exact_ip,' 681 'FORMAT(\'%3s\', pwrx.deepest_cstate) AS deepest_cstate,' 682 'FORMAT(\'%3s\', pwrx.last_cstate) AS last_cstate,' 683 'CASE WHEN pwrx.wake_reason=1 THEN \'Interrupt\'' 684 ' WHEN pwrx.wake_reason=2 THEN \'Timer Deadline\'' 685 ' WHEN pwrx.wake_reason=4 THEN \'Monitored Address\'' 686 ' WHEN pwrx.wake_reason=8 THEN \'HW\'' 687 ' ELSE FORMAT(\'%2s\', pwrx.wake_reason)' 688 'END AS wake_reason' 689 ' FROM cbr' 690 ' FULL JOIN mwait ON mwait.id = cbr.id' 691 ' FULL JOIN pwre ON pwre.id = cbr.id' 692 ' FULL JOIN exstop ON exstop.id = cbr.id' 693 ' FULL JOIN pwrx ON pwrx.id = cbr.id' 694 ' INNER JOIN samples ON samples.id = coalesce(cbr.id, mwait.id, pwre.id, exstop.id, pwrx.id)' 695 ' INNER JOIN selected_events ON selected_events.id = samples.evsel_id' 696 ' ORDER BY samples.id') 697 698file_header = struct.pack("!11sii", b"PGCOPY\n\377\r\n\0", 0, 0) 699file_trailer = b"\377\377" 700 701def open_output_file(file_name): 702 path_name = output_dir_name + "/" + file_name 703 file = open(path_name, "wb+") 704 file.write(file_header) 705 return file 706 707def close_output_file(file): 708 file.write(file_trailer) 709 file.close() 710 711def copy_output_file_direct(file, table_name): 712 close_output_file(file) 713 sql = "COPY " + table_name + " FROM '" + file.name + "' (FORMAT 'binary')" 714 do_query(query, sql) 715 716# Use COPY FROM STDIN because security may prevent postgres from accessing the files directly 717def copy_output_file(file, table_name): 718 conn = PQconnectdb(toclientstr("dbname = " + dbname)) 719 if (PQstatus(conn)): 720 raise Exception("COPY FROM STDIN PQconnectdb failed") 721 file.write(file_trailer) 722 file.seek(0) 723 sql = "COPY " + table_name + " FROM STDIN (FORMAT 'binary')" 724 res = PQexec(conn, toclientstr(sql)) 725 if (PQresultStatus(res) != 4): 726 raise Exception("COPY FROM STDIN PQexec failed") 727 data = file.read(65536) 728 while (len(data)): 729 ret = PQputCopyData(conn, data, len(data)) 730 if (ret != 1): 731 raise Exception("COPY FROM STDIN PQputCopyData failed, error " + str(ret)) 732 data = file.read(65536) 733 ret = PQputCopyEnd(conn, None) 734 if (ret != 1): 735 raise Exception("COPY FROM STDIN PQputCopyEnd failed, error " + str(ret)) 736 PQfinish(conn) 737 738def remove_output_file(file): 739 name = file.name 740 file.close() 741 os.unlink(name) 742 743evsel_file = open_output_file("evsel_table.bin") 744machine_file = open_output_file("machine_table.bin") 745thread_file = open_output_file("thread_table.bin") 746comm_file = open_output_file("comm_table.bin") 747comm_thread_file = open_output_file("comm_thread_table.bin") 748dso_file = open_output_file("dso_table.bin") 749symbol_file = open_output_file("symbol_table.bin") 750branch_type_file = open_output_file("branch_type_table.bin") 751sample_file = open_output_file("sample_table.bin") 752if perf_db_export_calls or perf_db_export_callchains: 753 call_path_file = open_output_file("call_path_table.bin") 754if perf_db_export_calls: 755 call_file = open_output_file("call_table.bin") 756ptwrite_file = open_output_file("ptwrite_table.bin") 757cbr_file = open_output_file("cbr_table.bin") 758mwait_file = open_output_file("mwait_table.bin") 759pwre_file = open_output_file("pwre_table.bin") 760exstop_file = open_output_file("exstop_table.bin") 761pwrx_file = open_output_file("pwrx_table.bin") 762 763def trace_begin(): 764 printdate("Writing to intermediate files...") 765 # id == 0 means unknown. It is easier to create records for them than replace the zeroes with NULLs 766 evsel_table(0, "unknown") 767 machine_table(0, 0, "unknown") 768 thread_table(0, 0, 0, -1, -1) 769 comm_table(0, "unknown", 0, 0, 0) 770 dso_table(0, 0, "unknown", "unknown", "") 771 symbol_table(0, 0, 0, 0, 0, "unknown") 772 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) 773 if perf_db_export_calls or perf_db_export_callchains: 774 call_path_table(0, 0, 0, 0) 775 call_return_table(0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0) 776 777unhandled_count = 0 778 779def is_table_empty(table_name): 780 do_query(query, 'SELECT * FROM ' + table_name + ' LIMIT 1'); 781 if query.next(): 782 return False 783 return True 784 785def drop(table_name): 786 do_query(query, 'DROP VIEW ' + table_name + '_view'); 787 do_query(query, 'DROP TABLE ' + table_name); 788 789def trace_end(): 790 printdate("Copying to database...") 791 copy_output_file(evsel_file, "selected_events") 792 copy_output_file(machine_file, "machines") 793 copy_output_file(thread_file, "threads") 794 copy_output_file(comm_file, "comms") 795 copy_output_file(comm_thread_file, "comm_threads") 796 copy_output_file(dso_file, "dsos") 797 copy_output_file(symbol_file, "symbols") 798 copy_output_file(branch_type_file, "branch_types") 799 copy_output_file(sample_file, "samples") 800 if perf_db_export_calls or perf_db_export_callchains: 801 copy_output_file(call_path_file, "call_paths") 802 if perf_db_export_calls: 803 copy_output_file(call_file, "calls") 804 copy_output_file(ptwrite_file, "ptwrite") 805 copy_output_file(cbr_file, "cbr") 806 copy_output_file(mwait_file, "mwait") 807 copy_output_file(pwre_file, "pwre") 808 copy_output_file(exstop_file, "exstop") 809 copy_output_file(pwrx_file, "pwrx") 810 811 printdate("Removing intermediate files...") 812 remove_output_file(evsel_file) 813 remove_output_file(machine_file) 814 remove_output_file(thread_file) 815 remove_output_file(comm_file) 816 remove_output_file(comm_thread_file) 817 remove_output_file(dso_file) 818 remove_output_file(symbol_file) 819 remove_output_file(branch_type_file) 820 remove_output_file(sample_file) 821 if perf_db_export_calls or perf_db_export_callchains: 822 remove_output_file(call_path_file) 823 if perf_db_export_calls: 824 remove_output_file(call_file) 825 remove_output_file(ptwrite_file) 826 remove_output_file(cbr_file) 827 remove_output_file(mwait_file) 828 remove_output_file(pwre_file) 829 remove_output_file(exstop_file) 830 remove_output_file(pwrx_file) 831 os.rmdir(output_dir_name) 832 printdate("Adding primary keys") 833 do_query(query, 'ALTER TABLE selected_events ADD PRIMARY KEY (id)') 834 do_query(query, 'ALTER TABLE machines ADD PRIMARY KEY (id)') 835 do_query(query, 'ALTER TABLE threads ADD PRIMARY KEY (id)') 836 do_query(query, 'ALTER TABLE comms ADD PRIMARY KEY (id)') 837 do_query(query, 'ALTER TABLE comm_threads ADD PRIMARY KEY (id)') 838 do_query(query, 'ALTER TABLE dsos ADD PRIMARY KEY (id)') 839 do_query(query, 'ALTER TABLE symbols ADD PRIMARY KEY (id)') 840 do_query(query, 'ALTER TABLE branch_types ADD PRIMARY KEY (id)') 841 do_query(query, 'ALTER TABLE samples ADD PRIMARY KEY (id)') 842 if perf_db_export_calls or perf_db_export_callchains: 843 do_query(query, 'ALTER TABLE call_paths ADD PRIMARY KEY (id)') 844 if perf_db_export_calls: 845 do_query(query, 'ALTER TABLE calls ADD PRIMARY KEY (id)') 846 do_query(query, 'ALTER TABLE ptwrite ADD PRIMARY KEY (id)') 847 do_query(query, 'ALTER TABLE cbr ADD PRIMARY KEY (id)') 848 do_query(query, 'ALTER TABLE mwait ADD PRIMARY KEY (id)') 849 do_query(query, 'ALTER TABLE pwre ADD PRIMARY KEY (id)') 850 do_query(query, 'ALTER TABLE exstop ADD PRIMARY KEY (id)') 851 do_query(query, 'ALTER TABLE pwrx ADD PRIMARY KEY (id)') 852 853 printdate("Adding foreign keys") 854 do_query(query, 'ALTER TABLE threads ' 855 'ADD CONSTRAINT machinefk FOREIGN KEY (machine_id) REFERENCES machines (id),' 856 'ADD CONSTRAINT processfk FOREIGN KEY (process_id) REFERENCES threads (id)') 857 do_query(query, 'ALTER TABLE comms ' 858 'ADD CONSTRAINT threadfk FOREIGN KEY (c_thread_id) REFERENCES threads (id)') 859 do_query(query, 'ALTER TABLE comm_threads ' 860 'ADD CONSTRAINT commfk FOREIGN KEY (comm_id) REFERENCES comms (id),' 861 'ADD CONSTRAINT threadfk FOREIGN KEY (thread_id) REFERENCES threads (id)') 862 do_query(query, 'ALTER TABLE dsos ' 863 'ADD CONSTRAINT machinefk FOREIGN KEY (machine_id) REFERENCES machines (id)') 864 do_query(query, 'ALTER TABLE symbols ' 865 'ADD CONSTRAINT dsofk FOREIGN KEY (dso_id) REFERENCES dsos (id)') 866 do_query(query, 'ALTER TABLE samples ' 867 'ADD CONSTRAINT evselfk FOREIGN KEY (evsel_id) REFERENCES selected_events (id),' 868 'ADD CONSTRAINT machinefk FOREIGN KEY (machine_id) REFERENCES machines (id),' 869 'ADD CONSTRAINT threadfk FOREIGN KEY (thread_id) REFERENCES threads (id),' 870 'ADD CONSTRAINT commfk FOREIGN KEY (comm_id) REFERENCES comms (id),' 871 'ADD CONSTRAINT dsofk FOREIGN KEY (dso_id) REFERENCES dsos (id),' 872 'ADD CONSTRAINT symbolfk FOREIGN KEY (symbol_id) REFERENCES symbols (id),' 873 'ADD CONSTRAINT todsofk FOREIGN KEY (to_dso_id) REFERENCES dsos (id),' 874 'ADD CONSTRAINT tosymbolfk FOREIGN KEY (to_symbol_id) REFERENCES symbols (id)') 875 if perf_db_export_calls or perf_db_export_callchains: 876 do_query(query, 'ALTER TABLE call_paths ' 877 'ADD CONSTRAINT parentfk FOREIGN KEY (parent_id) REFERENCES call_paths (id),' 878 'ADD CONSTRAINT symbolfk FOREIGN KEY (symbol_id) REFERENCES symbols (id)') 879 if perf_db_export_calls: 880 do_query(query, 'ALTER TABLE calls ' 881 'ADD CONSTRAINT threadfk FOREIGN KEY (thread_id) REFERENCES threads (id),' 882 'ADD CONSTRAINT commfk FOREIGN KEY (comm_id) REFERENCES comms (id),' 883 'ADD CONSTRAINT call_pathfk FOREIGN KEY (call_path_id) REFERENCES call_paths (id),' 884 'ADD CONSTRAINT callfk FOREIGN KEY (call_id) REFERENCES samples (id),' 885 'ADD CONSTRAINT returnfk FOREIGN KEY (return_id) REFERENCES samples (id),' 886 'ADD CONSTRAINT parent_call_pathfk FOREIGN KEY (parent_call_path_id) REFERENCES call_paths (id)') 887 do_query(query, 'CREATE INDEX pcpid_idx ON calls (parent_call_path_id)') 888 do_query(query, 'CREATE INDEX pid_idx ON calls (parent_id)') 889 do_query(query, 'ALTER TABLE ptwrite ' 890 'ADD CONSTRAINT idfk FOREIGN KEY (id) REFERENCES samples (id)') 891 do_query(query, 'ALTER TABLE cbr ' 892 'ADD CONSTRAINT idfk FOREIGN KEY (id) REFERENCES samples (id)') 893 do_query(query, 'ALTER TABLE mwait ' 894 'ADD CONSTRAINT idfk FOREIGN KEY (id) REFERENCES samples (id)') 895 do_query(query, 'ALTER TABLE pwre ' 896 'ADD CONSTRAINT idfk FOREIGN KEY (id) REFERENCES samples (id)') 897 do_query(query, 'ALTER TABLE exstop ' 898 'ADD CONSTRAINT idfk FOREIGN KEY (id) REFERENCES samples (id)') 899 do_query(query, 'ALTER TABLE pwrx ' 900 'ADD CONSTRAINT idfk FOREIGN KEY (id) REFERENCES samples (id)') 901 902 printdate("Dropping unused tables") 903 if is_table_empty("ptwrite"): 904 drop("ptwrite") 905 if is_table_empty("mwait") and is_table_empty("pwre") and is_table_empty("exstop") and is_table_empty("pwrx"): 906 do_query(query, 'DROP VIEW power_events_view'); 907 drop("mwait") 908 drop("pwre") 909 drop("exstop") 910 drop("pwrx") 911 if is_table_empty("cbr"): 912 drop("cbr") 913 914 if (unhandled_count): 915 printdate("Warning: ", unhandled_count, " unhandled events") 916 printdate("Done") 917 918def trace_unhandled(event_name, context, event_fields_dict): 919 global unhandled_count 920 unhandled_count += 1 921 922def sched__sched_switch(*x): 923 pass 924 925def evsel_table(evsel_id, evsel_name, *x): 926 evsel_name = toserverstr(evsel_name) 927 n = len(evsel_name) 928 fmt = "!hiqi" + str(n) + "s" 929 value = struct.pack(fmt, 2, 8, evsel_id, n, evsel_name) 930 evsel_file.write(value) 931 932def machine_table(machine_id, pid, root_dir, *x): 933 root_dir = toserverstr(root_dir) 934 n = len(root_dir) 935 fmt = "!hiqiii" + str(n) + "s" 936 value = struct.pack(fmt, 3, 8, machine_id, 4, pid, n, root_dir) 937 machine_file.write(value) 938 939def thread_table(thread_id, machine_id, process_id, pid, tid, *x): 940 value = struct.pack("!hiqiqiqiiii", 5, 8, thread_id, 8, machine_id, 8, process_id, 4, pid, 4, tid) 941 thread_file.write(value) 942 943def comm_table(comm_id, comm_str, thread_id, time, exec_flag, *x): 944 comm_str = toserverstr(comm_str) 945 n = len(comm_str) 946 fmt = "!hiqi" + str(n) + "s" + "iqiqiB" 947 value = struct.pack(fmt, 5, 8, comm_id, n, comm_str, 8, thread_id, 8, time, 1, exec_flag) 948 comm_file.write(value) 949 950def comm_thread_table(comm_thread_id, comm_id, thread_id, *x): 951 fmt = "!hiqiqiq" 952 value = struct.pack(fmt, 3, 8, comm_thread_id, 8, comm_id, 8, thread_id) 953 comm_thread_file.write(value) 954 955def dso_table(dso_id, machine_id, short_name, long_name, build_id, *x): 956 short_name = toserverstr(short_name) 957 long_name = toserverstr(long_name) 958 build_id = toserverstr(build_id) 959 n1 = len(short_name) 960 n2 = len(long_name) 961 n3 = len(build_id) 962 fmt = "!hiqiqi" + str(n1) + "si" + str(n2) + "si" + str(n3) + "s" 963 value = struct.pack(fmt, 5, 8, dso_id, 8, machine_id, n1, short_name, n2, long_name, n3, build_id) 964 dso_file.write(value) 965 966def symbol_table(symbol_id, dso_id, sym_start, sym_end, binding, symbol_name, *x): 967 symbol_name = toserverstr(symbol_name) 968 n = len(symbol_name) 969 fmt = "!hiqiqiqiqiii" + str(n) + "s" 970 value = struct.pack(fmt, 6, 8, symbol_id, 8, dso_id, 8, sym_start, 8, sym_end, 4, binding, n, symbol_name) 971 symbol_file.write(value) 972 973def branch_type_table(branch_type, name, *x): 974 name = toserverstr(name) 975 n = len(name) 976 fmt = "!hiii" + str(n) + "s" 977 value = struct.pack(fmt, 2, 4, branch_type, n, name) 978 branch_type_file.write(value) 979 980def sample_table(sample_id, evsel_id, machine_id, thread_id, comm_id, dso_id, symbol_id, sym_offset, ip, time, cpu, to_dso_id, to_symbol_id, to_sym_offset, to_ip, period, weight, transaction, data_src, branch_type, in_tx, call_path_id, insn_cnt, cyc_cnt, *x): 981 if branches: 982 value = struct.pack("!hiqiqiqiqiqiqiqiqiqiqiiiqiqiqiqiiiBiqiqiq", 20, 8, sample_id, 8, evsel_id, 8, machine_id, 8, thread_id, 8, comm_id, 8, dso_id, 8, symbol_id, 8, sym_offset, 8, ip, 8, time, 4, cpu, 8, to_dso_id, 8, to_symbol_id, 8, to_sym_offset, 8, to_ip, 4, branch_type, 1, in_tx, 8, call_path_id, 8, insn_cnt, 8, cyc_cnt) 983 else: 984 value = struct.pack("!hiqiqiqiqiqiqiqiqiqiqiiiqiqiqiqiqiqiqiqiiiBiqiqiq", 24, 8, sample_id, 8, evsel_id, 8, machine_id, 8, thread_id, 8, comm_id, 8, dso_id, 8, symbol_id, 8, sym_offset, 8, ip, 8, time, 4, cpu, 8, to_dso_id, 8, to_symbol_id, 8, to_sym_offset, 8, to_ip, 8, period, 8, weight, 8, transaction, 8, data_src, 4, branch_type, 1, in_tx, 8, call_path_id, 8, insn_cnt, 8, cyc_cnt) 985 sample_file.write(value) 986 987def call_path_table(cp_id, parent_id, symbol_id, ip, *x): 988 fmt = "!hiqiqiqiq" 989 value = struct.pack(fmt, 4, 8, cp_id, 8, parent_id, 8, symbol_id, 8, ip) 990 call_path_file.write(value) 991 992def call_return_table(cr_id, thread_id, comm_id, call_path_id, call_time, return_time, branch_count, call_id, return_id, parent_call_path_id, flags, parent_id, insn_cnt, cyc_cnt, *x): 993 fmt = "!hiqiqiqiqiqiqiqiqiqiqiiiqiqiq" 994 value = struct.pack(fmt, 14, 8, cr_id, 8, thread_id, 8, comm_id, 8, call_path_id, 8, call_time, 8, return_time, 8, branch_count, 8, call_id, 8, return_id, 8, parent_call_path_id, 4, flags, 8, parent_id, 8, insn_cnt, 8, cyc_cnt) 995 call_file.write(value) 996 997def ptwrite(id, raw_buf): 998 data = struct.unpack_from("<IQ", raw_buf) 999 flags = data[0] 1000 payload = data[1] 1001 exact_ip = flags & 1 1002 value = struct.pack("!hiqiqiB", 3, 8, id, 8, payload, 1, exact_ip) 1003 ptwrite_file.write(value) 1004 1005def cbr(id, raw_buf): 1006 data = struct.unpack_from("<BBBBII", raw_buf) 1007 cbr = data[0] 1008 MHz = (data[4] + 500) / 1000 1009 percent = ((cbr * 1000 / data[2]) + 5) / 10 1010 value = struct.pack("!hiqiiiiii", 4, 8, id, 4, cbr, 4, MHz, 4, percent) 1011 cbr_file.write(value) 1012 1013def mwait(id, raw_buf): 1014 data = struct.unpack_from("<IQ", raw_buf) 1015 payload = data[1] 1016 hints = payload & 0xff 1017 extensions = (payload >> 32) & 0x3 1018 value = struct.pack("!hiqiiii", 3, 8, id, 4, hints, 4, extensions) 1019 mwait_file.write(value) 1020 1021def pwre(id, raw_buf): 1022 data = struct.unpack_from("<IQ", raw_buf) 1023 payload = data[1] 1024 hw = (payload >> 7) & 1 1025 cstate = (payload >> 12) & 0xf 1026 subcstate = (payload >> 8) & 0xf 1027 value = struct.pack("!hiqiiiiiB", 4, 8, id, 4, cstate, 4, subcstate, 1, hw) 1028 pwre_file.write(value) 1029 1030def exstop(id, raw_buf): 1031 data = struct.unpack_from("<I", raw_buf) 1032 flags = data[0] 1033 exact_ip = flags & 1 1034 value = struct.pack("!hiqiB", 2, 8, id, 1, exact_ip) 1035 exstop_file.write(value) 1036 1037def pwrx(id, raw_buf): 1038 data = struct.unpack_from("<IQ", raw_buf) 1039 payload = data[1] 1040 deepest_cstate = payload & 0xf 1041 last_cstate = (payload >> 4) & 0xf 1042 wake_reason = (payload >> 8) & 0xf 1043 value = struct.pack("!hiqiiiiii", 4, 8, id, 4, deepest_cstate, 4, last_cstate, 4, wake_reason) 1044 pwrx_file.write(value) 1045 1046def synth_data(id, config, raw_buf, *x): 1047 if config == 0: 1048 ptwrite(id, raw_buf) 1049 elif config == 1: 1050 mwait(id, raw_buf) 1051 elif config == 2: 1052 pwre(id, raw_buf) 1053 elif config == 3: 1054 exstop(id, raw_buf) 1055 elif config == 4: 1056 pwrx(id, raw_buf) 1057 elif config == 5: 1058 cbr(id, raw_buf) 1059