Load year data in a reference table.
 

1 Creation Order

The order that must be followed to get the calendar structure is the following.

  1. Tables
    1. Year
    2. Day
  2. Procedures
    1. Week of year
    2. Calendar generation
  3. Trigger
 

2 Tables

There are two tables that need to be created to generate the calendar.

 

2.1 Year table

Example
Copy
-- **************************************************************************
                        -- DEISTER WebStudio XSQL-SCHEMA Fri May 24 15:26:30 CEST 2019 Engine: informix
-- calendar_year
-- **************************************************************************
CREATE TABLE calendar_year (
    numyear smallint not null,
    nameyear varchar(20)
);
ALTER TABLE calendar_year LOCK MODE (ROW);

-- Index to avoid automatic named by database (named with pk name).
CREATE UNIQUE INDEX p_calendar_year ON calendar_year(numyear);
ALTER TABLE calendar_year
 ADD CONSTRAINT 
 PRIMARY KEY (numyear)
 CONSTRAINT p_calendar_year;
Copy
<table name='calendar_year'>
    <column name='numyear' type='smallint' required='y'/> <!-- Year number -->
    <column name='nameyear' type='varchar' size='20' /> <!-- Year name -->
    
    <!-- INDEX -->
    <primary name='p_calendar_year' columns='numyear' />
</table>
 

2.2 Day table

Example
Copy
-- **************************************************************************
-- DEISTER WebStudio XSQL-SCHEMA Fri May 24 15:06:16 CEST 2019 Engine: informix
-- calendar_day
-- **************************************************************************
CREATE TABLE calendar_day (
    day date not null,
    daynum smallint not null,
    dayname varchar(15),
    yearnum smallint not null,
    yearname varchar(10),
    semesternum smallint not null,
    semestername varchar(10),
    quarternum smallint not null,
    quartername varchar(10),
    monthnum smallint not null,
    fullmonthname varchar(16),
    monthname varchar(10),
    sevennum smallint not null,
    sevenname varchar(10),
    weeknum smallint not null,
    weekofyear integer not null,
    weekname varchar(10),
    weekdayname varchar(10)
);
ALTER TABLE calendar_day LOCK MODE (ROW);

-- Index to avoid automatic named by database (named with pk name).
CREATE UNIQUE INDEX p_calendar_day ON calendar_day(day);
ALTER TABLE calendar_day
 ADD CONSTRAINT 
 PRIMARY KEY (day)
 CONSTRAINT p_calendar_day;

CREATE  INDEX f_calendar_day1 ON calendar_day(yearnum);
ALTER TABLE calendar_day
 ADD CONSTRAINT  FOREIGN KEY (yearnum)
 REFERENCES calendar_year(numyear)
 ON DELETE CASCADE 
 CONSTRAINT f_calendar_day1;
Copy
<table name='calendar_day'>
    <column name='day'              type='date'                 required='y'/> <!-- Day -->
    <column name='daynum'           type='smallint'             required='y'/> <!-- Day in month number -->
    <column name='dayname'          type='varchar'  size='15'               /> <!-- Day name -->
    <column name='yearnum'          type='smallint'             required='y'/> <!-- Year number -->
    <column name='yearname'         type='varchar'  size='10'               /> <!-- Year name -->
    <column name='semesternum'      type='smallint'             required='y'/> <!-- Semester -->
    <column name='semestername'     type='varchar'  size='10'               /> <!-- Semester -->
    <column name='quarternum'       type='smallint'             required='y'/> <!-- Quarter Code -->
    <column name='quartername'      type='varchar'  size='10'               /> <!-- Quarter name -->
    <column name='monthnum'         type='smallint'             required='y'/> <!-- Month number -->
    <column name='fullmonthname'    type='varchar'  size='16'               /> <!-- Period name = month name in Catalán -->
    <column name='monthname'        type='varchar'  size='10'               /> <!-- Month name -->
    <column name='sevennum'         type='smallint'             required='y'/> <!-- Natural 7 days 1 to 7 = 1, 8 to 14=2, ... -->
    <column name='sevenname'        type='varchar'  size='10'               /> <!-- Week name -->
    <column name='weeknum'          type='smallint'             required='y'/> <!-- Week code -->
    <column name='weekofyear'       type='integer'              required='y'/> <!-- Week name -->
    <column name='weekname'         type='varchar'  size='10'               /> <!-- Week name -->
    <column name='weekdayname'      type='varchar'  size='10'               /> <!-- WeekDay Name: Mon,Tue,..Sun -->

    <!-- INDEX -->
    <primary name='p_calendar_day' columns='day' />
    
    <!-- FOREIGN KEYS -->
    <foreign name='f_calendar_day1' columns='yearnum' references='calendar_year' refcols='numyear' ondeletecascade='y' />
</table>
 

3 Procedures

There are two procedures that need to be created to generate the calendar.

 

3.1 Week of year

Example
Copy
CREATE FUNCTION week_of_year(dt date)
    RETURNS integer
    WITH(NOT VARIANT)

    DEFINE day1 date;
    DEFINE nbdays int;

    LET day1 = MDY(1, 1, YEAR(dt));
    LET nbdays = dt - day1;

    RETURN 1 + ((nbdays + CASE WHEN WEEKDAY(day1) = 0 THEN 7 ELSE WEEKDAY(day1) END - 1) / 7);

END FUNCTION;
 

3.2 Calendar generation

Example
Copy
CREATE PROCEDURE calendar_gen(p_anyo SMALLINT)

  -- Llamado desde trigger INSERT de labco_bical_year

    DEFINE errno INT;
    DEFINE isamno INT;
    DEFINE errmsg CHAR(80);
    DEFINE GLOBAL gl_debug SMALLINT DEFAULT 0; -- DEBUG FLAG
    
    DEFINE m_days_day LIKE calendar_day.day;
    DEFINE m_days_daynum LIKE calendar_day.daynum;
    DEFINE m_days_dayname LIKE calendar_day.dayname;
    DEFINE m_days_yearnum LIKE calendar_day.yearnum;
    DEFINE m_days_yearname LIKE calendar_day.yearname;
    DEFINE m_days_semesternum LIKE calendar_day.semesternum;
    DEFINE m_days_semestername LIKE calendar_day.semestername;
    DEFINE m_days_quarternum LIKE calendar_day.quarternum;
    DEFINE m_days_quartername LIKE calendar_day.quartername;
    DEFINE m_days_monthnum LIKE calendar_day.monthnum;
    DEFINE m_days_monthname LIKE calendar_day.monthname;
    DEFINE m_days_fullmonthname LIKE calendar_day.fullmonthname;
    DEFINE m_days_sevennum LIKE calendar_day.sevennum;
    DEFINE m_days_sevenname LIKE calendar_day.sevenname;
    DEFINE m_days_weeknum LIKE calendar_day.weeknum;
    DEFINE m_days_weekofyear LIKE calendar_day.weekofyear;
    DEFINE m_days_weekname LIKE calendar_day.weekname;
    DEFINE m_days_weekdayname LIKE calendar_day.weekdayname;
    
    
    
    DEFINE m_monthsname CHAR(3);
    DEFINE m_week_numweek SMALLINT;
    DEFINE m_curr_date DATE;
    
    -- --------------------------------------------------------------------
    -- Determina si se ha activado el flag de DEBUG global
    -- --------------------------------------------------------------------
    IF gl_debug > 0 THEN
        SET DEBUG FILE TO '/tmp/debug.log';
        TRACE ON;
    END IF
    
    -- ==============================================================
    -- Generacion de Dias (p_bptfa_cal_day)
    -- ==============================================================
    
    
    
    -- --------------------------------------------------------------------
    
    LET m_curr_date = MDY(1,1,p_anyo);
    WHILE m_curr_date <= MDY(12,31,p_anyo)
    
    LET m_monthsname = CASE WHEN MONTH(m_curr_date) = 1 THEN 'JAN'
        WHEN MONTH(m_curr_date) = 2 THEN 'FEB'
        WHEN MONTH(m_curr_date) = 3 THEN 'MAR'
        WHEN MONTH(m_curr_date) = 4 THEN 'APR'
        WHEN MONTH(m_curr_date) = 5 THEN 'MAY'
        WHEN MONTH(m_curr_date) = 6 THEN 'JUN'
        WHEN MONTH(m_curr_date) = 7 THEN 'JUL'
        WHEN MONTH(m_curr_date) = 8 THEN 'AUG'
        WHEN MONTH(m_curr_date) = 9 THEN 'SEP'
        WHEN MONTH(m_curr_date) = 10 THEN 'OCT'
        WHEN MONTH(m_curr_date) = 11 THEN 'NOV'
        WHEN MONTH(m_curr_date) = 12 THEN 'DEC'
    END;
    
    LET m_days_fullmonthname = CASE WHEN MONTH(m_curr_date) = 1 THEN   'Gener'
        WHEN MONTH(m_curr_date) = 2 THEN  'Febrer'
        WHEN MONTH(m_curr_date) = 3 THEN  'Març'
        WHEN MONTH(m_curr_date) = 4 THEN  'Abril'
        WHEN MONTH(m_curr_date) = 5 THEN  'Maig'
        WHEN MONTH(m_curr_date) = 6 THEN  'Juny'
        WHEN MONTH(m_curr_date) = 7 THEN  'Juliol'
        WHEN MONTH(m_curr_date) = 8 THEN  'Agost'
        WHEN MONTH(m_curr_date) = 9 THEN  'Setembre'
        WHEN MONTH(m_curr_date) = 10 THEN 'Octubre'
        WHEN MONTH(m_curr_date) = 11 THEN 'Novembre'
        WHEN MONTH(m_curr_date) = 12 THEN 'Desembre'
    END;
    
    EXECUTE PROCEDURE week_of_year(m_curr_date) INTO m_week_numweek;
    
    LET m_days_dayname = LPAD(DAY(m_curr_date),2,'0') || '-' || m_monthsname || '-' || YEAR(m_curr_date);
    
    LET m_days_daynum = DAY(m_curr_date);
    LET m_days_yearnum = YEAR(m_curr_date);
    LET m_days_yearname = 'Year ' || YEAR(m_curr_date);
    LET m_days_semesternum = CASE WHEN m_curr_date <= MDY(6,30,p_anyo) THEN 1 ELSE 2 END;
    LET m_days_semestername = 'S' || m_days_semesternum;
    -- LET m_days_semestername = m_days_yearnum || '-S' || m_days_semesternum;
    LET m_days_quarternum = CASE WHEN m_curr_date <= MDY(3,31,p_anyo) THEN 1
        WHEN m_curr_date <= MDY(6,30,p_anyo) THEN 2
        WHEN m_curr_date <= MDY(9,30,p_anyo) THEN 3
    ELSE 4 END;
    LET m_days_quartername = 'Q' || m_days_quarternum;
    -- LET m_days_monthnum = (YEAR(m_curr_date) * 100) + MONTH(m_curr_date);
    LET m_days_monthnum = MONTH(m_curr_date);
    LET m_days_monthname = 'M' || LPAD(MONTH(m_curr_date), 2, '0');
    LET m_days_sevennum = CASE WHEN DAY(m_curr_date) BETWEEN 1 AND 7 THEN 1
        WHEN DAY(m_curr_date) BETWEEN 8 AND 14 THEN 2
        WHEN DAY(m_curr_date) BETWEEN 15 AND 21 THEN 3
        WHEN DAY(m_curr_date) BETWEEN 22 AND 28 THEN 4
        WHEN DAY(m_curr_date) BETWEEN 29 AND 31 THEN 5
    END;
    LET m_days_sevenname = CASE WHEN DAY(m_curr_date) BETWEEN 1 AND 7 THEN '01 - 07'
        WHEN DAY(m_curr_date) BETWEEN 8 AND 14 THEN '08 - 14'
        WHEN DAY(m_curr_date) BETWEEN 15 AND 21 THEN '15 - 21'
        WHEN DAY(m_curr_date) BETWEEN 22 AND 28 THEN '22 - 28'
        WHEN DAY(m_curr_date) BETWEEN 29 AND 31 THEN '29, 30, 31'
    END;
    LET m_days_weeknum = m_week_numweek;
    LET m_days_weekofyear = (m_days_yearnum * 100) + m_days_weeknum;
    LET m_days_weekname = 'W' || LPAD(m_week_numweek,2,'0');
    LET m_days_weekdayname = CASE WHEN WEEKDAY(m_curr_date) = 0 THEN '7.Sunday'
        WHEN WEEKDAY(m_curr_date) = 1 THEN '1.Monday'
        WHEN WEEKDAY(m_curr_date) = 2 THEN '2.Tuesday'
        WHEN WEEKDAY(m_curr_date) = 3 THEN '3.Wednesday'
        WHEN WEEKDAY(m_curr_date) = 4 THEN '4.Thursday'
        WHEN WEEKDAY(m_curr_date) = 5 THEN '5.Friday'
        WHEN WEEKDAY(m_curr_date) = 6 THEN '6.Saturday'
    END;
    
    
    
    INSERT INTO calendar_day(day                  , daynum             , dayname            , yearnum           , yearname, 
                              semesternum         , semestername       , quarternum         , quartername       , monthnum,
                              fullmonthname       , monthname          , sevennum           , sevenname         , weeknum ,
                              weekofyear          , weekname           , weekdayname        )
                                       
                      VALUES (m_curr_date         , m_days_daynum      , m_days_dayname     , m_days_yearnum    , m_days_yearname,
                              m_days_semesternum  , m_days_semestername, m_days_quarternum  , m_days_quartername, m_days_monthnum,
                              m_days_fullmonthname, m_days_monthname   , m_days_sevennum    , m_days_sevenname  , m_days_weeknum, 
                              m_days_weekofyear   , m_days_weekname    , m_days_weekdayname );
    
    LET m_curr_date = m_curr_date + 1 UNITS DAY;
    END WHILE;

END PROCEDURE;
 

4 Trigger

There is one trigger needed to fill the table when generating the calendar.

Example
Copy
-- **************************************************************************
-- calendar_year_ins
-- DEISTER WebStudio XSQL-TRIGGER Fri May 24 15:21:47 CEST 2019 Engine: informix
-- **************************************************************************
CREATE TRIGGER calendar_year_ins
INSERT  ON calendar_year
REFERENCING NEW AS nxt
  FOR EACH ROW
   (
   EXECUTE PROCEDURE calendar_gen(nxt.numyear)
   )
;
Copy
<xsql-trigger
    name='calendar_year_ins'
    table='calendar_year'
    event='insert'
>
    <foreach-row>
        <execute-procedure name='calendar_gen'>
            <in>
                <param><nxt>numyear</nxt></param>
            </in>
        </execute-procedure>
    </foreach-row>
</xsql-trigger>
 

5 Example of year generation

 

5.1 Insert of the year

The next code shows how to insert a new year in the calendar table system.

Example
Copy
INSERT INTO calendar_year (numyear, nameyear) VALUES (2019, "2019");
 

5.2 Select of the data generated

The select after the insert of the desired year will show:

Example
Copy
SELECT * FROM calendar year;

        
        Result:
            +=======+========+
            |numyear|nameyear|
            +=======+========+
            |2.019  |2019    | 
            +=======+========+
        

SELECT * FROM calendar_day;

        
        Result:
|==========+======+===============+=======+==========+===========+============+==========+===========+========+================+==========+========+==========+=======+==========+==========+===========+
|day       |daynum|dayname        |yearnum|yearname  |semesternum|semestername|quarternum|quartername|monthnum|fullmonthname   |monthname |sevennum|sevenname |weeknum|weekofyear|weekname  |weekdayname|
|==========+======+===============+=======+==========+===========+============+==========+===========+========+================+==========+========+==========+=======+==========+==========+===========+
|2019-01-01|     1|01-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       1|01 - 07   |      1|    201901|W01       |2.Tuesday  |
|2019-01-02|     2|02-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       1|01 - 07   |      1|    201901|W01       |3.Wednesda |
|2019-01-03|     3|03-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       1|01 - 07   |      1|    201901|W01       |4.Thursday |
|2019-01-04|     4|04-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       1|01 - 07   |      1|    201901|W01       |5.Friday   |
|2019-01-05|     5|05-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       1|01 - 07   |      1|    201901|W01       |6.Saturday |
|2019-01-06|     6|06-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       1|01 - 07   |      1|    201901|W01       |7.Sunday   |
|2019-01-07|     7|07-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       1|01 - 07   |      2|    201902|W02       |1.Monday   |
|2019-01-08|     8|08-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       2|08 - 14   |      2|    201902|W02       |2.Tuesday  |
|2019-01-09|     9|09-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       2|08 - 14   |      2|    201902|W02       |3.Wednesda |
|2019-01-10|    10|10-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       2|08 - 14   |      2|    201902|W02       |4.Thursday |
|2019-01-11|    11|11-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       2|08 - 14   |      2|    201902|W02       |5.Friday   |
|2019-01-12|    12|12-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       2|08 - 14   |      2|    201902|W02       |6.Saturday |
|2019-01-13|    13|13-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       2|08 - 14   |      2|    201902|W02       |7.Sunday   |
|2019-01-14|    14|14-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       2|08 - 14   |      3|    201903|W03       |1.Monday   |
|2019-01-15|    15|15-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       3|15 - 21   |      3|    201903|W03       |2.Tuesday  |
|2019-01-16|    16|16-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       3|15 - 21   |      3|    201903|W03       |3.Wednesda |
|2019-01-17|    17|17-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       3|15 - 21   |      3|    201903|W03       |4.Thursday |
|2019-01-18|    18|18-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       3|15 - 21   |      3|    201903|W03       |5.Friday   |
|2019-01-19|    19|19-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       3|15 - 21   |      3|    201903|W03       |6.Saturday |
|2019-01-20|    20|20-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       3|15 - 21   |      3|    201903|W03       |7.Sunday   |
|2019-01-21|    21|21-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       3|15 - 21   |      4|    201904|W04       |1.Monday   |
|2019-01-22|    22|22-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       4|22 - 28   |      4|    201904|W04       |2.Tuesday  |
|2019-01-23|    23|23-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       4|22 - 28   |      4|    201904|W04       |3.Wednesda |
|2019-01-24|    24|24-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       4|22 - 28   |      4|    201904|W04       |4.Thursday |
|2019-01-25|    25|25-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       4|22 - 28   |      4|    201904|W04       |5.Friday   |
|2019-01-26|    26|26-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       4|22 - 28   |      4|    201904|W04       |6.Saturday |
|2019-01-27|    27|27-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       4|22 - 28   |      4|    201904|W04       |7.Sunday   |
|2019-01-28|    28|28-JAN-2019    |   2019|Year 2019 |          1|S1          |         1|Q1         |       1|Gener           |M01       |       4|22 - 28   |      5|    201905|W05       |1.Monday   |
|==========+======+===============+=======+==========+===========+============+==========+===========+========+================+==========+========+==========+=======+==========+==========+===========+