SPOD for a query
I have two queries that need to be executed by a PL/SQL program. Both of them are quite complex, and both of them have a large section which is identical – because they are different views of the same underlying source data.
One option is to expand out both queries in full, e.g.:
Query 1:
SELECT <complicated expressions> FROM ( <large complicated query> ), <other tables> WHERE <complicated predicates>;
Query 2:
SELECT <different complicated expressions> FROM ( <large complicated query> ), <other different tables> WHERE <different complicated predicates>;
I don’t like the fact that my <large complicated query> is repeated in full in both cursor definitions. I’d rather have one place where that subquery is defined, because it should remain the same for both queries, since they are supposed to be different views of the same underlying data.
Another option is to create a view on the <large complicated query>, and refer to that in both queries. This is a perfectly acceptable option, and one which I often use. The only downside is if there are any parameters that need to be “fed” to the view. One way is for the view to expose the parameter as a column in the view, and for the calling query to simply query it on that column. This is not always the most efficient method, however, depending on the complexity of the view and how well Oracle can “push down” the predicate into the view at execution time. Another solution to the parameter problem is to use a user-defined context as described here.
The other downside which I don’t like for this case is that the view moves the query away from the package – I’d prefer to have the definitions close together and maintained in one location.
The solution which I used in this case is a pipelined function. For example:
FUNCTION large_complicated_query RETURN source_data_table_type PIPELINED IS rc source_data_type; BEGIN FOR r IN (<large complicated query>) LOOP rc.col1 := r.col1; rc.col2 := r.col2; -- etc. PIPE ROW (rc); END LOOP; RETURN; END;
Now, the two queries in my package can re-use it like this:
SELECT <complicated expressions> FROM TABLE(my_package.large_complicated_query) ,<other tables> WHERE <complicated predicates>;
In the package spec I have:
-- *** dev note: for internal use only *** TYPE source_data_type IS RECORD (col1 col1_data_type, etc....); TYPE source_data_type_table IS TABLE OF source_data_type; FUNCTION large_complicated_query RETURN source_data_table_type PIPELINED; -- *** ******************************* ***
Because the pipelined function is going to be called by SQL (in fact, two queries defined in the same package), its declaration must also be added to the package spec.
In the package body, I use private global variable(s) to hold the parameter for the large complicated query.
When the queries are run, the global variable(s) must first be set to the required parameter. The queries are run, then the global variables are cleared.
The pipelined function is deliberately not useful to other processes – if a developer tried to call it, they’d get no results because they can’t set the parameters (since they are declared as private globals).
A downside to this approach is that the optimizer will not be able to optimize the entire queries “as a whole” – it will execute the entire query in the pipelined function (at least, until the calling queries decide to stop fetching from it). For my case, however, this is not a problem. The entire process runs in less than a second – and this is 10 times faster than it needs to be. In other words, in this case maintainability is more important than performance.
There may be other ways to do this (in fact, I’m quite sure there are), but this way worked for me.