Re: SQL result formatting on TO_CHAR different in 12c

From: Mladen Gogala <gogala.mladen_at_gmail.com>
Date: Mon, 17 Apr 2017 17:11:28 -0400
Message-ID: <a4992f4d-4315-476f-b5a5-ed0a2bd26f90_at_gmail.com>



Hi Sandra,
Here is why I love sqlcl:

mgogala_at_umajor:~$ sql scott/tiger_at_test122

SQLcl: Release 4.2.0 Production on Mon Apr 17 17:09:02 2017

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

Connected to:

Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

SQL> First, let's do standard SQL*Plus stuff, which does the same thing as SQL*Plus. The new client is written in such a way to be as compatible with SQL*Plus as possible:

SQL> SQL> select * from emp;

      EMPNO ENAME JOB MGR HIREDATE SAL COMM

     DEPTNO


       7369 SMITH CLERK 7902 19801217 800          20

       7499 ALLEN SALESMAN 7698 19810220 1600 300          30

       7521 WARD SALESMAN 7698 19810222 1250 500          30

       7566 JONES MANAGER 7839 19810402 2975          20

       7654 MARTIN SALESMAN 7698 19810928 1250 1400          30

       7698 BLAKE MANAGER 7839 19810501 2850          30

       7782 CLARK MANAGER 7839 19810609 2450          10

       7788 SCOTT ANALYST 7566 19870419 3000          20

       7839 KING PRESIDENT 19811117 5000          10

       7844 TURNER SALESMAN 7698 19810908 1500 0          30

       7876 ADAMS CLERK 7788 19870523 1100          20

       7900 JAMES CLERK 7698 19811203 950          30

       7902 FORD ANALYST 7566 19811203 3000          20

       7934 MILLER CLERK 7782 19820123 1300          10

14 rows selected.

Elapsed: 00:00:00.148

Now, let's turn on "special" formatting:

SQL> set sqlformat ansiconsole

SQL> select * from emp;

EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO 7369 SMITH CLERK 7902 19801217 800 20 7499 ALLEN SALESMAN 7698 19810220 1600 300 30 7521 WARD SALESMAN 7698 19810222 1250 500 30 7566 JONES MANAGER 7839 19810402 2975 20 7654 MARTIN SALESMAN 7698 19810928 1250 1400 30 7698 BLAKE MANAGER 7839 19810501 2850 30 7782 CLARK MANAGER 7839 19810609 2450 10 7788 SCOTT ANALYST 7566 19870419 3000 20 7839 KING PRESIDENT 19811117 5000 10 7844 TURNER SALESMAN 7698 19810908 1500 0 30 7876 ADAMS CLERK 7788 19870523 1100 20 7900 JAMES CLERK 7698 19811203 950 30 7902 FORD ANALYST 7566 19811203 3000 20 7934 MILLER CLERK 7782 19820123 1300 10 14 rows selected.

Elapsed: 00:00:00.243

SQL> Basically, you have the SQL*Developer formatting options available from command line. Also, from SQL*Plus, you can use HTML formatting to prevent line wrapping. There is also a "repeat" command which can turn SQLcl into an instant monitor. Yes, it would require some testing, but the wast majority of your scripts would probably work as it is. You will have to change the scripts for 12c anyway. In addition to that, SQLcl has an excellent help and its principal author is on this forum, very willing to answer questions.
Regards

On 04/17/2017 04:48 PM, Sandra Becker wrote:
> We don't have SQLPATH or ORACLE_PATH set in these environments. Not
> sure about using sqlcl; it would still require making changes to
> several environments. Not something our users are keen on right now.
>
> Sandy
>
> On Sun, Apr 16, 2017 at 11:32 AM, Mladen Gogala
> <gogala.mladen_at_gmail.com <mailto:gogala.mladen_at_gmail.com>> wrote:
>
> Hi Sandra,
> I don't have anything with such large lines, so I cannot test, but
> I have recently switched to sqlcl, which I find superior to
> SQL*Plus in many aspects. Also, what used to be SQLPATH in
> releases before 12c is now called ORACLE_PATH. A little bit of
> additional marketing doesn't hurt, I suppose. This is what I use
> for my initialization script:
>
> if [ -t 0 ]; then
>
> ORACLE_HOME=/usr/lib/instantclient_12_1
>
> LD_LIBRARY_PATH=$ORACLE_HOME
>
> TNS_ADMIN=/usr/local/tns
>
> TWO_TASK=local
>
> PATH=$ORACLE_HOME:$PATH
>
> SQLPATH=$HOME/misc/SQL
>
> ORACLE_PATH=$SQLPATH
>
> fi
>
> EDITOR="vi"
>
> NLS_DATE_FORMAT='YYYYMMDD'
>
> PATH=$PATH:$HOME/sqlcl/bin
>
> cd $HOME
>
> stty erase '^?' intr '^C' susp '^Z' quit '^Y' kill '^X' echoe
>
> unset LS_COLORS
>
> TERM=vt100
>
> tset -r
>
> [ -r $HOME/.aliases ] && source $HOME/.aliases
>
> The beginning if -t 0 is a remnant from an old version of Red Hat
> which used to be confused by LD_LIBRARY _PATH set to
> $ORACLE_HOME/lib and some GUI tools did not work. As fas as I
> remember, there was an incompatible Python library in
> $ORACLE_HOME/lib, which used to mess up Red Hat GUI.
> On 04/13/2017 04:13 PM, Sandra Becker wrote:
>> Oracle EE 12.1.0.2, 2-node RAC
>> RHEL 5
>> We recently upgraded from 11.2.0.4 to 12.1.0.2. We have several
>> scripts running out of crontab to monitor various aspects of our
>> applications. The analysts are seeing different formatting of
>> the results of these scripts in 12c than they did in 11g.
>> 11g - all output was on one line - linesize set to 1000, only 10
>> columns, date, timestamp, and number formats. In the script,
>> they use TO_CHAR to get the desired format.
>> 12c - no changes to the script; now each column is on a separate
>> line. If I set linesize to 10000, I see the expect behavior with
>> a whole lot of whitespace between columns.
>> I still had copy of this production database that I used to
>> practice the upgrade. I went in and changed the parameter
>> permit_92_wrap_format to false. Behavior reverted back to what
>> we saw in 11g. However, I'm not convinced this is the right
>> workaround.
>> Has anyone else see this behavior? We have a lot of scripts and
>> changing all of them to use a column alias and column formatting
>> (which should have been done in the first place) would be a major
>> undertaking. I haven't found any bugs on MOS related to this yet
>> or any useful information in the Oracle docs. My co-worker is
>> opening an SR, but no response yet.
>> Thank you in advance for any guidance.
>> --
>> Sandy B.
>
> --
> Mladen Gogala
> Oracle DBA
> Tel:(347) 321-1217 <tel:%28347%29%20321-1217>
>
> --
> Sandy B.

-- 
Mladen Gogala
Oracle DBA
Tel: (347) 321-1217

--
http://www.freelists.org/webpage/oracle-l
Received on Mon Apr 17 2017 - 23:11:28 CEST

Original text of this message