1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-03 20:02:46 +03:00

Make plpgsql support FOR over a query specified by a cursor declaration,

for improved compatibility with Oracle.

Pavel Stehule, with some fixes by me.
This commit is contained in:
Tom Lane
2008-04-06 23:43:29 +00:00
parent 2604359251
commit 347dd6a1cf
8 changed files with 947 additions and 568 deletions

View File

@ -1,6 +1,6 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.126 2008/04/01 03:51:09 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.127 2008/04/06 23:43:29 tgl Exp $ -->
<chapter id="plpgsql">
<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
<indexterm zone="plpgsql">
@ -195,7 +195,7 @@ END <optional> <replaceable>label</replaceable> </optional>;
<para>
A <replaceable>label</replaceable> is only needed if you want to
identify the block for use
identify the block for use
in an <literal>EXIT</> statement, or to qualify the names of the
variables declared in the block. If a label is given after
<literal>END</>, it must match the label at the block's beginning.
@ -285,10 +285,12 @@ $$ LANGUAGE plpgsql;
<para>
All variables used in a block must be declared in the
declarations section of the block.
(The only exception is that the loop variable of a <literal>FOR</> loop
declarations section of the block.
(The only exceptions are that the loop variable of a <literal>FOR</> loop
iterating over a range of integer values is automatically declared as an
integer variable.)
integer variable, and likewise the loop variable of a <literal>FOR</> loop
iterating over a cursor's result is automatically declared as a
record variable.)
</para>
<para>
@ -317,7 +319,7 @@ arow RECORD;
The <literal>DEFAULT</> clause, if given, specifies the initial value assigned
to the variable when the block is entered. If the <literal>DEFAULT</> clause
is not given then the variable is initialized to the
<acronym>SQL</acronym> null value.
<acronym>SQL</acronym> null value.
The <literal>CONSTANT</> option prevents the variable from being assigned to,
so that its value remains constant for the duration of the block.
If <literal>NOT NULL</>
@ -750,7 +752,7 @@ PREPARE <replaceable>statement_name</>(integer, integer) AS SELECT $1 &lt; $2;
data type, or the variable has a specific size/precision
(like <type>char(20)</type>), the result value will be implicitly
converted by the <application>PL/pgSQL</application> interpreter using
the result type's output-function and
the result type's output-function and
the variable type's input-function. Note that this could potentially
result in run-time errors generated by the input function, if the
string form of the result value is not acceptable to the input function.
@ -1049,7 +1051,7 @@ EXECUTE <replaceable class="command">command-string</replaceable> <optional> INT
If the <literal>STRICT</> option is given, an error is reported
unless the query produces exactly one row.
</para>
<para>
The command string can use parameter values, which are referenced
in the command as <literal>$1</>, <literal>$2</>, etc.
@ -1082,8 +1084,8 @@ EXECUTE 'SELECT count(*) FROM '
<para>
An <command>EXECUTE</> with a simple constant command string and some
<literal>USING</> parameters, as in the first example above, is
functionally equivalent to just writing the command directly in
<application>PL/pgSQL</application> and allowing replacement of
functionally equivalent to just writing the command directly in
<application>PL/pgSQL</application> and allowing replacement of
<application>PL/pgSQL</application> variables to happen automatically.
The important difference is that <command>EXECUTE</> will re-plan
the command on each execution, generating a plan that is specific
@ -1198,7 +1200,7 @@ EXECUTE 'UPDATE tbl SET '
not deliver unintended results. For example the <literal>WHERE</> clause
<programlisting>
'WHERE key = ' || quote_nullable(keyvalue)
</programlisting>
</programlisting>
will never succeed if <literal>keyvalue</> is null, because the
result of using the equality operator <literal>=</> with a null operand
is always null. If you wish null to work like an ordinary key value,
@ -1281,50 +1283,51 @@ GET DIAGNOSTICS integer_var = ROW_COUNT;
<itemizedlist>
<listitem>
<para>
A <command>SELECT INTO</command> statement sets
<literal>FOUND</literal> true if a row is assigned, false if no
row is returned.
A <command>SELECT INTO</command> statement sets
<literal>FOUND</literal> true if a row is assigned, false if no
row is returned.
</para>
</listitem>
<listitem>
<para>
A <command>PERFORM</> statement sets <literal>FOUND</literal>
true if it produces (and discards) one or more rows, false if
no row is produced.
A <command>PERFORM</> statement sets <literal>FOUND</literal>
true if it produces (and discards) one or more rows, false if
no row is produced.
</para>
</listitem>
<listitem>
<para>
<command>UPDATE</>, <command>INSERT</>, and <command>DELETE</>
statements set <literal>FOUND</literal> true if at least one
row is affected, false if no row is affected.
<command>UPDATE</>, <command>INSERT</>, and <command>DELETE</>
statements set <literal>FOUND</literal> true if at least one
row is affected, false if no row is affected.
</para>
</listitem>
<listitem>
<para>
A <command>FETCH</> statement sets <literal>FOUND</literal>
true if it returns a row, false if no row is returned.
A <command>FETCH</> statement sets <literal>FOUND</literal>
true if it returns a row, false if no row is returned.
</para>
</listitem>
<listitem>
<para>
A <command>MOVE</> statement sets <literal>FOUND</literal>
true if it successfully repositions the cursor, false otherwise.
A <command>MOVE</> statement sets <literal>FOUND</literal>
true if it successfully repositions the cursor, false otherwise.
</para>
</listitem>
<listitem>
<para>
A <command>FOR</> statement sets <literal>FOUND</literal> true
if it iterates one or more times, else false. This applies to
all three variants of the <command>FOR</> statement (integer
<command>FOR</> loops, record-set <command>FOR</> loops, and
dynamic record-set <command>FOR</>
loops). <literal>FOUND</literal> is set this way when the
<command>FOR</> loop exits; inside the execution of the loop,
<literal>FOUND</literal> is not modified by the
<command>FOR</> statement, although it might be changed by the
execution of other statements within the loop body.
A <command>FOR</> statement sets <literal>FOUND</literal> true
if it iterates one or more times, else false. This applies to
all four variants of the <command>FOR</> statement (integer
<command>FOR</> loops, record-set <command>FOR</> loops,
dynamic record-set <command>FOR</> loops, and cursor
<command>FOR</> loops).
<literal>FOUND</literal> is set this way when the
<command>FOR</> loop exits; inside the execution of the loop,
<literal>FOUND</literal> is not modified by the
<command>FOR</> statement, although it might be changed by the
execution of other statements within the loop body.
</para>
</listitem>
</itemizedlist>
@ -1391,7 +1394,7 @@ NULL;
important) part of <application>PL/pgSQL</>. With
<application>PL/pgSQL</>'s control structures,
you can manipulate <productname>PostgreSQL</> data in a very
flexible and powerful way.
flexible and powerful way.
</para>
<sect2 id="plpgsql-statements-returning">
@ -1649,7 +1652,7 @@ END IF;
</programlisting>
<programlisting>
IF v_count &gt; 0 THEN
IF v_count &gt; 0 THEN
INSERT INTO users_count (count) VALUES (v_count);
RETURN 't';
ELSE
@ -1721,7 +1724,7 @@ END IF;
<programlisting>
IF number = 0 THEN
result := 'zero';
ELSIF number &gt; 0 THEN
ELSIF number &gt; 0 THEN
result := 'positive';
ELSIF number &lt; 0 THEN
result := 'negative';
@ -1879,7 +1882,7 @@ LOOP
-- some computations
EXIT WHEN count &gt; 100;
CONTINUE WHEN count &lt; 50;
-- some computations for count IN [50 .. 100]
-- some computations for count IN [50 .. 100]
END LOOP;
</programlisting>
</para>
@ -1935,16 +1938,16 @@ END LOOP <optional> <replaceable>label</replaceable> </optional>;
<para>
This form of <literal>FOR</> creates a loop that iterates over a range
of integer values. The variable
of integer values. The variable
<replaceable>name</replaceable> is automatically defined as type
<type>integer</> and exists only inside the loop (any existing
definition of the variable name is ignored within the loop).
The two expressions giving
the lower and upper bound of the range are evaluated once when entering
the loop. If the <literal>BY</> clause isn't specified the iteration
step is 1, otherwise it's the value specified in the <literal>BY</>
the loop. If the <literal>BY</> clause isn't specified the iteration
step is 1, otherwise it's the value specified in the <literal>BY</>
clause, which again is evaluated once on loop entry.
If <literal>REVERSE</> is specified then the step value is
If <literal>REVERSE</> is specified then the step value is
subtracted, rather than added, after each iteration.
</para>
@ -2045,7 +2048,7 @@ $$ LANGUAGE plpgsql;
rows:
<synopsis>
<optional> &lt;&lt;<replaceable>label</replaceable>&gt;&gt; </optional>
FOR <replaceable>target</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional> LOOP
FOR <replaceable>target</replaceable> IN EXECUTE <replaceable>text_expression</replaceable> <optional> USING <replaceable>expression</replaceable> <optional>, ...</optional> </optional> LOOP
<replaceable>statements</replaceable>
END LOOP <optional> <replaceable>label</replaceable> </optional>;
</synopsis>
@ -2057,6 +2060,12 @@ END LOOP <optional> <replaceable>label</replaceable> </optional>;
As with <command>EXECUTE</command>, parameter values can be inserted
into the dynamic command via <literal>USING</>.
</para>
<para>
Another way to specify the query whose results should be iterated
through is to declare it as a cursor. This is described in
<xref linkend="plpgsql-cursor-for-loop">.
</para>
</sect2>
<sect2 id="plpgsql-error-trapping">
@ -2293,6 +2302,14 @@ DECLARE
cursor variables while the third uses a bound cursor variable.
</para>
<note>
<para>
Bound cursors can also be used without explicitly opening them,
via the <command>FOR</> statement described in
<xref linkend="plpgsql-cursor-for-loop">.
</para>
</note>
<sect3>
<title><command>OPEN FOR</command> <replaceable>query</replaceable></title>
@ -2640,7 +2657,7 @@ END;
BEGIN;
SELECT reffunc2();
reffunc2
reffunc2
--------------------
&lt;unnamed cursor 1&gt;
(1 row)
@ -2676,6 +2693,36 @@ COMMIT;
</para>
</sect3>
</sect2>
<sect2 id="plpgsql-cursor-for-loop">
<title>Looping Through a Cursor's Result</title>
<para>
There is a variant of the <command>FOR</> statement that allows
iterating through the rows returned by a cursor. The syntax is:
<synopsis>
<optional> &lt;&lt;<replaceable>label</replaceable>&gt;&gt; </optional>
FOR <replaceable>recordvar</replaceable> IN <replaceable>bound_cursor</replaceable> <optional> ( <replaceable>argument_values</replaceable> ) </optional> LOOP
<replaceable>statements</replaceable>
END LOOP <optional> <replaceable>label</replaceable> </optional>;
</synopsis>
The cursor variable must have been bound to some query when it was
declared, and it <emphasis>cannot</> be open already. The
<command>FOR</> statement automatically opens the cursor, and it closes
the cursor again when the loop exits. A list of actual argument value
expressions must appear if and only if the cursor was declared to take
arguments. These values will be substituted in the query, in just
the same way as during an <command>OPEN</>.
The variable <replaceable>recordvar</replaceable> is automatically
defined as type <type>record</> and exists only inside the loop (any
existing definition of the variable name is ignored within the loop).
Each row returned by the cursor is successively assigned to this
record variable and the loop body is executed.
</para>
</sect2>
</sect1>
<sect1 id="plpgsql-errors-and-messages">
@ -2716,8 +2763,8 @@ RAISE <replaceable class="parameter">level</replaceable> '<replaceable class="pa
<para>
Inside the format string, <literal>%</literal> is replaced by the
next optional argument's string representation. Write
<literal>%%</literal> to emit a literal <literal>%</literal>.
Arguments can be simple variables or expressions,
<literal>%%</literal> to emit a literal <literal>%</literal>.
Arguments can be simple variables or expressions,
but the format must be a simple string literal.
</para>
@ -2772,7 +2819,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<para>
When a <application>PL/pgSQL</application> function is called as a
trigger, several special variables are created automatically in the
trigger, several special variables are created automatically in the
top-level block. They are:
<variablelist>
@ -2812,7 +2859,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<term><varname>TG_WHEN</varname></term>
<listitem>
<para>
Data type <type>text</type>; a string of either
Data type <type>text</type>; a string of either
<literal>BEFORE</literal> or <literal>AFTER</literal>
depending on the trigger's definition.
</para>
@ -2857,7 +2904,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<listitem>
<para>
Data type <type>name</type>; the name of the table that caused the trigger
invocation. This is now deprecated, and could disappear in a future
invocation. This is now deprecated, and could disappear in a future
release. Use <literal>TG_TABLE_NAME</> instead.
</para>
</listitem>
@ -2867,7 +2914,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<term><varname>TG_TABLE_NAME</varname></term>
<listitem>
<para>
Data type <type>name</type>; the name of the table that
Data type <type>name</type>; the name of the table that
caused the trigger invocation.
</para>
</listitem>
@ -2877,7 +2924,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
<term><varname>TG_TABLE_SCHEMA</varname></term>
<listitem>
<para>
Data type <type>name</type>; the name of the schema of the
Data type <type>name</type>; the name of the schema of the
table that caused the trigger invocation.
</para>
</listitem>
@ -2918,7 +2965,7 @@ RAISE EXCEPTION 'Nonexistent ID --> %', user_id;
trigger manager to skip the rest of the operation for this row
(i.e., subsequent triggers are not fired, and the
<command>INSERT</>/<command>UPDATE</>/<command>DELETE</> does not occur
for this row). If a nonnull
for this row). If a nonnull
value is returned then the operation proceeds with that row value.
Returning a row value different from the original value
of <varname>NEW</> alters the row that will be inserted or updated
@ -2998,8 +3045,8 @@ CREATE TRIGGER emp_stamp BEFORE INSERT OR UPDATE ON emp
<para>
This example trigger ensures that any insert, update or delete of a row
in the <literal>emp</literal> table is recorded (i.e., audited) in the <literal>emp_audit</literal> table.
The current time and user name are stamped into the row, together with
in the <literal>emp</literal> table is recorded (i.e., audited) in the <literal>emp_audit</literal> table.
The current time and user name are stamped into the row, together with
the type of operation performed on it.
</para>
@ -3009,7 +3056,7 @@ CREATE TABLE emp (
salary integer
);
CREATE TABLE emp_audit(
CREATE TABLE emp_audit(
operation char(1) NOT NULL,
stamp timestamp NOT NULL,
userid text NOT NULL,
@ -3045,8 +3092,8 @@ AFTER INSERT OR UPDATE OR DELETE ON emp
<para>
One use of triggers is to maintain a summary table
of another table. The resulting summary can be used in place of the
original table for certain queries &mdash; often with vastly reduced run
of another table. The resulting summary can be used in place of the
original table for certain queries &mdash; often with vastly reduced run
times.
This technique is commonly used in Data Warehousing, where the tables
of measured or observed data (called fact tables) might be extremely large.
@ -3061,7 +3108,7 @@ AFTER INSERT OR UPDATE OR DELETE ON emp
<para>
The schema detailed here is partly based on the <emphasis>Grocery Store
</emphasis> example from <emphasis>The Data Warehouse Toolkit</emphasis>
</emphasis> example from <emphasis>The Data Warehouse Toolkit</emphasis>
by Ralph Kimball.
</para>
@ -3122,7 +3169,7 @@ CREATE OR REPLACE FUNCTION maint_sales_summary_bytime() RETURNS TRIGGER AS $main
ELSIF (TG_OP = 'UPDATE') THEN
-- forbid updates that change the time_key -
-- (probably not too onerous, as DELETE + INSERT is how most
-- (probably not too onerous, as DELETE + INSERT is how most
-- changes will be made).
IF ( OLD.time_key != NEW.time_key) THEN
RAISE EXCEPTION 'Update of time_key : % -&gt; % not allowed', OLD.time_key, NEW.time_key;
@ -3152,15 +3199,15 @@ CREATE OR REPLACE FUNCTION maint_sales_summary_bytime() RETURNS TRIGGER AS $main
amount_cost = amount_cost + delta_amount_cost
WHERE time_key = delta_time_key;
EXIT insert_update WHEN found;
EXIT insert_update WHEN found;
BEGIN
INSERT INTO sales_summary_bytime (
time_key,
amount_sold,
units_sold,
time_key,
amount_sold,
units_sold,
amount_cost)
VALUES (
VALUES (
delta_time_key,
delta_amount_sold,
delta_units_sold,
@ -3357,7 +3404,7 @@ CONTEXT: SQL statement in PL/PgSQL function "logfunc2" near line 5
The <application>PL/pgSQL</> interpreter parses the function's source
text and produces an internal binary instruction tree the first time the
function is called (within each session). The instruction tree
fully translates the
fully translates the
<application>PL/pgSQL</> statement structure, but individual
<acronym>SQL</acronym> expressions and <acronym>SQL</acronym> commands
used in the function are not translated immediately.
@ -3410,7 +3457,7 @@ $$ LANGUAGE plpgsql;
start a new database session so that <function>populate()</function>
will be compiled afresh, before it will work again. You can avoid
this problem by using <command>CREATE OR REPLACE FUNCTION</command>
when updating the definition of
when updating the definition of
<function>my_function</function>, since when a function is
<quote>replaced</quote>, its OID is not changed.
</para>
@ -3527,10 +3574,10 @@ $$ LANGUAGE plpgsql;
</para>
<para>
In the case of <function>logfunc2</function>, the
In the case of <function>logfunc2</function>, the
<productname>PostgreSQL</productname> main parser does not know
what type <literal>'now'</literal> should become and therefore
it returns a data value of type <type>text</type> containing the string
what type <literal>'now'</literal> should become and therefore
it returns a data value of type <type>text</type> containing the string
<literal>now</literal>. During the ensuing assignment
to the local variable <varname>curtime</varname>, the
<application>PL/pgSQL</application> interpreter casts this
@ -3710,11 +3757,11 @@ a_output := a_output || $$ AND name LIKE 'foobar'$$
<xref linkend="plpgsql-porting-ex2">.
For example:
<programlisting>
a_output := a_output || '' if v_'' ||
referrer_keys.kind || '' like ''''''''''
|| referrer_keys.key_string || ''''''''''
then return '''''' || referrer_keys.referrer_type
|| ''''''; end if;'';
a_output := a_output || '' if v_'' ||
referrer_keys.kind || '' like ''''''''''
|| referrer_keys.key_string || ''''''''''
then return '''''' || referrer_keys.referrer_type
|| ''''''; end if;'';
</programlisting>
The value of <literal>a_output</literal> would then be:
<programlisting>
@ -3726,8 +3773,8 @@ if v_... like ''...'' then return ''...''; end if;
<programlisting>
a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
|| referrer_keys.key_string || $$'
then return '$$ || referrer_keys.referrer_type
|| $$'; end if;$$;
then return '$$ || referrer_keys.referrer_type
|| $$'; end if;$$;
</programlisting>
where we assume we only need to put single quote marks into
<literal>a_output</literal>, because it will be re-quoted before use.
@ -3796,14 +3843,6 @@ a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
</para>
</listitem>
<listitem>
<para>
No need for cursors in <application>PL/pgSQL</>, just put the
query in the <literal>FOR</literal> statement. (See <xref
linkend="plpgsql-porting-ex2">.)
</para>
</listitem>
<listitem>
<para>
In <productname>PostgreSQL</> the function body must be written as
@ -3823,7 +3862,7 @@ a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
<listitem>
<para>
Since there are no packages, there are no package-level variables
either. This is somewhat annoying. You can keep per-session state
either. This is somewhat annoying. You can keep per-session state
in temporary tables instead.
</para>
</listitem>
@ -3840,6 +3879,23 @@ a_output := a_output || $$ if v_$$ || referrer_keys.kind || $$ like '$$
</para>
</listitem>
<listitem>
<para>
<command>FOR</> loops over queries (other than cursors) also work
differently: the target variable(s) must have been declared,
whereas <application>PL/SQL</> always declares them implicitly.
An advantage of this is that the variable values are still accessible
after the loop exits.
</para>
</listitem>
<listitem>
<para>
There are various notational differences for the use of cursor
variables.
</para>
</listitem>
</itemizedlist>
</para>
@ -3939,36 +3995,34 @@ $$ LANGUAGE plpgsql;
The following procedure grabs rows from a
<command>SELECT</command> statement and builds a large function
with the results in <literal>IF</literal> statements, for the
sake of efficiency. Notice particularly the differences in the
cursor and the <literal>FOR</literal> loop.
sake of efficiency.
</para>
<para>
This is the Oracle version:
<programlisting>
CREATE OR REPLACE PROCEDURE cs_update_referrer_type_proc IS
CURSOR referrer_keys IS
SELECT * FROM cs_referrer_keys
CURSOR referrer_keys IS
SELECT * FROM cs_referrer_keys
ORDER BY try_order;
func_cmd VARCHAR(4000);
BEGIN
func_cmd VARCHAR(4000);
BEGIN
func_cmd := 'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host IN VARCHAR,
v_domain IN VARCHAR, v_url IN VARCHAR) RETURN VARCHAR IS BEGIN';
v_domain IN VARCHAR, v_url IN VARCHAR) RETURN VARCHAR IS BEGIN';
FOR referrer_key IN referrer_keys LOOP
FOR referrer_key IN referrer_keys LOOP
func_cmd := func_cmd ||
' IF v_' || referrer_key.kind
|| ' LIKE ''' || referrer_key.key_string
|| ''' THEN RETURN ''' || referrer_key.referrer_type
|| '''; END IF;';
END LOOP;
|| '''; END IF;';
END LOOP;
func_cmd := func_cmd || ' RETURN NULL; END;';
func_cmd := func_cmd || ' RETURN NULL; END;';
EXECUTE IMMEDIATE func_cmd;
END;
/
EXECUTE IMMEDIATE func_cmd;
END;
/
show errors;
</programlisting>
</para>
@ -3978,29 +4032,28 @@ show errors;
<programlisting>
CREATE OR REPLACE FUNCTION cs_update_referrer_type_proc() RETURNS void AS $func$
DECLARE
referrer_key RECORD; -- declare a generic record to be used in a FOR
CURSOR referrer_keys IS
SELECT * FROM cs_referrer_keys
ORDER BY try_order;
func_body text;
func_cmd text;
BEGIN
BEGIN
func_body := 'BEGIN';
-- Notice how we scan through the results of a query in a FOR loop
-- using the FOR &lt;record&gt; construct.
FOR referrer_key IN SELECT * FROM cs_referrer_keys ORDER BY try_order LOOP
FOR referrer_key IN referrer_keys LOOP
func_body := func_body ||
' IF v_' || referrer_key.kind
|| ' LIKE ' || quote_literal(referrer_key.key_string)
|| ' THEN RETURN ' || quote_literal(referrer_key.referrer_type)
|| '; END IF;' ;
END LOOP;
END LOOP;
func_body := func_body || ' RETURN NULL; END;';
func_cmd :=
'CREATE OR REPLACE FUNCTION cs_find_referrer_type(v_host varchar,
v_domain varchar,
v_url varchar)
v_url varchar)
RETURNS varchar AS '
|| quote_literal(func_body)
|| ' LANGUAGE plpgsql;' ;
@ -4364,7 +4417,7 @@ $$ LANGUAGE plpgsql STRICT IMMUTABLE;
--
-- instr functions that mimic Oracle's counterpart
-- Syntax: instr(string1, string2, [n], [m]) where [] denotes optional parameters.
--
--
-- Searches string1 beginning at the nth character for the mth occurrence
-- of string2. If n is negative, search backwards. If m is not passed,
-- assume 1 (search starts at first character).