7 Replies Latest reply on Aug 28, 2018 1:04 PM by KatReed

    Oracle Apex - virtual column error raised

    KatReed

      I am currently working in Oracle Application Express 18.1.0.00.45 and I am getting an error that I do not understand.

      I created an interactive grid using the following query:

      select periodic_topics_id, filter, topic, 
      CASE WHEN LINK1 like '%116%' then LINK1||:APP_SESSION
      ELSE LINK1
      END AS LINK1
      From periodic_topics
      where meeting like :P31_MEETING_DESC
      and (nvl(:P31_FILTER,'0') = '0' or instr(:P31_FILTER||':',filter||':') > 0)

      In the table in the database, the periodic_topics_id column is the primary key and it is automatically populated when a new row is added to the table using the following trigger:

      create or replace TRIGGER periodic_topics_trigger 
      BEFORE
      INSERT ON periodic_topics
      FOR EACH ROW
      BEGIN :new.periodic_topics_id := periodic_topics_seq.nextval;
      END;

      In the APEX application, link1 is a textfield and in the "Link" section of this column's properties, the "Target" is of type URL and the URL is &LINK1. I also indicated in the APEX application that periodic_topics_id is the primary key. These are the properties of the link column that I am referring to:

      pic.png

      The problem: when I manually insert a value into a cell in the "LINK1" column of the interactive grid, an error is raised that says:

      "•Ajax call returned server error ORA-20987: APEX - Process 'Periodic Topics - Save Interactive Grid Data' raised 'ORA-01733: virtual column not allowed here' while executing a DML command. This error can occur if a column is based on an aggregation or SQL expression. Set column attribute 'Query Only' to Yes to exclude the column from the INSERT and UPDATE statement. - Contact your application administrator. for ."

      However, if I create the interactive grid using the same query but without the case statement, then I have no problem adding a link in the interactive grid. No error occurs. In other words, no error occurs when I try to add a value to the "Link1" column in the interactive grid if I create the interactive grid using the following query:

      select periodic_topics_id, filter, topic, link1 
      From periodic_topics
      where meeting like :P31_MEETING_DESC
      and (nvl(:P31_FILTER,'0') = '0' or instr(:P31_FILTER||':',filter||':') > 0)

      Just FYI, I need the query to have the case statement because some of the links will direct the user to external websites and others will direct the user to another page in the application. Without the case statement concatenating :APP_SESSION to the link, the user is forced to log back in to the application whenever they click on a link that directs them to another page in the application.

      Does anyone know why the error would occur when the case statement is in the query but not when the case statement isn't in the query?

      Thank you in advance.

        • 1. Re: Oracle Apex - virtual column error raised
          Pierre Yotti

          Ajax call returned server error ORA-20987: APEX - Process 'Periodic Topics - Save Interactive Grid Data' raised 'ORA-01733: virtual column not allowed here' while executing a DML command. This error can occur if a column is based on an aggregation or SQL expression. Set column attribute 'Query Only' to Yes to exclude the column from the INSERT and UPDATE statement. - Contact your application administrator. for ."

           

           

          Set the links column attribut Query Only to Yes and Boom it will works  

          • 2. Re: Oracle Apex - virtual column error raised
            Bharat G

            I hope Link1 is not a Number field. Try to change the case statement like below and check.

             

            select periodic_topics_id, filter, topic,
            CASE WHEN LINK1 like '%116%' then LINK1||'&APP_SESSION.'
            ELSE LINK1
            END AS LINK1
            From periodic_topics
            where meeting like :P31_MEETING_DESC
            and (nvl(:P31_FILTER,'0') = '0' or instr(:P31_FILTER||':',filter||':') > 0)

             

            And what is this 116 in when condition refers to ?

             

            Regards,

            Bharat

            • 3. Re: Oracle Apex - virtual column error raised
              KatReed

              Thank you for your response. I tired setting the attribute "query only" to yes for the Link column, but when I did that I was not able to edit the Link column in the interactive grid. Meaning, I couldn't manually enter a new URL value into the Link column in the interactive grid because it was set to "query only", so it was excluded from insert and update statements. Pierre Yotti

              • 4. Re: Oracle Apex - virtual column error raised
                KatReed

                Bharat G Thank you for your response. Link1 is a textfield. The 116 is the application number for my application and because the application number is in the URL for every page in the application, I use that number as a way of telling Oracle Apex that if that application number is in the URL then to concatenate the APP_SESSION to the end of the string. Thank you for your possible solution, but unfortunately when I tried to implement your solution the same error was raised when I clicked the "Save" button on the Interactive Grid.

                • 5. Re: Oracle Apex - virtual column error raised
                  fac586

                  KatReed wrote:

                   

                  I am currently working in Oracle Application Express 18.1.0.00.45 and I am getting an error that I do not understand.

                  I created an interactive grid using the following query:

                  select periodic_topics_id, filter, topic, 
                  CASE WHEN LINK1 like '%116%' then LINK1||:APP_SESSION
                  ELSE LINK1
                  END AS LINK1
                  From periodic_topics
                  where meeting like :P31_MEETING_DESC
                  and (nvl(:P31_FILTER,'0') = '0' or instr(:P31_FILTER||':',filter||':') > 0)

                  In the table in the database, the periodic_topics_id column is the primary key and it is automatically populated when a new row is added to the table using the following trigger:

                  create or replace TRIGGER periodic_topics_trigger 
                  BEFORE
                  INSERT ON periodic_topics
                  FOR EACH ROW
                  BEGIN :new.periodic_topics_id := periodic_topics_seq.nextval;
                  END;

                  In the APEX application, link1 is a textfield and in the "Link" section of this column's properties, the "Target" is of type URL and the URL is &LINK1. I also indicated in the APEX application that periodic_topics_id is the primary key. These are the properties of the link column that I am referring to:

                  pic.png

                  The problem: when I manually insert a value into a cell in the "LINK1" column of the interactive grid, an error is raised that says:

                  "•Ajax call returned server error ORA-20987: APEX - Process 'Periodic Topics - Save Interactive Grid Data' raised 'ORA-01733: virtual column not allowed here' while executing a DML command. This error can occur if a column is based on an aggregation or SQL expression. Set column attribute 'Query Only' to Yes to exclude the column from the INSERT and UPDATE statement. - Contact your application administrator. for ."

                  However, if I create the interactive grid using the same query but without the case statement, then I have no problem adding a link in the interactive grid. No error occurs. In other words, no error occurs when I try to add a value to the "Link1" column in the interactive grid if I create the interactive grid using the following query:

                  select periodic_topics_id, filter, topic, link1 
                  From periodic_topics
                  where meeting like :P31_MEETING_DESC
                  and (nvl(:P31_FILTER,'0') = '0' or instr(:P31_FILTER||':',filter||':') > 0)

                  Just FYI, I need the query to have the case statement because some of the links will direct the user to external websites and others will direct the user to another page in the application. Without the case statement concatenating :APP_SESSION to the link, the user is forced to log back in to the application whenever they click on a link that directs them to another page in the application.

                  Does anyone know why the error would occur when the case statement is in the query but not when the case statement isn't in the query?

                  The error is occurring because the case expression does indeed turn LINK1 into a virtual column. Oracle cannot use the LINK1 column in DML operations because it is sourced from an expression, not a column name.

                   

                  There is a simple fix.

                   

                  1. Change the IG source query to:

                   

                  select periodic_topics_id, filter, topic, link1
                  From periodic_topics
                  where meeting like :P31_MEETING_DESC
                  and (nvl(:P31_FILTER,'0') = '0' or instr(:P31_FILTER||':',filter||':') > 0)
                  

                   

                  2. Manually add a column to the grid (Ctrl+Click on the Columns node in Page Designer and select Create Column).

                   

                  3. Set the following properties on the new column:

                   

                  Name: LINK_SESSION

                  Type: Hidden

                  Source Type: SQL Expression

                  SQL Expression:

                  case
                    when link1 like '%116%' then :app_session 
                    else null 
                  end 
                  

                   

                  4. Change the link Target on the LINK1 column to &LINK1.&LINK_SESSION.

                   

                  However this is not a robust solution:

                   

                  • What if the application ID has to change?
                  • What if a user pastes in an external URL that coincidentally includes the characters "116"?
                  • What if a ":" is missed from the end of an internal URL?
                  • 6. Re: Oracle Apex - virtual column error raised
                    KatReed

                    fac586 Thank you for your response. Your solution does make sense and I tried to implement it, but when I got down to number 3, APEX would not accept the SQL Expression you suggested because it says that "LINK1" is not a valid identifier. The error states: ORA-06550: line 2, column 5: ORA-00904: "LINK1": invalid identifier

                     

                    • 7. Re: Oracle Apex - virtual column error raised
                      KatReed

                      fac586 Nevermind, your solution worked! For some reason, I was still able to "Save and Run" the page despite the "invalid identifier" error, which seems strange. When I ran the page with your solution, I was able to add a URL to the LINK1 column and the interactive grid saved without error! Thank you very much for your help.