Category Archives: SQLDev

SQLcl – enabling MCS for JDBC thin driver

Let’s say you have configured TLS authentication for your database users using the Microsoft Certificate Store (MCS) on Windows clients.

For OCI based client this is pretty well documented and understood:

sqlnet.ora

SQLNET.AUTHENTICATION_SERVICES = (TCPS)
WALLET_LOCATION = (SOURCE = (METHOD = MCS))
SSL_SERVER_DN_MATCH = yes

tnsnames.ora

DEV1_TLS =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCPS)(HOST = ol7ora19dev1.spotonoracle.com)(PORT = 2484))
    (CONNECT_DATA =
      (SERVICE_NAME = DEV1.spotonoracle.com)
    )
    (SECURITY =
      (SSL_SERVER_CERT_DN = "cn=dev1,ou=servers,ou=oracle,dc=spotonoracle,dc=com")
    )
  )

With above configuration I can connect to the database using SQL*Plus.

C:\Users\user1>sqlplus /@dev1_tls

SQL*Plus: Release 12.2.0.1.0 Production on Wed May 29 18:31:53 2019

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

Last Successful login time: Wed May 29 2019 18:10:15 +02:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production

Note that I use a 12.2 OCI client. This is because of bug 25809524 for which the fix has not made its way into the 18c release. I hope the soon to be released 19c client for Windows will have the fix.

In a previous post I’ve shown how to use a file based wallet (cwallet.sso) for JDBC thin applications,namely SQLcl. Unfortunately, we cannot simply change the WALLET_LOCATION parameter as we do in sqlnet.ora. This does not work:

set JAVA_TOOL_OPTIONS=-Doracle.net.wallet_location=(SOURCE=(METHOD=MCS)) -Doracle.net.authentication_services=(TCPS) -Doracle.net.ssl_server_dn_match=true

In order for JDBC thin applications to access the Microsoft Certificate Store we have to set Windows platform specific settings for trust store and key store properties:

set JAVA_TOOL_OPTIONS=-Djavax.net.ssl.trustStore=NONE -Djavax.net.ssl.trustStoreType=Windows-ROOT -Djavax.net.ssl.keyStore=NONE -Djavax.net.ssl.keyStoreType=Windows-MY -Doracle.net.authentication_services=(TCPS) -Doracle.net.ssl_server_dn_match=true

C:\Users\user1>sql /@dev1_tls
Picked up JAVA_TOOL_OPTIONS: -Djavax.net.ssl.trustStore=NONE -Djavax.net.ssl.trustStoreType=Windows-ROOT -Djavax.net.ssl.keyStore=NONE -Djavax.net.ssl.keyStoreType=Windows-MY -Doracle.net.authentication_services=(TCPS,KERBEROS5) -Doracle.net.ssl_server_dn_match=true

SQLcl: Release 19.1 Production on Wed May 29 18:45:21 2019

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

Last Successful login time: Wed May 29 2019 18:45:22 +02:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

This works for SQLcl, SQL Developer, and any reasonable JDBC thin application. 🙂

SQLcl – enabling TLS for JDBC thin driver

This is a quick follow-up from my previous post. This time we’re going to add TLS capabilities to SQLcl. I’m going to reuse the java security file we created earlier to override the security provider’s list (/opt/sqldeveloper/sqldeveloper/bin/sqldev.java.security).

The thing with SQLcl is there is no configuration file like in SQL Developer. No problem, all we did was adding JVM options anyway, except for adding “oraclepki.jar” to the CLASSPATH. Luckily, SQLcl ships with a recent version so we don’t need that.
To add the JVM options we can use either JAVA_TOOL_OPTIONS or _JAVA_OPTIONS. It can’t get simpler than that, can it?

$ export JAVA_TOOL_OPTIONS='-Doracle.net.wallet_location="(SOURCE=(METHOD=FILE)(METHOD_DATA=(DIRECTORY=/home/btr/tns/wallet)))" -Doracle.net.authentication_services="(TCPS)" -Doracle.net.ssl_server_dn_match=false -Djava.security.properties=/opt/sqldeveloper/sqldeveloper/bin/sqldev.java.security'
 

Connect using username/password but use TLS for in-flight traffic encryption:

$ sql system/********@"(DESCRIPTION=(ADDRESS=(HOST=ol7122rac-scan.localdomain)(PROTOCOL=TCPS)(PORT=1523))(CONNECT_DATA=(SERVICE_NAME=pdbrac1.localdomain)))"
Picked up JAVA_TOOL_OPTIONS: -Doracle.net.wallet_location="(SOURCE=(METHOD=FILE)(METHOD_DATA=(DIRECTORY=/home/btr/tns/wallet)))" -Doracle.net.authentication_services="(TCPS)" -Doracle.net.ssl_server_dn_match=false -Djava.security.properties=/opt/sqldeveloper/sqldeveloper/bin/sqldev.java.security

SQLcl: Release 18.1.1 Production on Tue May 29 20:51:26 2018

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

Last Successful login time: Tue May 29 2018 20:51:26 -04:00

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


SQL> 

Or connecting using TLS authentication:

$ sql /@"(DESCRIPTION=(ADDRESS=(HOST=ol7122rac-scan.localdomain)(PROTOCOL=TCPS)(PORT=1523))(CONNECT_DATA=(SERVICE_NAME=pdbrac1.localdomain)))"
Picked up JAVA_TOOL_OPTIONS: -Doracle.net.wallet_location="(SOURCE=(METHOD=FILE)(METHOD_DATA=(DIRECTORY=/home/btr/tns/wallet)))" -Doracle.net.authentication_services="(TCPS)" -Doracle.net.ssl_server_dn_match=false -Djava.security.properties=/opt/sqldeveloper/sqldeveloper/bin/sqldev.java.security

SQLcl: Release 18.1.1 Production on Tue May 29 20:57:30 2018

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

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


SQL> 

SQL Developer – enabling TLS for JDBC thin driver

I don’t think this is documented anywhere (and no hits on google) but it shows once again how awsome SQL Developer is. 🙂
Instead of using “jdbc:oracle:oci” for TLS enabled connections we’re going to set SQL Developer up to do just that with “jdbc:oracle:thin”. In that regard, SQL Developer is no more special than any Java application.
To keep it short I’m sticking to the basics, maybe I’ll add some variations into the comments later.
First, we need to add “OraclePKIProvider” to the JRE security provider’s list. The provider’s list is defined in “$JAVA_HOME/jre/lib/security/java.security”.
I’m going to append to it by creating a new file that I only source from SQL Developer. In my case, the next free slot is 10. Depending on your OS and JRE version the list may slightly vary.
(also make sure that the java.security file is appendable: “security.overridePropertiesFile=true”)

$ vi /opt/sqldeveloper/sqldeveloper/bin/sqldev.java.security
security.provider.10=oracle.security.pki.OraclePKIProvider

Next, we add a few options to the sqldeveloper.conf file:

$ vi /opt/sqldeveloper/sqldeveloper/bin/sqldeveloper.conf
# add this to end of the config file

# specify the path to your SSO wallet file
AddVMOption -Doracle.net.wallet_location="(SOURCE=(METHOD=FILE)(METHOD_DATA=(DIRECTORY=/home/btr/tns/wallet)))"
# this is required if you want to use TLS authentication next to in-flight traffic encryption
AddVMOption -Doracle.net.authentication_services="(TCPS)"
# optionally, if you want the client to verify the server certificate
AddVMOption -Doracle.net.ssl_server_dn_match=true
# append/override JRE security config to add Oracle provider
AddVMOption -Djava.security.properties=/opt/sqldeveloper/sqldeveloper/bin/sqldev.java.security
# even SQLDev 18.1 ships with a very old version that is not compatible - just download the latest one from OTN
AddJavaLibFile /home/btr/orasec/jlib/oraclepki.jar

That’s it, we’re done.

Now you can create connections using TNS, LDAP, or Advanced. Basic/EZCONNECT does not support to specify the protocol, so it can’t be used for TLS.

Here we only use TLS for in-flight traffic encryption:

And here, we make use of TLS user authentication:

Secure Postgres connection from SQL Developer

Searching the web it seems most people use “org.postgresql.ssl.NonValidatingFactory” to connect to Postgres from SQL Developer.

This doesn’t seem to be a good idea as the documentation states it is not secure:
Provide a SSLSocketFactory that allows SSL connections to be made without validating the server's certificate. This is more convenient for some applications, but is less secure as it allows "man in the middle" attacks.

Looking into the jar file under “/org/postgres/ssl” you’ll also find SingleCertValidatingFactory. Now that’s much better:
Provides a SSLSocketFactory that authenticates the remote server against an explicit pre-shared SSL certificate. This is more secure than using the NonValidatingFactory as it prevents "man in the middle" attacks. It is also more secure than relying on a central CA signing your server's certificate as it pins the server's certificate.

Let’s get to it…

The boring part: load the Postgres JDBC driver
Go to “Tools” -> “Preferences…” -> “Third Party JDBC Drivers” and add the jar file

The tricky part: getting the connect string right (it’s actually not that hard)
Syntax:

<hostname>/<database>?ssl=true&sslfactory=org.postgresql.ssl.SingleCertValidatingFactory&sslfactoryarg=file:<path-to-cert-file>&

For example:

abc.xzy.us-east-1.rds.amazonaws.com/postgres?ssl=true&sslfactory=org.postgresql.ssl.SingleCertValidatingFactory&sslfactoryarg=file:/home/btr/certs/amazon-rds.crt&

Enter this entire string in the “Hostname” field.

The exciting part: playing with your newly connected Postgres database 🙂

Keep it secure!

Tracking down PGA memory leak – a walkthrough

The other day I tracked down a nasty problem one application was having. It was first noticed in the alert.log:

ORA-04036: PGA memory used by the instance exceeds PGA_AGGREGATE_LIMIT
...
PGA memory used by the instance exceeds PGA_AGGREGATE_LIMIT of 7000 MB
Immediate Kill Session#: 686, Serial#: 26646
Immediate Kill Session: sess: 0x19e7c2a78  OS pid: 35173

Checking the PGA memory from gv$process revealed a shocking picture:

SQL> select prc.inst_id, ses.sid, ses.serial#, prc.pid, prc.spid, round(prc.pga_used_mem/1024/1024) used_mb, round(prc.pga_alloc_mem/1024/1024) alloc_mb, round((prc.pga_alloc_mem - prc.pga_used_mem)/1024/1024, 0) unused_mb, round(prc.pga_freeable_mem/1024/1024) freeable_mb, round(prc.pga_max_mem/1024/1024) max_mb
from gv$process prc
  left outer join gv$session ses on (ses.inst_id = prc.inst_id and ses.paddr = prc.addr and ses.type = 'USER')
order by used_mb desc
fetch first 10 rows only;

   INST_ID        SID    SERIAL#        PID SPID                        USED_MB   ALLOC_MB  UNUSED_MB                             FREEABLE_MB     MAX_MB
---------- ---------- ---------- ---------- ------------------------ ---------- ---------- ---------- --------------------------------------- ----------
         1        655      50496         89 338934                          227        284         57                                       0        499
         1        675      45630        137 338938                          223        280         57                                       0        296
         1        416       7124        285 315339                          222        281         58                                       1        298
         1        290      45321        296 81710                           184        233         49                                       0        280
         2        296      52565         98 223329                          163        207         45                                       0        270
         2        710       8463        293 386687                          162        207         45                                       0        270
         1         67      15923         54 98311                           147        187         40                                       0        264
         2        295      25163        242 316189                          143        185         42                                       0        266
         1         32      55120        270 358206                          137        178         41                                       0        260
         2        309      13006        230 167307                          135        175         39                                       0        258

 10 rows selected 

A lot of sessions used between 100MB and 230MB. Monitoring these sessions over some time showed that the memory was never released, something’s definitely wrong. PGA dumps of a couple of connections all showed the same pattern.

oradebug setmypid
oradebug dump pga_detail_get <pid>
SQL> select category, name, heap_name, round(bytes/1024/1024, 0) size_mb, allocation_count
from gv$process_memory_detail
where pid = 89
order by pid, bytes desc
fetch first 10 rows only;

CATEGORY        NAME                       HEAP_NAME          SIZE_MB                        ALLOCATION_COUNT
--------------- -------------------------- --------------- ---------- ---------------------------------------
Other           permanent memory           kolarsCreateCt         214                                   10541
Other           free memory                top uga heap            57                                    1571
Other           free memory                kolarsCreateCt           3                                    4907
Other           free memory                session heap             2                                    1016
Other           kollalos2                  koh-kghu sessi           1                                      86
Other           permanent memory           pga heap                 1                                      43
Other           kxsFrame4kPage             session heap             0                                     123
Other           qmushtCreate               qmtmInit                 0                                       6
PL/SQL          static frame of inst       koh-kghu sessi           0                                      36
Other           inode->map_kdlimem         buckets_kdliug           0                                       9

The closest I come to kolarsCreateCt in the oradebug doc is this:

oradebug doc component
...
Components in library GENERIC:
--------------------------
...
  LOB                          LOB (koll, kola)
...

This is the clue that there is apparently a LOB resource management problem. Luckily, the PL/SQL code base was not too big and only a couple of places where LOB handling was done. But, all LOBs seemed to be handled correctly.
One thing, though, I first didn’t pay much attention to was a few “XMLTYPE.getClobVal()” in SELECT statements. I’ve used that myself in the past a couple of times and knew this returned a persistent LOB handle and should not leak.
I took one of these SQL statements and ran them in my favorite tool, SQL Developer, and BOOOOOM! My session just consumed a couple of hundreds of megabytes of PGA memory and wouldn’t release it until I closed the connection.

So I crafted a little test case to check what’s going on.

SQL> create table xmltest(id number, data xmltype, primary key (id))
SQL>   xmltype column data store as binary xml;
SQL> insert into xmltest (id, data) values (1, '<someelement></someelement>');
SQL> commit;
SQL> select t.id, dbms_lob.istemporary(t.data.getclobval()) is_temp from xmltest t;

        ID    IS_TEMP
---------- ----------
         1          1

I don’t think this is what I knew from past experience so I did a quick MOS search and found following bug report:
Bug 23061709 : HIGH KOLARSCREATECT AND ORA-04036 WHEN XMLTYPE COLUMN IS STORED AS BINARY

OK, lets change the XMLType storage to CLOB and see what happens:

SQL> create table xmltest(id number, data xmltype, primary key (id))
SQL>   xmltype column data store as securefile clob;
SQL> insert into xmltest (id, data) values (1, '<someelement></someelement>');
SQL> commit;
SQL> select t.id, dbms_lob.istemporary(t.data.getclobval()) is_temp from xmltest t;

        ID    IS_TEMP
---------- ----------
         1          0

To be fair, the documentation for 11.2, 12.1, and 12.2 all state the following:
“This member function returns a CLOB containing the serialized XML representation. If the CLOB returned is temporary, it must be freed after use.”

Because I always run my tests in SQL*Plus additionally to SQL Developer I was puzzled to see that there’s no memory leak. Why does it not happen in SQL*Plus? I thought that maybe SQL*Plus is clever enough to always check for temporary LOBs and free them.

Firing up gdb with this script proved me right.

break OCILobFreeTemporary
  commands
    where
    continue
  end

This SQL fetches five rows with CLOB data.

SQL> select t.id, t.data.getclobval() from xmltest t where rownum <= 5;

Output from gdb:

Breakpoint 1, 0x00007f678cc3d250 in OCILobFreeTemporary () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libclntsh.so.12.1
#0  0x00007f678cc3d250 in OCILobFreeTemporary () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libclntsh.so.12.1
#1  0x00007f678eafb1ef in afioci () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#2  0x00007f678eaed912 in afifpilobfreetemp () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#3  0x00007f678eaed799 in afifpifretmp () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#4  0x00007f678eae8f20 in afidet () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#5  0x00007f678eb272f3 in safiqry () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#6  0x00007f678eb096e3 in afiqry () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#7  0x00007f678eb21bf2 in afixeqqry () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#8  0x00007f678eb21521 in afixeqsql () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#9  0x00007f678eb20ed5 in afixeqr () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#10 0x00007f678eabfd74 in aficfd () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#11 0x00007f678eabec49 in aficdr () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#12 0x00007f678eaeacf2 in afidrv () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libsqlplus.so
#13 0x00000000004007a1 in main ()

Breakpoint 1, 0x00007f678cc3d250 in OCILobFreeTemporary () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libclntsh.so.12.1
...
#13 0x00000000004007a1 in main ()

Breakpoint 1, 0x00007f678cc3d250 in OCILobFreeTemporary () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libclntsh.so.12.1
...
#13 0x00000000004007a1 in main ()

Breakpoint 1, 0x00007f678cc3d250 in OCILobFreeTemporary () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libclntsh.so.12.1
...
#13 0x00000000004007a1 in main ()

Breakpoint 1, 0x00007f678cc3d250 in OCILobFreeTemporary () from /u01/app/oracle/product/12.1.0.2.161018/RAC/lib/libclntsh.so.12.1
...
#13 0x00000000004007a1 in main ()

Five rows fetched and gdb shows five calls to OCILobFreeTemporary. The call to OCILobFreeTemporary originates from libsqlplus.so which tells me it’s not the OCI layer itself handling it, it’s the logic in SQL*Plus.

Next, I wanted to see myself what happens in a Java/JDBC application. Here’s the relevant snippet from my test case:

      String sql = "select t.id, t.data.getclobval() from xmltest t where rownum <= 5";
      stmt = conn.prepareStatement(sql);
      
      for (int i=0; i<3; i++) {
      stmt = conn.prepareStatement(sql);
        rset = stmt.executeQuery();

        while (rset.next ()) {
          System.out.println (rset.getInt(1));
          xmlclob = rset.getClob(2);
          xmlclob.free();
        }

        rset.close();

        c.format("\nPress ENTER 1 to proceed.\n");
        c.readLine();
      }

Like SQL*Plus being an application handling the LOB resources, you have to do it programmatically in Java as well. Line 11 frees the temporary LOB.
Without the free() call on the Clob you will see the memory leak when there XMLType storage clause is XML BINARY. It happens, even when do don’t reference the LOB column in Java:

        while (rset.next ()) {
          System.out.println (rset.getInt(1));
        }

Lesson learnt: never trust what you think you know! Sometimes things change in subtle ways.

Know Your Font: update on SQL Developer oddity

A while back I posted a note about an oddity I ran into using SQL Developer on Windows (see here for details). As I couldn’t leave the issue alone I eventually found the root cause with a little help from my friends (fellow developers): It’s the font “DialogInput” SQL Developer uses by default. As I learned, “DialogInput” is a so-called logical font (read about that here). Apparently, these logical fonts are a composition of multiple physical fonts depending on what’s actually installed on your system and hence, differ on my Linux and Windows systems. This little Java program prints out the font composition:

import java.awt.Font;
import java.lang.reflect.Method;
import java.util.Locale;

import sun.font.CompositeFont;
import sun.font.Font2D;
import sun.font.PhysicalFont;

public class Test {
    public static void main(String... args)
    throws Exception
    {
        Font font = new Font("DialogInput", Font.PLAIN, 12);
        describeFont(font);
    }

    private static void describeFont(Font font)
    throws Exception
    {
        Method method = font.getClass().getDeclaredMethod("getFont2D");
        method.setAccessible(true);
        Font2D f = (Font2D)method.invoke(font);

        describeFont2D(f);
    }

    private static void describeFont2D(Font2D font)
    {
        if (font instanceof CompositeFont)
        {
            System.out.println("Font '" + font.getFontName(Locale.getDefault()) + "' is composed of:");

            CompositeFont cf = (CompositeFont)font;
            for (int i = 0; i < cf.getNumSlots(); i++)
            {
                PhysicalFont pf = cf.getSlotFont(i);
                describeFont2D(pf);
            }
        }
        else
            System.out.println("-> " + font);
    }
}

Output from my Linux system:

Font 'DialogInput.plain' is composed of:
-> ** TrueType Font: Family=DejaVu Sans Mono Name=DejaVu Sans Mono style=0 fileName=/usr/share/fonts/dejavu/DejaVuSansMono.ttf
-> ** TrueType Font: Family=DejaVu Sans Mono Name=DejaVu Sans Mono Bold style=1 fileName=/usr/share/fonts/dejavu/DejaVuSansMono-Bold.ttf
-> ** Type1 Font: Family=Nimbus Mono L Name=Nimbus Mono L Regular style=0 fileName=/usr/share/fonts/default/Type1/n022003l.pfb
-> ** TrueType Font: Family=VL Gothic Name=VL Gothic Regular style=0 fileName=/usr/share/fonts/vlgothic/VL-Gothic-Regular.ttf
-> ** TrueType Font: Family=NanumGothic Name=NanumGothic style=0 fileName=/usr/share/fonts/nhn-nanum/NanumGothic.ttf
-> ** TrueType Font: Family=Lohit Bengali Name=Lohit Bengali style=0 fileName=/usr/share/fonts/lohit-bengali/Lohit-Bengali.ttf
-> ** TrueType Font: Family=Lohit Gujarati Name=Lohit Gujarati style=0 fileName=/usr/share/fonts/lohit-gujarati/Lohit-Gujarati.ttf
-> ** TrueType Font: Family=Lohit Punjabi Name=Lohit Punjabi style=0 fileName=/usr/share/fonts/lohit-punjabi/Lohit-Punjabi.ttf
-> ** TrueType Font: Family=Lohit Tamil Name=Lohit Tamil style=0 fileName=/usr/share/fonts/lohit-tamil/Lohit-Tamil.ttf
-> ** TrueType Font: Family=Meera Name=Meera style=0 fileName=/usr/share/fonts/smc/Meera.ttf
-> ** TrueType Font: Family=Lohit Kannada Name=Lohit Kannada style=0 fileName=/usr/share/fonts/lohit-kannada/Lohit-Kannada.ttf
-> ** TrueType Font: Family=Lohit Telugu Name=Lohit Telugu style=0 fileName=/usr/share/fonts/lohit-telugu/Lohit-Telugu.ttf
-> ** TrueType Font: Family=Lohit Oriya Name=Lohit Oriya style=0 fileName=/usr/share/fonts/lohit-oriya/Lohit-Oriya.ttf
-> ** TrueType Font: Family=LKLUG Name=LKLUG style=0 fileName=/usr/share/fonts/lklug/lklug.ttf
-> ** TrueType Font: Family=FreeMono Name=FreeMono style=0 fileName=/usr/share/fonts/gnu-free/FreeMono.ttf
-> ** TrueType Font: Family=FreeSans Name=FreeSans style=0 fileName=/usr/share/fonts/gnu-free/FreeSans.ttf
-> ** TrueType Font: Family=FreeSerif Name=FreeSerif style=0 fileName=/usr/share/fonts/gnu-free/FreeSerif.ttf
-> ** TrueType Font: Family=OpenSymbol Name=OpenSymbol style=0 fileName=/usr/share/fonts/opensymbol/opens___.ttf
-> ** TrueType Font: Family=PakType Naqsh Name=PakType Naqsh style=0 fileName=/usr/share/fonts/paktype-naqsh/PakType_Naqsh.ttf
-> ** TrueType Font: Family=Khmer OS Name=Khmer OS style=0 fileName=/usr/share/fonts/khmeros/KhmerOS.ttf
-> ** TrueType Font: Family=Padauk Name=Padauk style=0 fileName=/usr/share/fonts/sil-padauk/Padauk.ttf
-> ** TrueType Font: Family=Lohit Devanagari Name=Lohit Devanagari style=0 fileName=/usr/share/fonts/lohit-devanagari/Lohit-Devanagari.ttf
-> ** TrueType Font: Family=DejaVu Sans Name=DejaVu Sans style=0 fileName=/usr/share/fonts/dejavu/DejaVuSans.ttf
-> ** TrueType Font: Family=DejaVu Serif Name=DejaVu Serif style=0 fileName=/usr/share/fonts/dejavu/DejaVuSerif.ttf
-> ** TrueType Font: Family=Nuosu SIL Name=Nuosu SIL style=0 fileName=/usr/share/fonts/sil-nuosu/NuosuSIL.ttf
-> ** TrueType Font: Family=PT Sans Name=PT Sans style=0 fileName=/usr/share/fonts/paratype-pt-sans/PTS55F.ttf
-> ** TrueType Font: Family=Abyssinica SIL Name=Abyssinica SIL style=0 fileName=/usr/share/fonts/sil-abyssinica/AbyssinicaSIL-R.ttf
-> ** TrueType Font: Family=Carlito Name=Carlito style=0 fileName=/usr/share/fonts/google-crosextra-carlito/Carlito-Regular.ttf
-> ** TrueType Font: Family=Liberation Sans Name=Liberation Sans style=0 fileName=/usr/share/fonts/liberation/LiberationSans-Regular.ttf
-> ** TrueType Font: Family=Liberation Serif Name=Liberation Serif style=0 fileName=/usr/share/fonts/liberation/LiberationSerif-Regular.ttf
-> ** TrueType Font: Family=Noto Sans Mandaic Name=Noto Sans Mandaic style=0 fileName=/usr/share/fonts/google-noto/NotoSansMandaic-Regular.ttf
-> ** TrueType Font: Family=Noto Sans Meetei Mayek Name=Noto Sans Meetei Mayek style=0 fileName=/usr/share/fonts/google-noto/NotoSansMeeteiMayek-Regular.ttf
-> ** TrueType Font: Family=Noto Sans Tagalog Name=Noto Sans Tagalog style=0 fileName=/usr/share/fonts/google-noto/NotoSansTagalog-Regular.ttf
-> ** TrueType Font: Family=Noto Sans Tai Tham Name=Noto Sans Tai Tham style=0 fileName=/usr/share/fonts/google-noto/NotoSansTaiTham-Regular.ttf
-> ** TrueType Font: Family=Noto Sans Tai Viet Name=Noto Sans Tai Viet style=0 fileName=/usr/share/fonts/google-noto/NotoSansTaiViet-Regular.ttf
-> ** TrueType Font: Family=Waree Name=Waree style=0 fileName=/usr/share/fonts/thai-scalable/Waree.ttf
-> ** TrueType Font: Family=Mingzat Name=Mingzat style=0 fileName=/usr/share/fonts/sil-mingzat/Mingzat-R.ttf
-> ** TrueType Font: Family=Jomolhari Name=Jomolhari style=0 fileName=/usr/share/fonts/jomolhari/Jomolhari-alpha3c-0605331.ttf
-> ** TrueType Font: Family=WenQuanYi Zen Hei Name=WenQuanYi Zen Hei style=0 fileName=/usr/share/fonts/wqy-zenhei/wqy-zenhei.ttc
-> ** TrueType Font: Family=WenQuanYi Zen Hei Name=WenQuanYi Zen Hei style=0 fileName=/usr/share/fonts/wqy-zenhei/wqy-zenhei.ttc
-> ** TrueType Font: Family=AR PL UMing CN Name=AR PL UMing CN style=0 fileName=/usr/share/fonts/cjkuni-uming/uming.ttc
-> ** TrueType Font: Family=AR PL UMing CN Name=AR PL UMing CN style=0 fileName=/usr/share/fonts/cjkuni-uming/uming.ttc
-> ** TrueType Font: Family=AR PL UMing CN Name=AR PL UMing CN style=0 fileName=/usr/share/fonts/cjkuni-uming/uming.ttc

Output from my Windows system:

FFont 'DialogInput.plain' is composed of:
-> ** TrueType Font: Family=Courier New Name=Courier New style=0 fileName=C:\Windows\Fonts\COUR.TTF
-> ** TrueType Font: Family=Wingdings Name=Wingdings style=0 fileName=C:\Windows\Fonts\WINGDING.TTF
-> ** TrueType Font: Family=Symbol Name=Symbol style=0 fileName=C:\Windows\Fonts\SYMBOL.TTF
-> ** TrueType Font: Family=Lucida Sans Name=Lucida Sans Regular style=0 fileName=C:\Program Files\Java\jdk1.7.0_45\jre\lib\fonts\LucidaSansRegular.ttf
-> ** TrueType Font: Family=MingLiU Name=MingLiU style=0 fileName=C:\Windows\Fonts\MINGLIU.TTC
-> ** TrueType Font: Family=Lucida Sans Name=Lucida Sans Regular style=0 fileName=C:\Program Files\Java\jdk1.7.0_45\jre\lib\fonts\LucidaSansRegular.ttf
-> ** TrueType Font: Family=SimSun Name=SimSun style=0 fileName=C:\Windows\Fonts\SIMSUN.TTC
-> ** TrueType Font: Family=Lucida Sans Name=Lucida Sans Regular style=0 fileName=C:\Program Files\Java\jdk1.7.0_45\jre\lib\fonts\LucidaSansRegular.ttf
-> ** TrueType Font: Family=MS Gothic Name=MS Gothic style=0 fileName=C:\Windows\Fonts\MSGOTHIC.TTC
-> ** TrueType Font: Family=Gulim Name=Gulim style=0 fileName=C:\Windows\Fonts\gulim.TTC
-> ** TrueType Font: Family=MingLiU-ExtB Name=MingLiU-ExtB style=0 fileName=C:\Windows\Fonts\MINGLIUB.TTC
-> ** TrueType Font: Family=SimSun-ExtB Name=SimSun-ExtB style=0 fileName=C:\Windows\Fonts\SIMSUNB.TTF
-> ** TrueType Font: Family=Sylfaen Name=Sylfaen style=0 fileName=C:\Windows\Fonts\sylfaen.ttf

And therein lies the tragic of the issue: on Windows “DialogInput” includes the font “MingLiU” which in turn represents Unicode code point U+0092 as right single quotation mark (see here).

Conclusion
I appologize for falsely accusing SQL Developer to do something strange when it is perfectly fine. On the other hand, it’s utterly beyond me why someone would design a font to represent a PRIVATE USE TWO Unicode code point to be a printable, otherwise perfectly well-defined character.
When in doubt, change the SQL Developer properties to a physical font you know or get familiar with the code points it supports – know your font!

SQL Developer oddity on Windows

Recently, I have come across a bit of a strange behaviour in SQL Developer when verifying the correctness of the data entered into a database from various clients (Linux / Windows / Solaris) -> think of client characterset in NLS_LANG.
In various MOS notes Oracle propagates the use of SQL Developer as a “known good client” to check data in the database, e.g. 1628060.1.
The one thing that struck me was when SQL Deloper displayed a right single quotation mark instead of a blank square symbol “[]” (representing a non-printable character).

Before we go to the test case I need to clarify a few points:

  • Databases tested 11.2.0.3 and 11.2.0.4
  • All databases running AL32UTF8 database character set
  • All databases running AL16UTF16 national character set
  • SQL Developer version tested: 4.0.2.15

Now, let’s look what happens if I run following query:

select unistr('\0092') char_display, dump(unistr('\0092'), 16) char_dump from dual;

Result on Linux:

linux_sqldev

Result on Windows:

windows_sqldev

Basically, I’m asking the system to display Unicode code point U+0092 which is a private control character and is not associated with a printable symbol.
In my opinion the Linux version is returning the right result while the one on Windows clearly does some code page conversion.
So, if you’re running SQL Developer on Windows it might no longer be a “known good client” as for sure the result as shown is unexpected.