Filter the JSON Payload Column | Native Object Store ( NOS ) | Teradata Vantage - Filtering on the Payload Column of a Foreign Table - Advanced SQL Engine - Teradata Database

Teradata Vantage™ - Native Object Store Getting Started Guide

Product
Advanced SQL Engine
Teradata Database
Release Number
17.05
Published
January 2021
Language
English (United States)
Last Update
2021-01-22
dita:mapPath
zws1595641486108.ditamap
dita:ditavalPath
hoy1596145193032.ditaval
dita:id
B035-1214
lifecycle
previous
Product Category
Software
Teradata Vantage
Path filters usually make queries more efficient because they access less data from external storage.

The examples and results show a sample river flow data set. To use your own data, replace the table and column names, and authorization object.

  1. To run NOS-related commands, log on to the database as a user with the required privileges.
  2. Create a foreign table using a custom PATHPATTERN. Use the authorization object created in Controlling Foreign Table Access with an AUTHORIZATION Object:
    CREATE FOREIGN TABLE riverflow_json_path
    , EXTERNAL SECURITY DEFINER TRUSTED DefAuth
    (
      Location VARCHAR(2048) CHARACTER SET UNICODE CASESPECIFIC,
      Payload JSON INLINE LENGTH 32000 CHARACTER SET UNICODE
    )
    USING (
      LOCATION('YOUR-STORAGE-ACCOUNT')
      PATHPATTERN('$data/$siteno/$year/$month/$day')
    );

    See Variable Substitutions for Examples for the credentials and location values for the sample river flow data set.

  3. Run a query using a payload filter only:
    SELECT TOP 2
      CAST(payload.GageHeight AS FLOAT)( FORMAT '-ZZZ9.99') TheGageHeight,
      CAST(payload.Flow AS FLOAT)(FORMAT '-ZZZZ9.99') TheFlow
      FROM riverflow_json_path
      WHERE payload.site_no = '09394500';

    Result:

    TheGageHeight    TheFlow
    -------------  ---------
             6.39      45.60
             5.04       3.53
  4. Because the site_no attribute also appears as part of the path, a better way to write this query that uses path filtering instead of payload filtering is:
    SELECT TOP 2
      CAST(payload.GageHeight AS FLOAT)( FORMAT '-ZZZ9.99') TheGageHeight,
      CAST (payload.Flow AS FLOAT)(FORMAT '-ZZZZ9.99') TheFlow
      FROM riverflow_json_path
      WHERE $path.$siteno = '09394500';

    Using path filtering is more efficient. Path filtering reduces the number of external objects read. You can view the query log if it is enabled to see that fewer external objects are accessed and less data is transferred with the second query.

    For details on the NOS-related DBQL fields, see the Orange Book, Native Object Store: Teradata Vantage™ Advanced SQL Engine, TDN0009800 and Teradata Vantage™ - Data Dictionary, B035-1092.

    Result:

    TheGageHeight    TheFlow
    -------------  ---------
             6.40      62.90
             5.04       3.53

    Note, TOP does not return the same results each time it is run.