Browsing "Older Posts"

APEX-AT-WORK no image

Working with XML files and APEX - Part 1: Upload

Von Tobias Arnhold → 11.28.2013
Working with Oracle and XML can be a pain in the ass especially at the beginning when you don't know the hidden secrets. :) That's why I want to give some major hints how to integrate XML files in APEX applications.

This time I will provide an easy way how to upload a file into a table with a XMLType column.

Let's assume that this is our example XML file:
<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<leagues>
  <league id="1" name="2. Bundeliga">
    <teams>
      <team>
        <id>1</id>
        <name location="Dresden" stadium="Glücksgas-Stadion">SG Dynamo Dresden</name>
      </team>
      <team>
        <id>2</id>
        <name location="Cologne" stadium="RheinEnergieStadion">1. FC Köln</name>
      </team>
      <team>
        <id>3</id>
        <name location="Berlin" stadium="Alte Försterei">1. FC Union Berlin</name>
      </team>
      <team>
        <id>4</id>
        <name location="Düsseldorf" stadium="Esprit Arena">Fortuna Düsseldorf</name>
      </team>
    </teams>
  </league>
</leagues>

Now we need the necessary DDL:

--------------------------------------------------------
--  DDL for XML Table IMP_FM
--------------------------------------------------------
CREATE TABLE IMP_FM 
(
  ID NUMBER NOT NULL 
, USER_NAME VARCHAR2(20 BYTE) 
, XML_FILE XMLTYPE 
, CONSTRAINT IMP_FM_PK PRIMARY KEY 
  (
    ID 
  )
  ENABLE 
) 
XMLTYPE XML_FILE STORE AS BINARY XML ALLOW NONSCHEMA;

/

CREATE SEQUENCE IMP_FM_SEQ INCREMENT BY 1 MAXVALUE 9999999999999999999999999999 MINVALUE 1 NOCACHE;

/

CREATE OR REPLACE TRIGGER "IMP_FM_BI_TR" BEFORE
INSERT ON "IMP_FM" FOR EACH row 
BEGIN
 IF :NEW.USER_NAME IS NULL THEN 
    :NEW.USER_NAME := UPPER(NVL(v('APP_USER'),USER));
 END IF;
 IF :NEW.ID IS NULL THEN 
    SELECT IMP_FM_SEQ.NEXTVAL INTO :NEW.ID FROM DUAL;
 END IF;
END;
/

--------------------------------------------------------
--  DDL for Table ERR_LOG
--------------------------------------------------------

  CREATE TABLE "ERR_LOG" 
   ( "AKTION" VARCHAR2(4000), 
 "APP_ID" NUMBER, 
 "APP_PAGE_ID" NUMBER, 
 "APP_USER" VARCHAR2(10), 
 "ORA_ERROR" VARCHAR2(4000), 
 "CUSTOM_ERROR" VARCHAR2(4000), 
 "PARAMETER" VARCHAR2(4000), 
 "TIME_STAMP" DATE, 
 "PROC_NAME" VARCHAR2(500), 
 "CLOB_FIELD" CLOB
   ) ;
/

  ALTER TABLE "ERR_LOG" MODIFY ("PROC_NAME" NOT NULL ENABLE);
  ALTER TABLE "ERR_LOG" MODIFY ("TIME_STAMP" NOT NULL ENABLE);
  ALTER TABLE "ERR_LOG" MODIFY ("APP_USER" NOT NULL ENABLE);
  ALTER TABLE "ERR_LOG" MODIFY ("APP_PAGE_ID" NOT NULL ENABLE);
  ALTER TABLE "ERR_LOG" MODIFY ("APP_ID" NOT NULL ENABLE);
  ALTER TABLE "ERR_LOG" MODIFY ("AKTION" NOT NULL ENABLE);
/

Our XML table has the column XML_FILE from type XMLTYPE. Thats the place where our uploaded files will be saved in.
With XMLTYPE you need to define the way the XML should be saved. As I found out (thanks to Carsten Czarski) the "BINARY XML" option is the most effective one.

More details about the saving options can be found here:
http://www.oracle.com/technetwork/database-features/xmldb/xmlchoosestorage-v1-132078.pdf
http://www.liberidu.com/blog/2007/06/24/oracle-11g-xmltype-storage-options/
http://grow-n-shine.blogspot.de/2011/11/one-of-biggest-change-that-oracle-has.html

During my tests (30MB XML file) I started with the option "XMLTYPE XML_FILE STORE AS CLOB" which leaded to a real bad result time.
One of the selects had a executing time of 314 seconds
With the "XMLTYPE XML_FILE STORE AS BINARY XML" it went down to 1 second.

Ok my system did not had a lot of CPU or RAM but to show the difference out of a performance point of view it is a great example.

Last but not least we need the PL/SQL Code to upload our XML file:
For quality aspects I always use packages with some debug features when I need PL/SQL code. Thats why this example becomes maybe a bit bigger then it normally would be.

CREATE OR REPLACE 
PACKAGE PKG_IMP AS 

  procedure fm_imp (p_filename varchar2);

END PKG_IMP;

/

CREATE OR REPLACE 
PACKAGE BODY PKG_IMP AS

/* ********************* */
/* Package Variables     */
/* ********************* */
  gv_proc_name    VARCHAR2(100);
  gv_action       VARCHAR2(4000);
  gv_ora_error    VARCHAR2(4000);
  gv_custom_error VARCHAR2(4000);
  gv_parameter    VARCHAR2(4000);
  gv_apex_err_txt VARCHAR2(500);
  

  GV_USERNAME     VARCHAR2(100)     := UPPER(NVL(v('APP_USER'),USER));

/* ********************* */
/* Save errors           */
/* ********************* */
PROCEDURE ADD_ERR  IS
   PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
     INSERT
     INTO ERR_LOG
      ( PROC_NAME,AKTION,APP_ID,APP_PAGE_ID,APP_USER,ORA_ERROR,CUSTOM_ERROR,PARAMETER,TIME_STAMP )
      VALUES
      ( gv_proc_name,gv_action,nvl(v('APP_ID'),0),nvl(v('APP_PAGE_ID'),0),nvl(GV_USERNAME,'Unknown'),
        gv_ora_error,gv_custom_error,gv_parameter,sysdate );
     COMMIT;
END; 

/* ********************* */
/* Import Procedure      */ 
/* ********************* */

procedure fm_imp (p_filename varchar2) AS
 
  v_blob BLOB;
  v_xml  XMLTYPE;

BEGIN
  gv_proc_name := 'pkg_imp.fm_imp';
  gv_parameter := '';
 
  gv_parameter := 'p_filename: ' || p_filename;
  
  gv_action := 'Delete old data';
  DELETE FROM IMP_FM
   WHERE user_name = GV_USERNAME;
   
 
  gv_action := 'Read file';
  SELECT blob_content 
    INTO v_blob
    FROM wwv_flow_files
   WHERE name = p_filename;
  
  gv_action := 'XML Conversion';
  v_xml := XMLTYPE (v_blob,NLS_CHARSET_ID('AL32UTF8'));
  /* UTF-8 clause because we use it in our XML file */

  gv_action := 'Insert in IMP_BESTELLLISTE_XML';
  INSERT
  INTO IMP_FM
    ( USER_NAME, XML_DATEI )
  VALUES
    ( GV_USERNAME, v_xml );

  gv_action := 'Delete file';
  DELETE FROM wwv_flow_files
    WHERE name = p_filename;

  COMMIT;
  
EXCEPTION
WHEN OTHERS THEN   
      gv_ora_error := SQLERRM;
      gv_custom_error := 'Internal Error. Action canceled.';
      ROLLBACK;
      ADD_ERR; raise_application_error(-20001, gv_custom_error);
          
END fm_imp; 
END PKG_IMP;

Inside APEX you call our procedure as SUBMIT PL/SQL Process:

  PKG_IMP.FM_IMP (:P1_FILE);
  -- P1_FILE is the file browse item.
That's it.

BTW: My SQL Developer stopped working / got really slow when I tried to update a BINARY XML column.

Next time I will write about my troubles in selecting XML data as readable SQL result.
APEX-AT-WORK no image

Switching from Windows to Mac

Von Tobias Arnhold → 11.24.2013
A year ago I bought a Macbook Pro and tried to develope APEX applications with it successfully.
You may ask yourself why? I just want to stay "up to date" and work with the best technique on the market. A couple of colleagues mentioned the performance is better with Mac. Reason enough for me to check it out.

I never needed many special developer tools to build APEX applications in Windows:

 - SQL Developer / Data Modeler - SQL/PLSQL development
 - Firefox + Firebug - APEX development
 - Notepad++ - Universal code editor
 - Greenshot - Make screen copies
 - WinMerge - Compare files
 - Gimp - Working with images
 - MS Office - Documentation / Importing / Presentation
 - Virtual Box - Virtual environment

All these tools (except MS Office) do not need an installation (portable version available) and became my standard apex-at-work-kit for each company. I hated to get used to different development-tools all the time.

With Mac I tried to find the same or at least similar tools which I was used to work with in Windows before:

 - SQL Developer / Data Modeler
 - Firefox + Firebug
 - Ultraedit (is payware but no freeware came so close to Notepad++ like Ultraedit)
 - Skitch
 - No good alternative found yet, but you could check out this link: apple.stackexchange.com
 - Gimp
 - MS Office
 - Virtual Box

The performance of my Macbook Pro (bought on Ebay and extended with SSD and RAM) is actually amazing. At the moment there is no reason to change from testing mode into buying the newest model mode. :)

Next step is to test APEX development on Windows 8.1 :)

I don't want to decide about the best OS. For me it is just interesting finding the most effective way in developing APEX applications.

Btw.: You may wonder why I didn't say anything about SVN or similar tools. Most companies have their own software versioning-tools which means company dependent solutions. My point of interest is company-independent-tools.

There are a lot of more necessary tools but to 95 % of the time I work with the described ones.





APEX-AT-WORK no image

APEX sei ein langsames Tool

Von Tobias Arnhold → 11.14.2013
Nachdem ich den Blogpost von Joel Kallman gelesen habe, dachte ich mir ein paar eigene Erfahrungen zum Thema APEX und Performance beizutragen.

Die Aussage APEX sei ein langsames inperformantes Tool, ist einfach nur FALSCH!
Wenn jemand ein Auto mit angezogener Handbremse fährt, dann liegt die langsame Geschwindigkeit nicht am Auto sondern am Fahrer.
Wenn ich in meiner APEX Anwendung inperformanten PL/SQL, SQL oder JS Code einbaue, dann liegt es nicht an APEX sondern an mir, der die internen Funktionalitäten nicht versteht. Der Aussage lieber in Oracle Skills statt in APEX Skills zu investieren kann ich nur beipflichten. Wobei ich statt Oracle Skills eher die SQL Skills im Vordergrund sehe.

In meiner Zeit als Festangestellter und als Freelancer habe ich mit verschiedensten APEX Versionen in unterschiedlichsten Hardware Umgebungen gearbeitet.
Von einer virtuellen 1 CPU Umgebung bis hin zur Exadata war alles dabei. Die inhaltlichen Anforderungen waren bei den LowCost Systemen teilweise anspruchsvoller als in den High Performance Umgebungen.

Wo liegt nun der Schlüssel zum Erfolg?
Meiner Meinung nach in weniger PL/SQL und vielmehr in guten SQL, durchdachter Konzeption und der Verwendung von möglichst viel APEX Standard Funktionalität! 
Die meisten komplexen PL/SQL Themen kann ich mit Hilfe von Oracle Standard SQL Funktionen lösen. Beispiel: "Analytische Funktionen"

Ich meine, Sie arbeiten mit einer der schnellsten Datenbanksoftware auf dem Markt.
Was kann diese am Besten? SQL.

Natürlich ist und bleibt ein erheblicher Erfolgsfaktor einer jeden APEX Lösung, die notwendige Konzeptarbeit am Anfang eines jeden Projektes zu leisten. Da kann auch das Beste SQL schnell zum scheitern Verurteilt sein. Folgende Fragen sollten dabei immer in Betracht gezogen werden?

Was mache ich eigentlich für ein Projekt: OLTP oder OLAP? 
Wie komplex sind die Tabellenstrukturen?
Wie sieht das Mengengerüst aus ?
Wie viele Datensätze werden die Tabellen haben?
Kann ich eventuell Daten auch redundant abspeichern?
Wird das System auf Dauer erheblich mehr Datensätze generieren?
Wenn ja, wie viele? Welche Tabellen sind betroffen? Benötige ich spezielle Tests?
Sind Bottlenecks erkennbar?
Welche Schnittstellen müssen integriert/geschaffen werden?
Gibt es bereits Erfahrungen mit diesen Schnittstellen?
Werden sich auch nach Fertigstellung der Anwendung häufig die Anforderungen ändern?
Haben schon andere Entwickler versucht die Anforderungen umzusetzen? Wenn ja, dann gilt es hier besonders zu Glänzen. :) ...und den Kunden nicht wieder zu enttäuschen.

Statt sich einzig und allein an Vorstudien oder Konzepten zu orientieren, sollte der Kontakt zum Kunden gesucht werden.

Warum?
Die meisten Dokumente die den Inhalt einer neuen Anwendung transportieren sollen, hören dabei immer bei den komplexen Themen auf Antworten zu liefern. Nur die Fachverantwortlichen können einem frühzeitig mit entsprechenden Hinweisen aufkommende Probleme erkennen lassen.
Außerdem kann der Kunde so frühzeitig auf visuelle und funktionale Entscheidungen einwirken.

Nur weil jeder mit APEX sehr schnell Lösungen generieren kann, heißt dies nicht, dass jegliche Softwareentwicklungsprinzipien außer Kraft gesetzt werden können und dürfen.





APEX-AT-WORK no image

Example using the analytical function: LAG

Von Tobias Arnhold → 11.13.2013
I'm actually a big fan of using analytical functions instead of using SUB-Selects or custom PL/SQL functions.

The reason is quite simple: 
You save a lot of SQL executing time.

Another positive side is: 
The amount of code lines is also less then the other two solutions would need.

Negativ aspect:
You need to understand the logic behind analytical functions and you need to practice with them. :)

What was my problem?
I had some incomplete data to fix. Some rows of one column in my table were not filled. For my luck I did know that the previous row included the right value.

Here the example:
/* Using the LAG function */
select  OE2.ID, 
        OE2.CAR_NO,
        CASE WHEN OE2.CAR_NO IS NULL THEN
                  LAG(OE2.CAR_NO, 1, 0) OVER (ORDER BY OE2.ID)
            ELSE  OE2.CAR_NO END as CAR_NO_FIXED
 from TBL_ORDER_LIST OE2
 
/* Using the SUB-Select */
select  OE2.ID, 
        OE2.CAR_NO,
        CASE 
        WHEN OE2.CAR_NO IS NULL THEN ( SELECT OE1.CAR_NO
                                      FROM TBL_ORDER_LIST OE1 
                                      WHERE OE2.ID = OE1.ID-1
                                     )
        ELSE OE2.CAR_NO END AS CAR_NO_FIXED
 from TBL_ORDER_LIST OE2

The more rows you have in the table the bigger will be the difference in execution time.

If you want to know more about the LAG function.
Try this link:
http://www.oracle-base.com/articles/misc/lag-lead-analytic-functions.php