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)')
222else:
223	do_query(query, 'CREATE TABLE samples ('
224		'id		integer		NOT NULL	PRIMARY KEY,'
225		'evsel_id	bigint,'
226		'machine_id	bigint,'
227		'thread_id	bigint,'
228		'comm_id	bigint,'
229		'dso_id		bigint,'
230		'symbol_id	bigint,'
231		'sym_offset	bigint,'
232		'ip		bigint,'
233		'time		bigint,'
234		'cpu		integer,'
235		'to_dso_id	bigint,'
236		'to_symbol_id	bigint,'
237		'to_sym_offset	bigint,'
238		'to_ip		bigint,'
239		'period		bigint,'
240		'weight		bigint,'
241		'transaction_	bigint,'
242		'data_src	bigint,'
243		'branch_type	integer,'
244		'in_tx		boolean,'
245		'call_path_id	bigint)')
246
247if perf_db_export_calls or perf_db_export_callchains:
248	do_query(query, 'CREATE TABLE call_paths ('
249		'id		integer		NOT NULL	PRIMARY KEY,'
250		'parent_id	bigint,'
251		'symbol_id	bigint,'
252		'ip		bigint)')
253if perf_db_export_calls:
254	do_query(query, 'CREATE TABLE calls ('
255		'id		integer		NOT NULL	PRIMARY KEY,'
256		'thread_id	bigint,'
257		'comm_id	bigint,'
258		'call_path_id	bigint,'
259		'call_time	bigint,'
260		'return_time	bigint,'
261		'branch_count	bigint,'
262		'call_id	bigint,'
263		'return_id	bigint,'
264		'parent_call_path_id	bigint,'
265		'flags		integer,'
266		'parent_id	bigint)')
267
268# printf was added to sqlite in version 3.8.3
269sqlite_has_printf = False
270try:
271	do_query(query, 'SELECT printf("") FROM machines')
272	sqlite_has_printf = True
273except:
274	pass
275
276def emit_to_hex(x):
277	if sqlite_has_printf:
278		return 'printf("%x", ' + x + ')'
279	else:
280		return x
281
282do_query(query, 'CREATE VIEW machines_view AS '
283	'SELECT '
284		'id,'
285		'pid,'
286		'root_dir,'
287		'CASE WHEN id=0 THEN \'unknown\' WHEN pid=-1 THEN \'host\' ELSE \'guest\' END AS host_or_guest'
288	' FROM machines')
289
290do_query(query, 'CREATE VIEW dsos_view AS '
291	'SELECT '
292		'id,'
293		'machine_id,'
294		'(SELECT host_or_guest FROM machines_view WHERE id = machine_id) AS host_or_guest,'
295		'short_name,'
296		'long_name,'
297		'build_id'
298	' FROM dsos')
299
300do_query(query, 'CREATE VIEW symbols_view AS '
301	'SELECT '
302		'id,'
303		'name,'
304		'(SELECT short_name FROM dsos WHERE id=dso_id) AS dso,'
305		'dso_id,'
306		'sym_start,'
307		'sym_end,'
308		'CASE WHEN binding=0 THEN \'local\' WHEN binding=1 THEN \'global\' ELSE \'weak\' END AS binding'
309	' FROM symbols')
310
311do_query(query, 'CREATE VIEW threads_view AS '
312	'SELECT '
313		'id,'
314		'machine_id,'
315		'(SELECT host_or_guest FROM machines_view WHERE id = machine_id) AS host_or_guest,'
316		'process_id,'
317		'pid,'
318		'tid'
319	' FROM threads')
320
321do_query(query, 'CREATE VIEW comm_threads_view AS '
322	'SELECT '
323		'comm_id,'
324		'(SELECT comm FROM comms WHERE id = comm_id) AS command,'
325		'thread_id,'
326		'(SELECT pid FROM threads WHERE id = thread_id) AS pid,'
327		'(SELECT tid FROM threads WHERE id = thread_id) AS tid'
328	' FROM comm_threads')
329
330if perf_db_export_calls or perf_db_export_callchains:
331	do_query(query, 'CREATE VIEW call_paths_view AS '
332		'SELECT '
333			'c.id,'
334			+ emit_to_hex('c.ip') + ' AS ip,'
335			'c.symbol_id,'
336			'(SELECT name FROM symbols WHERE id = c.symbol_id) AS symbol,'
337			'(SELECT dso_id FROM symbols WHERE id = c.symbol_id) AS dso_id,'
338			'(SELECT dso FROM symbols_view  WHERE id = c.symbol_id) AS dso_short_name,'
339			'c.parent_id,'
340			+ emit_to_hex('p.ip') + ' AS parent_ip,'
341			'p.symbol_id AS parent_symbol_id,'
342			'(SELECT name FROM symbols WHERE id = p.symbol_id) AS parent_symbol,'
343			'(SELECT dso_id FROM symbols WHERE id = p.symbol_id) AS parent_dso_id,'
344			'(SELECT dso FROM symbols_view  WHERE id = p.symbol_id) AS parent_dso_short_name'
345		' FROM call_paths c INNER JOIN call_paths p ON p.id = c.parent_id')
346if perf_db_export_calls:
347	do_query(query, 'CREATE VIEW calls_view AS '
348		'SELECT '
349			'calls.id,'
350			'thread_id,'
351			'(SELECT pid FROM threads WHERE id = thread_id) AS pid,'
352			'(SELECT tid FROM threads WHERE id = thread_id) AS tid,'
353			'(SELECT comm FROM comms WHERE id = comm_id) AS command,'
354			'call_path_id,'
355			+ emit_to_hex('ip') + ' AS ip,'
356			'symbol_id,'
357			'(SELECT name FROM symbols WHERE id = symbol_id) AS symbol,'
358			'call_time,'
359			'return_time,'
360			'return_time - call_time AS elapsed_time,'
361			'branch_count,'
362			'call_id,'
363			'return_id,'
364			'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,'
365			'parent_call_path_id,'
366			'calls.parent_id'
367		' FROM calls INNER JOIN call_paths ON call_paths.id = call_path_id')
368
369do_query(query, 'CREATE VIEW samples_view AS '
370	'SELECT '
371		'id,'
372		'time,'
373		'cpu,'
374		'(SELECT pid FROM threads WHERE id = thread_id) AS pid,'
375		'(SELECT tid FROM threads WHERE id = thread_id) AS tid,'
376		'(SELECT comm FROM comms WHERE id = comm_id) AS command,'
377		'(SELECT name FROM selected_events WHERE id = evsel_id) AS event,'
378		+ emit_to_hex('ip') + ' AS ip_hex,'
379		'(SELECT name FROM symbols WHERE id = symbol_id) AS symbol,'
380		'sym_offset,'
381		'(SELECT short_name FROM dsos WHERE id = dso_id) AS dso_short_name,'
382		+ emit_to_hex('to_ip') + ' AS to_ip_hex,'
383		'(SELECT name FROM symbols WHERE id = to_symbol_id) AS to_symbol,'
384		'to_sym_offset,'
385		'(SELECT short_name FROM dsos WHERE id = to_dso_id) AS to_dso_short_name,'
386		'(SELECT name FROM branch_types WHERE id = branch_type) AS branch_type_name,'
387		'in_tx'
388	' FROM samples')
389
390do_query(query, 'END TRANSACTION')
391
392evsel_query = QSqlQuery(db)
393evsel_query.prepare("INSERT INTO selected_events VALUES (?, ?)")
394machine_query = QSqlQuery(db)
395machine_query.prepare("INSERT INTO machines VALUES (?, ?, ?)")
396thread_query = QSqlQuery(db)
397thread_query.prepare("INSERT INTO threads VALUES (?, ?, ?, ?, ?)")
398comm_query = QSqlQuery(db)
399comm_query.prepare("INSERT INTO comms VALUES (?, ?)")
400comm_thread_query = QSqlQuery(db)
401comm_thread_query.prepare("INSERT INTO comm_threads VALUES (?, ?, ?)")
402dso_query = QSqlQuery(db)
403dso_query.prepare("INSERT INTO dsos VALUES (?, ?, ?, ?, ?)")
404symbol_query = QSqlQuery(db)
405symbol_query.prepare("INSERT INTO symbols VALUES (?, ?, ?, ?, ?, ?)")
406branch_type_query = QSqlQuery(db)
407branch_type_query.prepare("INSERT INTO branch_types VALUES (?, ?)")
408sample_query = QSqlQuery(db)
409if branches:
410	sample_query.prepare("INSERT INTO samples VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)")
411else:
412	sample_query.prepare("INSERT INTO samples VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)")
413if perf_db_export_calls or perf_db_export_callchains:
414	call_path_query = QSqlQuery(db)
415	call_path_query.prepare("INSERT INTO call_paths VALUES (?, ?, ?, ?)")
416if perf_db_export_calls:
417	call_query = QSqlQuery(db)
418	call_query.prepare("INSERT INTO calls VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)")
419
420def trace_begin():
421	printdate("Writing records...")
422	do_query(query, 'BEGIN TRANSACTION')
423	# id == 0 means unknown.  It is easier to create records for them than replace the zeroes with NULLs
424	evsel_table(0, "unknown")
425	machine_table(0, 0, "unknown")
426	thread_table(0, 0, 0, -1, -1)
427	comm_table(0, "unknown")
428	dso_table(0, 0, "unknown", "unknown", "")
429	symbol_table(0, 0, 0, 0, 0, "unknown")
430	sample_table(0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0)
431	if perf_db_export_calls or perf_db_export_callchains:
432		call_path_table(0, 0, 0, 0)
433		call_return_table(0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0, 0)
434
435unhandled_count = 0
436
437def trace_end():
438	do_query(query, 'END TRANSACTION')
439
440	printdate("Adding indexes")
441	if perf_db_export_calls:
442		do_query(query, 'CREATE INDEX pcpid_idx ON calls (parent_call_path_id)')
443		do_query(query, 'CREATE INDEX pid_idx ON calls (parent_id)')
444
445	if (unhandled_count):
446		printdate("Warning: ", unhandled_count, " unhandled events")
447	printdate("Done")
448
449def trace_unhandled(event_name, context, event_fields_dict):
450	global unhandled_count
451	unhandled_count += 1
452
453def sched__sched_switch(*x):
454	pass
455
456def bind_exec(q, n, x):
457	for xx in x[0:n]:
458		q.addBindValue(str(xx))
459	do_query_(q)
460
461def evsel_table(*x):
462	bind_exec(evsel_query, 2, x)
463
464def machine_table(*x):
465	bind_exec(machine_query, 3, x)
466
467def thread_table(*x):
468	bind_exec(thread_query, 5, x)
469
470def comm_table(*x):
471	bind_exec(comm_query, 2, x)
472
473def comm_thread_table(*x):
474	bind_exec(comm_thread_query, 3, x)
475
476def dso_table(*x):
477	bind_exec(dso_query, 5, x)
478
479def symbol_table(*x):
480	bind_exec(symbol_query, 6, x)
481
482def branch_type_table(*x):
483	bind_exec(branch_type_query, 2, x)
484
485def sample_table(*x):
486	if branches:
487		for xx in x[0:15]:
488			sample_query.addBindValue(str(xx))
489		for xx in x[19:22]:
490			sample_query.addBindValue(str(xx))
491		do_query_(sample_query)
492	else:
493		bind_exec(sample_query, 22, x)
494
495def call_path_table(*x):
496	bind_exec(call_path_query, 4, x)
497
498def call_return_table(*x):
499	bind_exec(call_query, 12, x)
500