Skip to Main Content
  • Questions
  • Mechanism to remove Special Characters in many columns of many tables in a database

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Saahir.

Asked: September 19, 2015 - 12:42 pm UTC

Last updated: September 21, 2015 - 3:30 am UTC

Version: 10.2.0.2

Viewed 10K+ times! This question is

You Asked

Hi Tom,

Apology for posting an older version of database question which happens to be 10g(10.2.0.2). Tom, I am looking for a way to find out any special characters to name a few like (inverted question marks, Euro symbols, tild(~)...etc) hidden in many columns of a many tables within a database. Due to this all our XML reports which gets interfaced with EBS are failing.

Is there a way to write a query (or) with PL/SQL anonymous blocks which helps to find out what are those columns and remove it. We do have plans to migrate it to 12c and we did a POC by upgrading to 12c(12.1.0.2). There as well, we could notice such symbols in many columsn. We are sure that it's not a NLS_LANG as we never tried any other language other than English(US-UTF8).

Looking forward for your reply...

Rgrds,
Saahir


and Connor said...

ok, first decide on an update SQL that defines what you mean by special characters, and what you want to replace them with, and write that for a single column on a single table.

For example, you might decide on:

update MY_TABLE
set col1 = replace( translate(col1, chr(1)||chr(2)||chr(3), chr(0)), chr(0))
where col1 != replace( translate(col1, chr(1)||chr(2)||chr(3), chr(0)), chr(0))

which changes all chr(1)..chr(3) to a chr(0), and then removes the chr(0).

Once you have THAT query defined, its easy enough to dynamically generate a suite of updates for all columns in all tables, for example

select
'update '||table_name||
'set '||column_name||' = '||replace( translate('||column_name||', chr(1)||chr(2)||chr(3), chr(0)), chr(0)) '||
'where '||column_name||' != '||replace( translate('||column_name||', chr(1)||chr(2)||chr(3), chr(0)), chr(0));'
from all_tab_columns
where owner in ( ... )
and data_type like '%CHAR%'


You could make more advanced (eg one pass for multiple columns), but you get the basic idea.

Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

How about Regexp (introduced in 10g)

Rajeshwaran Jeyabal, September 20, 2015 - 6:47 am UTC

I am looking for a way to find out any special characters

rajesh@ORA10G> create table t as select * from all_objects
  2  where rownum <=10;

Table created.

rajesh@ORA10G>
rajesh@ORA10G> select count(*) from t
  2  where regexp_like(object_name,'[[:punct:]]');

  COUNT(*)
----------
        10

1 row selected.

rajesh@ORA10G> update t
  2  set object_name = regexp_replace(object_name,'[[:punct:]]')
  3  where regexp_like(object_name,'[[:punct:]]');

10 rows updated.

rajesh@ORA10G> select count(*) from t
  2  where regexp_like(object_name,'[[:punct]]');

  COUNT(*)
----------
         0

1 row selected.

rajesh@ORA10G>

Connor McDonald
September 21, 2015 - 3:30 am UTC

Agreed - it doesnt really matter what mechanism is used to define a "special character", but once its been done for a single column/table, its easy enough to abstract out.