Skip to Main Content
  • Questions
  • Parameterized views -vs- views with where conditions

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, Giri.

Asked: June 02, 2008 - 1:10 pm UTC

Last updated: July 26, 2009 - 6:54 am UTC

Version: 10.1.2

Viewed 50K+ times! This question is

You Asked

Hi Tom,

I am a long time reader of asktom.oracle.com and delighted to see 'submit a new question' enabled after a very long time.

Which of the following would be a better choice from scalability, performance, ease of development, ease of maintenance.

First option:-
---------------
Develop a view and have where clause embeded in different queries (JDBC/Reporting layers etc).

Example:
--------
SELECT ...
FROM EMPLOYEE_VW
WHERE HIRE_DATE BETWEEN <p_min_date> AND <p_max_date>


Second option:-
---------------
Develop a parameterized view using sys_context. Have client set the parameters using sys_context.

Example:
--------

-- Set the context for Min and max dates.
DBMS_SESSION.set_context (namespace => 'CTX_SLR_PARAMS',
ATTRIBUTE => 'min_date',
VALUE => p_min_date
);

DBMS_SESSION.set_context(namespace => 'CTX_SLR_PARAMS',
ATTRIBUTE => 'max_date',
VALUE => p_max_date
);


-- Query the generic view.

SELECT ...
FROM EMPLOYEE_PARAM_VIEW;


-- View is built like this.

SELECT ...
FROM EMPLOYEE
WHERE hire_date BETWEEN SYS_CONTEXT ('CTX_SLR_PARAMS', 'min_date')
AND SYS_CONTEXT ('CTX_SLR_PARAMS', 'max_date')


I tried bench marking (trace & Explain Plan) with simple tables and i didn't see any difference between above. It would be great if you could provide when would a parameterized view make sense.

Thank you,
Giri.

and Tom said...

under the covers, they would be "the same" more or less.

both are views.
both (can) "bind" against hire_date.


the first one would be able to use bind peeking (could be a bad thing, could be a good thing)


I would not opt for the 'parameterized' view - to me, it is "less clear". I've used that approach very infrequently (once that I can remember in fact). In general, I have nothing against having the "sql" be there and it is more flexible as well - I can say "hire_date > :x" if I wanted to with the regular view.

If I wanted to constraint the predicate - I would use a stored procedure that took inputs and opened a ref cursor with a specific predicate.

Rating

  (5 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Thank you..

Giri Chintarlapalli, June 03, 2008 - 1:26 pm UTC

Tom, Thank you so much for the response. As always, extremely helpful.

Other options for parameterized view

Simon Young, June 05, 2008 - 6:22 am UTC

Hi

I have used a couple of alternate approaches to the parameterized view.

Using session context might not always be appropriate in a situation with connection pools perhaps? I am thinking that if you fail to set context you might get the last user of the connection's parameters.

Alternate 1) Create a Global Temporary Table as ON COMMIT DELETE ROWS to contain parameter values. This table can be referenced in the view SQL to achieve the desired subsetting - as simple or complex as you like. The 'parameters' will then have transaction only scope.

Alternate 2) Pretty much the same as Toms's suggestion to have a Stored Proc returning a Ref Cursor, but I sometimes use a PIPELINED function instead, as this supports even the dumbest of clients. Some clients are not capable of handling Ref Cursors at all, or handle them badly (in my experience).
Tom Kyte
June 05, 2008 - 10:12 am UTC

...
I am thinking that if you fail to set context you
might get the last user of the connection's parameters.

...

that would, umm, be true of a none connection pool environment, if you fail to set the context (which would be called A BUG IN YOUR CODE) you will get the wrong stuff - obviously. Single stateful connection or not.



Giving The Customer What He Wants

Joe Bloggs, June 10, 2008 - 11:13 am UTC

I think it's about time we did away with the need for this silly SYS_CONTEXT rubbish.

Oracle should introduce proper parametrised...parameterised...parametarised... Oh damn it! - views with parameters - so as to conform to everyone's expectations.

For example,

CREATE OR REPLACE VIEW VIEW_ABC (parm1 INTEGER, parm2 DATE) AS
  SELECT *
  FROM   XYZ
  WHERE  EXISTS (SELECT 'X'
                 FROM   QPR
                 WHERE  QPR.JOIN_COLUMN_1 = XYZ.JOIN_COLUMN_1
                 AND    QPR.ATTR_COLUMN_1 = (parm1)
                 AND    QPR.ATTR_COLUMN_2 = (parm2))
/

Then, all we need do is,
SELECT *
FROM   VIEW_ABC (101, SYSDATE)
/

No probs. with bind variables. Nicely integrated as one would expect.

Parameterized views -- different approach

Lawrence Winkler, October 24, 2008 - 10:54 pm UTC

The prettiest approach to creating a parameterized view (almost) is to create a pl/sql function that returns an Oracle collection type. Then query the 'view' with a query such as

SELECT *
FROM TABLE(mycollectionfunction(parameter list));

This requires defining CREATE TYPEs first. Here is my simple code in an HR application to find all the departments a position (appointment) is works for as of a given date.

CREATE OR REPLACE
type APPTDEPT_TY is object (appt_department varchar2(11));

CREATE OR REPLACE
type APPTDEPT_TBL_TY is table of apptdept_ty;

CREATE FUNCTION q_apptdept (p_appointment_id varchar2, p_date date)
RETURN apptdept_tbl_ty
IS
CURSOR cur (c_appt_id varchar2, c_date date)
IS
SELECT d.appt_department
FROM apptdept d
WHERE D.APPOINTMENT_ID = c_appt_id
AND D.DEPT_EFF_DATE <= c_date
AND (D.DEPT_END_DATE IS NULL
OR D.DEPT_END_DATE >= c_date);

ty apptdept_ty;
tbl apptdept_tbl_ty := apptdept_tbl_ty ();
BEGIN
FOR rec IN cur (p_appointment_id, p_date) LOOP
ty := apptdept_ty (rec.appt_department);
tbl.EXTEND;
tbl (tbl.LAST) := ty;
END LOOP;

RETURN tbl;
END;

Now, we can execute the query

SELECT *
FROM TABLE(Q_APPTDEPT('00123456',SYSDATE));

to get all departments for appoinmtent '00123456' that are active as of today.





Tom Kyte
October 25, 2008 - 8:28 am UTC

you would use a pipelined function for this


CREATE FUNCTION q_apptdept (p_appointment_id varchar2, p_date date)
<b>PIPELINED</b>
      RETURN apptdept_tbl_ty
   IS
      CURSOR cur (c_appt_id varchar2, c_date date)
      IS
         SELECT   d.appt_department
           FROM   apptdept d
          WHERE   D.APPOINTMENT_ID = c_appt_id
              AND D.DEPT_EFF_DATE <= c_date
              AND (D.DEPT_END_DATE IS NULL
                OR D.DEPT_END_DATE >= c_date);
   BEGIN
      FOR rec IN cur (p_appointment_id, p_date) 
      LOOP
         <b>pipe row( apptdept_ty (rec.appt_department) )</b>;
      END LOOP;
<b>
      RETURN;</b>
   END;



same concept as dbms_xplan....

Parameterized View

chandini paterson, July 23, 2009 - 3:45 am UTC

Tom,
In your very first reply to the original poster, you said that you wouldn't consider a parameterized view. What if you had a situation where you had tables that held data for different companies and you wanted to let user's only see the data for their specific company. Without going for a full-blown FGAC implementation, i thought the easiest way to do this was to do a
SELECT <col>
FROM <table_name>
WHERE <conditions>
AND company_id = sys_context('my_ctx', 'company_id);
Would you not use a view with parameters this way either? Since the same SQL could be used in different places, wouldn't it make sense to just have it defined as a view once? Thank you, Chandini



Tom Kyte
July 26, 2009 - 6:54 am UTC

for this, I would use fine grained access control, what is so "full blown" about it (you make it sound like a bad thing?)

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library