Discussions
Categories
- 196.7K All Categories
- 2.2K Data
- 234 Big Data Appliance
- 1.9K Data Science
- 449.8K Databases
- 221.5K General Database Discussions
- 3.8K Java and JavaScript in the Database
- 31 Multilingual Engine
- 549 MySQL Community Space
- 477 NoSQL Database
- 7.9K Oracle Database Express Edition (XE)
- 3K ORDS, SODA & JSON in the Database
- 532 SQLcl
- 4K SQL Developer Data Modeler
- 186.8K SQL & PL/SQL
- 21.2K SQL Developer
- 295.3K Development
- 17 Developer Projects
- 138 Programming Languages
- 292K Development Tools
- 104 DevOps
- 3.1K QA/Testing
- 645.9K Java
- 27 Java Learning Subscription
- 37K Database Connectivity
- 153 Java Community Process
- 105 Java 25
- 22.1K Java APIs
- 138.1K Java Development Tools
- 165.3K Java EE (Java Enterprise Edition)
- 17 Java Essentials
- 157 Java 8 Questions
- 85.9K Java Programming
- 79 Java Puzzle Ball
- 65.1K New To Java
- 1.7K Training / Learning / Certification
- 13.8K Java HotSpot Virtual Machine
- 94.2K Java SE
- 13.8K Java Security
- 203 Java User Groups
- 24 JavaScript - Nashorn
- Programs
- 389 LiveLabs
- 37 Workshops
- 10.2K Software
- 6.7K Berkeley DB Family
- 3.5K JHeadstart
- 5.6K Other Languages
- 2.3K Chinese
- 170 Deutsche Oracle Community
- 1K Español
- 1.9K Japanese
- 230 Portuguese
processing string with REGEXP_LIKE

Hi,
i am forced to ask a question related to this api i tried a couple of formats but dont seem to work.
question: iam getting various strings but i want to return only if the patter is like
starting with "KEN" then 2 digits then 4 letters,
examples: "KEN07YURW" ; "KEN14HSRW" ; "KEN20TWRQ" etc
SELECT ...FROM SUPPLIERS WHERE REGEXP_LIKE (NAME, '^KEN[:digit:]{2}[A-Z]{4}$');
any suggestion is appreciated.
thanks.
Best Answer
-
Hi, @Gor_Mahia
SELECT ...FROM SUPPLIERS WHERE REGEXP_LIKE (NAME, '^KEN[:digit:]{2}[A-Z]{4}$');
You're very close! Classifiers like [:digit:] only work within another set of square brackets. Try
WHERE REGEXP_LIKE (NAME, '^KEN[[:digit:]]{2}[A-Z]{4}$');
I assume the 4 letters at the end of the pattern must be upper case, and that name must end immediately after those four letters.
I hope this answers your question. If not, post a little sample data (CREATE TABLE and INSERT statements) and the exact results you want from that data. Point out where the expression above is not doing what you want, and explain, in different words, what you're looking for.
Answers
-
Hi, @Gor_Mahia
SELECT ...FROM SUPPLIERS WHERE REGEXP_LIKE (NAME, '^KEN[:digit:]{2}[A-Z]{4}$');
You're very close! Classifiers like [:digit:] only work within another set of square brackets. Try
WHERE REGEXP_LIKE (NAME, '^KEN[[:digit:]]{2}[A-Z]{4}$');
I assume the 4 letters at the end of the pattern must be upper case, and that name must end immediately after those four letters.
I hope this answers your question. If not, post a little sample data (CREATE TABLE and INSERT statements) and the exact results you want from that data. Point out where the expression above is not doing what you want, and explain, in different words, what you're looking for.
-
Hi,
If performance is very important, then try not to use regular expressions. You can do what you requested using less powerful functions like this:
WHERE SUBSTR (name, 1, 3) = 'KEN' AND TRANSLATE ( SUBSTR (name, 4) , '012345678ABCDEFGHIJKLMNOPQRSTUVWXY' , '999999999ZZZZZZZZZZZZZZZZZZZZZZZZZ ) = '999ZZZZ'
If you'd care to post some sample data, then I could test it.
-
In your regular expression, please be aware that the meaning of
[A-Z]
depends on the session's language characteristics (specifically, thenls_sort
parameter). For example, ifnls_sort='French'
, then lower-case letters from a to y (but not z!) are "between A and Z", because in French the order is A, a, B, b, C, c, ... , Z, z, unlike English where it is A, B, C, ..., Z, a, b, c, ... , z. The meaning of "ranges" in a regular expression is determined by the current collating sequence, as encoded innls_sort
.For this reason, especially if you work in a "global" environment (or a "local" but not English-centric one), it is safer to use the
[:upper:]
character class (wrapped within another pair of brackets, like Mr. Kulash pointed out for the other character class in your query).