Path Variables as Columns | Native Object Store ( NOS ) | Teradata Vantage - Using Path Variables as Columns in a View - Advanced SQL Engine - Teradata Database

Teradata Vantage™ - Native Object Store Getting Started Guide

Product
Advanced SQL Engine
Teradata Database
Release Number
17.10
Published
July 2021
Language
English (United States)
Last Update
2022-06-22
dita:mapPath
gmv1596851589343.ditamap
dita:ditavalPath
wrg1590696035526.ditaval
dita:id
B035-1214
lifecycle
previous
Product Category
Software
Teradata Vantage

By creating a view, path expressions (such as $path.$site_no) become columns in the view allowing the user to specify WHERE clauses on those columns without being aware that the underlying table contains complex path expressions.

The names given to the columns in the view are case insensitive. Although shown in mixed case, they can be referenced in SQL queries using any mix of case desired.

The examples use a sample river flow data set. To use your own data, replace the table and column names, and authorization object. See Variable Substitutions for Examples for the credentials and location values for the sample data set.

  1. To run NOS-related commands, log on to the database as a user with the required privileges.
  2. If the foreign table that the new view will represent does not exist, create it or ask your database administrator to create it. See Filtering Using a Path Filter in the CREATE FOREIGN TABLE Definition.
  3. Create the view of the foreign table:
    REPLACE VIEW view_name AS (
    SELECT
    CAST($path.$columnX AS data_type) columnX_alias,
    CAST($path.$columnY AS data_type) columnY_alias,
    CAST(SUBSTR($path.$columnZ, X, Y) AS data_type) columnZ_alias,
    columnN
    FROM table_name;

Example: Using Path Variables as Columns in a View

If not already done, create the view that is getting replaced. See Creating a Basic View.

If not already done, create the foreign table that the new view will represent. See Filtering Using a Path Filter in the CREATE FOREIGN TABLE Definition.

REPLACE VIEW riverflowview AS (
SELECT
CAST($path.$site_no AS CHAR(10)) TheSite,
CAST($path.$year AS CHAR(4)) TheYear,
CAST($path.$month AS CHAR(2)) TheMonth,
CAST(SUBSTR($path.$day, 1, 2) AS CHAR(2)) TheDay,
Flow,
GageHeight,
Precipitation
FROM riverflow_pathfilter);

Query the view:

SELECT TOP 2 * FROM riverflowview;

Your result will be similar to the following:

TheSite  TheYear TheMonth TheDay Flow  GageHeight  Precipitation
-------- ------- -------- ------ ----- ----------- ------------- 
09396100    2018       07     18 17500	  10.21           .00
09396100    2018       07     24 17700	  10.25           .00

Columns with missing attributes return NULLs when the record does not contain the attribute.

Example: Run EXPLAIN on the Query to See How the Filtering is Done

EXPLAIN
SELECT thesite,COUNT(*)
FROM riverflowview WHERE thesite=09396100'
GROUP BY 1;

Your result will be similar to the following:

Explanation
--------------------------------------------------------------------------
[…]
  2) Next, we do a single-AMP RETRIEVE step from
     NOS_USR.riverflow_pathfilter in view riverflowview
     metadata by way of an all-rows scan with a condition of (
     "(TD_SYSFNLIB.NosExtractVarFromPath (
     NOS_USR.riverflow_pathfilter in view
     riverflowview.Location, '/s3/td-usgs-public.s3.amazonaws.com',
     2 )(CHAR(10), CHARACTER SET UNICODE, NOT CASESPECIFIC))= '09396100
     '") into Spool 2 (one-amp), which is built locally on that AMP.
     Then we do a SORT to order Spool 2 by the sort key.  The size of
     Spool 2 is estimated with no confidence to be 4 rows (2,820 bytes).
     The estimated time for this step is 0.55 seconds.
  3) We do a single-AMP RETRIEVE step from Spool 2 (Last Use) by way of
     an all-rows scan into Spool 5 (all_amps), which is binpacked and
     redistributed by size to all AMPs in TD_Map1.  The size of Spool 5
     is estimated with no confidence to be 4 rows (2,852 bytes).  The
     estimated time for this step is 0.06 seconds.
  4) We do an all-AMPs SUM step in TD_MAP1 to aggregate from
     NOS_USR.riverflow_pathfilter in view riverflowview
     by way of an object-store scan using Spool 5 (Last Use) with a
     condition of ("(TD_SYSFNLIB.NosExtractVarFromPath (
     NOS_USR.riverflow_pathfilter in view
     riverflowview.Location, '/s3/td-usgs-public.s3.amazonaws.com',
     2 )(CHAR(10), CHARACTER SET UNICODE, NOT CASESPECIFIC)(FLOAT,
     FORMAT '-9.99999999999999E-999'))=
     (NOS_USR.riverflow_pathfilter in view
     riverflowview.site_no)"), and the grouping identifier in field
     1.  Aggregate intermediate results are computed globally, then
     placed in Spool 4 in TD_Map1.  The size of Spool 4 is estimated
     with no confidence to be 222 rows (311,244 bytes).  The estimated
     time for this step is 2.18 seconds.
[…]

(2) is doing the path filtering. It is using the constant 09396100 as a path filtering expression to build the metadata spool. The metadata spool is the spool table that identifies the list of objects the query will actually process.

(4) is doing traditional row filtering. It is compares the site number extracted from the location string to the value in the actual data in the object store.