Thursday, July 31, 2008

Manually Creating a Tabular Form

When I first started developing in APEX (back when it was called HTMLDB) I had a requirement for a tabular form. I tried to use the standard tabular forms but it was very limited and I couldn't customize it to meet my requirements. I had poked around on the APEX forum, but wasn't able to find a reasonable solution.

After several iterations, I have come up with a process that works extremely well. It is slightly labor intensive but it has met all the requirements each time. Please note that Patrick Wolf, http://www.inside-oracle-apex.com/, has developed an open source framework to handle customized tabular forms. Though it is very good it does not allow for complete access. Marcie Young did a presentation at ODTUG 2008 which outlined a very similar method, this example is taking it a step further. A working example is available here: http://apex.oracle.com/pls/otn/f?p=20195:200

The process below will not only build a customized tabular form, but also handle the errors etc.

Overview
Here's an overview of the overall methodology
- Create 2 collections. One will handle data: DATA_COLLECTION and one will handle the errors: ERROR_COLLECTION.
- The DATA_COLLECTION will be loaded on the first viewing of the page and will only be refreshed from the database when the changes have been sent to the database.
- The ERROR_COLLECTION will contain errors specific for the corresponding entry in the DATA_COLLECTION. We could keep this in the same collection, but I like to keep them separate. It makes things easier if we need to add or remove columns.
- In the ERROR_COLLECTION I keep column 50 reserved for the row error. An example of when you'd need a row error is when you have a start and end date and the end date is before the start date.
- This application will allow users to modify the emp.ename and emp.salary fields
- In the data collection I keep column 1 reserved for the sequence id (seq_id). Note though I won't use it in this example, it has come in handy (especially when hiding/delete rows in the front end then submitting the page)

Getting Started

Step 1: Create a PL/SQL Process On Load Before Header called Create Collection
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
DECLARE
BEGIN
   IF NVL (:p200_reload_flag, 'N') = 'N'
   THEN
      -- IF error collection exists, delete
      IF apex_collection.collection_exists
                                     (p_collection_name      => 'ERROR_COLLECTION')
      THEN
         apex_collection.delete_collection
                                     (p_collection_name      => 'ERROR_COLLECTION');
      END IF;
 
      -- Create New Collection
      apex_collection.create_or_truncate_collection ('DATA_COLLECTION');
 
      FOR rec IN (SELECT   e.empno, e.ename, e.sal
                      FROM emp e
                  ORDER BY e.ename)
      LOOP
         apex_collection.add_member (p_collection_name      => 'DATA_COLLECTION',
                                     p_generate_md5         => 'NO',
                                     p_c002                 => rec.empno,
                                     p_c003                 => rec.ename,
                                     p_c004                 => TO_CHAR
                                                                      (rec.sal),
                                     -- Remember the collection is only text
                                     p_c049                 => 'Y',
                                     -- Modifiable Flag
                                     p_c050                 => 'U'
                                    -- SQL Action (Insert, Update, Delete)
                                    );
      END LOOP;
   --
   END IF;
 
-- Create Extra rows (if we wanted to add a new employee
   FOR i IN 1 .. NVL (:p200_num_extra_rows, 0)
   LOOP
      apex_collection.add_member (p_collection_name      => 'DATA_COLLECTION',
                                  p_generate_md5         => 'NO',
                                  p_c002                 => -1,
                                  -- use negative numbers for new employees
                                  p_c049                 => 'Y',
                                  p_c050                 => 'I'
                                 );
   END LOOP;
 
   -- Insert seq_id
   FOR rec IN (SELECT ac.seq_id
                 FROM apex_collections ac
                WHERE ac.collection_name = 'DATA_COLLECTION')
   LOOP
      apex_collection.update_member_attribute
                                   (p_collection_name      => 'DATA_COLLECTION',
                                    p_seq                  => rec.seq_id,
                                    p_attr_number          => 1,
                                    p_attr_value           => rec.seq_id
                                   );
   END LOOP;
END;

Step 2: Create a Report / SQL Report region for our custom tabular form called Employee Data
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
SELECT
   -- Notice how I'm keeping the idx value the same as the column value in the collection. This helps to keep things organized
   -- I also apply an id to each entry
   -- I append the error value to the empname and sal
   -- The Seq_id. Usefull when hiding rows (for delete) and then submitting from
   apex_item.hidden(1,x.seq_id, null, x.seq_id || '_seq_id') ||
   -- The Primary Key of the column
   apex_item.hidden(2, x.empno, null, x.seq_id || '_empno_id') || x.empno empno,
   -- Employee Name
   apex_item.text(3,x.empname,null, null, null, x.seq_id || '_empname_id') || err.empname employee_name,
   -- Employee Salary
   apex_item.text(4,x.sal, null, null, null, x.seq_id || '_sal_id') || err.sal ||
   -- Store the sql action type as well.
   apex_item.hidden(50,x.sql_action_typ, null, x.seq_id || '_sql_action_typ_id') sal,
   -- Last but not least the row error
   err.row_error
FROM   (SELECT  ac.c001 seq_id,
                ac.c002 empno,
                ac.c003 empname,
                ac.c004 sal,
                ac.c049 modifiable_flag,
                ac.c050 sql_action_typ
       FROM     apex_collections ac
       WHERE    ac.collection_name = 'DATA_COLLECTION'
       ORDER BY ac.seq_id) x,
      
      -- Error Collection
      (SELECT   ac.seq_id seq_id,
                ac.c002 empno,
                ac.c003 empname,
                ac.c004 sal,
                ac.c050 row_error -- Useful when individual data is correct, however the row of data is not. Ex: start/end dates
       FROM     apex_collections ac
       WHERE    ac.collection_name = 'ERROR_COLLECTION'
       ORDER BY ac.seq_id) err
WHERE x.seq_id = err.seq_id(+)        

Step 3: Add Region items and buttons

All items/buttons should be added to the report region
Create Buttons:
ADD, submit page. Branch to &APP_PAGE_ID.
SUBMIT, submit page. Branch to 201
Note: Page 201 is a simple sql report for
1
2
3
4
SELECT *
FROM EMP

Create Hidden and Protected Items:
P200_DISPLAY_ROW_ERROR_FLAG
- Source value or expression: N
- Comment: Used to determine if the error column should be displayed
P200_NUM_EXTRA_ROWS
- Source value or expression: 1
- Comment: Number of extra rows to add to the tabular form
P200_RELOAD_FLAG
- Comment: If Y then we won't refresh the collection with database values

Computations (After Submit)
P200_NUM_EXTRA_ROWS
Static: 1
Condition: Request = ADD

P200_NUM_EXTRA_ROWS
Static: 0
Condition: Request != ADD

P200_RELOAD_FLAG
Static: Y
Condition: None

P200_DISPLAY_ROW_ERROR_FLAG
Static: N
Condition: None

Step 4: Store Collection
After submit, this will store the data from the form into the collection. No data validation is performed at this point

Process: Store Collection
Type: PL/SQL Anonymous Block
Processing Point: On Submit: Before Computation and Validations
Source:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
DECLARE
BEGIN
 FOR i IN 1 .. apex_application.g_f01.COUNT LOOP
   apex_collection.update_member (p_collection_name            => 'DATA_COLLECTION',
-- I know some of you are still wondering why were are still wondering why I stored the seq_id as a collection attribute. This is why. If you had hidden the row (i.e. let the user "delete" it) then it would not show up on this and your collection synchronization wouldn't be correct.
          p_seq                        => apex_application.g_f01 (i), -- Sequence ID
                                  p_c001                       => apex_application.g_f01 (i), -- Sequence ID
                                  p_c002                       => apex_application.g_f02 (i), -- Empno
                                  p_c003                       => apex_application.g_f03 (i), -- Empname
                                  p_c004                       => apex_application.g_f04 (i), -- Sal
                                  p_c049                       => 'Y',   -- Modifiable Flag
                                  p_c050                       => UPPER(apex_application.g_f50 (i))
                                 );
 END LOOP;
END;

Step 5: Validation

Type: Page Level Validation
Type: PL/SQL - Function returning Error Text
Name: Validate Collection
Condition: When Button Pressed - SUBMIT
Validation Expression:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
DECLARE
   v_err_msg   VARCHAR2 (255);
BEGIN
   -- IF error collection exists, truncate. Else Create
   IF apex_collection.collection_exists
                                     (p_collection_name      => 'ERROR_COLLECTION')
   THEN
      apex_collection.truncate_collection
                                     (p_collection_name      => 'ERROR_COLLECTION');
   ELSE
      -- Create Error Collection
      apex_collection.create_or_truncate_collection ('ERROR_COLLECTION');
   END IF;
 
   -- Basic Check. Make sure the emp name is more than 5 chars long
   FOR x IN (SELECT ac.c003 empname, ac.c004 sal, ac.seq_id
               FROM apex_collections ac
              WHERE ac.collection_name = 'DATA_COLLECTION')
   LOOP
      -- Always add a blank error
      apex_collection.add_member (p_collection_name => 'ERROR_COLLECTION');
 
      IF LENGTH (x.empname) < 5
      THEN
         apex_collection.update_member
            (p_collection_name      => 'ERROR_COLLECTION',
             p_seq                  => x.seq_id,
             p_c003                 => '
<span style="color:red">Name must be 5 Chars</span>'
            );
         v_err_msg := 'Error Occured';
      END IF;
 
      -- Add a "row level" check for demo purposes
      IF LENGTH (x.empname) = LENGTH (x.sal)
      THEN
         apex_collection.update_member
             (p_collection_name      => 'ERROR_COLLECTION',
              p_seq                  => x.seq_id,
              p_c050                 => '
<span style="color:red">Row Level Error</span>'
             );
         apex_util.set_session_state (p_name       => 'P200_DISPLAY_ROW_ERROR_FLAG',
                                      p_value      => 'Y'
                                     );
         v_err_msg := 'Error Occured';
      END IF;
   END LOOP;
 
   RETURN v_err_msg;
END;

Step 6: Finishing it off

As you notice there's a column called: row_error. Set the condition where item: P200_DISPLAY_ROW_ERROR_FLAG = Y.