34.7. Using Descriptor Areas
  An SQL descriptor area is a more sophisticated method for processing
   the result of a
  
   SELECT
  
  ,
  
   FETCH
  
  or
   a
  
   DESCRIBE
  
  statement. An SQL descriptor area groups
   the data of one row of data together with metadata items into one
   data structure.  The metadata is particularly useful when executing
   dynamic SQL statements, where the nature of the result columns might
   not be known ahead of time. PostgreSQL provides two ways to use
   Descriptor Areas: the named SQL Descriptor Areas and the C-structure
   SQLDAs.
 
34.7.1. Named SQL Descriptor Areas #
A named SQL descriptor area consists of a header, which contains information concerning the entire descriptor, and one or more item descriptor areas, which basically each describe one column in the result row.
Before you can use an SQL descriptor area, you need to allocate one:
EXEC SQL ALLOCATE DESCRIPTOR identifier;
  The identifier serves as the " variable name " of the descriptor area. When you don't need the descriptor anymore, you should deallocate it:
EXEC SQL DEALLOCATE DESCRIPTOR identifier;
  
   To use a descriptor area, specify it as the storage target in an
   
    INTO
   
   clause, instead of listing host variables:
  
EXEC SQL FETCH NEXT FROM mycursor INTO SQL DESCRIPTOR mydesc;
If the result set is empty, the Descriptor Area will still contain the metadata from the query, i.e., the field names.
   For not yet executed prepared queries, the
   
    DESCRIBE
   
   statement can be used to get the metadata of the result set:
  
EXEC SQL BEGIN DECLARE SECTION; char *sql_stmt = "SELECT * FROM table1"; EXEC SQL END DECLARE SECTION; EXEC SQL PREPARE stmt1 FROM :sql_stmt; EXEC SQL DESCRIBE stmt1 INTO SQL DESCRIPTOR mydesc;
   Before PostgreSQL 9.0, the
   
    SQL
   
   keyword was optional,
    so using
   
    DESCRIPTOR
   
   and
   
    SQL DESCRIPTOR
   
   produced named SQL Descriptor Areas. Now it is mandatory, omitting
    the
   
    SQL
   
   keyword produces SQLDA Descriptor Areas,
    see
   
    Section 34.7.2
   
   .
  
   In
   
    DESCRIBE
   
   and
   
    FETCH
   
   statements,
    the
   
    INTO
   
   and
   
    USING
   
   keywords can be
    used to similarly: they produce the result set and the metadata in a
    Descriptor Area.
  
Now how do you get the data out of the descriptor area? You can think of the descriptor area as a structure with named fields. To retrieve the value of a field from the header and store it into a host variable, use the following command:
EXEC SQL GET DESCRIPTORname:hostvar=field;
   Currently, there is only one header field defined:
   
    
     COUNT
    
   
   , which tells how many item
    descriptor areas exist (that is, how many columns are contained in
    the result).  The host variable needs to be of an integer type.  To
    get a field from the item descriptor area, use the following
    command:
  
EXEC SQL GET DESCRIPTORnameVALUEnum:hostvar=field;
   
    
     num
    
   
   can be a literal integer or a host
    variable containing an integer. Possible fields are:
  
- 
     
      CARDINALITY(integer) #
- 
     number of rows in the result set 
- 
     
      DATA#
- 
     actual data item (therefore, the data type of this field depends on the query) 
- 
     
      DATETIME_INTERVAL_CODE(integer) #
- 
     When TYPEis9,DATETIME_INTERVAL_CODEwill have a value of1forDATE,2forTIME,3forTIMESTAMP,4forTIME WITH TIME ZONE, or5forTIMESTAMP WITH TIME ZONE.
- 
     
      DATETIME_INTERVAL_PRECISION(integer) #
- 
     not implemented 
- 
     
      INDICATOR(integer) #
- 
     the indicator (indicating a null value or a value truncation) 
- 
     
      KEY_MEMBER(integer) #
- 
     not implemented 
- 
     
      LENGTH(integer) #
- 
     length of the datum in characters 
- 
     
      NAME(string) #
- 
     name of the column 
- 
     
      NULLABLE(integer) #
- 
     not implemented 
- 
     
      OCTET_LENGTH(integer) #
- 
     length of the character representation of the datum in bytes 
- 
     
      PRECISION(integer) #
- 
     precision (for type numeric)
- 
     
      RETURNED_LENGTH(integer) #
- 
     length of the datum in characters 
- 
     
      RETURNED_OCTET_LENGTH(integer) #
- 
     length of the character representation of the datum in bytes 
- 
     
      SCALE(integer) #
- 
     scale (for type numeric)
- 
     
      TYPE(integer) #
- 
     numeric code of the data type of the column 
   In
   
    EXECUTE
   
   ,
   
    DECLARE
   
   and
   
    OPEN
   
   statements, the effect of the
   
    INTO
   
   and
   
    USING
   
   keywords are different. A Descriptor Area can also be manually built to
    provide the input parameters for a query or a cursor and
   
    USING SQL DESCRIPTOR
    
     
   is the way to pass the input parameters into a parameterized query. The statement
    to build a named SQL Descriptor Area is below:
  
      name
     
    
   
EXEC SQL SET DESCRIPTORnameVALUEnumfield= :hostvar;
   PostgreSQL supports retrieving more that one record in one
   
    FETCH
   
   statement and storing the data in host variables in this case assumes that the
    variable is an array. E.g.:
  
EXEC SQL BEGIN DECLARE SECTION; int id[5]; EXEC SQL END DECLARE SECTION; EXEC SQL FETCH 5 FROM mycursor INTO SQL DESCRIPTOR mydesc; EXEC SQL GET DESCRIPTOR mydesc VALUE 1 :id = DATA;
34.7.2. SQLDA Descriptor Areas #
An SQLDA Descriptor Area is a C language structure which can be also used to get the result set and the metadata of a query. One structure stores one record from the result set.
EXEC SQL include sqlda.h; sqlda_t *mysqlda; EXEC SQL FETCH 3 FROM mycursor INTO DESCRIPTOR mysqlda;
   Note that the
   
    SQL
   
   keyword is omitted. The paragraphs about
    the use cases of the
   
    INTO
   
   and
   
    USING
   
   keywords in
   
    Section 34.7.1
   
   also apply here with an addition.
    In a
   
    DESCRIBE
   
   statement the
   
    DESCRIPTOR
   
   keyword can be completely omitted if the
   
    INTO
   
   keyword is used:
  
EXEC SQL DESCRIBE prepared_statement INTO mysqlda;
The general flow of a program that uses SQLDA is:
- 
     Prepare a query, and declare a cursor for it. 
- 
     Declare an SQLDA for the result rows. 
- 
     Declare an SQLDA for the input parameters, and initialize them (memory allocation, parameter settings). 
- 
     Open a cursor with the input SQLDA. 
- 
     Fetch rows from the cursor, and store them into an output SQLDA. 
- 
     Read values from the output SQLDA into the host variables (with conversion if necessary). 
- 
     Close the cursor. 
- 
     Free the memory area allocated for the input SQLDA. 
34.7.2.1. SQLDA Data Structure #
    SQLDA uses three data structure
     types:
    
     sqlda_t
    
    ,
    
     sqlvar_t
    
    ,
     and
    
     struct sqlname
    
    .
   
Tip
PostgreSQL's SQLDA has a similar data structure to the one in IBM DB2 Universal Database, so some technical information on DB2's SQLDA could help understanding PostgreSQL's one better.
34.7.2.1.1. sqlda_t Structure #
     The structure type
     
      sqlda_t
     
     is the type of the
      actual SQLDA.  It holds one record.  And two or
      more
     
      sqlda_t
     
     structures can be connected in a
      linked list with the pointer in
      the
     
      desc_next
     
     field, thus
      representing an ordered collection of rows.  So, when two or
      more rows are fetched, the application can read them by
      following the
     
      desc_next
     
     pointer in
      each
     
      sqlda_t
     
     node.
    
     The definition of
     
      sqlda_t
     
     is:
    
struct sqlda_struct
{
    char            sqldaid[8];
    long            sqldabc;
    short           sqln;
    short           sqld;
    struct sqlda_struct *desc_next;
    struct sqlvar_struct sqlvar[1];
};
typedef struct sqlda_struct sqlda_t;
    The meaning of the fields is:
- 
       
        sqldaid#
- 
       It contains the literal string "SQLDA ".
- 
       
        sqldabc#
- 
       It contains the size of the allocated space in bytes. 
- 
       
        sqln#
- 
       It contains the number of input parameters for a parameterized query in case it's passed into OPEN,DECLAREorEXECUTEstatements using theUSINGkeyword. In case it's used as output ofSELECT,EXECUTEorFETCHstatements, its value is the same assqldstatement
- 
       
        sqld#
- 
       It contains the number of fields in a result set. 
- 
       
        desc_next#
- 
       If the query returns more than one record, multiple linked SQLDA structures are returned, and desc_nextholds a pointer to the next entry in the list.
- 
       
        sqlvar#
- 
       This is the array of the columns in the result set. 
34.7.2.1.2. sqlvar_t Structure #
     The structure type
     
      sqlvar_t
     
     holds a column value
      and metadata such as type and length. The definition of the type
      is:
    
struct sqlvar_struct
{
    short          sqltype;
    short          sqllen;
    char          *sqldata;
    short         *sqlind;
    struct sqlname sqlname;
};
typedef struct sqlvar_struct sqlvar_t;
    The meaning of the fields is:
- 
       
        sqltype#
- 
       Contains the type identifier of the field. For values, see enum ECPGttypeinecpgtype.h.
- 
       
        sqllen#
- 
       Contains the binary length of the field. e.g., 4 bytes for ECPGt_int.
- 
       
        sqldata#
- 
       Points to the data. The format of the data is described in Section 34.4.4 . 
- 
       
        sqlind#
- 
       Points to the null indicator. 0 means not null, -1 means null. 
- 
       
        sqlname#
- 
       The name of the field. 
34.7.2.1.3. struct sqlname Structure #
     A
     
      struct sqlname
     
     structure holds a column name.  It
      is used as a member of the
     
      sqlvar_t
     
     structure.  The
      definition of the structure is:
    
#define NAMEDATALEN 64
struct sqlname
{
        short           length;
        char            data[NAMEDATALEN];
};
    The meaning of the fields is:
34.7.2.2. Retrieving a Result Set Using an SQLDA #
The general steps to retrieve a query result set through an SQLDA are:
- 
      Declare an sqlda_tstructure to receive the result set.
- 
      Execute FETCH/EXECUTE/DESCRIBEcommands to process a query specifying the declared SQLDA.
- 
      Check the number of records in the result set by looking at sqln, a member of thesqlda_tstructure.
- 
      Get the values of each column from sqlvar[0],sqlvar[1], etc., members of thesqlda_tstructure.
- 
      Go to next row ( sqlda_tstructure) by following thedesc_nextpointer, a member of thesqlda_tstructure.
- 
      Repeat above as you need. 
Here is an example retrieving a result set through an SQLDA.
    First, declare a
    
     sqlda_t
    
    structure to receive the result set.
   
sqlda_t *sqlda1;
    Next, specify the SQLDA in a command.  This is
     a
    
     FETCH
    
    command example.
   
EXEC SQL FETCH NEXT FROM cur1 INTO DESCRIPTOR sqlda1;
Run a loop following the linked list to retrieve the rows.
sqlda_t *cur_sqlda;
for (cur_sqlda = sqlda1;
     cur_sqlda != NULL;
     cur_sqlda = cur_sqlda->desc_next)
{
    ...
}
   
    Inside the loop, run another loop to retrieve each column data
     (
    
     sqlvar_t
    
    structure) of the row.
   
for (i = 0; i < cur_sqlda->sqld; i++)
{
    sqlvar_t v = cur_sqlda->sqlvar[i];
    char *sqldata = v.sqldata;
    short sqllen  = v.sqllen;
    ...
}
   
    To get a column value, check the
    
     sqltype
    
    value,
     a member of the
    
     sqlvar_t
    
    structure.  Then, switch
     to an appropriate way, depending on the column type, to copy
     data from the
    
     sqlvar
    
    field to a host variable.
   
char var_buf[1024];
switch (v.sqltype)
{
    case ECPGt_char:
        memset(&var_buf, 0, sizeof(var_buf));
        memcpy(&var_buf, sqldata, (sizeof(var_buf) <= sqllen ? sizeof(var_buf) - 1 : sqllen));
        break;
    case ECPGt_int: /* integer */
        memcpy(&intval, sqldata, sqllen);
        snprintf(var_buf, sizeof(var_buf), "%d", intval);
        break;
    ...
}
   
34.7.2.3. Passing Query Parameters Using an SQLDA #
The general steps to use an SQLDA to pass input parameters to a prepared query are:
- 
      Create a prepared query (prepared statement) 
- 
      Declare an sqlda_t structure as an input SQLDA. 
- 
      Allocate memory area (as sqlda_t structure) for the input SQLDA. 
- 
      Set (copy) input values in the allocated memory. 
- 
      Open a cursor with specifying the input SQLDA. 
Here is an example.
First, create a prepared statement.
EXEC SQL BEGIN DECLARE SECTION; char query[1024] = "SELECT d.oid, * FROM pg_database d, pg_stat_database s WHERE d.oid = s.datid AND (d.datname = ? OR d.oid = ?)"; EXEC SQL END DECLARE SECTION; EXEC SQL PREPARE stmt1 FROM :query;
    Next, allocate memory for an SQLDA, and set the number of input
     parameters in
    
     sqln
    
    , a member variable of
     the
    
     sqlda_t
    
    structure.  When two or more input
     parameters are required for the prepared query, the application
     has to allocate additional memory space which is calculated by
     (nr. of params - 1) * sizeof(sqlvar_t).  The example shown here
     allocates memory space for two input parameters.
   
sqlda_t *sqlda2; sqlda2 = (sqlda_t *) malloc(sizeof(sqlda_t) + sizeof(sqlvar_t)); memset(sqlda2, 0, sizeof(sqlda_t) + sizeof(sqlvar_t)); sqlda2->sqln = 2; /* number of input variables */
    After memory allocation, store the parameter values into the
    
     sqlvar[]
    
    array.  (This is same array used for
     retrieving column values when the SQLDA is receiving a result
     set.)  In this example, the input parameters
     are
    
     "postgres"
    
    , having a string type,
     and
    
     1
    
    , having an integer type.
   
sqlda2->sqlvar[0].sqltype = ECPGt_char; sqlda2->sqlvar[0].sqldata = "postgres"; sqlda2->sqlvar[0].sqllen = 8; int intval = 1; sqlda2->sqlvar[1].sqltype = ECPGt_int; sqlda2->sqlvar[1].sqldata = (char *) &intval; sqlda2->sqlvar[1].sqllen = sizeof(intval);
By opening a cursor and specifying the SQLDA that was set up beforehand, the input parameters are passed to the prepared statement.
EXEC SQL OPEN cur1 USING DESCRIPTOR sqlda2;
Finally, after using input SQLDAs, the allocated memory space must be freed explicitly, unlike SQLDAs used for receiving query results.
free(sqlda2);
34.7.2.4. A Sample Application Using SQLDA #
Here is an example program, which describes how to fetch access statistics of the databases, specified by the input parameters, from the system catalogs.
    This application joins two system tables, pg_database and
     pg_stat_database on the database OID, and also fetches and shows
     the database statistics which are retrieved by two input
     parameters (a database
    
     postgres
    
    , and OID
    
     1
    
    ).
   
First, declare an SQLDA for input and an SQLDA for output.
EXEC SQL include sqlda.h; sqlda_t *sqlda1; /* an output descriptor */ sqlda_t *sqlda2; /* an input descriptor */
Next, connect to the database, prepare a statement, and declare a cursor for the prepared statement.
int
main(void)
{
    EXEC SQL BEGIN DECLARE SECTION;
    char query[1024] = "SELECT d.oid,* FROM pg_database d, pg_stat_database s WHERE d.oid=s.datid AND ( d.datname=? OR d.oid=? )";
    EXEC SQL END DECLARE SECTION;
    EXEC SQL CONNECT TO testdb AS con1 USER testuser;
    EXEC SQL SELECT pg_catalog.set_config('search_path', '', false); EXEC SQL COMMIT;
    EXEC SQL PREPARE stmt1 FROM :query;
    EXEC SQL DECLARE cur1 CURSOR FOR stmt1;
   
    Next, put some values in the input SQLDA for the input
     parameters.  Allocate memory for the input SQLDA, and set the
     number of input parameters to
    
     sqln
    
    .  Store
     type, value, and value length into
    
     sqltype
    
    ,
    
     sqldata
    
    , and
    
     sqllen
    
    in the
    
     sqlvar
    
    structure.
   
    /* Create SQLDA structure for input parameters. */
    sqlda2 = (sqlda_t *) malloc(sizeof(sqlda_t) + sizeof(sqlvar_t));
    memset(sqlda2, 0, sizeof(sqlda_t) + sizeof(sqlvar_t));
    sqlda2->sqln = 2; /* number of input variables */
    sqlda2->sqlvar[0].sqltype = ECPGt_char;
    sqlda2->sqlvar[0].sqldata = "postgres";
    sqlda2->sqlvar[0].sqllen  = 8;
    intval = 1;
    sqlda2->sqlvar[1].sqltype = ECPGt_int;
    sqlda2->sqlvar[1].sqldata = (char *)&intval;
    sqlda2->sqlvar[1].sqllen  = sizeof(intval);
   
After setting up the input SQLDA, open a cursor with the input SQLDA.
    /* Open a cursor with input parameters. */
    EXEC SQL OPEN cur1 USING DESCRIPTOR sqlda2;
   
    Fetch rows into the output SQLDA from the opened cursor.
     (Generally, you have to call
    
     FETCH
    
    repeatedly
     in the loop, to fetch all rows in the result set.)
   
    while (1)
    {
        sqlda_t *cur_sqlda;
        /* Assign descriptor to the cursor  */
        EXEC SQL FETCH NEXT FROM cur1 INTO DESCRIPTOR sqlda1;
   
    Next, retrieve the fetched records from the SQLDA, by following
     the linked list of the
    
     sqlda_t
    
    structure.
   
    for (cur_sqlda = sqlda1 ;
         cur_sqlda != NULL ;
         cur_sqlda = cur_sqlda->desc_next)
    {
        ...
   
    Read each columns in the first record.  The number of columns is
     stored in
    
     sqld
    
    , the actual data of the first
     column is stored in
    
     sqlvar[0]
    
    , both members of
     the
    
     sqlda_t
    
    structure.
   
        /* Print every column in a row. */
        for (i = 0; i < sqlda1->sqld; i++)
        {
            sqlvar_t v = sqlda1->sqlvar[i];
            char *sqldata = v.sqldata;
            short sqllen  = v.sqllen;
            strncpy(name_buf, v.sqlname.data, v.sqlname.length);
            name_buf[v.sqlname.length] = '\0';
   
    Now, the column data is stored in the variable
    
     v
    
    .
     Copy every datum into host variables, looking
     at
    
     v.sqltype
    
    for the type of the column.
   
            switch (v.sqltype) {
                int intval;
                double doubleval;
                unsigned long long int longlongval;
                case ECPGt_char:
                    memset(&var_buf, 0, sizeof(var_buf));
                    memcpy(&var_buf, sqldata, (sizeof(var_buf) <= sqllen ? sizeof(var_buf)-1 : sqllen));
                    break;
                case ECPGt_int: /* integer */
                    memcpy(&intval, sqldata, sqllen);
                    snprintf(var_buf, sizeof(var_buf), "%d", intval);
                    break;
                ...
                default:
                    ...
            }
            printf("%s = %s (type: %d)\n", name_buf, var_buf, v.sqltype);
        }
   
Close the cursor after processing all of records, and disconnect from the database.
    EXEC SQL CLOSE cur1;
    EXEC SQL COMMIT;
    EXEC SQL DISCONNECT ALL;
   
The whole program is shown in Example 34.1 .
Example 34.1. Example SQLDA Program
#include#include #include #include #include EXEC SQL include sqlda.h; sqlda_t *sqlda1; /* descriptor for output */ sqlda_t *sqlda2; /* descriptor for input */ EXEC SQL WHENEVER NOT FOUND DO BREAK; EXEC SQL WHENEVER SQLERROR STOP; int main(void) { EXEC SQL BEGIN DECLARE SECTION; char query[1024] = "SELECT d.oid,* FROM pg_database d, pg_stat_database s WHERE d.oid=s.datid AND ( d.datname=? OR d.oid=? )"; int intval; unsigned long long int longlongval; EXEC SQL END DECLARE SECTION; EXEC SQL CONNECT TO uptimedb AS con1 USER uptime; EXEC SQL SELECT pg_catalog.set_config('search_path', '', false); EXEC SQL COMMIT; EXEC SQL PREPARE stmt1 FROM :query; EXEC SQL DECLARE cur1 CURSOR FOR stmt1; /* Create an SQLDA structure for an input parameter */ sqlda2 = (sqlda_t *)malloc(sizeof(sqlda_t) + sizeof(sqlvar_t)); memset(sqlda2, 0, sizeof(sqlda_t) + sizeof(sqlvar_t)); sqlda2->sqln = 2; /* a number of input variables */ sqlda2->sqlvar[0].sqltype = ECPGt_char; sqlda2->sqlvar[0].sqldata = "postgres"; sqlda2->sqlvar[0].sqllen = 8; intval = 1; sqlda2->sqlvar[1].sqltype = ECPGt_int; sqlda2->sqlvar[1].sqldata = (char *) &intval; sqlda2->sqlvar[1].sqllen = sizeof(intval); /* Open a cursor with input parameters. */ EXEC SQL OPEN cur1 USING DESCRIPTOR sqlda2; while (1) { sqlda_t *cur_sqlda; /* Assign descriptor to the cursor */ EXEC SQL FETCH NEXT FROM cur1 INTO DESCRIPTOR sqlda1; for (cur_sqlda = sqlda1 ; cur_sqlda != NULL ; cur_sqlda = cur_sqlda->desc_next) { int i; char name_buf[1024]; char var_buf[1024]; /* Print every column in a row. */ for (i=0 ; i sqld ; i++) { sqlvar_t v = cur_sqlda->sqlvar[i]; char *sqldata = v.sqldata; short sqllen = v.sqllen; strncpy(name_buf, v.sqlname.data, v.sqlname.length); name_buf[v.sqlname.length] = '\0'; switch (v.sqltype) { case ECPGt_char: memset(&var_buf, 0, sizeof(var_buf)); memcpy(&var_buf, sqldata, (sizeof(var_buf)<=sqllen ? sizeof(var_buf)-1 : sqllen) ); break; case ECPGt_int: /* integer */ memcpy(&intval, sqldata, sqllen); snprintf(var_buf, sizeof(var_buf), "%d", intval); break; case ECPGt_long_long: /* bigint */ memcpy(&longlongval, sqldata, sqllen); snprintf(var_buf, sizeof(var_buf), "%lld", longlongval); break; default: { int i; memset(var_buf, 0, sizeof(var_buf)); for (i = 0; i < sqllen; i++) { char tmpbuf[16]; snprintf(tmpbuf, sizeof(tmpbuf), "%02x ", (unsigned char) sqldata[i]); strncat(var_buf, tmpbuf, sizeof(var_buf)); } } break; } printf("%s = %s (type: %d)\n", name_buf, var_buf, v.sqltype); } printf("\n"); } } EXEC SQL CLOSE cur1; EXEC SQL COMMIT; EXEC SQL DISCONNECT ALL; return 0; } 
The output of this example should look something like the following (some numbers will vary).
oid = 1 (type: 1)
datname = template1 (type: 1)
datdba = 10 (type: 1)
encoding = 0 (type: 5)
datistemplate = t (type: 1)
datallowconn = t (type: 1)
dathasloginevt = f (type: 1)
datconnlimit = -1 (type: 5)
datfrozenxid = 379 (type: 1)
dattablespace = 1663 (type: 1)
datconfig =  (type: 1)
datacl = {=c/uptime,uptime=CTc/uptime} (type: 1)
datid = 1 (type: 1)
datname = template1 (type: 1)
numbackends = 0 (type: 5)
xact_commit = 113606 (type: 9)
xact_rollback = 0 (type: 9)
blks_read = 130 (type: 9)
blks_hit = 7341714 (type: 9)
tup_returned = 38262679 (type: 9)
tup_fetched = 1836281 (type: 9)
tup_inserted = 0 (type: 9)
tup_updated = 0 (type: 9)
tup_deleted = 0 (type: 9)
oid = 11511 (type: 1)
datname = postgres (type: 1)
datdba = 10 (type: 1)
encoding = 0 (type: 5)
datistemplate = f (type: 1)
datallowconn = t (type: 1)
dathasloginevt = f (type: 1)
datconnlimit = -1 (type: 5)
datfrozenxid = 379 (type: 1)
dattablespace = 1663 (type: 1)
datconfig =  (type: 1)
datacl =  (type: 1)
datid = 11511 (type: 1)
datname = postgres (type: 1)
numbackends = 0 (type: 5)
xact_commit = 221069 (type: 9)
xact_rollback = 18 (type: 9)
blks_read = 1176 (type: 9)
blks_hit = 13943750 (type: 9)
tup_returned = 77410091 (type: 9)
tup_fetched = 3253694 (type: 9)
tup_inserted = 0 (type: 9)
tup_updated = 0 (type: 9)
tup_deleted = 0 (type: 9)