Checkboxes in editable reports in APEX

We have all been there, we need to create an editable report and one of the columns contains a checkbox. So how should you handle this?

If you are using one of the recent APEX versions the easiest way is a tabular form. Just edit the column attributes of your checkbox column and at display as select “Simple Checkbox”. At the list of values definition type “Y,N”, where Y is the value the column will get when the checkbox is checked.

Tabular form checkbox

But what if you have multiple editable reports that have this requirement on one page? Then it starts to get interesting, since you can no longer use tabular forms.

With multiple editable reports we will be making our own editable report by using the API APEX_ITEM. You can read more about the APEX_ITEM API here.

We first create a report, and in our query we add our “active” column. We create two items there using the APEX_ITEM API: a checkbox and a hidden item. The parameter p_idx is the number  that apex uses to identify the items and write them in an APEX collection when the page is submitted. This has to be unique on the page. We set the value of both items to the id of the column. Why we need these will become clear later on.

SELECT APEX_ITEM.HIDDEN(p_idx =>1, p_value => id)

             ||APEX_ITEM.CHECKBOX(p_idx => 2, p_value => id , p_attributes => DECODE(active,’Y’,’checked=”checked”‘, NULL)) active

FROM MYTABLE

Next we go to report attributes, edit our active column and set display as Standard Report Column. This will allow APEX to render this properly.

Column attributes for APEX_ITEM API

Before we precede let me explain how checkboxes work. In HTML a checkbox that is not checked has no value it is considered NULL. This is something you will have noticed when you create a checkbox page item in APEX in a form. So if we loop over our APEX collection containing the checkboxes we will only loop over the checkboxes that have a value. This is no issue when you only need it to delete rows, but let me show you what happens if you try to use it to update rows. Let’s assume we have two columns, one contains our ID, and one contains our Checkbox with value Y.

APEX_ITEM.HIDDEN(p_idx => 1, p_value => id) APEX_ITEM.CHECKBOX(p_idx => 2, p_value => ‘Y’)
1 Checked
2 Not checked
3 Checked
4 Not checked

Assume we then loop over our first collection and do an update statement in our table:

FOR i in 1..APEX_APPLICATION.G_F01.COUNT LOOP

UPDATE MYTABLE SET active=NVL(APEX_APPLICATION07.G_F02(i),’N’)

WHERE id = APEX_APPLICATION.G_F01(i);

END LOOP;

Looks correct doesn’t it? Well it isn’t. When our process goes over the first row it will update correctly. When he tries to update the 2nd row he will update it wrongly to ‘Y’. And the 3rd row will give an error. That is because our 2nd APEX collection only contains two rows. It does not contain the rows that are not checked.

So now that I explained the problem let’s have a look at the solution.

DECLARE

l_yesno VARCHAR2(1);

TYPE t_checkboxes IS TABLE OF VARCHAR2(1);

l_checkboxes t_checkboxes := t_checkboxes();

BEGIN

FOR i IN 1..APEX_APPLICATION.G_F01.COUNT LOOP

FOR j IN  1..APEX_APPLICATION.G_F02.COUNT LOOP

IF APEX_APPLICATION.G_F01(i) = APEX_APPLICATION.G_F02(j) THEN

l_yesno := ‘Y’;

END IF;

END LOOP;

l_yesno := NVL(l_yesno,’N’);

l_checkboxes.EXTEND;

l_checkboxes(i) := l_yesno;

l_yesno := ‘N’;

END LOOP;

 

FORALL i IN INDICES OF APEX_APPLICATION.G_F01

UPDATE MYTABLE

SET ACTIVE = l_checkboxes(i)

WHERE id = APEX_APPLICATION.G_F01(i);

END;

We start by looping over our APEX collection containing our ID, inside that same loop we loop over the APEX collection with our checkboxes. Both contain as value our ID. If the values match, then the checkbox containing that ID has value ‘Y’. We insert this into a PL/SQL collection that we made for this purpose.

Lastly we do an update in our table, to set our new values. Notice how we only did one update statement using FORALL, and by doing so we limited our context switch to just one, and boosted our performance.

I now hope that everyone got a better idea of how they can deal with checkboxes rather easy, using only PL/SQL and APEX API’s.

5 thoughts on “Checkboxes in editable reports in APEX

  1. Hi, I follow every step that you write here. but somehow, when i click update, the value is not updated. it seems like the query doesn’t give any effect. do you think that I miss something?
    This is my query when I did select for the report:
    select TBL_INVOICE.INVOICE_ID as INVOICE_ID,
    TBL_INVOICE.INVOICE_NAME as INVOICE_NAME,
    dbms_lob.getlength(“INVOICE_FILE”) “INVOICE_FILE”,
    TBL_INVOICE.INVOICE_MIME_TYPE as INVOICE_MIME_TYPE,
    TBL_INVOICE.FORM_ID as FORM_ID,
    TBL_INVOICE.PRICE as PRICE,
    TBL_INVOICE.IS_RECOMMENDED as IS_RECOMMENDED,
    TBL_COMPANY.COMPANY_NAME as COMPANY_NAME,
    CASE WHEN TBL_INVOICE.IS_RECOMMENDED = 1 THEN apex_item.checkbox(1,TBL_INVOICE.IS_RECOMMENDED, ‘CHECKED’)
    WHEN TBL_INVOICE.IS_RECOMMENDED = 0 THEN apex_item.checkbox(1,TBL_INVOICE.IS_RECOMMENDED, ‘UNCHECKED’)
    END AS “Recommendation”
    from TBL_COMPANY TBL_COMPANY,
    TBL_INVOICE TBL_INVOICE
    where TBL_COMPANY.COMPANY_ID=TBL_INVOICE.COMPANY_ID AND TBL_INVOICE.FORM_ID=:P3_FORM_ID;

    1. Hello guest, thanks for trying our solution.

      The idea with this is to have the primary key of the record as the value of the checkbox.
      In this case, I guess, you would need to pass TBL_INVOICE.INVOICE_ID instead of TBL_INVOICE.IS_RECOMMENDED for the second parameter of APEX_ITEM.checkbox.

      Can you give this a try?

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

About Joni Vandenberghe