Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

regexp_instr tips

Oracle Database Tips by Donald BurlesonMay 25, 2016

Question: What does the regexp_instr operator do?  Can you show an example of using regexp_instr?

Answer:  The regexp_instr operator shows matching patterns within a string.

The regexp_instr function is a very powerful to extract patterns from inside a string.  Let's take a closer look at the prototype for the regexp_instr function:

regexp_instr (
   string,
   pattern,
   position,
   occurrence,
   return-option,
   parameters)

The last argument is the most important.  The "parameters" argument can be a combination of these formats:

i - Used to introduce case-insensitively
c - Keeps case (default value)
n - to make the dot (.) match new lines as well
m - to make ^ and $ match beginning and end of a line in a multi-line string

The "i" parameter is used to force case-insensitive parsing.  Just like the common UNIX "grep –i" command, we can use the lowercase "i" to extract both "Acre" and "acres".  The lowercase 'i" is also the last argument to the regexp_like function.

Oracle 10g introduced regular expression functions in SQL with the functions REGEXP_SUBSTR, REGEXP_REPLACE, REGEXP_INSTR and REGEXP_LIKE.

SELECT
   ENAME,
   REGEXP_SUBSTR(ENAME,'DAM') SUBSTR,
   REGEXP_INSTR(ENAME, 'T') INSTR,
   REGEXP_REPLACE(ENAME,'AM','@') REPLACE,
   REGEXP_COUNT(ENAME, 'A') COUNT
FROM
   EMP
WHERE
   REGEXP_LIKE(ENAME,'S');

ENAME      SUBSTR          INSTR REPLACE         COUNT
---------- ---------- ---------- ---------- ----------
SMITH                          4 SMITH               0
JONES                          0 JONES               0
SCOTT                          4 SCOTT               0

ADAMS      DAM                 0 AD@S                2
JAMES                          0 J@ES                1

REGEXP_SUBSTR returns the substring DAM if found, REGEXP_INSTR returns the position of the first 'T', REGEXP_REPLACE replaces the strings 'AM' with  '@' and REGEXP_COUNT counts the occurrences of 'A'. REGEXP_LIKE returns the strings that contain the pattern 'S'.

SELECT
   REGEXP_SUBSTR('Programming','[[:alpha:]]+',1,2)
FROM
   DUAL;

REGEXP
------
Oracle

 

This function is an advanced extension of the already existing INSTR function, which returns the location of the expression pattern in the source string.

 

The prototype of the REGEXP_INSTR function is shown below,

 

REGEXP_INSTR(<Source_string>, <Search_pattern>[, <Start_position>[, <Match_occurrence>[, <Return_option>[, <Match_modifier>]]]])

 

·         Source_string: The string to be searched for.

 

·         Search_pattern: The regular expression pattern that is to be searched for in the source string. This can be a combination of the POSIX and the Perl-influenced metacharacters mentioned in the above section.

 

·         Start_position: This is an optional parameter. This determines the position in the source string where the search starts. By default, it is 1, which is the starting position of the source string.

 

·         Match_occurrence: This is an optional parameter. This determines the appearance of the search pattern. By default, it is 1, which is the first appearance of the search pattern in the string.

 

·         Return_option: This is an optional parameter. By default, it is 0.

 

è If 0, the position of the first occurrence is returned.

 

è If 1, the position of the character after the first occurrence is returned.

 

·         Match_modifiers: This is an optional parameter. This parameter allows us to modify, the matching behavior of the function. The valid range of options is mentioned in the Pattern Matching Modifiers section explained above.

 

Text Position Search

The basic operation, which can be done using this function is to find the position of a character or a series of characters in the source string as shown below. The below statement returns the position of the first occurrence of the string INSTR in the source string with the return option as 0.

 

SELECT REGEXP_INSTR ('REGEXP_INSTR is an advanced extension of the INSTR function', 'INSTR', 1, 1, 0, 'i') regexp_instr

FROM dual;

 

Result:

8

 

When the return option is changed to 1, the function returns the position of the character after INSTR, that is, the position of the space is returned in the below example,

 

SELECT REGEXP_INSTR ('REGEXP_INSTR is an advanced extension of the INSTR function', 'INSTR', 1, 1, 1, 'i') regexp_instr

FROM dual;

 

Result:

13

Digit Position Search

The below statement, searches for the position of numeric digits present in the source string using the Perl influenced metacharacter \d. This function returns the position of the first digit in the source string, i.e., the position of the digit 1 is returned in the below example.

 

SELECT REGEXP_INSTR ('REGEXP_INSTR is introduced in the Oracle version 10g', '\d', 1) regexp_instr

FROM dual;

 

Result:

50

Vowels Position Search

The below listing searches and returns the position of the first vowel in the source string with case sensitivity check turned OFF manually using the match modifier set to i.

 

SELECT REGEXP_INSTR ('REGEXP_INSTR is an advanced extension of the INSTR function', '[aeiou]', 1, 1, 0, 'i') regexp_instr

FROM dual;

 

Result:

2

DOT Count

The position of the second occurring DOT character in the source string can be found using the below query statement. The search pattern “\.” searches for the literal DOT in the source string. As DOT is a metacharacter, it is escaped using the escape operator backslash.

 

SELECT REGEXP_INSTR ('REGEXP_INSTR.is.an.advanced.extension.of.the.INSTR.function', '\.', 1, 2, 0, 'i') regexp_instr

FROM dual;

 

Result:

16


 

 


   
Oracle Training from Don Burleson 

The best on site "Oracle training classes" are just a phone call away! You can get personalized Oracle training by Donald Burleson, right at your shop!

Oracle training
 
 


  Oracle consulting and training

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster