Do you know the difference between USER_TAB_COLS & USER_TAB_COLUMNS?

I just noticed the difference – I was wondering why I couldn’t see the virtual columns (i.e. columns that support function-based indexes) on a table, and it was because I was querying USER_TAB_COLUMNS. Once I used USER_TAB_COLS instead there they were.

The difference is noted in the documentation (Oracle 10g Release 2 (10.2)) for USER_TAB_COLS and ALL_TAB_COLS but not for USER_TAB_COLUMNS or ALL_TAB_COLUMNS, unfortunately.


Replace the default XDB welcome page

I was annoyed that to get to my main PL/SQL page I have to type in a full URL like this:

http://host:7777/mydad/home

(e.g. “mydad” could be “apex” for Oracle Apex)

If I was using Apache HTTP Server I’d do something this article suggests. But I’m using Oracle’s Embedded PL/SQL Gateway.

A. I got rid of the “:7777” by changing the HTTP port to 80, e.g.:

SQL> exec dbms_xdb.sethttpport(80);

Now, I can get to it without the port number:

http://host/mydad/home

B. Now I want to remove the need to remember to type “home”. To do this, I just tell the DAD what the default page is:

SQL> exec dbms_epg.set_dad_attribute('MYDAD','default-page','home');

Now, the url is a bit simpler:

http://host/mydad

The URL is now rewritten automatically to point to “mydad/home”.

C. Finally, I want to remove the need to specify the DAD. To do this is a little more complicated. I’ll create an XDB resource that will override the default XDB navigator that comes up.

    1. Log into Enterprise Manager

 

    1. Open the “Administration” tab and select “Resources” under “XML Database”

 

    1. Click “Create” and set the fields as follows:
      Owner = SYS
      Name = index.html
      Location = /
      Type = XML Database Resource File
      Source = Specify the file contents
      Contents =
      <html><head><meta http-equiv="REFRESH" content="0; URL=http://host/mydad"></head><body><a href="http://host/mydad">Home</a></body></html>

 

  1. Click “Ok”

(you’ll need to change “host” and “mydad” to appropriate values in the sample Contents above)

Now, the url is simply:

http://host

This causes it to load the index.html page from the XML database, which redirects to the DAD, the default page for which is “home”.


APEX 3.0 via Embedded PL/SQL Gateway

I managed to get APEX 3.0 working on Oracle 10.2.0.1 using the embedded PL/SQL gateway (i.e. without installing Apache), contrary to the advice given here. I used apex_epg_config instead of apex_epg_config11. For it to work, however, I had to remove some security on XDB so it’s not a recommended option. This involved modifying my xdbconfig.xml to allow anonymous access to XDB using this:

DECLARE
  configxml SYS.XMLType;
BEGIN
  SELECT INSERTCHILDXML(xdburitype('/xdbconfig.xml').getXML(),
         '/xdbconfig/sysconfig/protocolconfig/httpconfig',
         'allow-repository-anonymous-access',
         XMLType('true'),
         'xmlns=&quot;http://xmlns.oracle.com/xdb/xdbconfig.xsd&quot;')
  INTO configxml FROM DUAL;
  DBMS_XDB.cfg_update(configxml);
END;
/

Now for some general tips:

Tip #1. List Your DAD Authorizations

As described so well in the excellent article DBMS_EPG – The Embedded PL/SQL Gateway in Oracle 10g Database Release 2, you can authorize and deauthorize a DAD using the DBMS_EPG package. It should be noted that dropping a DAD will not remove the authorizations as well, so you need to deauthorize it as well. To find out what authorizations have been made on your database, you can query the DBA_EPG_DAD_AUTHORIZATION view, e.g.:

SQL&gt; select * from dba_epg_dad_authorization;

DAD_NAME USERNAME
-------- ---------
APEX     ANONYMOUS

1 row selected.

There’s also a USER_EPG_DAD_AUTHORIZATION view which shows the DAD_NAME for authorized DADs for the current user.


Tip #2. List Your DADS

You can find out what DADs have been set up on your instance using the DBMS_EPG package. There is a bug, however, that causes dbms_epg.get_all_dad_attributes to return nothing, so this script gets each attribute separately with dbms_epg.get_dad_attribute. The script lists all the DADS, their mappings and their attributes.

set serveroutput on

PROMPT list all dads
declare
  blank       dbms_epg.varchar2_table;
  dad_names   dbms_epg.varchar2_table;
  paths       dbms_epg.varchar2_table;
  procedure show_dad_attribute(dad in varchar2, attr in varchar2) is
    val varchar2(4000);
  begin
    val := dbms_epg.get_dad_attribute(dad, attr);
    if val is not null then
      dbms_output.put_line('... ' || attr || '=' || val);
    end if;
  end;
begin
  dbms_epg.get_dad_list(dad_names);
  if dad_names.count &gt; 0 then
    for i in dad_names.first..dad_names.last loop
      dbms_output.put_line(dad_names(i));
      paths := blank;
      dbms_epg.get_all_dad_mappings(dad_names(i), paths);
      if paths.count &gt; 0 then
        for j in paths.first..paths.last loop
          dbms_output.put_line('... path=' || paths(j));
        end loop;
      else
        dbms_output.put_line('... No mappings found');
      end if;
      show_dad_attribute(dad_names(i),'after-procedure');
      show_dad_attribute(dad_names(i),'always-describe-procedure');
      show_dad_attribute(dad_names(i),'authentication-mode');
      show_dad_attribute(dad_names(i),'before-procedure');
      show_dad_attribute(dad_names(i),'bind-bucket-lengths');
      show_dad_attribute(dad_names(i),'bind-bucket-widths');
      show_dad_attribute(dad_names(i),'cgi-environment-list');
      show_dad_attribute(dad_names(i),'compatibility-mode');
      show_dad_attribute(dad_names(i),'database-username');
      show_dad_attribute(dad_names(i),'default-page');
      show_dad_attribute(dad_names(i),'document-path');
      show_dad_attribute(dad_names(i),'document-procedure');
      show_dad_attribute(dad_names(i),'document-table-name');
      show_dad_attribute(dad_names(i),'error-style');
      show_dad_attribute(dad_names(i),'exclusion-list');
      show_dad_attribute(dad_names(i),'fetch-buffer-size');
      show_dad_attribute(dad_names(i),'input-filter-enable');
      show_dad_attribute(dad_names(i),'info-logging');
      show_dad_attribute(dad_names(i),'owa-debug-enable');
      show_dad_attribute(dad_names(i),'max-requests-per-session');
      show_dad_attribute(dad_names(i),'nls-language');
      show_dad_attribute(dad_names(i),'path-alias');
      show_dad_attribute(dad_names(i),'path-alias-procedure');
      show_dad_attribute(dad_names(i),'request-validation-function');
      show_dad_attribute(dad_names(i),'session-cookie-name');
      show_dad_attribute(dad_names(i),'session-state-management');
      show_dad_attribute(dad_names(i),'transfer-mode');
      show_dad_attribute(dad_names(i),'upload-as-long-raw');
    end loop;
  else
    dbms_output.put_line('No dads found');
  end if;
end;
/

When the above script is run, you’ll get something like this:

APEX
... path=/apex/*
... authentication-mode=Basic
... database-username=ANONYMOUS
... default-page=apex
... document-path=docs
... document-procedure=wwv_flow_file_mgr.process_download
... document-table-name=wwv_flow_file_objects$
... nls-language=american_america.al32utf8
... request-validation-function=wwv_flow_epg_include_modules.authorize