Select-item Metadata
Following a Prepare of a SELECT or CALL statement using the %SQL.StatementOpens in a new tab class, you can return metadata about each select-item column specified in the query, either by displaying all of the metadata or by specifying individual metadata items. This column metadata includes ODBC data type information, as well as client type and InterSystems Objects property origins and class type information.
The following example returns the number of columns specified in the most recently prepared query:
set myquery = "SELECT %ID AS id,Name,DOB,Age,AVG(Age),CURRENT_DATE,Home_State FROM Sample.Person"
set tStatement = ##class(%SQL.Statement).%New()
set qStatus = tStatement.%Prepare(myquery)
if qStatus'=1 {write "%Prepare failed:" do $System.Status.DisplayError(qStatus) quit}
write "Number of columns=",tStatement.%Metadata.columnCount,!
write "End of metadata"
The following example returns the column name (or column alias), ODBC data type, maximum data length (precision), and scale for each select-item field:
set $NAMESPACE="SAMPLES"
set myquery=2
set myquery(1)="SELECT Name AS VendorName,LastPayDate,MinPayment,NetDays,"
set myquery(2)="AVG(MinPayment),$HOROLOG,%TABLENAME FROM Sample.Vendor"
set rset = ##class(%SQL.Statement).%New()
set qStatus = rset.%Prepare(.myquery)
if qStatus'=1 {write "%Prepare failed:" do $System.Status.DisplayError(qStatus) quit}
set x=rset.%Metadata.columns.Count()
set x=1
while rset.%Metadata.columns.GetAt(x) {
set column=rset.%Metadata.columns.GetAt(x)
write !,x," ",column.colName," is data type ",column.ODBCType
write " with a size of ",column.precision," and scale = ",column.scale
set x=x+1 }
write !,"End of metadata"
The following example displays all of the column metadata using the %SQL.StatementMetadataOpens in a new tab %Display()Opens in a new tab instance method:
set query = "SELECT %ID AS id,Name,DOB,Age,AVG(Age),CURRENT_DATE,Home_State FROM Sample.Person"
set tStatement = ##class(%SQL.Statement).%New()
set qStatus = tStatement.%Prepare(query)
if qStatus'=1 {write "%Prepare failed:" do $System.Status.DisplayError(qStatus) quit}
do tStatement.%Metadata.%Display()
write !,"End of metadata"
This returns two table listings of the selected fields. The first columns metadata table lists column definition information:
Display Header |
%SQL.StatementColumnOpens in a new tab Property |
Description |
Column Name |
colName |
The SQL name of the column. If the column is given an alias, the column alias, not the field name, is listed here. Names and aliases are truncated to 12 characters.
For an expression, aggregate, literal, host variable, or subquery, the assigned “Expression_n”, “Aggregate_n”, “Literal_n”, “HostVar_n”, or “Subquery_n” label is listed (with n being the SELECT item sequence number). If you have assigned an alias to an expression, aggregate, literal, host variable, or subquery, the alias is listed here. |
Type |
ODBCType |
The integer code for the ODBC data type. These codes are listed in the Integer Codes for Data Types section of the Data Types reference page in the InterSystems SQL Reference. Note that these ODBC data type codes are not the same as the CType data type codes. |
Prec |
precision |
The precision or maximum length, in characters. Precision and scale metadata for TIME data types are described in Date, Time, PosixTime, and TimeStamp Data Types. |
Scale |
scale |
The maximum number of fractional decimal digits. Returns 0 for integer or non-numeric values. Precision and scale metadata for TIME data types are described in Date, Time, PosixTime, and TimeStamp Data Types. |
Null |
isNullable |
An integer value that indicates whether the column is defined as Non-NULL (0), or if NULL is permitted (1). The RowID returns 0. If the SELECT item is an aggregate or subquery that could result in NULL, or if it specifies the NULL literal, this item is set to 1. If the SELECT item is an expression or host variable, this item is set to 2 (cannot be determined). |
Label |
label |
The column name or column alias (same as Column Name). |
Table |
tableName |
The SQL table name. The actual table name is always listed here, even if you have given the table an alias. If the SELECT item is an expression or an aggregate no table name is listed. If the SELECT item is a subquery, the subquery table name is listed. |
Schema |
schemaName |
The table’s schema name. If no schema name was specified, returns the system-wide default schema. If the SELECT item is an expression or an aggregate no schema name is listed. If the SELECT item is a subquery no schema name is listed. |
CType |
clientType |
The integer code for the client data type. See the %SQL.StatementColumnOpens in a new tab clientTypeOpens in a new tab property for a list of values. |
The second columns metadata table lists extended column information. The Extended Column Info table lists each column with twelve boolean flags (SQLRESULTCOL), specified as Y (Yes) or N (No):
Boolean Flag |
%SQL.StatementColumnOpens in a new tab Property |
Description |
1: AutoIncrement |
isAutoIncrement |
The RowID and IDENTITY fields returns Y. |
2: CaseSensitive |
isCaseSensitive |
A string data type field with %EXACT collation returns Y.
A property that references a %SerialObject embedded object returns Y. |
3: Currency |
isCurrency |
A field defined with a data type of %Library.CurrencyOpens in a new tab, such as the MONEY data type. |
4: ReadOnly |
isReadOnly |
An Expression, Aggregate, Literal, HostVar, or Subquery returns Y. The RowID, IDENTITY, and RowVersion fields returns Y. |
5: RowVersion |
isRowVersion |
The RowVersion field returns Y. |
6: Unique |
isUnique |
A field defined as having a unique value constraint. The RowID and IDENTITY fields returns Y. |
7: Aliased |
isAliased |
The system supplies an alias to a non-field select-item. Therefore, an Expression, Aggregate, Literal, HostVar, or Subquery returns Y, whether or not the user replaced the system alias by specifying a column alias. This flag is not affected by user-specified column aliases. |
8: Expression |
isExpression |
An Expression returns Y. |
9: Hidden |
isHidden |
If the table is defined with %PUBLICROWID or SqlRowIdPrivate=0 (the default), the RowID field returns N. Otherwise, the RowID field returns Y. A property that references a %SerialObject embedded object returns Y. |
10: Identity |
isIdentity |
A field defined as an IDENTITY field returns Y. The RowID field if the RowID is not hidden returns Y. |
11: KeyColumn |
isKeyColumn |
A field defined as a primary key field or the target of a foreign key constraint. The RowID field returns Y. |
12: RowID |
isRowId |
The RowID and IDENTITY fields returns Y. |
13: isList |
isList |
A field defined as data type %Library.List or %Library.ListOfBinary, or a field that is a list or array collection returns Y. CType (client data type)=6.
An expression using the $LISTBUILD or $LISTFROMSTRING function to generate a list returns Y. |
The Extended Column Info metadata table lists the Column Name (the SQL name or column alias), the Linked Prop (linked persistent class property) and Type Class (data type class) for each of the selected fields. Note that the Linked Prop lists the persistent class name (not the SQL table name) and the property name (not the column alias).
-
For an ordinary table field (SELECT Name FROM Sample.Person): Linked Prop=Sample.Person.Name, Type Class=%Library.String.
-
For the table’s RowID (SELECT %ID FROM Sample.Person): Linked Prop= [none], Type Class=Sample.Person.
-
For an Expression, Aggregate, Literal, HostVar, or Subquery (SELECT COUNT(Name) FROM Sample.Person): Linked Prop= [none], Type Class=%Library.BigInt.
-
For a referenced %SerialObject embedded object property (SELECT Home_State FROM Sample.Person). Linked Prop=Sample.Address.State, Type Class=%Library.String.
-
For a field referencing a %SerialObject embedded object (SELECT Home FROM Sample.Person). Linked Prop=Sample.Person.Home, Type Class=Sample.Address.
In this example, the Home_State field in Sample.Person references the State property of the %SerialObject class Sample.Address.
The following example returns the metadata for a called stored procedure with one formal parameter, which is also a statement parameter:
set mysql = "CALL Sample.SP_Sample_By_Name(?)"
set tStatement = ##class(%SQL.Statement).%New()
set qStatus = tStatement.%Prepare(.mysql)
if qStatus'=1 {write "%Prepare failed:" do $System.Status.DisplayError(qStatus) quit}
do tStatement.%Metadata.%Display()
write !,"End of metadata"
It returns not only column (field) information, but also values for Statement Parameters, Formal Parameters, and Objects.
The following example returns the metadata for a with three formal parameters. One of these three parameters is designated with a question mark (?) making it a statement parameter:
set mycall = "CALL personsets(?,'MA')"
set tStatement = ##class(%SQL.Statement).%New(0,"sample")
set qStatus = tStatement.%Prepare(mycall)
if qStatus'=1 {write "%Prepare failed:" do $System.Status.DisplayError(qStatus) quit}
do tStatement.%Metadata.%Display()
write !,"End of metadata"
Note that this metadata returns no column information, but the Statement Parameters, Formal Parameters lists contain the column names and data types.