15.00 - About the Business Calendar Functions - Teradata Database

Teradata Database SQL Functions, Operators, Expressions, and Predicates

Product
Teradata Database
Release Number
15.00
Content Type
Programming Reference
Publication ID
B035-1145-015K
Language
English (United States)
Last Update
2018-09-24

About the Business Calendar Functions

You can specify business calendar functions in an SQL statement wherever you specify UDFs, for example, in an INSERT, UPDATE, DELETE, MERGE, or SELECT statement.

The following facts apply to the business calendar functions:

  • If you do not specify a calendar name, the calendar defaults to the session calendar.
  • All functions related to a year, for example MonthNumber_Of_Year, are calculated relative to January 1 of that year.
  • All functions related to a calendar, for example, DayNumber_Of_Calendar, are calculated relative to the beginning of the calendar, 1900-01-01.
  • You can specify these functions anywhere in a DML statement, in CHECK CONSTRAINTS in the DDL statements, and all other places in an SQL statement where a UDF can be specified.
  • All the definitions of the business calendar functions are stored in the TD_SYSFNLIB database. The format and title of the business calendar functions used in a SELECT statement follow the regular UDF style.
  • These functions are available to all Teradata users and do not require any privileges.
  • All the computations inside the functions are in UTC if the input is of type TIMESTAMP or TIMESTAMP WITH TIME ZONE.
  • Prerequisites for Using the Business Calendar Functions

    Before you can use these functions, you must run the Database Initialization Program (DIP) utility and execute the DIPSYSFNC script. The DIPALL or DIPSYSFNC script will create the calendar functions in the TD_SYSFNLIB database. For more information about the DIP utility, see Utilities: Volume 1 (A-K).

    If you have a UDF with the same name as a business calendar function, you must remove that UDF from the normal UDF search path before you can invoke the business calendar function. If the business calendar function is not found in the current database, Teradata Database searches for the function in the TD_SYSFNLIB database. Alternatively, you may invoke the calendar function by using the fully qualified syntax, TD_SYSFNLIB.calendar_function_name.

    Example : Cumulative Sales During First Week of All Quarters

    This example finds cumulative sales of an item during first week of all quarters. Results are shown for each calendar setting.

    SEL Item_Code, SUM(Sale_Amt) FROM Sales_Tbl
    WHERE WeekNumber_Of_Quarter(Sale_Date) = 1
    GROUP BY Item_Code;

    Example : Cumulative Sales During First Week of All Quarters - Teradata Calendar

    This example shows how cumulative sales for the first week of all quarters are totaled using the Teradata calendar.

    SET SESSION calendar = Teradata;
    SEL Item_Code, SUM(Sale_Amt) FROM Sales_Tbl
    WHERE WeekNumber_Of_Quarter(Sale_Date) = 1
    GROUP BY Item_Code;

    Example : Cumulative Sales During First Week of All Quarters - ISO Calendar

    This example shows how cumulative sales for the first week of all quarters are totaled using the ISO calendar.

    SET SESSION calendar = ISO;
    SEL Item_Code, SUM(Sale_Amt) FROM Sales_Tbl
    WHERE WeekNumber_Of_Quarter(Sale_Date) = 1
    GROUP BY Item_Code;

    Example : Cumulative Sales During First Week of All Quarters - Compatible Calendar

    This example shows how cumulative sales for the first week of all quarters are totaled using the Compatible calendar.

    SET SESSION calendar = Compatible;
    SEL Item_Code, SUM(Sale_Amt) FROM Sales_Tbl
    WHERE WeekNumber_Of_Quarter(Sale_Date) = 1
    GROUP BY Item_Code;

    Example : Cumulative Weekday Sales During First Week of All Quarters - Teradata Calendar

    This example finds cumulative sales of an item during weekdays of the first week of all quarters.

    SET SESSION calendar = Teradata;
    /* Setting SUNDAY and SATURDAY as weekend days. */
    exec dbc.createbusinesscalendarpattern('teradata','SUNDAY','OFF',);
    exec dbc.createbusinesscalendarpattern('teradata','SATURDAY','OFF',);
     
    SEL Item_Code, SUM(Sale_Amt) FROM Sales_Tbl,
           Sys_Calendar.BusinessCalendar
    WHERE WeekNumber_Of_Quarter(Sale_Date) = 1
    AND calendar_date = Sale_Date
    AND IsBusinessDay  = 1
    GROUP BY Item_Code
    ORDER BY 1;

    Example : Show Week 1 of September 2011

    This example shows week 1 of September, 2011, for each business calendar setting.

    SEL calendar_date, week_of_month FROM Sys_Calendar.BusinessCalendar
    WHERE week_of_month = 1
    AND month_of_year = 9
    AND year_of_calendar = 2011
    ORDER BY 1;
    SET SESSION calendar = ISO;

    SET SESSION calendar = Teradata;

    SET SESSION calendar = Compatible;

    Example : Inventory Status at the Beginning of Each Week in a Month

    The following example shows the inventory status at the beginning of each week for the month of September, 2011 for each business calendar setting.

    SEL Item, BEGIN(week_duration) AS WeekBegin, Inventory 
    FROM Inventory_Tbl
    EXPAND ON Duration AS week_duration
    BY ANCHOR WEEK_BEGIN;

    Example : Number of Weeks in Each Quarter in 2004

    The following example shows the number of weeks in each quarter for 2004.

    SEL quarter_of_year, MAX(week_of_quarter)
    FROM  Sys_Calendar.BusinessCalendar 
    WHERE year_of_calendar=2004 
    GROUP BY 1 ORDER BY 1;

    Example : Sales by Quarter

    The following example shows how sales are calculated by quarter for each business calendar setting.

    SEL QuarterNumber_Of_Year(Sale_Date) Quarter_No,
    Item_Code, SUM(Sale_Amt) FROM Sales_Tbl
    GROUP BY 1,2
    ORDER BY 1,2;