How to replace a part of string in char or varchar column?
If you use Firebird 2.1 or above, you can use built-in REPLACE function:
update t1 set c1 = replace(c1, 'old_str', 'new_str');
More info can be found in Firebird manual:
http://www.firebirdsql.org/refdocs/langrefupd21-intfunc-replace.html
If you are using older version of Firebird, you can combine STRPOS and SUBSTRING function and concatenate parts before and after the search string. Here's how the statement might look like:
update t1 set c1 =
CASE when strpos('old_str', c1) = 0 then c1
ELSE
substring(c1 from 1 for strpos('old_str', c1) - 1)
||'new_str'
||substring(c1 from strpos('old_str', c1)+char_length('new_str'))
END
Note that CHAR_LENGTH is available since Firebird 2.0. If you use earlier versions, try using STRLEN UDF instead.
Another useful function for string replacement is OVERLAY, also introduced in version 2.1. It also replaces the characters, main difference being replacing by position (and optionally length) instead of string-to-string replacement. The syntax is:
OVERLAY (string PLACING replacement-string FROM position [FOR length])
If replacement string would stretch over the end of the original string, the result would be extended. For example:
OVERLAY ('abc' PLACING 'de' FROM 3)
would result in string 'abde'.
The Length parameter is optional and used to limit the number of characters taken from replacement-string.