Running Oracle’s CSSCAN utility as sysdba

If you need to run Oracle’s CSSCAN utility to check a database prior to converting to a new character set, you may have problems getting it to run “as sysdba”. There are a number of articles on the web that explain how to do this, and most of the explanations don’t work.

Oracle.com says that you should use:

CSSCAN /AS SYSDBA FULL=Y

This gives the error:

LRM-00108: invalid positional parameter value 'SYSDBA'                         
failed to process command line parameters                                      

Scanner terminated unsuccessfully.

Others recommend:

csscan "SYS/[password] as sysdba" full=y tochar=AL32UTF8 array=1024000 process=16

Which results in:

LRM-00108: invalid positional parameter value 'as'                                                  
failed to process command line parameters                                                           

Scanner terminated unsuccessfully.

Various other guides on the web also fail to work. Trying to run csscan as “SYSTEM”, as suggested by Tech Republic and Oracle UK, you get the error:

CSS-00113: user system is not allowed to access data dictionary

Trying to run csscan as “SYS”, as suggested by Oracle Forums, results in the error:

ORA-28009: connection as SYS should be as SYSDBA or SYSOPER

ORACLE-BASE shows a method for running csscan in a Windows environment:

C:\>CSSCAN \"sys/password@db10g AS SYSDBA\" FULL=Y

This might work in Windows, on a Linux server you get:

CSS-00110: failed to parse userid
Scanner terminated unsuccessfully.

Here’s how you do it. Log in as a user with DBA rights and do the following:

> csscan full=y tochar=AL32UTF8 array=1024000 process=16

Character Set Scanner v2.1 : Release 10.2.0.0.0 - Production on Sat Apr 10 18:41:37 2010

Copyright (c) 1982, 2005, Oracle.  All rights reserved.

Username: sys/[password] as sysdba

That should run the database character scanner on your database. If you get the error:

CSS-00107: Character set migration utility schema not installed       

Scanner terminated unsuccessfully.

… then go back and install the character set migration utility schema, then try running csscan again. You can install the character set migration utility schema with:

> cd $ORACLE_HOME/rdbms/admin
> sqlplus /nolog                                         

SQL*Plus: Release 10.2.0.2.0 - Production on Sat Apr 10 18:40:04 2010

Copyright (c) 1982, 2005, Oracle.  All Rights Reserved.

SP2-0640: Not connected
18:40:04 nolog> connect / as sysdba
Connected.                         

Session altered.

Elapsed: 00:00:00.00
18:40:08 sys> @csminst.sql

If you get this error you can ignore it:

grant READ on directory log_file_dir to system                                                             
                        *                                                                                  
ERROR at line 1:                                                                                           
ORA-22930: directory does not exist    

Hope you find this useful.

Creating BETTER auto-increment columns in Oracle

I was explaining to a developer today how Oracle doesn’t support auto-increment columns for IDs and how you have to implement your own. I wanted to point him to a tutorial but I found that most of the tutorials have PL/SQL code with unexplained side effects. So I thought I’d post some Oracle PL/SQL code that behaves just like a MySQL or PostgreSQL auto-increment column, but which also fixes the sequence number when an application provides its own ID number for a record, which is one place where MySQL and PostgreSQL autoincrement columns fail.

Step 1: Know the names of your tablespaces. Know which tablespace you want to use for your tables and which tablespace you want to use for your indexes. Don’t assume that Oracle is going to put the table in the right place. To get a list of available tablespaces:

select tablespace_name from user_tablespaces;

Step 2: Create your table. In this example the table is built in the tablespace TDATA and the primary key index is built in the tablespace INDX.

create table example (
    id number not null,
    name varchar2(30),
    constraint example_pk primary key(id) using index tablespace INDX
) tablespace TDATA;

Note that by declaring the id column “not null” you can’t add a record with an empty ID field, ever.

Creating the primary key constraint on a separate line allows us to name the constraint, which can be handy when you’re looking through the data dictionary later on trying to figure out which constraint does what.

Step 3: Create a sequence. In this case I create an ID sequence that starts at 1 and goes on from there. If you want to start your ID sequence with a different number, or increment by some other amount, change these values.

create sequence example_id_seq start with 1 increment by 1;

Step 4: Create a trigger. This is what does the actual work setting the ID number. There are many ways to do this, here are two:

Method 1: Use a sequence-generated ID for all IDs.

create or replace trigger example_insert
before insert on example
for each row
begin
    select example_id_seq.nextval into :new.id from dual;
end;
/

Method 1 will always use a sequence-generated ID no matter what. For example:

SQL> insert into example (id, name) values (100, 'Earl');
1 row created.
SQL> insert into example (name) values ('Cleopatra');
1 row created.
SQL> insert into example (name) values ('Frankenstein');
1 row created.
SQL> select * from example;
        ID NAME
---------- ------------------------------
         1 Earl
         2 Cleopatra
         3 Frankenstein

In this case the trigger-supplied ID 1 overwrote the user-supplied id 100.

Method 2: Allow users to supply their own IDs when they want to.

create or replace trigger example_insert
before insert on example
for each row
declare
    max_id number;
    cur_seq number;
begin
    if :new.id is null then
        -- No ID passed, get one from the sequence
        select example_id_seq.nextval into :new.id from dual;
    else
        -- ID was set via insert, so update the sequence
        select greatest(nvl(max(id),0), :new.id) into max_id from example;
        select example_id_seq.nextval into cur_seq from dual;
        while cur_seq < max_id
        loop
            select example_id_seq.nextval into cur_seq from dual;
        end loop;
    end if;
end;
/

Method 2 will use the sequence-generated ID if the insert statement doesn’t supply an ID, which is what MySQL and PostgreSQL do. It also updates the sequence so that the next value of the sequence won’t collide with IDs supplied by an insert statement.

For example, let’s say I’m using Trigger Method 2 and just loaded the table with a bunch of old data, including old ID numbers.

SQL> delete from example;
3 rows deleted.
SQL> insert into example (id, name) values (200, 'Cleopatra');
1 row created.
SQL> insert into example (id, name) values (300, 'Frankenstein');
1 row created.
SQL> insert into example (name) values ('Earl');
1 row created.
SQL> select * from example;

        ID NAME
---------- ------------------------------
       200 Cleopatra
       300 Frankenstein
       301 Earl

The last record added gets an ID of 301.

Hope you find this useful.