Re: Excluding values with numbers

From: Charles Hooper <hooperc2000_at_yahoo.com>
Date: Wed, 30 Dec 2009 05:31:11 -0800 (PST)
Message-ID: <92f72abb-3a28-4f40-822c-431b928acf2b_at_o28g2000yqh.googlegroups.com>



On Dec 29, 11:54 am, Pankaj <harpreet.n..._at_gmail.com> wrote:
> Greetings,
>
> I am currently using Oracle9i Enterprise Edition Release 9.2.0.4.0. I
> have a table with following data
>
> Table 1 (Sample data)
> a12345
> A123423
> g13452
> G452323
> h34423
> r34323
> b23232
> n232323
>
> I am currently using this as a subquery in one of the query. As per a
> new request I have to now exclude all values which start with h, b or
> n followed by numeric values.
>
> So end result the subquery should give me is
>
> Table 1 (Sample data)
> a12345
> A123423
> g13452
> G452323
> r34323
>
> I am little stumped on this for now. Could not get it right in my
> query. Can anyone please advise here. Let me know if any more
> information is needed from my side.
>
> Note: The starting character in all values can sometimes in "lower
> case" or sometimes in "upper case".
>
> TIA
I agree with Joel's comments. Let's see if there is a hard way to do this.

CREATE TABLE T10(HOMEWORK VARCHAR2(20));

INSERT INTO T10 VALUES ('a12345');
INSERT INTO T10 VALUES ('A123423');
INSERT INTO T10 VALUES ('g13452');
INSERT INTO T10 VALUES ('G452323');
INSERT INTO T10 VALUES ('h34423');
INSERT INTO T10 VALUES ('r34323');
INSERT INTO T10 VALUES ('b23232');
INSERT INTO T10 VALUES ('n232323');
INSERT INTO T10 VALUES ('NB151517');
INSERT INTO T10 VALUES ('C0151517');
INSERT INTO T10 VALUES ('f9151517');
INSERT INTO T10 VALUES ('HE4423');

COMMIT; Note that I added a couple of extra rows just for fun.

Let's look at the ASCII values of the first and second characters: SELECT
  HOMEWORK,
  ASCII(SUBSTR(HOMEWORK,1,1)) ASC_VAL1,
  ASCII(SUBSTR(HOMEWORK,2,1)) ASC_VAL2
FROM
  T10;

HOMEWORK ASC_VAL1 ASC_VAL2
---------- ---------- ----------

a12345             97         49
A123423            65         49
g13452            103         49
G452323            71         52
h34423            104         51
r34323            114         51
b23232             98         50
n232323           110         50
NB151517           78         66
C0151517           67         48
f9151517          102         57
HE4423             72         69

OK, I see the ones that we want to exclude, let's build a matrix: SELECT
  HOMEWORK,

  ASCII(SUBSTR(HOMEWORK,1,1)) ASC_VAL1,
  ASCII(SUBSTR(HOMEWORK,2,1)) ASC_VAL2,
  DECODE(ASCII(SUBSTR(HOMEWORK,1,1)),

104,1,72,1,66,1,98,1,78,1,110,1,0) IS_EXC1,   DECODE(SIGN(ASCII(SUBSTR(HOMEWORK,2,1))-47),1,DECODE(SIGN(ASCII (SUBSTR(HOMEWORK,2,1))-58),-1,1,0),0) IS_EXC2 FROM
  T10;

HOMEWORK ASC_VAL1 ASC_VAL2 IS_EXC1 IS_EXC2 ---------- ---------- ---------- ---------- ----------

a12345             97         49          0          1
A123423            65         49          0          1
g13452            103         49          0          1
G452323            71         52          0          1
h34423            104         51          1          1
r34323            114         51          0          1
b23232             98         50          1          1
n232323           110         50          1          1
NB151517           78         66          1          0
C0151517           67         48          0          1
f9151517          102         57          0          1
HE4423             72         69          1          0

If there is a 1 in both of the right-most columns, then the row should be eliminated. What is the easiest way to tell if there is a 1 in both columns? Multiply the column values together, and if we receive a product of 1 then the row should be excluded: SELECT
  *
FROM
  (SELECT
    HOMEWORK,

    ASCII(SUBSTR(HOMEWORK,1,1)) ASC_VAL1,
    ASCII(SUBSTR(HOMEWORK,2,1)) ASC_VAL2,
    DECODE(ASCII(SUBSTR(HOMEWORK,1,1)),

104,1,72,1,66,1,98,1,78,1,110,1,0) IS_EXC1,     DECODE(SIGN(ASCII(SUBSTR(HOMEWORK,2,1))-47),1,DECODE(SIGN(ASCII (SUBSTR(HOMEWORK,2,1))-58),-1,1,0),0) IS_EXC2   FROM
    T10)
WHERE
  IS_EXC1*IS_EXC2<>1;

HOMEWORK ASC_VAL1 ASC_VAL2 IS_EXC1 IS_EXC2 ---------- ---------- ---------- ---------- ----------

a12345             97         49          0          1
A123423            65         49          0          1
g13452            103         49          0          1
G452323            71         52          0          1
r34323            114         51          0          1
NB151517           78         66          1          0
C0151517           67         48          0          1
f9151517          102         57          0          1
HE4423             72         69          1          0


Something tells me you want to do it the easy way. See if you can do anything with these functions:
REGEXP_INSTR
http://download.oracle.com/docs/cd/B19306_01/server.102/b14200/functions129.htm

REGEXP_SUBSTR
http://download.oracle.com/docs/cd/B19306_01/server.102/b14200/functions131.htm

*Always* post the DDL and DML to re-create your problem, and show us what you have tried previously.

Charles Hooper
Co-author of "Expert Oracle Practices: Oracle Database Administration from the Oak Table"
http://hoopercharles.wordpress.com/
IT Manager/Oracle DBA
K&M Machine-Fabricating, Inc. Received on Wed Dec 30 2009 - 07:31:11 CST

Original text of this message