When I’m doing demonstrations of Oracle SQL Developer, I’m frequently asked about our support for datatypes like XML, BLOBS, Timestamp, etc. When I’m put on the spot like that, I have a tendency to forget that I already have tables setup for this. So I end up writing a query to find a table that has a specific datatype. And that just … sucks.

So I’ve written a report to do this for me. AND it will take me to that table so I can quickly demonstrate the datatype feature support.

All of the datatypes in my database mapped to existing table columns
All of the datatypes in my database mapped to existing table columns

So the list of datatypes comes back, along with count of columns per, ordered alphabetically. As I click on a datatype, it loads the list of tables and column names so I can see what’s attached.

Note that the table names are hyperlinked – yup, I can auto-open the table editor for those entries. This quickly puts me to the contents of the table so I can browse the data and use the data type editors.

You can also see in my screenshot that the standard ‘Find/Highlight’ data grid feature works for reports.

In my report I’ve also restricted several schemas from the search.

Here’s the report source if you want to beg, borrow, steal…

<?xml version="1.0" encoding="UTF-8" ?>
<displays>
<display id="a6f420c6-013d-1000-8001-0a9a6ee4aed4" type="" style="Table" enable="true">
<name><![CDATA[Datatypes – Tables By Type]]></name>
<description><![CDATA[]]></description>
<tooltip><![CDATA[]]></tooltip>
<drillclass><![CDATA[null]]></drillclass>
<CustomValues>
<TYPE>horizontal</TYPE>
</CustomValues>
<query>
<sql><![CDATA[select data_type, count(*)
from dba_tab_cols
where owner not in (‘CTXSYS’, ‘SYS’, ‘SYSTEM’, ‘SYSAUX’, ‘SYSMAN’, ‘MDSYS’, ‘WMSYS’)
group by data_type
order by 1 asc]]></sql>
</query>
<pdf version="VERSION_1_7" compression="CONTENT">
<docproperty title="" author="" subject="" keywords="" />
<cell toppadding="2" bottompadding="2" leftpadding="2" rightpadding="2" horizontalalign="LEFT" verticalalign="TOP" wrap="true" />
<column>
<heading font="Times New Roman" size="10" style="NORMAL" color="-16777216" rowshading="-1" labeling="FIRST_PAGE" />
<footing font="Times New Roman" size="10" style="NORMAL" color="-16777216" rowshading="-1" labeling="NONE" />
<blob blob="NONE" zip="false" />
</column>
<table font="Times New Roman" size="10" style="NORMAL" color="-16777216" userowshading="false" oddrowshading="-1" evenrowshading="-1" showborders="true" spacingbefore="12" spacingafter="12" horizontalalign="LEFT" />
<header enable="false" generatedate="false">
<data>
null	</data>
</header>
<footer enable="false" generatedate="false">
<data value="null" />
</footer>
<security enable="false" useopenpassword="false" openpassword="" encryption="EXCLUDE_METADATA">
<permission enable="false" permissionpassword="" allowcopying="true" allowprinting="true" allowupdating="false" allowaccessdevices="true" />
</security>
<pagesetup papersize="LETTER" orientation="1" measurement="in" margintop="1.0" marginbottom="1.0" marginleft="1.0" marginright="1.0" />
</pdf>
<display id="null" type="" style="Table" enable="true">
<name><![CDATA[Tables]]></name>
<description><![CDATA[]]></description>
<tooltip><![CDATA[]]></tooltip>
<drillclass><![CDATA[null]]></drillclass>
<CustomValues>
<TYPE>horizontal</TYPE>
</CustomValues>
<query>
<sql><![CDATA[select owner, ‘SQLDEV:LINK:’
||owner
||’:’
||’TABLE’
||’:’
||table_name
||’:oracle.dbtools.raptor.controls.grid.DefaultDrillLink’ table_name, column_name
from dba_tab_cols
where data_type = :DATA_TYPE — if you see a smiley here the text should be a COLON directly followed by uppercase D
and owner not in (‘CTXSYS’, ‘SYS’, ‘SYSTEM’, ‘SYSAUX’, ‘SYSMAN’, ‘MDSYS’, ‘WMSYS’)
order by 1,2,3]]></sql>
<binds>
<bind id="DATA_TYPE">
<prompt><![CDATA[DATA_TYPE]]></prompt>
<tooltip><![CDATA[DATA_TYPE]]></tooltip>
<value><![CDATA[NULL_VALUE]]></value>
</bind>
</binds>
</query>
<pdf version="VERSION_1_7" compression="CONTENT">
<docproperty title="" author="" subject="" keywords="" />
<cell toppadding="2" bottompadding="2" leftpadding="2" rightpadding="2" horizontalalign="LEFT" verticalalign="TOP" wrap="true" />
<column>
<heading font="Times New Roman" size="10" style="NORMAL" color="-16777216" rowshading="-1" labeling="FIRST_PAGE" />
<footing font="Times New Roman" size="10" style="NORMAL" color="-16777216" rowshading="-1" labeling="NONE" />
<blob blob="NONE" zip="false" />
</column>
<table font="Times New Roman" size="10" style="NORMAL" color="-16777216" userowshading="false" oddrowshading="-1" evenrowshading="-1" showborders="true" spacingbefore="12" spacingafter="12" horizontalalign="LEFT" />
<header enable="false" generatedate="false">
<data>
null	</data>
</header>
<footer enable="false" generatedate="false">
<data value="null" />
</footer>
<security enable="false" useopenpassword="false" openpassword="" encryption="EXCLUDE_METADATA">
<permission enable="false" permissionpassword="" allowcopying="true" allowprinting="true" allowupdating="false" allowaccessdevices="true" />
</security>
<pagesetup papersize="LETTER" orientation="1" measurement="in" margintop="1.0" marginbottom="1.0" marginleft="1.0" marginright="1.0" />
</pdf>
</display>
</display>
</displays>

How Did You Do the Hyperlink Thingy With the Table Names?

If you tell SQL Developer the data come back is being formatted as a link, it will behave as a link. An earlier blog post on the subject goes into more detail, but basically you need something like this in the SELECT

'SQLDEV:LINK:'
     ||owner
     ||':'
     ||object_type
     ||':'
     ||object_name
     ||':oracle.dbtools.raptor.controls.grid.DefaultDrillLink'

So being lazy-PM, I now have a report to save me a few seconds in my presentations so maybe I can cover a few extra questions 🙂

Author

I'm a Distinguished Product Manager at Oracle. My mission is to help you and your company be more efficient with our database tools.

5 Comments

  1. Hi Jeff,
    In my SQL Developer I have tablespace report without any gauges. Could you please share your version?

  2. Okay – so I guess I need a quick tutorial on how to build and save a report in SQL Developer. I created a User Defined report and copied your code in but get a bizarre error when I run it. Must have missed something…

    • Check the XML that was copied out from my blog, my SQL has a 😀 in it which might have got interpreted as a ‘smiley’ which may have been replaced with a WP image URL. I have a comment in that XML for that line.

Reply To Dmitry Cancel Reply