Path Filter on a View for JSON | Native Object Store ( NOS ) | Teradata Vantage - 17.10 - Using a View with Path Filtering - Advanced SQL Engine - Teradata Database

Teradata Vantage™ - Native Object Store Getting Started Guide

Product
Advanced SQL Engine
Teradata Database
Release Number
17.10
Release Date
July 2021
Content Type
Programming Reference
Publication ID
B035-1214-171K
Language
English (United States)
The following example shows a view on a river flow foreign table that renames path (key) IDs and payload attributes, so that both kinds of data can be referred to in SQL queries.

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 it does not exist, create the foreign table or ask your database administrator to create the foreign table called riverflow_json_path: See Filtering on the Payload Column of a Foreign Table.
  3. Create the view of the foreign table:
    REPLACE VIEW riverflowview_json AS (
    SELECT
    CAST($path.$siteno AS CHAR(10)) TheSite,
    CAST($path.$year AS CHAR(4)) TheYear,
    CAST($path.$month AS CHAR(2)) TheMonth,
    CAST($path.$day AS CHAR(2)) TheDay,
    payload.site_no site_no,
    payload.datetime datetime,
    payload.Flow Flow,
    payload.GageHeight GageHieght,
    payload.Precipitation Precipitation,
    payload.GageHeight2 GageHeight2
    FROM riverflow_json_path
    WHERE TheSite = payload.site_no);
  4. Query the view:
    SELECT TOP 2 * FROM riverflowview_json;

    Results:

          TheSite  09396100
          TheYear  2018
         TheMonth  07
           TheDay  14
          site_no  09396100
         datetime  2018-07-14 00:00
             Flow  232
       GageHieght  2.16
    Precipitation  0.00
      GageHeight2  2.16
    
          TheSite  09396100
          TheYear  2018
         TheMonth  07
           TheDay  16
          site_no  09396100
         datetime  2018-07-16 00:00
             Flow  44.7
       GageHieght  1.50
    Precipitation  0.00
      GageHeight2  1.50
    

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

  5. Filter on the view to find the number of sites with the site number of 09396100:
    SELECT thesite,COUNT(*)
    FROM riverflowview_json WHERE thesite='09396100'
    GROUP BY 1;

    Result:

    TheSite        Count(*)
    ----------  -----------
    09396100           3086
  6. Run EXPLAIN on the query to see how the filtering is done:
    EXPLAIN
    SELECT thesite,COUNT(*)
    FROM riverflowview_json 
    WHERE thesite='09396100'
    GROUP BY 1;

    Result:

    Explanation
    --------------------------------------------------------------
    […]
      2) Next, we do a single-AMP RETRIEVE step from
         NOS_USR.riverflow_json_path in view riverflowview_json metadata by
         way of an all-rows scan with a condition of (
         "(TD_SYSFNLIB.NosExtractVarFromPath (NOS_USR.riverflow_json_path
         in view riverflowview_json.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 38 rows (26,790 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 38 rows (27,094 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_json_path in view riverflowview_json
         by way of an object-store scan using Spool 5 (Last Use) with a
         condition of ("((TD_SYSFNLIB.NosExtractVarFromPath (
         NOS_USR.riverflow_json_path in view riverflowview_json.Location,
         '/s3/td-usgs-public.s3.amazonaws.com', 2 )(CHAR(10), CHARACTER SET
         UNICODE, NOT CASESPECIFIC))= '09396100 ') AND
         (((TD_SYSFNLIB.NosExtractVarFromPath (NOS_USR.riverflow_json_path
         in view riverflowview_json.Location,
         '/s3/td-usgs-public.s3.amazonaws.com', 2 )(CHAR(10), CHARACTER SET
         UNICODE, NOT CASESPECIFIC))=
         (TRANSLATE((NOS_USR.riverflow_json_path in view
         riverflowview_json.Payload .JSONEXTRACTVALUE (
         '$.site_no'(VARCHAR(64000), CHARACTER SET LATIN, NOT
         CASESPECIFIC)))USING LATIN_TO_UNICODE))) AND
         ((TRANSLATE((NOS_USR.riverflow_json_path in view
         riverflowview_json.Payload .JSONEXTRACTVALUE (
         '$.site_no'(VARCHAR(64000), CHARACTER SET LATIN, NOT
         CASESPECIFIC)))USING LATIN_TO_UNICODE))= '09396100 '))"), 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 1,498 rows (
         2,100,196 bytes).  The estimated time for this step is 24.02
         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 JSON payload (the actual data in the object store).