Ask the Expert

How to use SQL's POSITION function with substrings

I have a column in one table which contains data like this:

SE.108.000.034MFJ
SE.108.000.034MFJ-0LNC
SE.108.001.023LIN-1PBA.NNA
SE.108.050.043ERTO-0FTA
SE.045.000.011EMFJ

I would like to extract everything from the left until the "-" character. I have tried (SUBSTR(p1.location,1, INSTR(p1.location,'-')-1)) but the problem is that INSTR returns "0" if no "-" are found, and then the SUBSTR is empty. What other possibilities do I have?

    Requires Free Membership to View

Here's a really simple "trick" you can use: just concatenate a dash onto the end of the column when searching for the position of the first dash.

SELECT SUBSTRING(
          p1.location 
          FROM 1
          FOR POSITION('-' IN p1.location||'-') - 1
                )
  FROM daTable AS p1

In this query, the SUBSTRING and POSITION functions are the standard SQL versions of these functions. These functions behave just as you would expect. Your particular database system may have slightly different names and syntax for these functions, but they will work the same way.

When the column value contains a dash, you get the expected result. For example, consider the value:

SE.108.050.043ERTO-0FTA

This value is 23 characters long, and contains a dash at position 19. When we concatenate the extra dash to the end of this value, it becomes:

SE.108.050.043ERTO-0FTA-

However, the POSITION function will find the first dash at position 19. Then we subtract 1 from this position number, giving 18, and use this as the length of the substring to be extracted:

SE.108.050.043ERTO

Now let's consider the case where the column value contains no dash, such as:

SE.045.000.011EMFJ

This value is 18 characters long. When we concatenate the dash to the end of this value, it becomes:

SE.108.050.043EMFJ-

The POSITION function will find the extra dash which we concatenated to the end, at position 19. Subtracting 1 gives 18, which just happens to be the length of the original column value. So in this case, the SUBSTRING function returns the entire value.

Neat, eh?

This was first published in January 2009

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to: