Search All Fields In All Tables For A Specific Value (Oracle)
Asked Answered
C

18

146

Is it possible to search every field of every table for a particular value in Oracle?

There are hundreds of tables with thousands of rows in some tables so I know this could take a very long time to query. But the only thing I know is that a value for the field I would like to query against is 1/22/2008P09RR8. <

I've tried using this statement below to find an appropriate column based on what I think it should be named but it returned no results.

SELECT * from dba_objects 
WHERE object_name like '%DTN%'

There is absolutely no documentation on this database and I have no idea where this field is being pulled from.

Any thoughts?

Coreen answered 16/10, 2008 at 13:14 Comment(6)
Can we do this using a single query instead of using a stored procedure?Kissable
Yes, it is possible to do it in pure SQL. See SQL to Search for a VALUE in all COLUMNS of all TABLES in an entire SCHEMAExodontist
@LalitKumarB The page you listed is no longer accessible. Would it be possible to post some information as an answer?Apospory
@DodziDzakuma The page is accessible lalitkumarb.wordpress.com/2015/01/06/… Also I have posted an answer, please scroll down or see https://mcmap.net/q/144956/-search-all-fields-in-all-tables-for-a-specific-value-oracleExodontist
If you're having trouble figuring out Lalit Kumar query, try this demo: sqlfiddle.com/#!4/76924c/2/0Cerebro
Yeah, I know its 12 years later. Toad has a search feature for this.Hunfredo
F
118

Quote:

I've tried using this statement below to find an appropriate column based on what I think it should be named but it returned no results.*

SELECT * from dba_objects WHERE
object_name like '%DTN%'

A column isn't an object. If you mean that you expect the column name to be like '%DTN%', the query you want is:

SELECT owner, table_name, column_name FROM all_tab_columns WHERE column_name LIKE '%DTN%';

But if the 'DTN' string is just a guess on your part, that probably won't help.

By the way, how certain are you that '1/22/2008P09RR8' is a value selected directly from a single column? If you don't know at all where it is coming from, it could be a concatenation of several columns, or the result of some function, or a value sitting in a nested table object. So you might be on a wild goose chase trying to check every column for that value. Can you not start with whatever client application is displaying this value and try to figure out what query it is using to obtain it?

Anyway, diciu's answer gives one method of generating SQL queries to check every column of every table for the value. You can also do similar stuff entirely in one SQL session using a PL/SQL block and dynamic SQL. Here's some hastily-written code for that:

    SET SERVEROUTPUT ON SIZE 100000

    DECLARE
      match_count INTEGER;
    BEGIN
      FOR t IN (SELECT owner, table_name, column_name
                  FROM all_tab_columns
                  WHERE owner <> 'SYS' and data_type LIKE '%CHAR%') LOOP

        EXECUTE IMMEDIATE
          'SELECT COUNT(*) FROM ' || t.owner || '.' || t.table_name ||
          ' WHERE '||t.column_name||' = :1'
          INTO match_count
          USING '1/22/2008P09RR8';

        IF match_count > 0 THEN
          dbms_output.put_line( t.table_name ||' '||t.column_name||' '||match_count );
        END IF;

      END LOOP;

    END;
    /

There are some ways you could make it more efficient too.

In this case, given the value you are looking for, you can clearly eliminate any column that is of NUMBER or DATE type, which would reduce the number of queries. Maybe even restrict it to columns where type is like '%CHAR%'.

Instead of one query per column, you could build one query per table like this:

SELECT * FROM table1
  WHERE column1 = 'value'
     OR column2 = 'value'
     OR column3 = 'value'
     ...
     ;
Faliscan answered 16/10, 2008 at 14:54 Comment(14)
You should restrict it to char, varchar and varchar2 columns, since number and date columns cannot possibly contain that string.Ine
@ammoQ -- like I said in the second-to-last paragraph?Faliscan
I ran this on 9i and I get column_name unknown error. Can someone tell me what modification will be required to run this on 9i?Mansur
@Mansur -- sorry, that was actually a mistake in my code, not a version issue. The loop should have been driven by all_tab_columns not all_tables. I've fixed it.Faliscan
@DaveCosta - Thanks for the fix but I still get 'table or view does not exist' error on line 6. Line 6 being "Execute Immediate".Mansur
@Mansur - Made a couple more enhancements. Take owner into account, which is probably the cause of your current error. I also filtered out everything owned by SYS for performance, and restricted to character data types to avoid numeric comparison errors.Faliscan
Can we do this using a single query instead of using a stored procedure?Kissable
@Kissable - technically the above is not a stored procedure, it's an anonymous block. But I take it you would prefer a single SQL query. I can't think of a way to do that for any non-trivial set of tables; since the table and column names will vary, you need to use dynamic SQL. However, if you used my code as the basis for a pipelined function, you could then select from that function as a row source, so you would be able to get the results as the output of a query.Faliscan
The same could be done in SQL using xmlsequence. And dbms_output should be avoided in production systems.Exodontist
@DaveCosta how can I perform a like search in the same sql?Drolet
@SoumitriPattnaik you'd probably change = to LIKE in the dynamic SQL statement.Faliscan
I am getting the error 00904 - "Name" : invalid identifier with both solutions Lalit Kumar and @DaveCosta due to the database design. Where should I add the clause to overcome it?Buddhi
@Buddhi Sounds like you might have a mixed-case column name. If so, you need to modify the dynamic SQL statements to put double quotes around the column name.Faliscan
Doesn't work with VARCHAR2(255 CHAR) datatype.Hydrolyse
T
41

I did some modification to the above code to make it work faster if you are searching in only one owner. You just have to change the 3 variables v_owner, v_data_type and v_search_string to fit what you are searching for.

SET SERVEROUTPUT ON SIZE 100000

DECLARE
  match_count INTEGER;
-- Type the owner of the tables you are looking at
  v_owner VARCHAR2(255) :='ENTER_USERNAME_HERE';

-- Type the data type you are look at (in CAPITAL)
-- VARCHAR2, NUMBER, etc.
  v_data_type VARCHAR2(255) :='VARCHAR2';

-- Type the string you are looking at
  v_search_string VARCHAR2(4000) :='string to search here...';

BEGIN
  FOR t IN (SELECT table_name, column_name FROM all_tab_cols where owner=v_owner and data_type = v_data_type) LOOP

    EXECUTE IMMEDIATE 
    'SELECT COUNT(*) FROM '||t.table_name||' WHERE '||t.column_name||' = :1'
    INTO match_count
    USING v_search_string;

    IF match_count > 0 THEN
      dbms_output.put_line( t.table_name ||' '||t.column_name||' '||match_count );
    END IF;

  END LOOP;
END;
/
Tieshatieup answered 25/2, 2011 at 6:55 Comment(6)
I had to comment the first line in order to be able to run this query. Also I was not able to remove the owner filter and run the query.Kevon
I needed to put double quotes around the table name / column name to avoid issues when these need to be quoted: 'SELECT COUNT(*) FROM "'||t.table_name||'" WHERE "'||t.column_name||'" = :1'Rhythm
Watch out that all_tab_cols also contains views, despite the nameCroatian
what exactly is dbms_output? Because the queries get executed successfully in DataGrip, but I do not see any result after.Shortfall
I know this is a bit old, but when I run this I just get a Script Output of "anonymous block completed"Horrible
As of this year 2022, this should be the answer marked. :-) thanks and this works like charm! on Oracle 10g, 19c.Maxi
E
10

I know this is an old topic. But I see a comment to the question asking if it could be done in SQL rather than using PL/SQL. So thought to post a solution.

The below demonstration is to Search for a VALUE in all COLUMNS of all TABLES in an entire SCHEMA:

  • Search a CHARACTER type

Let's look for the value KING in SCOTT schema.

SQL> variable val varchar2(10)
SQL> exec :val := 'KING'

PL/SQL procedure successfully completed.

SQL> SELECT DISTINCT SUBSTR (:val, 1, 11) "Searchword",
  2    SUBSTR (table_name, 1, 14) "Table",
  3    SUBSTR (column_name, 1, 14) "Column"
  4  FROM cols,
  5    TABLE (xmlsequence (dbms_xmlgen.getxmltype ('select '
  6    || column_name
  7    || ' from '
  8    || table_name
  9    || ' where upper('
 10    || column_name
 11    || ') like upper(''%'
 12    || :val
 13    || '%'')' ).extract ('ROWSET/ROW/*') ) ) t
 14  ORDER BY "Table"
 15  /

Searchword  Table          Column
----------- -------------- --------------
KING        EMP            ENAME

SQL>
  • Search a NUMERIC type

Let's look for the value 20 in SCOTT schema.

SQL> variable val NUMBER
SQL> exec :val := 20

PL/SQL procedure successfully completed.

SQL> SELECT DISTINCT SUBSTR (:val, 1, 11) "Searchword",
  2    SUBSTR (table_name, 1, 14) "Table",
  3    SUBSTR (column_name, 1, 14) "Column"
  4  FROM cols,
  5    TABLE (xmlsequence (dbms_xmlgen.getxmltype ('select '
  6    || column_name
  7    || ' from '
  8    || table_name
  9    || ' where upper('
 10    || column_name
 11    || ') like upper(''%'
 12    || :val
 13    || '%'')' ).extract ('ROWSET/ROW/*') ) ) t
 14  ORDER BY "Table"
 15  /

Searchword  Table          Column
----------- -------------- --------------
20          DEPT           DEPTNO
20          EMP            DEPTNO
20          EMP            HIREDATE
20          SALGRADE       HISAL
20          SALGRADE       LOSAL

SQL>
Exodontist answered 6/1, 2015 at 7:38 Comment(3)
hrmm.... using xml looks like overkill. Besides: Error occurred in XML processing ORA-00932: inconsistent datatypes: expected NUMBER got BLOBStallings
ORA-19202: Error occurred in XML processing ORA-00932: inconsistent datatypes: expected CHAR got BLOB ORA-06512: at "SYS.DBMS_XMLGEN", line 288 ORA-06512: at line 1 19202. 00000 - "Error occurred in XML processing%s" *Cause: An error occurred when processing the XML function *Action: Check the given error message and fix the appropriate problemQuinquevalent
Any Ideas? ORA-19202: Error occurred in XML processing ORA-22813: operand value exceeds system limits ORA-06512: at "SYS.DBMS_XMLGEN", line 288 ORA-06512: at line 1Lacey
H
9

Here is another modified version that will compare a lower substring match. This works in Oracle 11g.

DECLARE
  match_count INTEGER;
-- Type the owner of the tables you are looking at
  v_owner VARCHAR2(255) :='OWNER_NAME';

-- Type the data type you are look at (in CAPITAL)
-- VARCHAR2, NUMBER, etc.
  v_data_type VARCHAR2(255) :='VARCHAR2';

-- Type the string you are looking at
  v_search_string VARCHAR2(4000) :='%lower-search-sub-string%';

BEGIN
  FOR t IN (SELECT table_name, column_name FROM all_tab_cols where owner=v_owner and data_type = v_data_type) LOOP

    EXECUTE IMMEDIATE 
    'SELECT COUNT(*) FROM '||t.table_name||' WHERE lower('||t.column_name||') like :1'
    INTO match_count
    USING v_search_string;

    IF match_count > 0 THEN
      dbms_output.put_line( t.table_name ||' '||t.column_name||' '||match_count );
    END IF;

  END LOOP;
END;
/
Hampstead answered 22/9, 2011 at 14:25 Comment(0)
D
8

Yes you can and your DBA will hate you and will find you to nail your shoes to the floor because that will cause lots of I/O and bring the database performance really down as the cache purges.

select column_name from all_tab_columns c, user_all_tables u where c.table_name = u.table_name;

for a start.

I would start with the running queries, using the v$session and the v$sqlarea. This changes based on oracle version. This will narrow down the space and not hit everything.

Detergency answered 16/10, 2008 at 13:27 Comment(0)
T
8

I was having following issues for @Lalit Kumars answer,

ORA-19202: Error occurred in XML processing
ORA-00904: "SUCCESS": invalid identifier
ORA-06512: at "SYS.DBMS_XMLGEN", line 288
ORA-06512: at line 1
19202. 00000 -  "Error occurred in XML processing%s"
*Cause:    An error occurred when processing the XML function
*Action:   Check the given error message and fix the appropriate problem

Solution is:

WITH  char_cols AS
  (SELECT /*+materialize */ table_name, column_name
   FROM   cols
   WHERE  data_type IN ('CHAR', 'VARCHAR2'))
SELECT DISTINCT SUBSTR (:val, 1, 11) "Searchword",
       SUBSTR (table_name, 1, 14) "Table",
       SUBSTR (column_name, 1, 14) "Column"
FROM   char_cols,
       TABLE (xmlsequence (dbms_xmlgen.getxmltype ('select "'
       || column_name
       || '" from "'
       || table_name
       || '" where upper("'
       || column_name
       || '") like upper(''%'
       || :val
       || '%'')' ).extract ('ROWSET/ROW/*') ) ) t
ORDER  BY "Table"
/ 
Togliatti answered 27/11, 2017 at 20:0 Comment(0)
D
7

I modified Flood's script to execute once for each table rather than for every column of each table for faster execution. It requires Oracle 11g or greater.

    set serveroutput on size 100000

declare
    v_match_count integer;
    v_counter integer;

    -- The owner of the tables to search through (case-sensitive)
    v_owner varchar2(255) := 'OWNER_NAME';
    -- A string that is part of the data type(s) of the columns to search through (case-insensitive)
    v_data_type varchar2(255) := 'CHAR';
    -- The string to be searched for (case-insensitive)
    v_search_string varchar2(4000) := 'FIND_ME';

    -- Store the SQL to execute for each table in a CLOB to get around the 32767 byte max size for a VARCHAR2 in PL/SQL
    v_sql clob := '';
begin
    for cur_tables in (select owner, table_name from all_tables where owner = v_owner and table_name in 
                       (select table_name from all_tab_columns where owner = all_tables.owner and data_type like '%' ||  upper(v_data_type) || '%')
                       order by table_name) loop
        v_counter := 0;
        v_sql := '';

        for cur_columns in (select column_name from all_tab_columns where 
                            owner = v_owner and table_name = cur_tables.table_name and data_type like '%' || upper(v_data_type) || '%') loop
            if v_counter > 0 then
                v_sql := v_sql || ' or ';
            end if;
            v_sql := v_sql || 'upper(' || cur_columns.column_name || ') like ''%' || upper(v_search_string) || '%''';
            v_counter := v_counter + 1;
        end loop;

        v_sql := 'select count(*) from ' || cur_tables.table_name || ' where ' || v_sql;

        execute immediate v_sql
        into v_match_count;

        if v_match_count > 0 then
            dbms_output.put_line('Match in ' || cur_tables.owner || ': ' || cur_tables.table_name || ' - ' || v_match_count || ' records');
        end if;
    end loop;

    exception
        when others then
            dbms_output.put_line('Error when executing the following: ' || dbms_lob.substr(v_sql, 32600));
end;
/
Darton answered 8/3, 2012 at 7:4 Comment(0)
A
5

I would do something like this (generates all the selects you need). You can later on feed them to sqlplus:

echo "select table_name from user_tables;" | sqlplus -S user/pwd | grep -v "^--" | grep -v "TABLE_NAME" | grep "^[A-Z]" | while read sw;
do echo "desc $sw" | sqlplus -S user/pwd | grep -v "\-\-\-\-\-\-" | awk -F' ' '{print $1}' | while read nw;
do echo "select * from $sw where $nw='val'";
done;
done;

It yields:

select * from TBL1 where DESCRIPTION='val'
select * from TBL1 where ='val'
select * from TBL2 where Name='val'
select * from TBL2 where LNG_ID='val'

And what it does is - for each table_name from user_tables get each field (from desc) and create a select * from table where field equals 'val'.

Ayn answered 16/10, 2008 at 13:48 Comment(0)
E
5

if we know the table and colum names but want to find out the number of times string is appearing for each schema:

Declare

owner VARCHAR2(1000);
tbl VARCHAR2(1000);
cnt number;
ct number;
str_sql varchar2(1000);
reason varchar2(1000);
x varchar2(1000):='%string_to_be_searched%';

cursor csr is select owner,table_name 
from all_tables where table_name ='table_name';

type rec1 is record (
ct VARCHAR2(1000));

type rec is record (
owner VARCHAR2(1000):='',
table_name VARCHAR2(1000):='');

rec2 rec;
rec3 rec1;
begin

for rec2 in csr loop

--str_sql:= 'select count(*) from '||rec.owner||'.'||rec.table_name||' where CTV_REMARKS like '||chr(39)||x||chr(39);
--dbms_output.put_line(str_sql);
--execute immediate str_sql

execute immediate 'select count(*) from '||rec2.owner||'.'||rec2.table_name||' where column_name like '||chr(39)||x||chr(39)
into rec3;
if rec3.ct <> 0 then
dbms_output.put_line(rec2.owner||','||rec3.ct);
else null;
end if;
end loop;
end;
Escapade answered 2/11, 2012 at 9:43 Comment(0)
C
3

Procedure to Search Entire Database:

    CREATE or REPLACE PROCEDURE SEARCH_DB(SEARCH_STR IN VARCHAR2, TAB_COL_RECS OUT VARCHAR2) IS
      match_count integer;
      qry_str varchar2(1000);
      CURSOR TAB_COL_CURSOR IS 
          SELECT TABLE_NAME,COLUMN_NAME,OWNER,DATA_TYPE FROM ALL_TAB_COLUMNS WHERE DATA_TYPE in ('NUMBER','VARCHAR2') AND OWNER='SCOTT';
          BEGIN  
            FOR TAB_COL_REC  IN TAB_COL_CURSOR
            LOOP
              qry_str := 'SELECT COUNT(*) FROM '||TAB_COL_REC.OWNER||'.'||TAB_COL_REC.TABLE_NAME|| 
              ' WHERE '||TAB_COL_REC.COLUMN_NAME;
               IF TAB_COL_REC.DATA_TYPE = 'NUMBER' THEN
                      qry_str := qry_str||'='||SEARCH_STR; 
               ELSE
                       qry_str := qry_str||' like '||SEARCH_STR; 
               END IF;
                       --dbms_output.put_line( qry_str );
                EXECUTE IMMEDIATE  qry_str  INTO match_count;
                IF match_count > 0 THEN          
                   dbms_output.put_line( qry_str );
                  --dbms_output.put_line( TAB_COL_REC.TABLE_NAME ||' '||TAB_COL_REC.COLUMN_NAME ||' '||match_count);     
                    TAB_COL_RECS := TAB_COL_RECS||'@@'||TAB_COL_REC.TABLE_NAME||'##'||TAB_COL_REC.COLUMN_NAME;
                END IF; 
          END LOOP;
     END SEARCH_DB;    

Execute Statement

  DECLARE
    SEARCH_STR VARCHAR2(200);
    TAB_COL_RECS VARCHAR2(200);
    BEGIN
      SEARCH_STR := 10;
      SEARCH_DB(
        SEARCH_STR => SEARCH_STR,
        TAB_COL_RECS => TAB_COL_RECS
      );
     DBMS_OUTPUT.PUT_LINE('TAB_COL_RECS = ' || TAB_COL_RECS);
     END;

Sample Results

Connecting to the database test.
SELECT COUNT(*) FROM SCOTT.EMP WHERE DEPTNO=10
SELECT COUNT(*) FROM SCOTT.DEPT WHERE DEPTNO=10
TAB_COL_RECS = @@EMP##DEPTNO@@DEPT##DEPTNO
Process exited.
Disconnecting from the database test.
Cantina answered 11/11, 2011 at 8:16 Comment(2)
Error report - ORA-00933: SQL command not properly ended ORA-06512: at "TBOWNER.SEARCH_DB", line 17 ORA-06512: at "TBOWNER.SEARCH_DB", line 17 ORA-06512: at line 6 00933. 00000 - "SQL command not properly ended"Raney
I am getting above error, while running the procedure. Running like this DECLARE SEARCH_STR VARCHAR2(200); TAB_COL_RECS VARCHAR2(200); BEGIN SEARCH_STR := 'REQ000000839496'; SEARCH_DB( SEARCH_STR => SEARCH_STR, TAB_COL_RECS => TAB_COL_RECS ); DBMS_OUTPUT.PUT_LINE('TAB_COL_RECS = ' || TAB_COL_RECS); END;Raney
S
3

I found the best solution but it's a little slow. (It will work perfectly with all SQL IDE's.)

SELECT DISTINCT table_name, column_name, data_type
  FROM user_tab_cols,
  TABLE (xmlsequence (dbms_xmlgen.getxmltype ('select '
  || column_name
  || ' from '
  || table_name
  || ' where lower('
  || column_name
  || ') like lower(''%'
  || 'your_text_here'
  || '%'')' ).extract ('ROWSET/ROW/*') ) ) a
  where table_name not in (
    select distinct table_name
      from user_tab_cols where data_type like 'SDO%'
      or data_type like '%LOB') AND DATA_TYPE = 'VARCHAR2'
  order by table_name, column_name;
Shipwright answered 8/5, 2021 at 0:11 Comment(1)
Breaks on LONG BINARY columns :(Sedum
F
2

I don't of a simple solution on the SQL promprt. Howeve there are quite a few tools like toad and PL/SQL Developer that have a GUI where a user can input the string to be searched and it will return the table/procedure/object where this is found.

Fascinator answered 16/10, 2008 at 13:21 Comment(0)
F
2

There are some free tools that make these kind of search, for example, this one works fine and source code is available: https://sites.google.com/site/freejansoft/dbsearch

You'll need the Oracle ODBC driver and a DSN to use this tool.

Finegan answered 4/10, 2010 at 8:35 Comment(0)
V
2

--it run completed -- no error

    SET SERVEROUTPUT ON SIZE 100000

DECLARE
   v_match_count     INTEGER;
   v_counter         INTEGER;




v_owner           VARCHAR2 (255) := 'VASOA';
v_search_string   VARCHAR2 (4000) := '99999';
v_data_type       VARCHAR2 (255) := 'CHAR';
v_sql             CLOB := '';

BEGIN
   FOR cur_tables
      IN (  SELECT owner, table_name
              FROM all_tables
             WHERE     owner = v_owner
                   AND table_name IN (SELECT table_name
                                        FROM all_tab_columns
                                       WHERE     owner = all_tables.owner
                                             AND data_type LIKE
                                                       '%'
                                                    || UPPER (v_data_type)
                                                    || '%')
          ORDER BY table_name)
   LOOP
      v_counter := 0;
      v_sql := '';

      FOR cur_columns
         IN (SELECT column_name, table_name
               FROM all_tab_columns
              WHERE     owner = v_owner
                    AND table_name = cur_tables.table_name
                    AND data_type LIKE '%' || UPPER (v_data_type) || '%')
      LOOP
         IF v_counter > 0
         THEN
            v_sql := v_sql || ' or ';
         END IF;

         IF cur_columns.column_name is not null
         THEN
            v_sql :=
                  v_sql
               || 'upper('
               || cur_columns.column_name
               || ') ='''
               || UPPER (v_search_string)||'''';

            v_counter := v_counter + 1;
         END IF;

      END LOOP;

      IF v_sql is  null
      THEN
         v_sql :=
               'select count(*) from '
            || v_owner
            || '.'
            || cur_tables.table_name;

      END IF;

      IF v_sql is not null
      THEN
         v_sql :=
               'select count(*) from '
            || v_owner
            || '.'
            || cur_tables.table_name
            || ' where '
            || v_sql;
      END IF;

      --v_sql := 'select count(*) from ' ||v_owner||'.'|| cur_tables.table_name ||' where '||  v_sql;


      --dbms_output.put_line(v_sql);
      --DBMS_OUTPUT.put_line (v_sql);

      EXECUTE IMMEDIATE v_sql INTO v_match_count;

      IF v_match_count > 0
      THEN
        DBMS_OUTPUT.put_line (v_sql);
        dbms_output.put_line('Match in ' || cur_tables.owner || ': ' || cur_tables.table_name || ' - ' || v_match_count || ' records');
      END IF;

   END LOOP;
EXCEPTION
   WHEN OTHERS
   THEN
      DBMS_OUTPUT.put_line (
            'Error when executing the following: '
         || DBMS_LOB.SUBSTR (v_sql, 32600));
END;
/
Valleau answered 13/4, 2015 at 2:26 Comment(0)
T
1

Modifying the code to search case-insensitively using a LIKE query instead of finding exact matches...

DECLARE
  match_count INTEGER;
  -- Type the owner of the tables you want to search.
  v_owner VARCHAR2(255) :='USER';
  -- Type the data type you're looking for (in CAPS). Examples include: VARCHAR2, NUMBER, etc.
  v_data_type VARCHAR2(255) :='VARCHAR2';
  -- Type the string you are looking for.
  v_search_string VARCHAR2(4000) :='Test';
BEGIN
  dbms_output.put_line( 'Starting the search...' );
  FOR t IN (SELECT table_name, column_name FROM all_tab_cols where owner=v_owner and data_type = v_data_type) LOOP
    EXECUTE IMMEDIATE 
    'SELECT COUNT(*) FROM '||t.table_name||' WHERE LOWER('||t.column_name||') LIKE :1'
    INTO match_count
    USING LOWER('%'||v_search_string||'%');
    IF match_count > 0 THEN
      dbms_output.put_line( t.table_name ||' '||t.column_name||' '||match_count );
    END IF;
  END LOOP;
END;
Tenstrike answered 19/6, 2017 at 15:53 Comment(0)
R
1

Borrowing, slightly enhancing and simplifying from this Blog post the following simple SQL statement seems to do the job quite well:

SELECT DISTINCT (:val) "Search Value", TABLE_NAME "Table", COLUMN_NAME "Column"
FROM cols,
     TABLE (XMLSEQUENCE (DBMS_XMLGEN.GETXMLTYPE(
       'SELECT "' || COLUMN_NAME || '" FROM "' || TABLE_NAME || '" WHERE UPPER("'
       || COLUMN_NAME || '") LIKE UPPER(''%' || :val || '%'')' ).EXTRACT
       ('ROWSET/ROW/*')))
ORDER BY "Table";
Rhythm answered 19/9, 2017 at 13:59 Comment(0)
T
0

I understand I'm not supposed to ask for help, but I have tried every variation of the provided answers, and none have worked. The simplest one I prefer to borrow shows a syntax error for which I can't understand.

SyntaxError

Thermopile answered 2/11, 2023 at 19:25 Comment(0)
A
-1

The Oracle LIKE condition allows wildcards to be used in the WHERE clause of a SELECT, INSERT, UPDATE, or DELETE statement.

%: to match any string of any length

Eg-

SELECT last_name
   FROM   customer_tab
   WHERE  last_name LIKE '%A%';

-: to match on a single character

Eg-

SELECT last_name
   FROM   customer_tab
   WHERE  last_name LIKE 'A_t';
Adulterant answered 23/6, 2021 at 7:55 Comment(0)

© 2022 - 2024 — McMap. All rights reserved.