Search code examples
sqloracleoracle-apexdatagridviewlinkcolumn

Trying to create an APEX Link Column that queries a report


Basically, say I have a report A and I want to add a link column to it, and I set its target to a page in the application...the page its referring to has another report (lets call it B)

Is it possible for me to somehow make it so that table A's link column opens the page with Report B with rows that have the same column value for one of their columns?


Example here:

A

Name Num1 Num2
--------------
A    5    3
B    3    3
C    4    2

B

Name Quantity Serial
--------------------
D    2        3
E    1        8
F    4        6

So if I click the link column for row A, I want it to open report B and only shows rows where its Num2 = Serial, so only row D would show since it is the only one that equals 3


Solution

  • Using Report Linking to Filter Other APEX Report Outputs

    I had some fun with this one although. The "A" and "B" stuff was pretty dry, so I decided to create a data set that was more engaging, and perhaps clearer to understand for the rest of us... :) This is how the data-ecosystem was broken down, and the way I fulfilled the OP requirements.

    The Test Schema:

    Welcome to the manufacturing facilities of the "Recipe Stack" Food Works. The schema design and ERD (Entity Relation Diagram) is below, with the sample data used for this demonstration:

    Stack Recipe Works ERD

    The data relations are as follows:

    1. The staff at the Stack Food-Works keeps an inventory of all ingredients for the types of meals and prepared foods they manufacture. Each ingredient has a unique ID (INGREDIENT_ID) and the staff tracks the amounts of each item in their pantry.
    2. Each ingredient can be used in multiple recipes, but they will be used exactly once for a given recipe.
    3. The ENTREE_RECIPE table has a COMPOSITE KEY which means it is the combination of the two pieces of this composite key (ENTREE_NAME and INGREDIENT_SEQ) that should be unique.
    4. There is a FOREIGN KEY relation between the INGREDIENT_ID values of both tables.

    Report Display Requirements (APEX and SQL Design Elements)

    Selecting an item from the FIRST report is used as the input and the restriction/filter criteria of the second report.

    User Case #1:

    1. User Selects a Ingredient ID from the list of available ingredients in the pantry.
    2. Input from (1) filters output of the RECIPE REPORT. This is a list of all the recipes that have the chosen ingredient in their formula.

    User Case #2:

    1. User Selects an ENTREE_NAME from the RECIPE REPORT. The ENTREE_NAME is used to deliver a third report: the RECIPE FORMULA which is the full recipe for the entree item that was selected from the previous report.

    Testing Tools

    (You usually need these these for the more complex pages, so it's a good start to use or develop them for the easier ones...)

    I made my own, but you can also invoke the SESSION link on the developer's tool bar at the bottom of the APEX page on your running application (when it is displayed).

    APEX Session Tracking Link (Developer Toolbar)

    Here's my idea; it's a header region that also has a button to RESET input values so that I can clear the cache and retest or try other examples. I'll show later how you can use this link to see what is going on. You can see it in the discussion of testing at the bottom of this guide.

    APEX Report/Page Design and SQL Parametrization

    My columnn linking scheme looks similar to the previous post such as the one from FTaveras. This is how my linking works. What's different is that I do not go to another page, I simply go BACK to the same page I came from. Redirects and Branches apparently don't care if they are simply returning to the same location.

    What is different on the return trip is that page parameters that were originally null or unpopulated NOW have a value. That value now brings life to the reports on the page that were empty.

    Step 1: The PANTRY REPORT

    1. Output: Query all items from the FOOD_SUPPLIES table.
    2. Inputs: Supply links by INGREDIENT_ID to filter the RECIPE_REPORT output.

    Stack Food Works: Pantry Report

    How to do it: (hint) To accomplish this, define the report column/field value in your report layout design page as a "linked" column and assign its value as a page item. The page item will be referenced in the SQL query of the next report...

    APEX Page Design Query by Report Linking

    Step 2: The RECIPE REPORT

    1. Output: Query all records from the ENTREE_RECIPE table which have the INGREDIENT_ID from Step 1 within their formula.
    2. Input: Supply links by ENTREE_NAME to filter the RECIPE_FORMULA output.

    Stack Food Works: Recipe Report

    How to do it: (hint) Include the page item defined from Step 1 within the SQL query of this report:

        SELECT * FROM entree_recipe 
         WHERE ingredient_id = :P3_INGREDIENT_ID 
    

    Step 3: The FORMULA REPORT

    1. Output: Query all records from the ENTREE_RECIPE table which have the ENTREE_NAME selected from Step 2.

    Stack Food Works: Formula Report

    Debug and Test Run

    Most will be able to get this far without any problems. If not, here are a couple of examples of how you can debug and test your work. There may be some built-in tools and packages that already exist within Apex, so any suggestions on alternate approaches are welcome in the comments...!

    Using the APEX Developer SESSION Output

    After selecting the inputs for the trial run, click on the SESSION link on the developer toolbar at the bottom of the page. This is an example output:

    APEX Developer SESSION Report

    Note that the page items that were set for that session are displayed. The inputs I used for this test were:

    1. INGREDIENT_ID: 6432
    2. ENTREE_NAME: peach cobbler (fresh)

    Extra Credit: This one is an alternate approach. It may be useful to design something like this as an add-on to any app you design. You do not need to remove it from your app when you push it to production because there is a "conditional display/suppress" feature for page regions. (check it out)

    An Example of a custom page debug region

    Simply set a global parameter as a "mode" on your Apex app. Set the value to "DEBUG" or "TEST" or whatever and key all your instances of this page region to display only when the global parameter is set to it.

    Wrap Up and Discussion

    Hopefully, you've enjoyed your visit to the "Stack Food Works" (no tasting or sampling from the line, please).

    This has been more of a holistic approach to Apex app design. It helps to have a methodology to map out each step, and a way to check your work at both the beginning and the end of your development process. Using smaller examples like this demo to apply these methods provides a chance to understand Apex development as a Software Creation PROCESS.