This introduction includes summarized material about the Informix TimeSeries module and cron tasks. It is recommended to previously read the following documentation on Timeseries found here.

1 TimeSeries

1.1 Creating a TimeSeries in Informix

To start off, first make sure the BTS module is integrated into the database. If the module is not in the database, please follow the instructions provided in the TimeSeries section.

From here we can start creating everything that will be necessary. First, it should be pointed out that the version 18.3 of Axional Studio, when creating a table that includes a TimeSeries field, will automatically provide you with all the queries necessary to create a TimeSeries in the Informix tab. Nonetheless, the needed queries will be detailed in the following lines.

When we talk about a TimeSeries we are referring to storing multiple columns into a single one from a table. This avoids tables to become huge and get higher processing times because of their dimensions. This multiple columns that will be stored into a table's column, will be created into a row type that will store all the data into a reserved space of the database.

For starters a TimeSeries needs a time pattern, which will be used to request for the information and then wait until the time is out to repeat the action again. In our example, a 60 second time pattern, from 1 to 60, that is inserted into the table CalendarPatterns with the name of patt_1min.

Copy
INSERT INTO CalendarPatterns 
    VALUES ('patt_1min', '{1 on , 59 off}, second')

Creating a pattern of 60 seconds is recommended as other time units might cause exceptions. If a longer time is desired, it can be adapted later when defining the cron (see section 2) and initializing the TimeSeries values with an irregular parameteer (see section 1.3).

Once our pattern is created, we can proceed to create a calendar into the table CalendarTable in which all the information will exist. For the purposed example, the calendar name is cal_1min_2019, it starts 01-01-2019 at 00:00:00, the pattern starts at the same time, and then the pattern name is also given.

Copy
INSERT INTO CalendarTable (c_name, c_calendar)
     VALUES ('cal_1min_2019', 'startdate(2014-01-01 00:00:00), 
              pattstart(2019-01-01 00:00:00), pattname(patt_1min)')

Once our calendar is ready we can start by creating the rowtype with the columns we will be storing. In the weather example the columns will be the following.

Copy
CREATE ROW TYPE rowtype_owm_cities_data(
    date_received datetime year to fraction(5),
    city_sun_rise datetime year to second,
    city_sun_set datetime year to second,
    temperature_value decimal(4,2),
    temperature_min decimal(4,2),
    temperature_max decimal(4,2),
    temperature_unit char(12),
    humidity_value int,
    humidity_unit char(12),
    pressure_value int,
    pressure_unit char(12),
    wind_speed_value decimal(10,2),
    wind_speed_name char(50),
    wind_direction_value int,
    wind_direction_code char(4),
    wind_direction_name char(12),
    clouds_value int,
    clouds_name char(20),
    visibility_value int,
    precipitation_value decimal(6,2),
    precipitation_mode char(10),
    precipitation_unit char(12),
    lastupdate_value datetime year to second
);

The first column of the row type has to be a DATETIME YEAR TO FRACTION(5). If this does not match, non valid datetime exceptions will appear.

More information about this columns can be found in the Data Model section of the example.

Now that the rowtype has been created we can create the table that will be storing it. In the example the table will be owm_cities_data_hist_ts and it will have two columns, city_id to identify to which city the data belongs to and owm_data that will be bearing the the TimeSeries row type we just created.

Copy
CREATE TABLE owm_cities_data_hist_ts (
    city_id int not null,
    owm_data TimeSeries(rowtype_owm_cities_data)
);

To continue, please make sure you have already created a dbspace to store the TimeSeries as the next step will execute a procedure to create the storing container.

To execute this procedure we need to provide the desired name of the container, in the example container_owm_cities_data; the name of the dbspace, in the example d_data; the name of the table we created before, in the example being owm_cities_data_hist_ts; and finally the size of the container anf the increment by which it grows. If specified to 0 or negative number, 16KB are used.

Copy
EXECUTE PROCEDURE TSContainerCreate ('container_owm_cities_data', 'd_data', 'rowtype_owm_cities_data', 0, 0);

Now that all the tables are created, to have a better access to the data we are storing, a virtual table will be created. This table will have all the columns of owm_cities_data_hist_ts with the exception that, instead of owm_data we will have the columns of the row it contains. A virtual table can be created using the following procedure and feeding it the name of the original TimeSeries table and the name we wish the virtual one to have.

Copy
EXECUTE PROCEDURE tscreatevirtualtab ('v_wic_mobile_devices_data_hist_ts', 
                          'wic_mobile_devices_data_hist_ts')

1.2 Creating TimeSeries in XSQL

When coding the TimeSeries in XSQL, we use the following structure. We include it inside the table definition as if it were a normal column. Inside this definition we describe all the columns we will want our rowtype to have, just like we would define then inside the table definition.

It allows generating a TimeSeries column inside a table definition.

<tseries
    rowtype_name='rowtype_name'
    pattern_name='pattern_name'
    pattern_on='pattern_on'
    pattern_off='pattern_off'
    pattern_unit='pattern_unit'
    calendar_name='calendar_name'
    calendar_start='calendar_start'
    container_name='container_name'
    container_dbspace='container_dbspace'
    column_name='column_name'
    view_name='view_name'
>
    <column /> +
</tseries>
Example

This definition belongs to the weather example used in this documentation.

Copy
<tseries
    rowtype_name='rowtype_owm_cities_data'
    pattern_name='patt_1min'
    pattern_on='1'
    pattern_off='59'
    pattern_unit='second'
    calendar_name='cal_1min_2019'
    calendar_start='2019-01-01 00:00:00'
    container_name='container_owm_cities_data'
    container_dbspace='d_data'
    column_name='owm_data'
    view_name='owm_cities_data_hist_ts_vti'
>
    
    <column name='date_received'                    type='datetime'     size='year to fraction(5)'   default='current'  info='Data received date'/>
    <column name='city_sun_rise'                    type='datetime'     size='year to second'                           info='Time of city sunrise'/>
    <column name='city_sun_set'                     type='datetime'     size='year to second'                           info='Time of city sunset'/>
    <column name='temperature_value'                type='decimal'      size='4,2'                                      info='Current temperature'/>
    <column name='temperature_min'                  type='decimal'      size='4,2'                                      info='Minimum temperature'/>
    <column name='temperature_max'                  type='decimal'      size='4,2'                                      info='Maximum temperature'/>
    <column name='temperature_unit'                 type='char'         size='12'                                       info='Units format'/>
    <column name='humidity_value'                   type='int'                                                          info='Current humidity'/>
    <column name='humidity_unit'                    type='char'         size='12'                                       info='Units format'/>
    <column name='pressure_value'                   type='int'                                                          info='Current pressure'/>
    <column name='pressure_unit'                    type='char'         size='12'                                       info='Units format'/>
    <column name='wind_speed_value'                 type='decimal'      size='10,2'                                     info='Current wind speed'/>
    <column name='wind_speed_name'                  type='char'         size='50'                                       info='Wind description'/>
    <!-- Wind gusts don't usually appear on the data load and we don't know how they are represented, although they can be included in the fututre.-->
    <!-- <column name='wind_gusts'                       type=' '            size=' '                                           info='Wind gusts'/> -->
    <column name='wind_direction_value'             type='int'                                                          info='Wind direction in degrees'/>
    <column name='wind_direction_code'              type='char'         size='4'                                        info='Wind direction code'/>
    <column name='wind_direction_name'              type='char'         size='12'                                       info='Wind direction description'/>
    <column name='clouds_value'                     type='int'                                                          info='Cloudiness percentage'/>
    <column name='clouds_name'                      type='char'         size='20'                                       info='Cloudiness description'/>
    <column name='visibility_value'                 type='int'                                                          info='Current visibility'/>
    <column name='precipitation_value'              type='decimal'      size='6,2'                                      info='Current precipitation'/>
    <column name='precipitation_mode'               type='char'         size='10'                                       info='Precipitation marker'/>
    <column name='precipitation_unit'               type='char'         size='12'                    default='mm'       info='Units format'/>
    <column name='lastupdate_value'                 type='datetime'     size='year to second'                           info='Last updated'/>
    
</tseries>

The first column of the row type has to be a DATETIME YEAR TO FRACTION(5). If this does not match, non valid datetime exceptions will appear.

Any other non TimeSeries columns we want our table to have, can be defined normally inside the table definition with the column tag. The primary key of our table has to be defined outside the tseries tag.

The result of the XSQL table definition for the weather example would look as follows. The conversions from XSQL to Informix can also be seen and are explained in the former section.

Copy
<table name='owm_cities_data_hist_ts'>

    <!-- COLUMNS -->
    <column name='city_id'                          type='int'                             required='y'        info='City id'/>

    <tseries
        rowtype_name='rowtype_owm_cities_data'
        pattern_name='patt_1min'
        pattern_on='1'
        pattern_off='59'
        pattern_unit='second'
        calendar_name='cal_1min_2019'
        calendar_start='2019-01-01 00:00:00'
        container_name='container_owm_cities_data'
        container_dbspace='d_data'
        column_name='owm_data'
        view_name='owm_cities_data_hist_ts_vti'
    >
        
        <column name='date_received'                    type='datetime'     size='year to fraction(5)'   default='current'  info='Data received date'/>
        <column name='city_sun_rise'                    type='datetime'     size='year to second'                           info='Time of city sunrise'/>
        <column name='city_sun_set'                     type='datetime'     size='year to second'                           info='Time of city sunset'/>
        <column name='temperature_value'                type='decimal'      size='4,2'                                      info='Current temperature'/>
        <column name='temperature_min'                  type='decimal'      size='4,2'                                      info='Minimum temperature'/>
        <column name='temperature_max'                  type='decimal'      size='4,2'                                      info='Maximum temperature'/>
        <column name='temperature_unit'                 type='char'         size='12'                                       info='Units format'/>
        <column name='humidity_value'                   type='int'                                                          info='Current humidity'/>
        <column name='humidity_unit'                    type='char'         size='12'                                       info='Units format'/>
        <column name='pressure_value'                   type='int'                                                          info='Current pressure'/>
        <column name='pressure_unit'                    type='char'         size='12'                                       info='Units format'/>
        <column name='wind_speed_value'                 type='decimal'      size='10,2'                                     info='Current wind speed'/>
        <column name='wind_speed_name'                  type='char'         size='50'                                       info='Wind description'/>
        <!-- Wind gusts don't usually appear on the data load and we don't know how they are represented, although they can be included in the fututre.-->
        <!-- <column name='wind_gusts'                       type=' '            size=' '                                           info='Wind gusts'/> -->
        <column name='wind_direction_value'             type='int'                                                          info='Wind direction in degrees'/>
        <column name='wind_direction_code'              type='char'         size='4'                                        info='Wind direction code'/>
        <column name='wind_direction_name'              type='char'         size='12'                                       info='Wind direction description'/>
        <column name='clouds_value'                     type='int'                                                          info='Cloudiness percentage'/>
        <column name='clouds_name'                      type='char'         size='20'                                       info='Cloudiness description'/>
        <column name='visibility_value'                 type='int'                                                          info='Current visibility'/>
        <column name='precipitation_value'              type='decimal'      size='6,2'                                      info='Current precipitation'/>
        <column name='precipitation_mode'               type='char'         size='10'                                       info='Precipitation marker'/>
        <column name='precipitation_unit'               type='char'         size='12'                    default='mm'       info='Units format'/>
        <column name='lastupdate_value'                 type='datetime'     size='year to second'                           info='Last updated'/>
        
    </tseries>

    <!-- INDEXES -->
    <index name='i_owm_cities_data_hist_ts1' columns='city_id'         />

    <!-- FOREIGNS -->
    <foreign name='f_owm_cities_data_hist_ts1' columns='city_id'   references='owm_cities'  refcols='city_id' ondeletecascade='y' />
</table>
Copy
-- **************************************************************************
-- DEISTER WebStudio XSQL-SCHEMA Thu Aug 08 10:29:15 CEST 2019 Engine: informix
-- owm_cities_data_hist_ts
-- **************************************************************************
INSERT INTO CalendarPatterns VALUES ('patt_1min', '{1 on, 59 off}, second');
INSERT INTO CalendarTable (c_name, c_calendar) VALUES ('cal_1min_2019', 'startdate(2019-01-01 00:00:00), pattstart(2019-01-01 00:00:00), pattname(patt_1min)');
CREATE ROW TYPE rowtype_owm_cities_data(
    date_received datetime year to fraction(5),
    city_sun_rise datetime year to second,
    city_sun_set datetime year to second,
    temperature_value decimal(4,2),
    temperature_min decimal(4,2),
    temperature_max decimal(4,2),
    temperature_unit char(12),
    humidity_value int,
    humidity_unit char(12),
    pressure_value int,
    pressure_unit char(12),
    wind_speed_value decimal(10,2),
    wind_speed_name char(50),
    wind_direction_value int,
    wind_direction_code char(4),
    wind_direction_name char(12),
    clouds_value int,
    clouds_name char(20),
    visibility_value int,
    precipitation_value decimal(6,2),
    precipitation_mode char(10),
    precipitation_unit char(12),
    lastupdate_value datetime year to second
);
EXECUTE PROCEDURE TSContainerCreate ('container_owm_cities_data', 'd_data', 'rowtype_owm_cities_data', 0, 0);

CREATE TABLE owm_cities_data_hist_ts (
    city_id int not null
    ,owm_data TimeSeries(rowtype_owm_cities_data)
);
ALTER TABLE owm_cities_data_hist_ts LOCK MODE (ROW);

EXECUTE PROCEDURE tscreatevirtualtab('owm_cities_data_hist_ts_vti','owm_cities_data_hist_ts');

CREATE INDEX i_owm_cities_data_hist_ts1
 ON owm_cities_data_hist_ts(city_id);

-- Omitido indice f_owm_cities_data_hist_ts1 dado que ya existe un indice sobre las columnas 
ALTER TABLE owm_cities_data_hist_ts
 ADD CONSTRAINT  FOREIGN KEY (city_id)
 REFERENCES owm_cities(city_id)
 ON DELETE CASCADE 
 CONSTRAINT f_owm_cities_data_hist_ts1;

1.3 Inserting data

Before adding any elements to the TimeSeries, it needs to be initialized. In the example we have 5 cities, from which we will receive weather information. This implies the initialization has to be done for all of them before they can start recollecting data. To do so, an insert has to be performed to the table owm_cities_data_hist_ts.

Copy
INSERT INTO owm_cities_data_hist_ts 
     VALUES ('London', "origin(2019-01-01 00:00:00.00000), 
              calendar(cal_1min_2019), container(container_owm_cities_data), 
              threshold(0), irregular, []")

The origin date specifies the first time slot that will be filled. The irregular parameter means that only if data is received the timeslot will be generated. This same parameter can be regular, which means that all timeslots will be generated regardless of having data.

The example is provided with an insertion trigger that will automatically initialize the TimeSeries for the inserted new city. See more in the Triggers, functions and scripts section in Data model.

Once the TimeSeries is initialized for each city, we can proceed to insert data into the table. Even though it can be done through both the original and virtual table, we will use the virtual table for all the transactions. This way, inserting, selecting, deleting or updating can be performed the usual way.

In this example we will use a loading script and a cron to program timed data loading. More detailed information to be found in Data model.

1.4 Other TimeSeries functions

If any of the built parts created for the specific TimeSeries have to be delated, renamed or updated, please refer to the section TimeSeries for additional and more detailed information on how to do so.

2 Cron Tasks

The example described in the following documentation is driven by a cron task. This cron task is programmed to be executed every 10 minutes and call the script owm_cities_get_data.

Copy
<call name='owm_cities_get_data'/>

For more information on how to program a cron task, please refer to the Programming documentation linked.