Extracting Characters from the Left and Right Side of a LONG VARCHAR
Jim_Knicely
- Select Field - Administrator
The LEFT SQL function returns the specified characters from the left side of a string while the RIGHT SQL function returns the specified characters from the right side of a string.
Example:
dbadmin=> SELECT left('Vertica is cool!', 7), right('Everybody loves Vertica', 7); left | right ---------+--------- Vertica | Vertica (1 row)
Unfortunately the LEFT and RIGHT SQL functions won’t work on table columns having the LONG VARCHAR data type where the data size can be up to 32000000 octets.
dbadmin=> \d big_stuff; List of Fields by Tables Schema | Table | Column | Type | Size | Default | Not Null | Primary Key | Foreign Key -------+-----------+--------+-----------------------+---------+---------+----------+-------------+------------- public | big_stuff | c1 | int | 8 | | f | f | public | big_stuff | json | long varchar(1048576) | 1048576 | | f | f | (2 rows) dbadmin=> SELECT LEFT(json, 10) json_left_10_chars, dbadmin-> RIGHT(json, 10) json_right_10_chars dbadmin-> FROM big_stuff; ERROR 3457: Function LEFT(long varchar, int) does not exist, or permission is denied for LEFT(long varchar, int) HINT: No function matches the given name and argument types. You may need to add explicit type casts
Alternatively, we can use the SBSTR function to find characters from the left and right side of a LONG VARCHAR!
dbadmin=> SELECT SUBSTR(json, 1, 10) json_left_chars, dbadmin-> SUBSTR(json, LENGTH(json)-9) json_right_10_chars dbadmin-> FROM big_stuff; json_left_chars | json_right_10_chars ----------------+--------------------- "c": "6EgQ | zXppo4Yi"} (1 row)
Helpful Links:
https://www.vertica.com/docs/9.2.x/HTML/Content/Authoring/SQLReferenceManual/Functions/String/LEFT.htm
Have fun!
0