1# PerfettoSQL Syntax 2*This page documents the syntax of PerfettoSQL, a dialect of SQL used in trace 3processor and other Perfetto analysis tools to query traces.* 4 5PerfettoSQL is a direct descendent of the 6[dialect of SQL implemented by SQLite](https://www.sqlite.org/lang.html). 7Specifically, any SQL valid in SQLite is also valid in PerfettoSQL. 8 9Unfortunately, the SQLite syntax alone is not sufficient for two reasons: 101. It is quite basic e.g. it does not support creating functions or macros 112. It cannot be used to access features which are only available in Perfetto 12tooling e.g. it cannot be used to create efficient analytic tables, import 13modules from the PerfettoSQL standard library etc. 14 15For this reason, PerfettoSQL adds new pieces of syntax which make the experience 16of writing SQL queries better. All such additons include the keyword `PERFETTO` 17to make it clear that they are PerfettoSQL-only. 18 19<!-- TODO(b/290185551): we should really talk about our "recommendations" (e.g. 20using CREATE PERFETTO TABLE instead of CREATE TABLE) somewhere and reference it 21here. --> 22 23## Including PerfettoSQL modules 24`INCLUDE PERFETTO MODULE` is used to import all tables/views/functions/macros 25defined in a PerfettoSQL module (e.g. from the 26[PerfettoSQL standard library](/docs/analysis/stdlib-docs.autogen)). 27 28Note that this statement acts more similar to `#include` statements in C++ 29rather than `import` statements from Java/Python. Specifically, all objects 30in the module become available in the global namespace without being qualified 31by the module name. 32 33Example: 34```sql 35-- Include all tables/views/functions from the android.startup.startups module 36-- in the standard library. 37INCLUDE PERFETTO MODULE android.startup.startups; 38 39-- Use the android_startups table defined in the android.startup.startups 40-- module. 41SELECT * 42FROM android_startups; 43``` 44 45For interactive development, the key can contain a wildcards: 46```sql 47-- Include all modules under android/. 48INCLUDE PERFETTO MODULE android.*; 49 50-- Or all stdlib modules: 51INCLUDE PERFETTO MODULE *; 52 53-- However, note, that both patterns are not allowed in stdlib. 54``` 55 56## Defining functions 57`CREATE PEFETTO FUNCTION` allows functions to be defined in SQL. The syntax is 58similar to the syntax in PostgreSQL or GoogleSQL. 59 60<!-- TODO(b/290185551): talk about different possible argument/return types. --> 61 62Example: 63```sql 64-- Create a scalar function with no arguments. 65CREATE PERFETTO FUNCTION constant_fn() RETURNS INT AS SELECT 1; 66 67-- Create a scalar function taking two arguments. 68CREATE PERFETTO FUNCTION add(x INT, y INT) RETURNS INT AS SELECT $x + $y; 69 70-- Create a table function with no arguments 71CREATE PERFETTO FUNCTION constant_tab_fn() 72RETURNS TABLE(ts LONG, dur LONG) AS 73SELECT column1 as ts, column2 as dur 74FROM ( 75 VALUES 76 (100, 10), 77 (200, 20) 78); 79 80-- Create a table function with one argument 81CREATE PERFETTO FUNCTION sched_by_utid(utid INT) 82RETURNS TABLE(ts LONG, dur LONG, utid INT) AS 83SELECT ts, dur, utid 84FROM sched 85WHERE utid = $utid; 86``` 87 88## Creating efficient tables 89`CREATE PERFETTO TABLE` allows defining tables optimized for analytic queries 90on traces. These tables are both more performant and more memory efficient than 91SQLite native tables created with `CREATE TABLE`. 92 93Note however the full feature set of `CREATE TABLE` is not supported: 941. Perfetto tables cannot be inserted into and are read-only after creation 952. Perfetto tables must be defined and populated using a `SELECT` statement. 96 They cannot be defined by column names and types. 97 98Example: 99```sql 100-- Create a Perfetto table with constant values. 101CREATE PERFETTO TABLE constant_table AS 102SELECT column1 as ts, column2 as dur 103FROM ( 104 VALUES 105 (100, 10), 106 (200, 20) 107); 108 109-- Create a Perfetto table with a query on another table. 110CREATE PERFETTO TABLE slice_sub_table AS 111SELECT * 112FROM slice 113WHERE name = 'foo'; 114``` 115 116### Schema 117 118Perfetto tables can have an optional explicit schema. The schema syntax is the 119same as the function argument or returned-from-a-function table, 120i.e. a comma-separated list of (column name, colum type) pairs in parenthesis 121after table or view name. 122 123```sql 124CREATE PERFETTO TABLE foo(x INT, y STRING) AS 125SELECT 1 as x, 'test' as y 126``` 127 128### Index 129 130`CREATE PERFETTO INDEX` lets you create indexes on Perfetto tables, similar to 131how you create indexes in SQLite databases. These indexes are built on specific 132columns, and Perfetto internally maintains these columns in a sorted order. 133This means operations benefiting from sorting on an indexed column (or group of 134columns) will be significantly faster, as if you were operating on a column 135that's already sorted. 136 137NOTE: Indexes have non-trivial memory cost, so it's important to only use them 138when there is a need for performance improvement. 139 140NOTE: Indexes will be used by views created on the indexed table, but they will 141not be inherited by any child tables, as shown in the below SQL. 142 143NOTE: If the query filters/joins on `id` column of the table (one that is a 144primary key of the table) there is no need to add a Perfetto index, as Perfetto 145tables already have special performance optimizations for operations that can 146benefit from sorting. 147 148Example of usage: 149```sql 150CREATE PERFETTO TABLE foo AS 151SELECT * FROM slice; 152 153-- Creates and stores an index `foo_track` on column `track_id` of table foo. 154CREATE PERFETTO INDEX foo_track ON foo(track_id); 155-- Creates or replaces an index created on two columns. It will be used for 156-- operations on `track_id` and can be used on operations on `name` only if 157-- there has been an equality constraint on `track_id` too. 158CREATE OR REPLACE PERFETTO INDEX foo_track_and_name ON foo(track_id, name); 159``` 160 161The performance of those two queries should be very different now: 162```sql 163-- This doesn't have an index so it will have to linearily scan whole column. 164SELECT * FROM slice WHERE track_id = 10 AND name > "b"; 165 166-- This has an index and can use binary search. 167SELECT * FROM foo WHERE track_id = 10 AND name > "b"; 168 169-- The biggest difference should be noticeable on joins: 170-- This join: 171SELECT * FROM slice JOIN track WHERE slice.track_id = track.id; 172-- will be noticeably slower than this: 173SELECT * FROM foo JOIN track WHERE slice.track_id = track.id; 174``` 175 176Indexes can be dropped: 177```sql 178DROP PERFETTO INDEX foo_track ON foo; 179``` 180 181 182## Creating views with a schema 183 184Views can be created via `CREATE PERFETTO VIEW`, taking an optional schema. 185With the exception of the schema, they behave exactly the same as regular 186SQLite views. 187 188NOTE: the use of `CREATE PERFETTO VIEW` instead of `CREATE VIEW` is required in 189the standard library where each column must be documented. 190 191```sql 192CREATE PERFETTO VIEW foo(x INT, y STRING) AS 193SELECT 1 as x, 'test' as y 194``` 195 196## Defining macros 197`CREATE PEFETTO MACRO` allows macros to be defined in SQL. The design of macros 198is inspired by the macros in Rust. 199 200The following are recommended uses of macros: 201- Passing tables as arguments to a "function-like" snippet of SQL. 202 203Macros are powerful but also dangerous if used incorrectly, making debugging 204extremely difficult. For this reason, it's recommended that they are used 205sparingly when they are needed and only for the recommended uses described 206above. If only passing around scalar SQL values, use functions as discussed 207above. 208 209NOTE: Macros are expanded with a pre-processing step *before* any execution 210happens. Expansion is a purely syntatic operation involves replacing the macro 211invocation with the SQL tokens in the macro definition. 212 213As macros are syntactic, the types of arguments and return types in macros are 214different to the types used in functions and correspond to parts of the SQL 215parse tree. The following are the supported types: 216 217| Type name | Description | 218| --------- | ----------- | 219| `Expr` | Corresponds to any SQL scalar expression. | 220| `TableOrSubquery` | Corresponds to either an SQL table or a subquery | 221| `ColumnName` | Corresponds to a column name of a table | 222 223Example: 224```sql 225-- Create a macro taking no arguments. Note how the returned SQL fragment needs 226-- to be wrapped in brackets to make it a valid SQL expression. 227-- 228-- Note: this is a strongly discouraged use of macros as a simple SQL 229-- function would also work here. 230CREATE PERFETTO MACRO constant_macro() RETURNS Expr AS (SELECT 1); 231 232-- Using the above macro. Macros are invoked by suffixing their names with !. 233-- This is similar to how macros are invoked in Rust. 234SELECT constant_macro!(); 235 236-- This causes the following SQL to be actually executed: 237-- SELECT (SELECT 1); 238 239-- A variant of the above. Again, strongly discouraged. 240CREATE PERFETTO MACRO constant_macro_no_bracket() RETURNS Expr AS 2; 241 242-- Using the above macro. 243SELECT constant_macro_no_bracket!(); 244 245-- This causes the following SQL to be actually executed: 246-- SELECT 2; 247 248-- Creating a macro taking a single scalar argument and returning a scalar. 249-- Note: again this is a strongly discouraged use of macros as functions can 250-- also do this. 251CREATE PERFETTO MACRO single_arg_macro(x Expr) RETURNS Expr AS (SELECT $x); 252SELECT constant_macro!() + single_arg_macro!(100); 253 254-- Creating a macro taking both a table and a scalar expression as an argument 255-- and returning a table. Note again how the returned SQL statement is wrapped 256-- in brackets to make it a subquery. This allows it to be used anywhere a 257-- table or subquery is allowed. 258-- 259-- Note: if tables are reused multiple times, it's recommended that they be 260-- "cached" with a common-table expression (CTE) for performance reasons. 261CREATE PERFETTO MACRO multi_arg_macro(x TableOrSubquery, y Expr) 262RETURNS TableOrSubquery AS 263( 264 SELECT input_tab.input_col + $y 265 FROM $x AS input_tab; 266) 267```