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