Oracle9i Discoverer Desktop User's Guide
Version 9.0.2 for Windows

A90886-01

Home

Solution Area

Contents

Index

Prev Next

A
Calculation Examples

This appendix contains the following sections:

A.1 Getting More Information

For more information about Analytic Functions, and Oracle functions in general, refer to the following Oracle publications:

A.2 About the examples in this chapter

The examples in the following sections use the Video Stores Tutorial.

A.3 Additional formatting

The examples in this chapter use the following additional formatting:

A.4 Simple Calculation Examples

This section provides the following examples to help you create Calculations.


NOTE: For more information on how to create Calculations, refer to Section 8.3, "Creating Calculations."


A.4.1 Calculate the number of rows returned by a query

This example calculates the number of rows returned by a query.

Table A-1 Workbook configuration for `Calculate the number of rows returned by a query'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region, City 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000 AND Region = Central 

Calculation Name 

Rows returned 

Calculation 

ROWCOUNT 

Notes 

ROWCOUNT does not count NULL values. To calculate the number of rows returned by a query, including NULL values, first create a temporary item One record, (Calculation = `1').
Then, create a Calculation Rows returned to count the occurrences of One record, (SUM(Video Sales Analysis.One record)) 

Display Data 

 

A.4.2 Calculate a 25% increase in sales

This example calculates a 25% increase in sales figures.

Table A-2 Workbook configuration for `Calculate a 25% increase in profits'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region, City 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000 AND Region = Central 

Calculation Name 

25% Increase 

Calculation 

Sales SUM * 1.25 

Display Data 

 

A.4.3 Convert text to upper-case

As well as the extensive range of mathematical functions available in Discoverer, you also have access to a wide range of number and text formatting functions. This example uses a Calculation to re-format City text data to upper-case.

Table A-3 Workbook configuration for `Convert City text to upper-case'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000 AND Region = Central 

Calculation Name 

City(Upper Case) 

Calculation 

UPPER(City) 

Display Data 

 

A.5 Analytic Function Examples

Oracle Discoverer supports the Analytic Functions that are included in Oracle Server 8.1.6 and above. Discoverer also extends the functionality of standard SQL by allowing you to nest Analytic Functions. You can use these advanced functions to perform sophisticated analysis on your data.

This section contains the following sub-sections:

A.5.1 Analytic Function Categories

Analytic Functions are classified in the following categories:

A.5.2 Calculations and Drilling Into and out of data

When you use Analytic Functions, note that they have a precise definition which does not change as you drill, pivot, or sort the result set. For example, if you use the RANK function to assign ranks to sales figures partitioned by Quarter, if you drill down the Month level, the rank still only applies to the Quarter level.

A.5.3 About The Analytic Function Template

When creating Analytic Functions in Discoverer, you can either type or paste them directly into the Calculation dialog box, or you can select them from the function list.

If you select them from the function list, you are presented with a generic Analytic Function Template that helps you define the function by telling you what information you may need to provide. Templates should be used as a guide. Because templates are designed to cover most types of usage, you will not always need to use every part of the template.

For example, when you paste a new RANK Analytic Function into a calculation box, Discoverer provides the following template:

Although you can define a complex function using both expressions (expr1 and expr2), you can often define a simple function using only the ORDER BY expression; for example:

NOTE: By default, results data is sorted in ascending order (ASC), nulls first (NULLS FIRST).

For more information about expressions used by the Analytic Function template, refer to "More about the Analytic Function Template".

A.5.4 Ranking Function Examples

A.5.4.1 About Ranking

Ranking functions compute the rank of an item with respect to other items in an ordered list.

A.5.4.2 Assign Ranks to sales figures

This example ranks to a set of sales figures.

Table A-4 Workbook configuration for `Assign Ranks to sales figures'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000 AND Region = Central 

Calculation Name 

Rank 

Calculation 

RANK() OVER(ORDER BY Sales SUM DESC) 

Notes 

By default, ranked results data is sorted in ascending order (ASC), nulls first (NULLS FIRST). The additional DESC parameter sorts the results in descending order, which ranks the highest value with the Rank 1. 

Display Data 

 

A.5.4.3 Assign Ranks to sales figures within Region

This example ranks a set of sales figures within each Region for each Year.

Table A-5 Workbook configuration for `Assign Ranks to sales figures within Region'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000 

Calculation Name 

Rank Top 

Calculation 

RANK() OVER(PARTITION BY Year, Region ORDER BY Sales SUM DESC) 

Display Data 

 

A.5.4.4 Show the top three selling Cities per Region

This example ranks a set of sales figures and displays the top three selling Cities for each Region.

Table A-6 Workbook configuration for `Show the top three selling Cities per Region'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000

Rank Top <= 3 

Calculation Name 

Rank Top 

Calculation 

RANK() OVER(PARTITION BY Year, Region ORDER BY Sales SUM DESC) 

Tip 

To quickly filter the list to the first, second, or third ranked cities, pivot the Rank Top item to the page axis, (see also Section 4.1.2, "Pivoting Data on a Table"). 

Display Data 

 

A.5.4.5 Show the top three and bottom three selling Cities per Region

This example ranks a set of sales figures and displays the top three and bottom three performing Cities per Region.

Table A-7 Workbook configuration for `Show the top and bottom three selling Cities per Region'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000

Rank Top <= 3 OR Rank Bottom <= 3 

Calculation Name 

Rank Top 

Calculation 

RANK() OVER(PARTITION BY Year, Region ORDER BY Sales SUM DESC) 

Additional Calculations Required 

Rank Bottom = RANK() OVER(PARTITION BY Year, Region ORDER BY Sales SUM ASC) 

Notes 

This analysis involves three steps:

1 - Assign ranks to Cities on Sales SUM in descending order, as Rank Top.

2 - Assign ranks to Cities on Sales SUM in ascending order, as Rank Bottom.

3 - Displaying only Rank Top, filter the data using a Condition to return only the top three and bottom three ranked Brands.

In the example shown below, in the `Central' Region, the top three cities are ranked 1, 2, and 3; the bottom three cities are ranked 5, 6, and 7.
In the `East' Region, the top three cities are ranked 1, 2, and 3; the bottom three cities are ranked 6, 7, and 8, and so on.
 

Display Data 

 

A.5.5 Banding Function Examples

A.5.5.1 About Banding

Banding is a type of ranking that divides a list of values in a partition into a specified number of groups called Bands (also known as buckets) and assigns each value to a Band.

Two common types of banding are:

A.5.5.2 Producing equi-width Bands (1)

This example divides Sales figures into bands according to their value, (also known as equi-width bands).

Table A-8 Workbook configuration for `Producing equi-width Bands (1)'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000, Region = Central 

Calculation Name 

Sales Bands 

Calculation 

GREATEST(1,4-FLOOR((Sales SUM-Min Sales for Region)/GREATEST(1,FLOOR((Max Sales for Region-Min Sales for Region+1)/4)))) 

Additional Calculations Required 

Max Sales for Region = MAX(Sales SUM) OVER(PARTITION BY Region,Year)

Min Sales for Region = MIN(Sales SUM) OVER(PARTITION BY Region,Year) 

Notes 

Using the Central Region and Year 2000 as an example, this function takes the largest value (45,758) minus the smallest value (7,749) and divides it by four, ((45,758-7,749)/4), giving four equal Bands of 9,502.25. This gives four bands with the following ranges:

  • Band 1 - 36,255.75 to 45,758

  • Band 2 - 26,753.5 to 36,255.75

  • Band 3 - 17,251.25 to 26,753.5

  • Band 4 - 7,749 to 17,251.25

Each value is placed in one of the four Bands depending on which range the Sales SUM value falls into. 

Display Data 

 

A.5.5.3 Producing equi-width Bands (2)

This example creates the same results as the example in "Producing equi-width Bands (1)", except that it uses a CASE statement rather than the GREATEST function.
Again, the example divides Sales figures into bands according to their value, using a CASE function, (see also

Table A-9 Workbook configuration for `Producing equi-width Bands (2)'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000, Region = Central 

Calculation Name 

Sales Bands 2 

Calculation 

CASE
WHEN Sales SUM < Q1 THEN 4
WHEN Sales SUM < Q2 THEN 3
WHEN Sales SUM < Q3 THEN 2
WHEN Sales SUM >= Q3 THEN 1
END 

Additional Calculations Required 

MAX Sales = MAX(Sales SUM) OVER(PARTITION BY Year)

MIN Sales = MIN(Sales SUM) OVER(PARTITION BY Year)

Range = (MAX Sales - MIN Sales)/4

Q1 = MIN Sales + Range

Q2 = MIN Sales + (Range*2)

Q3 = MAX Sales - Range 

Notes 

This function uses a series of IF statements in the form of a CASE function to assign sales figures into bands, (see Band Ranges below).

 

Display Data

 

 

"Producing equi-width Bands (1)").

A.5.5.4 Producing equi-height Bands

This example assigns a set of sales figures into two equi-height Bands.

Table A-10 Workbook configuration for `Producing equi-height Bands'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000, Region = Central 

Calculation Name 

Sales Bands 3 

Calculation 

NTILE(2) OVER(PARTITION BY Year, Region ORDER BY Sales SUM DESC) 

Notes 

Using the Central Region and Year 2000 as an example, this function takes the number of values (which is six) and divides it by two, giving three values per Band. It then takes the list of values ordered by Sales SUM and places values one, two, and three in Band 1, values four, five, and six in Band 2. 

Display Data 

 

A.5.6 Windowing Function Examples

A.5.6.1 About Windowing

Windowing functions are used to compute aggregates using values from other rows. For example, cumulative, moving, and centered aggregates.

Two common types of windowing are:


A.5.6.2 Calculate a three month moving sales average

This example uses a logical window to calculate a moving three month Sales average.

Table A-11 Workbook configuration for `Calculate a three month moving Sales average'

Select Items 

Video Analysis Information: Year (Calendar Year), Month (Calendar Month), Sales SUM 

Sort Order 

Year, Month 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000, Region = Central 

Calculation Name 

Moving Avg 

Calculation 

AVG(Sales SUM) OVER(ORDER BY "Month" RANGE
INTERVAL '2' MONTH PRECEDING) 

Notes 

Note that you define the RANGE INTERVAL as `2', not `3', even though you want a three month Window. This is because the Window expression implicitly includes the current row. Therefore, in this example, the INTERVAL `2' plus the current row gives a total of three months, (2 + current row = 3). 

Display Data 

 



A.5.6.3 Show the cumulative values of sales

This example uses a physical window to calculate the cumulative value of sales.

Table A-12 Workbook configuration for `Show the cumulative value of sales'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000, Region = Central 

Calculation Name 

Cumulative Total 

Calculation 

SUM(Sales SUM) OVER(ORDER BY Year ROWS UNBOUNDED PRECEDING) 

Display Data 

 



A.5.7 Reporting Function Examples

A.5.7.1 About Reporting Functions

Reporting functions are used to compute aggregates.

A.5.7.2 Calculate annual sales by Year

This example calculates annual sales by Year.

Table A-13 Workbook configuration for `Calculate annual sales by Year'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000 

Calculation Name 

Annual Sales 

Calculation 

SUM(Sales SUM) OVER() 

Display Data 

 

A.5.7.3 Calculate annual sales by region

This example calculates the total annual sales by Year and Region.

Table A-14 Workbook configuration for `Calculate annual sales by region'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000 

Calculation Name 

Annual Sales by Region 

Calculation 

SUM(Sales SUM) OVER(PARTITION BY Year, Region ORDER BY Year, Region) 

Display Data 

 

A.5.7.4 Calculate percentage of annual sales by Region

This example calculates the percentage of annual sales per Region for each City in each Year.

Table A-15 Workbook configuration for `Calculate percentage of annual sales'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region, % of Annual Sales 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000 

Calculation Name 

% of Annual Sales 

Calculation 

Sales SUM*100/Annual Sales by Region 

Additional Calculations Required 

Annual Sales by Region= SUM(Sales SUM) OVER(PARTITION BY Year, Region ORDER BY Year, Region) 

Display Data 

 

A.5.7.5 Calculate sales as a percentage of total Sales

This example calculates sales as a percentage of total Sales.

Table A-16 Workbook configuration for `Calculate sales as a percentage of total profit'

Select Items 

Video Analysis Information: Year (Calendar Year), Region, City, Sales SUM 

Sort Order 

Year, Region, % of Annual Sales 

Conditions 

Department = Video Sale OR Department = Video Rental

Year = 2000, Region = Central 

Calculation Name 

% of total Sales 

Calculation 

RATIO_TO_REPORT(Sales SUM) OVER()*100 

Display Data 

 

A.5.8 Lag/Lead Function Examples

A.5.8.1 About Lag/Lead Functions

LAG and LEAD functions are typically used to compare values in different time periods. For example, compare sales figures in 2000 with sales figures in 2001.

A.5.8.2 Compare sales figures across time

This example compares sales figures across time.

Table A-17 Workbook configuration for `Compare sales figures across time'

Select Items 

Video Analysis Information: Year (Calendar Year), Sales SUM 

Sort Order 

Year 

Conditions 

Department = Video Sale OR Department = Video Rental

Region = Central 

Calculation Name 

Previous Year 

Calculation 

LAG(Sales SUM,1) OVER(ORDER BY Year) 

Notes 

Because there are no comparative figures for 1998, the Previous Year value for 1998 is blank. 

Display Data 

 


A.5.8.3 Calculate sales growth across time

Using the comparative sales figures from example 11.8.2, this example calculates the sales growth across time.

Table A-18 Workbook configuration for `Calculate sales growth across time'

Select Items 

Video Analysis Information: Year (Calendar Year), Sales SUM 

Sort Order 

Year 

Conditions 

Department = Video Sale OR Department = Video Rental

Region = Central 

Calculation Name 

Growth 

Calculation 

(Sales SUM-Previous Year)*100/Previous Year 

Additional Calculations Required 

Previous Year = LAG(Sales SUM,1) OVER(ORDER BY Year) 

Notes 

Because there are no comparative figures for 1998, the Previous Year value for 1998 is blank. 

Display Data 

 

A.5.8.4 Rank sales growth

Using the comparative sales figures from examples A.2.8.2 and A.2.8.3, this example ranks sales growth by year.

Table A-19 Workbook configuration for `Rank sales growth'

Select Items 

Video Analysis Information: Year (Calendar Year), Sales SUM 

Sort Order 

Year 

Conditions 

Department = Video Sale OR Department = Video Rental

Region = Central 

Calculation Name 

Rank Growth 

Calculation 

RANK() OVER(ORDER BY Growth DESC) 

Additional Calculations Required 

Previous Year = LAG(Sales SUM,1) OVER(PARTITION BY 'Year' ORDER BY 'Year' )

Growth = (Sales SUM-Previous Year)*100/Previous Year 

Notes 

Because there are no comparative figures for 1998, the Previous Year and Growth values for 1998 are blank and the Rank Growth is calculated as `1'. 

Display Data 

 


A.5.9 Statistical Function Examples

A.5.9.1 About Statistics Functions

Statistics functions are used to compute covariance, correlation, and linear regression statistics. Each function operates on an unordered set. They also can be used as windowing and reporting functions.

A.5.9.2 Calculate linear regression

This example computes an ordinary least-squares regression line that expresses the Profit SUM per Month as a linear function of its Sales SUM. The following functions are used:

A.6 More about the Analytic Function Template

When you paste a new Analytic Function into a Calculation box, Discoverer provides the following generic template:

The expressions are used as follows.

For more information about Oracle expressions, refer to "Getting More Information".

A.7 Analytic Functions and Sequencing

When you use Analytic Functions in Conditions, the way that you combine them with non-Analytic Functions affects the Discoverer data returned by the query. The following sequencing rules apply:

To illustrate how sequencing affects the Discoverer data returned by a query, consider the following two scenarios.

In the first scenario, we apply two simple Conditions: Region = `Central', and Rank <= 3 (where Rank is an Analytic Function).
The Region = `Central' condition is applied first, then Rank <= 3.
Therefore, only Sales figures for the Central Region that have a ranking of three or less are included in the Results Set.

In the second scenario, we apply a single advanced Condition: Region = `Central' AND Rank <= 3, (where Rank is an Analytic Function).
The Rank <= 3 condition is applied first, then the Region = `Central' condition.
Therefore, only figures in the Central Region that have an overall ranking of three or less are included in the Results Set.


Prev Next
Oracle
Copyright © 2002 Oracle Corporation.

All Rights Reserved.

Home

Solution Area

Contents

Index