Oracle9i SQL Reference
Release 1 (9.0.1)

Part Number A90125-01
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback

Go to previous page Go to beginning of chapter Go to next page

Functions, 166 of 166


User-Defined Functions

You can write user-defined functions in PL/SQL or Java to provide functionality that is not available in SQL or SQL built-in functions. User-defined functions can appear in a SQL statement anywhere SQL functions can appear, that is, wherever an expression can occur.

For example, user-defined functions can be used in the following:

user_defined_function::=


Text description of functions148.gif follows
Text description of user_defined_function

The optional expression list must match attributes of the function, package, or operator.

Restriction: The DISTINCT and ALL keywords are valid only with a user-defined aggregate function.

See Also:

 

Prerequisites

User-defined functions must be created as top-level functions or declared with a package specification before they can be named within a SQL statement.

To use a user function in a SQL expression, you must own or have EXECUTE privilege on the user function. To query a view defined with a user function, you must have SELECT privileges on the view. No separate EXECUTE privileges are needed to select from the view.

See Also:

 

Name Precedence

Within a SQL statement, the names of database columns take precedence over the names of functions with no parameters. For example, if the Human Resources manager creates the following two objects in the hr schema:

CREATE TABLE new_emps (new_sal NUMBER, ...);
CREATE FUNCTION new_sal RETURN NUMBER IS BEGIN ... END;

then in the following two statements, the reference to new_sal refers to the column new_emps.new_sal:

SELECT new_sal FROM new_emps;
SELECT new_emps.new_sal FROM new_emps;

To access the function new_sal, you would enter:

SELECT hr.new_sal FROM new_emps;

Here are some sample calls to user functions that are allowed in SQL expressions:

circle_area (radius)
payroll.tax_rate (empno)
scott.payroll.tax_rate (dependent, empno)@ny
Example

To call the tax_rate user function from schema hr, execute it against the ss_no and sal columns in tax_table, and place the results in the variable income_tax, specify the following:

SELECT hr.tax_rate (ss_no, sal)
    INTO income_tax
    FROM tax_table
    WHERE ss_no = tax_id;

Naming Conventions

If only one of the optional schema or package names is given, the first identifier can be either a schema name or a package name. For example, to determine whether PAYROLL in the reference PAYROLL.TAX_RATE is a schema or package name, Oracle proceeds as follows:

  1. Check for the PAYROLL package in the current schema.

  2. If a PAYROLL package is not found, look for a schema name PAYROLL that contains a top-level TAX_RATE function. If no such function is found, return an error.

  3. If the PAYROLL package is found in the current schema, look for a TAX_RATE function in the PAYROLL package. If no such function is found, return an error.

You can also refer to a stored top-level function using any synonym that you have defined for it.


Go to previous page Go to beginning of chapter Go to next page
Oracle
Copyright © 1996-2001, Oracle Corporation.

All Rights Reserved.
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback