Select Page

How to “MAX” out your Fast Refresh Materialized Views

Author: Dallas Willett | | December 10, 2010

With a very simple materialized view that contains an aggregate function like MAX, Oracle can perform a fast refresh of the materialized view. However, once we start adding some complexity to the materialized view query, Oracle starts to either error out on the fast refresh, or will disallow the creation of the fast refresh materialized view in the first place. At Blue Gecko, we occasionally come across a problem, while providing remote DBA services for clients, that cannot be solved by only reading the Oracle documentation. One such problem was for a client who wanted to use a MAX aggregate function in a complex, fast refresh materialized view. The Oracle documentation says that this is not possible. As a materialized view query goes from simple to complex, Oracle’s fast refresh mechanism starts to fail. Is it possible to overcome these limitations with a fast refresh materialized view? And if so, how? Can we have our MAX and FAST REFRESH it too? The answer is yes and I’ll show you how.

How does a simple materialized view query with a MAX aggregate function work?

Before we dive into how to make a complex materialized view (mview) query work, let’s look at a simple mview query. How exactly does a fast refresh of a simple mview query work when it includes an aggregate function like MAX? Let’s work through an example. To show how oracle performs a fast refresh of a simple materialized view with a MAX aggregate function, we will start with a fairly generic “orders” table and create a materialized view that contains the maximum order amount for each customer.

  CREATE TABLE orders (
    order_id                       NUMBER(38)    NOT NULL,
    customer_id                    NUMBER(38)    NOT NULL,
    order_date                     DATE          NOT NULL,
    state                          CHAR(1)       NOT NULL,
    order_amount                   NUMBER(18,2)  NULL,
    CONSTRAINT orders_pk PRIMARY KEY (order_id)
  );

  CREATE MATERIALIZED VIEW LOG on orders
   WITH PRIMARY KEY, ROWID,
   SEQUENCE (customer_id, order_amount) INCLUDING NEW VALUES;

  CREATE MATERIALIZED VIEW orders_by_cust_mv
   REFRESH FAST AS
  SELECT customer_id
       , COUNT(*) as num_orders
       , MAX(order_amount) as max_order_amount
  FROM orders
  GROUP BY customer_id;

Let’s look at the contents of the orders table and the contents of the mview based on some data I added to the orders table:

  SQL> SELECT * FROM orders ORDER BY customer_id, order_amount;

    ORDER_ID CUSTOMER_ID ORDER_DAT S ORDER_AMOUNT
  ---------- ----------- --------- - ------------
           1        1010 08-DEC-10 C         5.05
           2        1010 08-DEC-10 O        12.99
           5        1010 06-DEC-10 C        42.42
           4        1010 07-DEC-10 C        55.01
           3        1010 07-DEC-10 C       123.41
           8        1020 07-DEC-10 C        74.85
           7        1020 07-DEC-10 C        99.15
           6        1020 08-DEC-10 O
           9        1030 08-DEC-10 O        13.33

  SQL> SELECT * FROM orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          5           123.41
         1020          3            99.15
         1030          1            13.33

Let’s now update a row to change the max_order_amount value for one of the customers. We will then refresh the mview and see the change.

  SQL> UPDATE orders SET order_amount=100.11
  WHERE order_amount=74.85 AND customer_id=1020;

  1 row updated.

  SQL> COMMIT;

  Commit complete.

  SQL> EXEC DBMS_MVIEW.REFRESH('orders_by_cust_mv','FAST');

  PL/SQL procedure successfully completed.

  SQL> SELECT * FROM orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          5           123.41
         1020          3           100.11
         1030          1            13.33

We can see that customer_id of 1020 has a new max_order_amount of 100.11, up from 99.15. That went well. Let’s update the data back to their original values to verify that fast refresh works when the max_order_amount decreases as well.

  SQL> UPDATE orders SET order_amount=77.85
  WHERE order_amount=100.11 AND customer_id=1020;

  1 row updated.

  SQL> COMMIT;

  Commit complete.

  SQL> EXEC DBMS_MVIEW.REFRESH('orders_by_cust_mv','FAST');

  PL/SQL procedure successfully completed.

  SQL> SELECT * FROM orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          5           123.41
         1020          3            99.15
         1030          1            13.33

Pretty cool. So how does Oracle accomplish this? If we take a 10046 trace of the fast refresh command we see that Oracle issues a DELETE against the mview for the effected rows in the materialized view log (mlog) table. In this case, it is only for the one customer_id that we updated. It then turns around does an INSERT of those rows again, getting the data from a SELECT against the orders table and filtering down to just the customer_id values it wants by using the mlog table. The mlog table in this case is called mlog$_orders and was created in our original CREATE MATERIALIZED VIEW LOG command. Here are the DELETE and INSERT statements from the trace:

  DELETE FROM "EXAMPLE"."ORDERS_BY_CUST_MV" "SNA$"
   WHERE (SYS_OP_MAP_NONNULL("SNA$"."CUSTOMER_ID")) IN
     (SELECT /*+ NO_MERGE  HASH_SJ */
             SYS_OP_MAP_NONNULL("MAS$"."CUSTOMER_ID")
        FROM
         (SELECT "MAS$"."CUSTOMER_ID", "MAS$"."ORDER_AMOUNT"
            FROM "EXAMPLE"."MLOG$_ORDERS" "MAS$"
           WHERE "MAS$".SNAPTIME$$ > :1 )
                 AS OF SNAPSHOT (:2) "MAS$")

  INSERT INTO "EXAMPLE"."ORDERS_BY_CUST_MV"
  SELECT /*+ */
         "AV$"."CUSTOMER_ID", COUNT(*),MAX("AV$"."ORDER_AMOUNT")
  FROM
   (SELECT  "MAS$".*
      FROM "EXAMPLE"."ORDERS" "MAS$"
     WHERE (SYS_OP_MAP_NONNULL("MAS$"."CUSTOMER_ID")) IN
      (SELECT SYS_OP_MAP_NONNULL("MAS$"."CUSTOMER_ID")
         FROM
         (SELECT /*+ HASH_SJ */
                 "MAS$"."CUSTOMER_ID",
                 "MAS$"."ORDER_AMOUNT"
            FROM "EXAMPLE"."MLOG$_ORDERS" "MAS$"
           WHERE "MAS$".SNAPTIME$$ > :1 )
                 AS OF SNAPSHOT (:2) "MAS$" )) "AV$"
  GROUP BY "AV$"."CUSTOMER_ID"

We can see that these DELETE and INSERT statements are fairly complicated for even our simple mview query. As our mview query goes from simple to complex, the logic to generate the appropriate DELETE and INSERT statements becomes more and more difficult.

What happens when we make the mview query more complex?

The example above shows that a simple mview with an aggregate function will fast refresh, but what happens when the mview query becomes more complex? As we will see, the fast refresh ability starts to fail. One change we could make that will cause Oracle to stop being able to fast refresh the materialized view is to add a WHERE clause to our mview query. There are other things we could change to make it complex as well. For example, we could add a SUM aggregate function, or a COUNT aggregate that includes a CASE statement. We won’t go into all the different ways an mview query could become complex here. Lets just look at what happens when we add the WHERE clause and try to refresh the mview. For our WHERE clause, let’s restrict our query to only those orders that are in a “closed” state. We will need to add the state column to the list of filter columns on the materialized view log. Let’s do that and also change the name of the mview from “orders_by_cust_mv” to “closed_orders_by_cust_mv” while we are at it.

  ALTER MATERIALIZED VIEW LOG FORCE ON orders
   ADD SEQUENCE (customer_id, order_id, state);

  CREATE MATERIALIZED VIEW closed_orders_by_cust_mv
   REFRESH FAST AS
  SELECT customer_id
       , COUNT(*) as num_orders
       , MAX(order_amount) as max_order_amount
  FROM orders
  WHERE state = 'C'
  GROUP BY customer_id;

  SQL> EXEC DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST');

  PL/SQL procedure successfully completed.

So far so good, but we haven’t updated any data yet. Let’s see what happens when we do.

  SQL> UPDATE orders SET order_amount=100.11
  WHERE order_amount=74.85 AND customer_id=1020;

  1 row updated.

  SQL> COMMIT;

  Commit complete.

  SQL> EXEC DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST');
  BEGIN DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST'); END;

  *
  ERROR at line 1:
  ORA-32314: REFRESH FAST of "EXAMPLE"."CLOSED_ORDERS_BY_CUST_MV" unsupported
  after deletes/updates
  ORA-06512: at "SYS.DBMS_SNAPSHOT", line 2251
  ORA-06512: at "SYS.DBMS_SNAPSHOT", line 2457
  ORA-06512: at "SYS.DBMS_SNAPSHOT", line 2426
  ORA-06512: at line 1

And we blow up. We get an ORA-32314 error and our mview will no longer fast refresh. We could try to use the DBMS_ADVISOR.TUNE_MVIEW procedure to try to see how Oracle would recommend modifing this mview in order to make it fast refresh, but we strike out there as well:

  DECLARE
   v_task_name varchar2(30);
  BEGIN
    DBMS_ADVISOR.TUNE_MVIEW(v_task_name,
    'CREATE MATERIALIZED VIEW closed_orders_by_cust_mv REFRESH FAST
    AS SELECT customer_id , COUNT(*) as num_orders , MAX(order_amount)
    as max_order_amount FROM orders
    WHERE state = ''C'' GROUP BY customer_id');
  END;
  /

  ERROR at line 1:
  ORA-13600: error encountered in Advisor
  QSM-03113: Cannot tune the MATERIALIZED VIEW statement
  QSM-02086: mv uses the MIN or MAX aggregate functions
  ORA-06512: at "SYS.DBMS_SYS_ERROR", line 86
  ORA-06512: at "SYS.PRVT_ACCESS_ADVISOR", line 202
  ORA-06512: at "SYS.PRVT_TUNE_MVIEW", line 1232
  ORA-06512: at "SYS.DBMS_ADVISOR", line 753
  ORA-06512: at line 4

So how can we fast refresh a complex mview with a MAX function?

Many people would stop here. They would run some Internet searches, check their favorite Oracle blogs and come up empty on how to proceed. Finding nothing, they would go back to their customers and give them the unpopular choice of either removing the aggregate functions from their mview or switching the mview to be a complete refresh. Is possible to work around this apparent roadblock? Yes, but not solely within the functionality of mviews that Oracle provides. To make this work we are going to need to utilize mviews in conjunction with an additional table we create and some PL/SQL. Here is how. In the simple mview example, Oracle was deleting and re-inserting the MAX value based on the changes that it saw in the mlog table. We’ll do the same thing, although I’m going to use the MERGE SQL statement to replace the DELETE and INSERT (more on that later). After we have the aggregate data we need in this new table, we will create a materialized view on top of both the original orders table and this new aggregate table. We will tie it all together with a PL/SQL procedure that updates the aggregate table and refreshes the mview at the same time. First let’s create the new aggregate table and populate it with all the data:

  CREATE TABLE closed_orders_by_cust_agg (
    customer_id                    NUMBER(38)    NOT NULL,
    max_order_amount               NUMBER(18,2)  NULL,
    CONSTRAINT closed_orders_by_cust_agg_pk PRIMARY KEY (customer_id)
  );

  MERGE INTO closed_orders_by_cust_agg agg
  USING (SELECT customer_id
              , MAX(order_amount) as max_order_amount
           FROM orders
          WHERE state = 'C'
          GROUP BY customer_id) tab
  ON (tab.customer_id = agg.customer_id)
  WHEN MATCHED THEN
    UPDATE SET agg.max_order_amount = tab.max_order_amount
  WHEN NOT MATCHED THEN
    INSERT
      (customer_id, max_order_amount)
    VALUES
      (tab.customer_id, tab.max_order_amount);
  COMMIT;

In order to get our mview to fast refresh we will need a materialized view log on the new aggregate table as well, so let’s do that first. We then modify the original mview query to pull the max_order_amount data from this new aggregate table. We join back to the orders table on the customer_id column to complete the new version of the materialized view.

  CREATE MATERIALIZED VIEW LOG ON closed_orders_by_cust_agg
    WITH PRIMARY KEY, ROWID,
   SEQUENCE (max_order_amount) INCLUDING NEW VALUES;

  CREATE MATERIALIZED VIEW closed_orders_by_cust_mv
   REFRESH FAST AS
  SELECT tab.customer_id
       , COUNT(*) as num_orders
       , agg.max_order_amount
  FROM orders tab
     , closed_orders_by_cust_agg agg
  WHERE tab.customer_id = agg.customer_id
    AND tab.state = 'C'
  GROUP BY tab.customer_id
         , agg.max_order_amount;

The initial data looks good. The max_order_amount column does not get updated when we refresh the mview, and it shouldn’t at this point. The aggregate table is a plain old table, separate from the orders table. There is nothing currently keeping the aggregate table in sync with the orders table. Let’s run a test to show that the aggregate table does not get updated when we update the orders table. When we then refresh the mview, we should expect the data to be out of sync. We’ll fix this in a minute.

  SQL> SELECT * FROM closed_orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          5           123.41
         1020          3            99.15

  SQL> UPDATE orders SET order_amount=100.11
  WHERE order_amount=74.85 AND customer_id=1020;

  1 row updated.

  SQL> COMMIT;

  Commit complete.

  SQL> EXEC DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST');

  PL/SQL procedure successfully completed.

  SQL> SELECT * FROM closed_orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          5           123.41
         1020          3            99.15

We updated the orders table, but the mview does not see the change as we expected. In order to have the data in the aggregate table updated properly, we’ll want to run another MERGE query each time we do a fast refresh. This merge query will be slightly different than the one we created to initially populate the aggregate table. We’ll do what Oracle did and use the materialized view log table to filter down the number of rows we want to update. Let’s take a look back at the original MERGE statement we used to populate the aggregate table:

  MERGE INTO closed_orders_by_cust_agg agg
  USING (SELECT customer_id
              , MAX(order_amount) as max_order_amount
           FROM orders
          WHERE state = 'C'
          GROUP BY customer_id) tab
  ON (tab.customer_id = agg.customer_id)
  WHEN MATCHED THEN
    UPDATE SET agg.max_order_amount = tab.max_order_amount
  WHEN NOT MATCHED THEN
    INSERT
      (customer_id, max_order_amount)
    VALUES
      (tab.customer_id, tab.max_order_amount);
  COMMIT;

We will want to update the aggregate data with every fast refresh, so let’s create a PL/SQL procedure that will combine this MERGE query with the refresh of the mview. We’ll grab the customer_id values that changed from the mlog table and update all the rows in the aggregate table that match those customer_id values. If the max_order_amount doesn’t change, we don’t need to update the aggregate table. For this optimization, we will add a WHERE clause to our UPDATE. I’ll underline the changes to the MERGE statement in our new refresh procedure below:

  CREATE OR REPLACE PROCEDURE ref_closed_orders_by_cust_mv AS
  BEGIN
    MERGE INTO closed_orders_by_cust_agg agg
    USING (SELECT customer_id
                , MAX(order_amount) as max_order_amount
             FROM orders
            WHERE state = 'C'
             AND (customer_id) IN
                  (SELECT customer_id FROM mlog$_orders)
            GROUP BY customer_id) tab
    ON (tab.customer_id = agg.customer_id)
    WHEN MATCHED THEN
      UPDATE SET agg.max_order_amount = tab.max_order_amount
      WHERE agg.max_order_amount != tab.max_order_amount
    WHEN NOT MATCHED THEN
      INSERT
        (customer_id, max_order_amount)
      VALUES
        (tab.customer_id, tab.max_order_amount);
    COMMIT;
    DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST');
  END;
  /

Now if we reset the order data back to the way it was and try our update again, we should see the change reflected in the mview.

  SQL> UPDATE orders SET order_amount=74.85
  WHERE order_amount=100.11 AND customer_id=1020;

  1 row updated.

  SQL> UPDATE orders SET order_amount=100.11
  WHERE order_amount=74.85 AND customer_id=1020;

  1 row updated.

  SQL> EXEC ref_closed_orders_by_cust_mv;

  PL/SQL procedure successfully completed.

  SQL> SELECT * FROM closed_orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          5           123.41
         1020          3           100.11

It works just the way we wanted it to, but we’re not quite done yet.

Potential issues with this approach

One potential complication we might encounter is if someone manually refreshes the mview without going through the PL/SQL procedure we created to do the refresh. If this happens, then the rows in the materialized view log table will be deleted without the aggregate table being updated. That would be bad as the aggregate table could get out of sync with the orders table and never get back in sync. We can prevent this by creating a second mview on the orders table that does nothing except pin the mview log entries to the table until we run the merge into the aggregate table. Let’s call this a “ghost” mview. This ghost mview is an added layer of redundancy. If you feel like you have control over how and who may issue refresh commands to your mviews, this second mview is not strictly necessary. For safety, I recommend creating this additional mview to pin the mlog entries until we run our MERGE command. Let’s look at what can happen without the additional ghost mview to pin the mlog entries.

  SQL> SELECT COUNT(*) FROM mlog$_orders;

    COUNT(*)
  ----------
           0

  SQL> UPDATE orders SET order_amount=100.11
  WHERE order_amount=74.85 AND customer_id=1020;

  1 row updated.

  SQL> COMMIT;

  Commit complete.

  SQL> SELECT COUNT(*) FROM mlog$_orders;

    COUNT(*)
  ----------
           2

  SQL> EXEC DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST');

  PL/SQL procedure successfully completed.

  SQL> SELECT COUNT(*) FROM mlog$_orders;

    COUNT(*)
  ----------
           0

  SQL> SELECT * FROM closed_orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          4           123.41
         1020          2            99.15

  SQL> EXEC ref_closed_orders_by_cust_mv;

  PL/SQL procedure successfully completed.

  SQL> SELECT * FROM closed_orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          4           123.41
         1020          2            99.15

We can see that the accidental refresh of the closed_orders_by_cust_mv materialized view removes the entries from the mlog. The subsequent execution of the PL/SQL refresh procedure we created misses the update because these mlog rows no longer exist. Our data is out of sync and nobody is happy. Let’s add the ghost mview to pin the mlog entries. Then we will modify the procedure to refresh the ghost mview after the merge and try this experiment again.

  CREATE MATERIALIZED VIEW closed_orders_by_cust_pin
   REFRESH FAST AS
  SELECT * FROM orders WHERE 0=1;

  CREATE OR REPLACE PROCEDURE ref_closed_orders_by_cust_mv AS
  BEGIN
    MERGE INTO closed_orders_by_cust_agg agg
    USING (SELECT customer_id
                , MAX(order_amount) as max_order_amount
             FROM orders
            WHERE state = 'C'
              AND (customer_id) IN
                  (SELECT customer_id FROM mlog$_orders)
            GROUP BY customer_id) tab
    ON (tab.customer_id = agg.customer_id)
    WHEN MATCHED THEN
      UPDATE SET agg.max_order_amount = tab.max_order_amount
       WHERE agg.max_order_amount != tab.max_order_amount
    WHEN NOT MATCHED THEN
      INSERT
        (customer_id, max_order_amount)
      VALUES
        (tab.customer_id, tab.max_order_amount);
    COMMIT;
    DBMS_MVIEW.REFRESH('closed_orders_by_cust_pin','FAST');
    DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST');
  END;
  /

When we run our update statement now, we see that an accidental refresh of the mview does not remove the entries from the mlog table.

  SQL> SELECT COUNT(*) FROM mlog$_orders;

    COUNT(*)
  ----------
           0

  SQL> UPDATE orders SET order_amount=100.11
  WHERE order_amount=74.85 AND customer_id=1020;

  1 row updated.

  SQL> COMMIT;

  Commit complete.

  SQL> EXEC DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST');

  PL/SQL procedure successfully completed.

  SQL> SELECT COUNT(*) FROM mlog$_orders;

    COUNT(*)
  ----------
           2

  SQL> SELECT * FROM closed_orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          5           123.41
         1020          3            99.15

  SQL> EXEC ref_closed_orders_by_cust_mv;

  PL/SQL procedure successfully completed.

  SQL> SELECT * FROM closed_orders_by_cust_mv ORDER BY customer_id;

  CUSTOMER_ID NUM_ORDERS MAX_ORDER_AMOUNT
  ----------- ---------- ----------------
         1010          5           123.41
         1020          3           100.11

  SQL> SELECT COUNT(*) FROM mlog$_orders;

    COUNT(*)
  ----------
           0

That looks better. The ghost mview to pin the mlog entries does the trick. The accidental refresh of the closed_orders_by_cust_mv materialized view does not remove the mlog rows and the subsequent procedure call correctly updates the aggregate table.

Why use MERGE instead of DELETE and INSERT

I mentioned earlier that I was going to use a MERGE SQL statement instead of a DELETE followed by an INSERT. Yet we know that Oracle does a DELETE followed by an INSERT when they update their aggregate data in the simple mview query case. Why don’t I follow that logic? I’m using MERGE for performance. If the max_order_amount doesn’t actually change based on any updates to the orders table, I would rather not DELETE and INSERT rows in the aggregate table. This would be unnecessary and would create rows in the aggregate table’s materialized view log, in turn causing us to do more work than we have to during the fast refresh of the mview. Will my data be correct? The correctness of the data remains because I’m joining the aggregate table back to the orders table, and I’m still filtering rows in the mview itself. You’ll see that with the MERGE SQL statement, I do leave some bogus data in the aggregate table when I either remove or modify data such that it no longer matches the WHERE clause. A DELETE and INSERT would remove these bogus rows. However, because of the join in the mview, this is not an issue. Let’s see what happens when I update all the orders to the “open” state.

  SQL> UPDATE orders SET state = 'O';

  9 rows updated.

  SQL> commit;

  Commit complete.

  SQL> EXEC ref_closed_orders_by_cust_mv;

  PL/SQL procedure successfully completed.

  SQL> SELECT * FROM closed_orders_by_cust_agg;

  CUSTOMER_ID MAX_ORDER_AMOUNT
  ----------- ----------------
         1010           123.41
         1020            99.15

  SQL> SELECT * FROM closed_orders_by_cust_mv ORDER BY customer_id;

  no rows selected

The data in the aggregate table is wrong, but the final mview is remains correct. If I wanted to expose this aggregate table to the end users, then I would change my MERGE to the more expensive DELETE and INSERT. And there you have it. A workaround for using aggregate functions like MAX in a complex, fast refresh materialized view.

A final look at the code

This code was tested on both 10g and 11g versions of Oracle. We started with the following materialized view definition that would not fast refresh after updates to the data.

  CREATE MATERIALIZED VIEW LOG on orders
   WITH PRIMARY KEY, ROWID,
   SEQUENCE (customer_id, order_amount, state) INCLUDING NEW VALUES;

  CREATE MATERIALIZED VIEW closed_orders_by_cust_mv
   REFRESH FAST AS
  SELECT customer_id
       , COUNT(*) as num_orders
       , MAX(order_amount) as max_order_amount
  FROM orders
  WHERE state = 'C'
  GROUP BY customer_id;

And we ended with a reworked materialized view, an additional table and PL/SQL procedure to support the MAX aggregate data, and a ghost mview to pin the mlog entries for safety.

  CREATE MATERIALIZED VIEW LOG on orders
   WITH PRIMARY KEY, ROWID,
   SEQUENCE (customer_id, order_amount, state) INCLUDING NEW VALUES;

  CREATE MATERIALIZED VIEW closed_orders_by_cust_pin
   REFRESH FAST AS
  SELECT * FROM orders WHERE 0=1;

  CREATE TABLE closed_orders_by_cust_agg (
    customer_id                    NUMBER(38)    NOT NULL,
    max_order_amount               NUMBER(18,2)  NULL,
    CONSTRAINT closed_orders_by_cust_agg_pk PRIMARY KEY (customer_id)
  );

  MERGE INTO closed_orders_by_cust_agg agg
  USING (SELECT customer_id
              , MAX(order_amount) as max_order_amount
           FROM orders
          WHERE state = 'C'
          GROUP BY customer_id) tab
  ON (tab.customer_id = agg.customer_id)
  WHEN MATCHED THEN
    UPDATE SET agg.max_order_amount = tab.max_order_amount
  WHEN NOT MATCHED THEN
    INSERT
      (customer_id, max_order_amount)
    VALUES
      (tab.customer_id, tab.max_order_amount);
  COMMIT;

  CREATE MATERIALIZED VIEW LOG ON closed_orders_by_cust_agg
   WITH PRIMARY KEY, ROWID,
   SEQUENCE (max_order_amount) INCLUDING NEW VALUES;

  CREATE MATERIALIZED VIEW closed_orders_by_cust_mv
   REFRESH FAST AS
  SELECT tab.customer_id
       , COUNT(*) as num_orders
       , agg.max_order_amount
  FROM orders tab
     , closed_orders_by_cust_agg agg
  WHERE tab.customer_id = agg.customer_id
    AND tab.state = 'C'
  GROUP BY tab.customer_id
         , agg.max_order_amount;

  CREATE OR REPLACE PROCEDURE ref_closed_orders_by_cust_mv AS
  BEGIN
    MERGE INTO closed_orders_by_cust_agg agg
    USING (SELECT customer_id
                , MAX(order_amount) as max_order_amount
             FROM orders
            WHERE state = 'C'
              AND (customer_id) IN
                  (SELECT customer_id FROM mlog$_orders)
            GROUP BY customer_id) tab
    ON (tab.customer_id = agg.customer_id)
    WHEN MATCHED THEN
      UPDATE SET agg.max_order_amount = tab.max_order_amount
       WHERE agg.max_order_amount != tab.max_order_amount
    WHEN NOT MATCHED THEN
      INSERT
        (customer_id, max_order_amount)
      VALUES
        (tab.customer_id, tab.max_order_amount);
    COMMIT;
    DBMS_MVIEW.REFRESH('closed_orders_by_cust_pin','FAST');
    DBMS_MVIEW.REFRESH('closed_orders_by_cust_mv','FAST');
  END;
  /

Dallas Willett Datavail – Remote DBA Services

How to Solve the Oracle Error ORA-12154: TNS:could not resolve the connect identifier specified

The “ORA-12154: TNS Oracle error message is very common for database administrators. Learn how to diagnose & resolve this common issue here today.

Vijay Muthu | February 4, 2021

Data Types: The Importance of Choosing the Correct Data Type

Most DBAs have struggled with the pros and cons of choosing one data type over another. This blog post discusses different situations.

Craig Mullins | October 11, 2017

How to Recover a Table from an Oracle 12c RMAN Backup

Our database experts explain how to recover and restore a table from an Oracle 12c RMAN Backup with this step-by-step blog. Read more.

Megan Elphingstone | February 2, 2017

Subscribe to Our Blog

Never miss a post! Stay up to date with the latest database, application and analytics tips and news. Delivered in a handy bi-weekly update straight to your inbox. You can unsubscribe at any time.

Work with Us

Let’s have a conversation about what you need to succeed and how we can help get you there.

CONTACT US

Work for Us

Where do you want to take your career? Explore exciting opportunities to join our team.

EXPLORE JOBS