Menu
Amazon Redshift
Database Developer Guide (API Version 2012-12-01)

STL_DDLTEXT

Captures the following DDL statements that were run on the system.

These DDL statements include the following queries and objects:

  • CREATE SCHEMA, TABLE, VIEW

  • DROP SCHEMA, TABLE, VIEW

  • ALTER SCHEMA, TABLE

See also STL_QUERYTEXT, STL_UTILITYTEXT, and SVL_STATEMENTTEXT. These tables provide a timeline of the SQL commands that are executed on the system; this history is useful for troubleshooting purposes and for creating an audit trail of all system activities.

Use the STARTTIME and ENDTIME columns to find out which statements were logged during a given time period. Long blocks of SQL text are broken into lines 200 characters long; the SEQUENCE column identifies fragments of text that belong to a single statement.

This table is visible to all users. Superusers can see all rows; regular users can see only their own data. For more information, see Visibility of Data in System Tables and Views.

Table Columns

Column Name Data Type Description
userid integer ID of the user who generated the entry.
xid bigint Transaction ID associated with the statement.
pid integer Process ID associated with the statement.
label character(30) Either the name of the file used to run the query or a label defined with a SET QUERY_GROUP command. If the query is not file-based or the QUERY_GROUP parameter is not set, this field is blank.
starttime timestamp Time in UTC that the query started executing, with 6 digits of precision for fractional seconds. For example: 2009-06-12 11:29:19.131358.
endtime timestamp Time in UTC that the query finished executing, with 6 digits of precision for fractional seconds. For example: 2009-06-12 11:29:19.131358.
sequence integer When a single statement contains more than 200 characters, additional rows are logged for that statement. Sequence 0 is the first row, 1 is the second, and so on.
text character(200) SQL text, in 200-character increments.

Sample Queries

The following query shows the DDL for four CREATE TABLE statements. The DDL text column is truncated for readability.

Copy
select xid, starttime, sequence, substring(text,1,40) as text from stl_ddltext order by xid desc, sequence; xid | starttime | sequence | text ------+----------------------------+----------+------------------------------------------ 1806 | 2013-10-23 00:11:14.709851 | 0 | CREATE TABLE supplier ( s_suppkey int4 N 1806 | 2013-10-23 00:11:14.709851 | 1 | s_comment varchar(101) NOT NULL ) 1805 | 2013-10-23 00:11:14.496153 | 0 | CREATE TABLE region ( r_regionkey int4 N 1804 | 2013-10-23 00:11:14.285986 | 0 | CREATE TABLE partsupp ( ps_partkey int8 1803 | 2013-10-23 00:11:14.056901 | 0 | CREATE TABLE part ( p_partkey int8 NOT N 1803 | 2013-10-23 00:11:14.056901 | 1 | ner char(10) NOT NULL , p_retailprice nu (6 rows)