Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations IamaSherpa on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

I need the equivalence of the STUFF Command from SQL Server 2000

Status
Not open for further replies.

LeonelSanchezJr

Programmer
Jan 26, 2001
522
US
My code is the following

SET DESTFN = STUFF(DESTNAME,CHARINDEX('200',DESTFN),8,@DATE)


Thanks,

Leo ;-)
 
Leo,

I'm certain that we can create a fine solution for you, but since some of us helpers are not proficient with SQL Server functions, could you please give us a non-syntactical, plain-English functional narrative of what you want the above STUFF function to do?


[santa]Mufasa
(aka Dave of Sandy, Utah, USA)
[I provide low-cost, remote Database Administration services: www.dasages.com]
 
Deletes a specified length of characters and inserts another set of characters at a specified starting point.

Syntax

STUFF ( character_expression , start , length ,character_expression )

Arguments
character_expression
Is an expression of character data. character_expression can be a constant, variable, or column of either character or binary data.

start
Is an integer value that specifies the location to start deletion and insertion. If start or length is negative, a null string is returned. If start is longer than the first character_expression, a null string is returned. start can be of type bigint.

length
Is an integer that specifies the number of characters to delete. If length is longer than the first character_expression, deletion occurs up to the last character in the last character_expression. length can be of type bigint.

Return Types
Returns character data if character_expression is one of the supported character data types. Returns binary data if character_expression is one of the supported binary data types.

Remarks
An error is raised if the resulting value is larger than the maximum supported by the return type.

Examples
The following example returns a character string created by deleting three characters from the first string, abcdef, starting at position 2, at b, and inserting the second string at the deletion point.
Code:
SELECT STUFF('abcdef', 2, 3, 'ijklmn')
GO
Here is the result set.
Code:
 Copy Code 
--------- 
aijklmnef 

(1 row(s) affected)
 
Hi Mufasa,

Grega is correct.
What I need is the following:
I have values in fields that look like this.

abc20070401pdfreport.pdf
somemore20070401pdfreport.pdf
andsomelonger20070401xlrpt.pdf
someshorter20070401.pdf
xyz20070401somelonger.pdf


What I need is to find the occurrence of "200"
and replace from that point forward 8 characters with
the current date as such:

abc20070417pdfreport.pdf
somemore20070417pdfreport.pdf
andsomelonger20070417xlrpt.pdf
someshorter20070417.pdf
xyz20070417somelonger.pdf


Thanks,

Leo ;-)
 
Thanks, both Leo and Greg, for the confirmation.

Following, then, is your very own, user-defined STUFF command for Oracle that meets the behavioural specifications of your SQL Server STUFF function:
Code:
create or replace function stuff
    (str_in varchar2, beg number, len number, str_new varchar2)
    return varchar2
is
begin
    return substr(str_in,1,beg-1)||str_new||substr(str_in,beg+len);
end;
/

Function created.
Following is the sample data you posted, in a table named "LEO":
Code:
SQL> select * from leo;

TXT
------------------------------
abc20070401pdfreport.pdf
somemore20070401pdfreport.pdf
andsomelonger20070401xlrpt.pdf
someshorter20070401.pdf
xyz20070401somelonger.pdf
Finally, here is the Oracle SQL equivalent of your original need, using the STUFF function:
Code:
col result format a30
select stuff(txt,instr(txt,'200'),8,to_char(sysdate,'yyyymmdd')) result from leo;

RESULT
------------------------------
abc20070417pdfreport.pdf
somemore20070417pdfreport.pdf
andsomelonger20070417xlrpt.pdf
someshorter20070417.pdf
xyz20070417somelonger.pdf
************************************************************************
Let us know if this meets your need(s).

[santa]Mufasa
(aka Dave of Sandy, Utah, USA)
[I provide low-cost, remote Database Administration services: www.dasages.com]
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top