pg_select

Name

pg_select -- loop over the result of a query

Synopsis

pg_select ?-rowbyrow? ?-nodotfields? ?-withoutnulls? ?-paramarray var? [-variables] ?-params paramList? ?-count countVar? conn commandString arrayVar procedure

Description

pg_select submits a query (SELECT statement) to the PostgreSQL server and executes a given chunk of code for each row in the result. The commandString must be a SELECT statement; anything else returns an error. The arrayVar variable is an array name used in the loop. For each row, arrayVar is filled in with the row values, using the column names as the array indices. Then the procedure is executed.

In addition to the column values, the following special entries are made in the array (unless the [-nodotfields] flag is provided):

.headers

A list of the column names returned by the query.

.numcols

The number of columns returned by the query.

.tupno

The current row number, starting at zero and incrementing for each iteration of the loop body.

If the [-param] flag is provided, then it contains a list of parameters that will replace "$1", "$2" and so on in the query string, as if it were a prepared statement. Be sure to properly escape or quote the "$" in the query. :)

If the [-paramarray] flag is provided, then a substitution is performed on the query, securely replacing each back-quote delimited name with the corresponding entry from the named array. If the array does not contain the named element, then NULL is substituted (similarly to the way an array created by -withoutnulls is generated). Each such name must occur in a location where a value or field name could appear.

If the [-variables] flag is provided, then embedded Tcl variables are passed as parameters. Variables can be flagged with ':' and array references and namespaces are supported. Complex variable names can usually be embedded with :{nasty-name-here} though no attempt at duplicating Tcl brace-escaping is made. If the variable does not exist, then NULL is substituted.

Notes: This substitution is performed by generating a positional parameter list and calling PQExecParams with a modified query containing $1, $2, ... where the original `names` appeared. This is a straight substitution, so if this mechanism is used the back-quote character (`) can not appear elsewhere in the query, even in a quoted string. There are a maximum of 99,999 names.

Arguments

[-params list]

Perform parameter substitution using PQexecParams or PQSendQueryParams.

[-paramarray arrayname]

Perform parameter substitution via `quoted` elements of the array using PQexecParams or PQSendQueryParams.

[-variables]

Substitute Tcl variables found in the SQL string using PQexecParams or PQSendQueryParams.

[-rowbyrow]

Perform the select in row-by-row mode. This means that the code block is called immediately results become available, rather than waiting for the query to complete.

[-nodotfields]

Suppress generation of the pseudo-fields .headers, .numcols, and .tupno.

[-withoutnulls]

If specified null columns will be unset from the array rather than being defined and containing the null string, typically an empty string.

[-count countVar]

Set the variable "countVar" to the number of tuples returned for use in the block.

conn

The handle of the connection on which to execute the query.

commandString

The SQL query to execute.

arrayVar

An array variable for returned rows.

procedure

The procedure to run for each returned row.

Return Value

Number of rows actually processed.

Examples

This examples assumes that the table table1 has columns control and name (and perhaps others):

pg_select $pgconn "SELECT * FROM table1;" array {
    puts [format "%5d %s" $array(control) $array(name)]
}

This example demonstrates how to use named parameters to securely perform queries on an SQL database:

# An array imported from some hive of scum and villainy like a web form.
set form(first) {Andrew'); DROP TABLE students;--}
set form(last) {Randall}

# Secure extraction of data
pg_select -paramarray form $pgconn "SELECT * from students WHERE firstname = `first` AND lastname = `last`;" row {
    lappend candidates $row(student_id) $row(firstname) $row(lastname) $row(age)
}