Apache Hive : Hive UDFs

Hive User-Defined Functions (UDFs) are custom functions developed in Java and seamlessly integrated with Apache Hive. UDFs are routines designed to accept parameters, execute a specific action, and return the resulting value. The return value can either be a single scalar row or a complete result set, depending on the UDF’s code and the implemented interface. UDFs represent a powerful capability that enhances classical SQL functionality by allowing the integration of custom code, providing Hive users with a versatile toolset. Apache Hive comes equipped with a variety of built-in UDFs that users can leverage. Similar to other SQL-based solutions, Hive also offers functionality to expand its already rich set of UDFs by incorporating custom ones as needed.

Important

Every UDF’s evaluate method is one row at a time! This means if your UDFs has complex code, it could introduce performance issue in execution time.

To gain an understanding of UDFs, let’s begin with an example to comprehend their execution pattern.

UDF’s in action

SELECT length(string\_col) FROM table\_name;

In this case, the length of thebuilt-in UDF evaluates each row of the string_col values. 

As we see how a built-in UDF works let’s see what kind of built-in UDFs the Apache Hive has.

Tipp

All Hive keywords are case-insensitive, including the names of Hive operators and functions. I.e: length and LENGTH are also accepted by the Hive.

Built-in Aggregate Functions (UDAF)

Hive Aggregate Functions (UDAF) take multiple rows as input and return a single row as output. Depending on the functionality it mostly aggregates the values and returns a single result. These functions are mainly used in the GROUP BY statements.

These functions can be used without GROUP BY as well. 

Return Type Name(Signature) Description Source code
bigint count(*) count(expr) count(DISTINCT expr[, expr...]) count(*) - Returns the total number of retrieved rows, including rows containing NULL values.count(expr) - Returns the number of rows for which the supplied expression is non-NULL.count(DISTINCT expr[, expr]) - Returns the number of rows for which the supplied expression(s) are unique and non-NULL. Execution of this can be optimized with hive.optimize.distinct.rewrite. GenericUDAFCount
double sum(col), sum(DISTINCT col) Returns the sum of the elements in the group or the sum of the distinct values of the column in the group. MODIFIED GenericUDAFSum
double avg(col), avg(DISTINCT col) Returns the average of the elements in the group or the average of the distinct values of the column in the group. GenericUDAFAverage
double min(col) Returns the minimum of the column in the group. GenericUDAFMin
double max(col) Returns the maximum value of the column in the group. GenericUDAFMax
double variance(col), var\_pop(col) Returns the variance of a numeric column in the group. MODIFIED GenericUDAFVariance
double var\_samp(col) Returns the unbiased sample variance of a numeric column in the group. GenericUDAFVarianceSample
double stddev\_pop(col) Returns the standard deviation of a numeric column in the group. GenericUDAFStd
double stddev\_samp(col) Returns the unbiased sample standard deviation of a numeric column in the group. GenericUDAFStdSample
double covar\_pop(col1, col2) Returns the population covariance of a pair of numeric columns in the group. GenericUDAFCovariance
double covar\_samp(col1, col2) Returns the sample covariance of a pair of numeric columns in the group. GenericUDAFCovarianceSample
double corr(col1, col2) Returns the Pearson coefficient of correlation of a pair of numeric columns in the group. GenericUDAFCorrelation
double percentile(bigint col, p) Returns the exact pth percentile of a column in the group (does not work with floating point types). p must be between 0 and 1. NOTE: A true percentile can only be computed for integer values. Use PERCENTILE_APPROX if your input is non-integral. UDAFPercentile
array percentile(bigint col, array(p1 [, p2]...)) Returns the exact percentiles p1, p2, … of a column in the group (does not work with floating point types). pi must be between 0 and 1. NOTE: A true percentile can only be computed for integer values. Use PERCENTILE_APPROX if your input is non-integral.
double percentile\_approx(double col, p [, B]) Returns an approximate pth percentile of a numeric column (including floating point types) in the group. The B parameter controls approximation accuracy at the cost of memory. Higher values yield better approximations, and the default is 10,000. When the number of distinct values in col is smaller than B, this gives an exact percentile value. GenericUDAFPercentileApprox
array percentile\_approx(double col, array(p1 [, p2]...) [, B]) Same as above, but accepts and returns an array of percentile values instead of a single one.
double regr\_avgx(independent, dependent) Equivalent to avg(dependent). 
double regr\_avgy(independent, dependent) Equivalent to avg(independent). 
double regr\_count(independent, dependent) Returns the number of non-null pairs used to fit the linear regression line. 
double regr\_intercept(independent, dependent) Returns the y-intercept of the linear regression line, i.e. the value of b in the equation dependent = a * independent + b.
double regr\_r2(independent, dependent) Returns the coefficient of determination for the regression. 
double regr\_slope(independent, dependent) Returns the slope of the linear regression line, i.e. the value of an in the equation dependent = a * independent + b. 
double regr\_sxx(independent, dependent) Equivalent to regr_count(independent, dependent) * var_pop(dependent). 
double regr\_sxy(independent, dependent) Equivalent to regr_count(independent, dependent) * covar_pop(independent, dependent). 
double regr\_syy(independent, dependent) Equivalent to regr_count(independent, dependent) * var_pop(independent).
array<struct {'x','y'}> histogram\_numeric(col, b) Computes a histogram of a numeric column in the group using b non-uniformly spaced bins. The output is an array of size b of double-valued (x,y) coordinates that represent the bin centers and heights GenericUDAFHistogramNumeric
array collect\_set(col) Returns a set of objects with duplicate elements eliminated. GenericUDAFCollectSet
array collect\_list(col) Returns a list of objects with duplicates.  GenericUDAFCollectList
int ntile(integer x) Divides an ordered partition into x groups called buckets and assign a bucket number to each row in the partition. This allows easy calculation of tertiles, quartiles, deciles, percentiles, and other common summary statistics. GenericUDAFNTile

Most of the UDAFs ignore NULL values. 

Built-in Table-Generating Functions (UDTF)

Normal user-defined functions, such as concat(), take in a single input row and output a single output row. In contrast, table-generating functions transform a single input row into multiple output rows. UDTF is one of the most advanced functions.

Row-set columns types Name(Signature) Description Source Code
T explode(ARRAY<T> a) Explodes an array to multiple rows. Returns a row-set with a single column (col), one row for each element from the array. GenericUDTFExplode
Tkey,Tvalue explode(MAP<Tkey,Tvalue> m) Explodes a map to multiple rows. Returns a row-set with two columns (key,value) , one row for each key-value pair from the input map.
int,T posexplode(ARRAY<T> a) Explodes an array to multiple rows with an additional positional column ofint type (position of items in the original array, starting with 0). Returns a row-set with two columns (pos,val), one row for each element from the array. GenericUDTFPosExplode
T1,…,Tn inline(ARRAY<STRUCT<f1:T1,...,fn:Tn>> a) Explodes an array of structs to multiple rows. Returns a row-set with N columns (N = number of top level elements in the struct), one row per struct from the array. GenericUDTFInline
T1,…,Tn/r stack(int r,T1 V1,...,Tn/r Vn) Breaks up n values V1,…,Vninto r rows. Each row will have n/r columns. r must be constant. GenericUDTFStack
string1,…,stringn json\_tuple(string jsonStr, string k1,...,string kn) Takes JSON string and a set of n keys, and returns a tuple of n values. This is a more efficient version of the get_json_object UDF because it can get multiple keys with just one call. GenericUDTFJSONTuple
string 1,…,stringn parse\_url\_tuple(string urlStr, string p1,...,string pn) Takes URLstring and a set of n URL parts, and returns a tuple of n values. This is similar to the parse_url() UDF but can extract multiple parts at once out of a URL. Valid part names are HOST, PATH, QUERY, REF, PROTOCOL, AUTHORITY, FILE, USERINFO, QUERY:. GenericUDTFParseUrlTuple

String Functions

There is no good engine without string manipulation functions. Apache Hive has rich built-instring functions. 

Return Type Name(Signature) Description Source code
int ascii(string str) Returns the numeric value of the first character of str. UDFAscii
string base64(binary bin) Converts the argument from binary to a base64string. UDFBase64
int character\_length(string str) Returns the number of UTF-8 characters contained in str. The function char_length is shorthand for this function. GenericUDFCharacterLength
string chr(bigint|double A) Returns the ASCII character having the binary equivalent to A. If A is larger than 256 the result is equivalent to chr(A % 256). Example: select chr(88); returns “X”. UDFChr
string concat(string|binary A,string|binary B...) Returns the string or bytes resulting from concatenating the strings or bytes passed in as parameters in order. For example, concat(‘foo’, ‘bar’) results in ‘foobar’. Note that this function can take any number of input strings. GenericUDFConcat
array<struct<string,double» context\_ngrams(array<array<string>>, array<string>, int K, int pf) Returns the top-k contextual N-grams from a set of tokenized sentences, given a string of “context”. See StatisticsAndDataMining for more information. GenericUDAFContextNGrams
string concat\_ws(string SEP, string A, string B...) Like concat() above, but with custom separator SEP. GenericUDFConcatWS
string concat\_ws(string SEP, array<string>) Like concat_ws() above, but taking an array ofstrings.
string decode(binary bin, string charset) Decodes the first argument into a string using the provided character set (one of ‘US-ASCII’, ‘ISO-8859-1’, ‘UTF-8’, ‘UTF-16BE’, ‘UTF-16LE’, ‘UTF-16’). If either argument is null, the result will also be null. GenericUDFDecode
string elt(N int, str1 string, str2s tring, str3 string,...) Return string at index number. For example elt(2,‘hello’,‘world’) returns ‘world’. Returns NULL if N is less than 1 or greater than the number of arguments. GenericUDFElt
binary encode(string src, string charset) Encodes the first argument into a BINARY using the provided character set (one of ‘US-ASCII’, ‘ISO-8859-1’, ‘UTF-8’, ‘UTF-16BE’, ‘UTF-16LE’, ‘UTF-16’). If either argument is null, the result will also be null.  GenericUDFEncode
int field(val T, val1 T, val2 T, val3 T,...) Returns the index of val in the val1,val2,val3,… list or 0 if not found. For example field(‘world’,‘say’,‘hello’,‘world’) returns 3.All primitive types are supported, arguments are compared using str.equals(x). If val is NULL, the return value is 0. GenericUDFField
int find\_in\_set(string str, string strList) Returns the first occurrence of str in strList where strList is a comma-delimited string. Returns null if either argument is null. Returns 0 if the first argument contains any commas. For example, find_in_set(‘ab’, ‘abc,b,ab,c,def’) returns 3. UDFFindInSet
string format\_number(number x, int d) Formats the number X to a format like ‘#,###,###.##’, rounded to D decimal places, and returns the result as a string. If D is 0, the result has no decimal point or fractional part. GenericUDFFormatNumber
string get\_json\_object(string json\_string,string path) Extracts JSON object from a JSON string based on JSON path specified, and returns JSON string of the extracted JSON object. It will return null if the input JSON string is invalid.NoteThe json path can only have the characters [0-9a-z_], i.e., no upper-case or special characters. Also, the keys cannot start with numbers. This is due to restrictions on Hive column names. UDFJson
boolean in\_file(string str, string filename) Returns true if the string str appears as an entire line in filename. GenericUDFInFile
int instr(string str, string substr) Returns the position of the first occurrence of substr in str. Returns null if either of the arguments are null and returns 0 if substr could not be found in str. Be aware that this is not zero-based. The first character in str has index 1. GenericUDFInstr
int length(string A) Returns the length of the string. GenericUDFLength
int locate(string substr,string str[,int pos]) Returns the position of the first occurrence of substr in str after position pos. GenericUDFLocate
string lower(string A) lcase(string A) Returns the string resulting from converting all characters of B to lowercase. For example, lower(‘fOoBaR’) results in ‘foobar’. GenericUDFLower
string lpad(string str,int len,string pad) Returns str, left-padded with pad to a length of len. If str is longer than len, the return value is shortened to len characters. In the case of an empty padstring, the return value is null. GenericUDFLpad
string ltrim(string A) Returns the string resulting from trimming spaces from the beginning(left-hand side) of A. For example, ltrim(' foobar ‘) results in ‘foobar ‘. GenericUDFLTrim
array<struct<string,double» ngrams(array<array<string>>,int N,int K,int pf) Returns the top-k N-grams from a set of tokenized sentences, such as those returned by the sentences() UDAF. See StatisticsAndDataMining for more information. GenericUDAFnGrams
int octet\_length(string str) Returns the number of octets required to hold the string str in UTF-8 encoding.  Note that octet_length(str) can be larger than character_length(str). GenericUDFOctetLength
string parse\_url(string urlString,string partToExtract [,string keyToExtract]) Returns the specified part from the URL. Valid values for partToExtract include HOST, PATH, QUERY, REF, PROTOCOL, AUTHORITY, FILE, and USERINFO. For example, parse_url('http://facebook.com/path1/p.php?k1=v1&k2=v2#Ref1’, ‘HOST’) returns ‘facebook.com’. Also, a value of a particular key in QUERY can be extracted by providing the key as the third argument, for example, parse_url('http://facebook.com/path1/p.php?k1=v1&k2=v2#Ref1’, ‘QUERY’, ‘k1’) returns ‘v1’. UDFParseUrl
string printf(string format, Obj... args) Returns the input formatted according to printf-style formatstrings. GenericUDFPrintf
string quote(string text) Returns the quoted string. NEW Includes escape character for any single quotes in Apache Hive 4.0.0 GenericUDFQuote
Input Output
NULL NULL
DONT ‘DONT’
DON’T ‘DON'T’
Return Type Name(Signature) Description Source code
string regexp\_extract(string subject, string pattern, int index) Returns the string extracted using the pattern. For example, regexp_extract(‘foothebar’, ‘foo(.*?)(bar)’, 2) returns ‘bar.’ Note that some care is necessary in using predefined character classes: using ‘\s’ as the second argument will match the letter s; ‘\s’ is necessary to match whitespace, etc. The ‘index’ parameter is the Java regex Matcher group() method index.  UDFRegExpExtract
string regexp\_replace(string INITIAL\_STRING, string PATTERN, string REPLACEMENT) Returns the string resulting from replacing all substrings in INITIAL_STRING that match the java regular expression syntax defined in PATTERN with instances of REPLACEMENT. For example, regexp_replace(“foobar”, “oo|ar”, “") returns ‘fb.’ Note that some care is necessary in using predefined character classes: using ‘\s’ as the second argument will match the letter s; ‘\s’ is necessary to match whitespace, etc. UDFRegExpReplace
string repeat(string str, int n) Repeats str in n times. UDFRepeat
string replace(string A, string OLD, string NEW) Returns the string A with all non-overlapping occurrences of OLD replaced with NEW. Example: select replace(“ababab”, “abab”, “Z”); returns “Zab”. UDFReplace
string reverse(string A) Returns the reversed string. UDFReverse
string rpad(string str,int len,string pad) Returns str, right-padded with pad to a length of len. If str is longer than len, the return value is shortened to len characters. In the case of an empty padstring, the return value is null. GenericUDFRpad
string rtrim(string A) Returns the string resulting from trimming spaces from the end(right-hand side) of A. For example, rtrim(’ foobar ‘) results in ' foobar’. GenericUDFRTrim
array<array> sentences(string str,string lang,string locale) Tokenizes a string of natural language text into words and sentences, where each sentence is broken at the appropriate sentence boundary and returned as an array of words. The ‘lang’ and ‘locale’ are optional arguments. For example, sentences(‘Hello there! How are you?') returns ( (“Hello”, “there”), (“How”, “are”, “you”) ). GenericUDFSentences
string space(int n) Returns a string of n spaces. UDFSpace
array split(string str, string pat) Splits str around pat (pat is a regular expression). GenericUDFSplit
map<string,string> str\_to\_map(text[, delimiter1, delimiter2]) Splits text into key-value pairs using two delimiters. Delimiter1 separates text into K-V pairs, and Delimiter2 splits each K-V pair. Default delimiters are ‘,’ for delimiter1 and ‘:’ for delimiter2. GenericUDFStringToMap
string substr(string|binary A,int start) substring(string|binary A,int start) Returns the substring or slice of the byte array of A starting from start position till the end of string A. For example, substr(‘foobar’, 4) results in ‘bar’. GenericUDFSubstringIndex
string substr(string|binary A,int start,int len) substring(string|binary A,int start,int len) Returns the substring or slice of the byte array of A starting from start position with length len. For example, substr(‘foobar’, 4, 1) results in ‘b’.
string substring\_index(string A,string delim,int count) Returns the substring from string A before count occurrences of the delimiter delim. If the count is positive, everything to the left of the final delimiter (counting from the left) is returned. If count is negative, everything to the right of the final delimiter (counting from the right) is returned. Substring_index performs a case-sensitive match when searching for delim. Example: substring_index('www.apache.org’, ‘.’, 2) = ‘www.apache’. GenericUDFSubstringIndex
string translate(string|char|varchar input,string|char|varchar from, string|char|varchar to) Translates the input string by replacing the characters present in the from string with the corresponding characters in the tostring. This is similar to the translate function in PostgreSQL. If any of the parameters to this UDF are NULL, the result is NULL as well.  GenericUDFTranslate
string trim(string A) Returns the string resulting from trimming spaces from both ends of A. For example, trim(' foobar ‘) results in ‘foobar’ GenericUDFTrim
binary unbase64(string str) Converts the argument from a base64 string to BINARY. UDFUnbase64
string upper(string A) ucase(string A) Returns the string resulting from converting all characters of A to upper case. For example, upper(‘fOoBaR’) results in ‘FOOBAR’. GenericUDFUpper
string initcap(string A) Returns string, with the first letter of each word in uppercase, and all other letters in lowercase. Words are delimited by whitespace. GenericUDFInitCap
int levenshtein(string A, string B) Returns the Levenshtein distance between two strings. Example: levenshtein(‘kitten’, ‘sitting’) results in 3. GenericUDFLevenshtein
string soundex(string A) Returns the soundex code of the string. Example: soundex(‘Miller’) results in M460. GenericUDFSoundex
string deserialize(base64 encoded message, compressionFormat) NEW Returns plain text string of given message which was compressed in compressionFormat and base64 encoded. Currently, Supports only ‘gzip’ for Gzip compressed and base 64 encoded strings.Example: deserialize(‘H4sIAAAAAAAA/ytJLS4BAAx+f9gEAAAA’, ‘gzip’) Result: test GenericUDFDeserialize

Date Functions

In many analytical workloads Date is one of the most used built-in functions in Hive. The following list contains the supported built-in date functions in Hive.

Return Type Name(Signature) Description Source code
string from\_unixtime(bigint unixtime[,string pattern]) Converts a number of seconds since epoch (1970-01-01 00:00:00 UTC) to a string representing the timestamp of that moment in the current time zone(using config “hive.local.time.zone”) using the specified pattern. If the pattern is missing the default is used (‘uuuu-MM-dd HH:mm:ss’ or yyyy-MM-dd HH:mm:ss’). Example: from_unixtime(0)=1970-01-01 00:00:00 (hive.local.time.zone=Etc/GMT)MODIFIEDAs of Hive 4.0.0 the “hive.datetime.formatter” property can be used to control the underlying formatter implementation and as a consequence the accepted patterns and their behavior.  Earlier versions used https://docs.oracle.com/javase/8/docs/api/java/text/SimpleDateFormat.html as the underlying formatter. GenericUDFFromUnixTime
bigint unix\_timestamp() Gets the current Unix timestamp in seconds. This function is not deterministic and its value is not fixed for the scope of a query execution, therefore prevents proper optimization of queries - this has been deprecated since 2.0 in favor of CURRENT_TIMESTAMP constant. GenericUDFUnixTimeStamp
bigint unix\_timestamp(string date) Converts a DateTimestring to unix time (seconds since epoch) using the default pattern(s). The default accepted patterns depend on the underlying formatter implementation. The DateTime string does not contain a timezone so the conversion uses the local time zone as specified by “hive.local.time.zone” property. Returns null when the conversion fails. Example: unix_timestamp(‘2009-03-20 11:30:01’) = 1237573801MODIFIEDAs of Hive 4.0.0 the “hive.datetime.formatter” property can be used to control the underlying formatter implementation and as a consequence the accepted patterns and their behavior. Earlier versions used https://docs.oracle.com/javase/8/docs/api/java/text/SimpleDateFormat.html as the underlying formatter.
bigint unix\_timestamp(string date,string pattern) Converts a date-time string to unix time (seconds since epoch) using the specified pattern. The accepted patterns and their behavior depend on the underlying formatter implementation. Returns null when the conversion fails. Example: unix_timestamp(‘2009-03-20’, ‘uuuu-MM-dd’) = 1237532400MODIFIEDAs of Hive 4.0.0 the “hive.datetime.formatter” property can be used to control the underlying formatter implementation and as a consequence the accepted patterns and their behavior.  Earlier versions used https://docs.oracle.com/javase/8/docs/api/java/text/SimpleDateFormat.html as the underlying formatter.
date to\_date(string timestamp) Returns the date part of a timestamp date object. Example: to_date(“1970-01-01 00:00:00”)  GenericUDFDate
int year(string date) Returns the year part of a date or a timestamp string: year(“1970-01-01 00:00:00”) = 1970, year(“1970-01-01”) = 1970. UDFYear
int quarter(date/timestamp/string) Returns the quarter of the year for a date, timestamp, or string in the range 1 to 4. Example: quarter(‘2015-04-08’) = 2. GenericUDFQuarter
int month(string date) Returns the month part of a date or a timestamp string. Example: month(“1970-11-01 00:00:00”) = 11, month(“1970-11-01”) = 11. UDFMonth
int day(string date) dayofmonth(date) Returns the day part of a date or a timestamp string. Example: day(“1970-11-01 00:00:00”) = 1, day(“1970-11-01”) = 1. UDFDayOfMonth
int hour(string date) Returns the hour of the timestamp: Example: hour(‘2009-07-30 12:58:59’) = 12, hour(‘12:58:59’) = 12. UDFHour
int minute(string date) Returns the minute of the timestamp. UDFMinute
int second(string date) Returns the second of the timestamp. UDFSecond
int weekofyear(string date) Returns the week number of a timestamp string. Example: weekofyear(“1970-11-01 00:00:00”) = 44 or weekofyear(“1970-11-01”) = 44. UDFWeekOfYear
int extract(field FROM source) Retrieve fields such as days or hours from the source. The source must be a date, timestamp, interval, or string that can be converted into either a date or timestamp. Supported fields include day, dayofweek, hour, minute, month, quarter, second, week and year.Examples:1. select extract(month from “2016-10-20”) results in 10. 2. select extract(hour from “2016-10-20 05:06:07”) results in 5. 3. select extract(dayofweek from “2016-10-20 05:06:07”) results in 5. 4. select extract(month from interval ‘1-3’ year to month) results in 3. 5. select extract(minute from interval ‘3 12:20:30’ day to second) results in 20.
int datediff(string enddate,string startdate) Returns the number of days from startdate to end date. Example: datediff(‘2009-03-01’, ‘2009-02-27’) = 2. GenericUDFDateDiff
date date\_add(date/timestamp/string startdate, tinyint/smallint/int days) Adds a number of days to startdate. Example: date_add(‘2008-12-31’, 1) = ‘2009-01-01’. GenericUDFDateAdd
date date\_sub(date/timestamp/string startdate, tinyint/smallint/int days) Subtracts a number of days to startdate: date_sub(‘2008-12-31’, 1) = ‘2008-12-30’. GenericUDFDateSub
timestamp from\_utc\_timestamp({any primitive type} ts,string timezone) Converts a timestamp* in UTC to a given timezone.* timestamp is a primitive type, including timestamp/date, tinyint/smallint/int/bigint, float/double and decimal.Fractional values are considered as seconds.integer values are considered as milliseconds. For example, from_utc_timestamp(2592000.0,‘PST’), from_utc_timestamp(2592000000,‘PST’) and from_utc_timestamp(timestamp ‘1970-01-30 16:00:00’,‘PST’) all return the timestamp 1970-01-30 08:00:00. GenericUDFFromUtcTimestamp
timestamp to\_utc\_timestamp({any primitive type} ts,string timezone) Converts a timestamp* in a given timezone to UTC.* timestamp is a primitive type, including timestamp/date, tinyint/smallint/int/bigint, float/double and decimal.Fractional values are considered as seconds.integer values are considered as milliseconds. For example, to_utc_timestamp(2592000.0,‘PST’), to_utc_timestamp(2592000000,‘PST’) and to_utc_timestamp(timestamp ‘1970-01-30 16:00:00’,‘PST’) all return the timestamp 1970-01-31 00:00:00. GenericUDFToUtcTimestamp
date current\_date Returns the current date at the start of query evaluation. All calls of current_date within the same query return the same value. GenericUDFCurrentDate
timestamp current\_timestamp Returns the current timestamp at the start of query evaluation. All calls of current_timestamp within the same query return the same value. GenericUDFCurrentTimestamp
string add\_months(string start\_date,int num\_months, output\_date\_format) Returns the date that is num_months after start_date. start_date is a string, date or timestamp. num_months is an integer. If start_date is the last day of the month or if the resulting month has fewer days than the day component of start_date, then the result is the last day of the resulting month. Otherwise, the result has the same day component as start_date. The default output format is ‘yyyy-MM-dd’.MODIFIEDBefore Hive 4.0.0, the time part of the date is ignored. As of Hive 4.0.0, add_months supports an optional argument output_date_format, which accepts a string that represents a valid date format for the output. This allows to retain the time format in the output.For example :add_months(‘2009-08-31’, 1) returns ‘2009-09-30’.add_months(‘2017-12-31 14:15:16’, 2, ‘YYYY-MM-dd HH:mm:ss’) returns ‘2018-02-28 14:15:16’. GenericUDFAddMonths
string last\_day(string date) Returns the last day of the month to which the date belongs. date is a string in the format ‘yyyy-MM-dd HH:mm:ss’ or ‘yyyy-MM-dd’. The time part of the date is ignored! GenericUDFLastDay
string next\_day(string start\_date,string day\_of\_week) Returns the first date which is later than start_date and named as day_of_week.  start_date  is a string/date/timestamp. day_of_week is 2 letters, 3 letters or full name of the day of the week (e.g. Mo, tue, FRIDAY). The time part of start_date is ignored. Example: next_day(‘2015-01-14’, ‘TU’) = 2015-01-20. GenericUDFNextDay
string trunc(string date,string format) Returns date truncated to the unit specified by the format. Supported formats: MONTH/MON/MM, YEAR/YYYY/YY. Example: trunc(‘2015-03-17’, ‘MM’) = 2015-03-01. GenericUDFTrunc
double months\_between(date1, date2) Returns the number of months between dates date1 and date2. If date1 is later than date2, then the result is positive. If date1 is earlier than date , then the result is negative. If date1 and date2 are either the same days of the month or both last days of months, then the result is always aninteger. Otherwise, the UDF calculates the fractional portion of the result based on a 31-day month and considers the difference in time components date1 and date2. date1 and date2 type can be date, timestamp or string in the format ‘yyyy-MM-dd’ or ‘yyyy-MM-dd HH:mm:ss’. The result is rounded to 8 decimal places. Example: months_between(‘1997-02-28 10:30:00’, ‘1996-10-30’) = 3.94959677 GenericUDFMonthsBetween
string date\_format(date/timestamp/string ts,string pattern) Converts a date/timestamp/string to a value of string using the specified pattern. The accepted patterns and their behavior depend on the underlying formatter implementation. The pattern argument should be constant. Example: date_format(‘2015-04-08’, ‘y’) = ‘2015’.date_format can be used to implement other UDFs, e.g.:* dayname(date) is date_format(date, ‘EEEE’) dayofyear(date) is date_format(date, ‘D’) MODIFIEDAs of Hive 4.0.0 the “hive.datetime.formatter” property can be used to control the underlying formatter implementation and as a consequence the accepted patterns and their behavior.  Earlier versions used https://docs.oracle.com/javase/8/docs/api/java/text/SimpleDateFormat.html as the underlying formatter. GenericUDFDateFormat

Mathematical Functions

The following built-in mathematical functions are supported in Hive. 

Return Type Name (Signature) Description Source code
double round(double a) Returns the rounded bigint value of a. GenericUDFRound
double round(double a,int d) Returns a rounded to d decimal places.
double bround(double a) Returns the rounded bigint value of a using HALF_EVEN rounding mode. Also known as Gaussian rounding or bankers' rounding. Example: bround(2.5) = 2, bround(3.5) = 4. GenericUDFBRound
double bround(double a,int d) Returns a rounded to d decimal places using HALF_EVEN rounding mode.  Example: bround(8.25, 1) = 8.2, bround(8.35, 1) = 8.4.
bigint floor(double a) Returns the maximum bigint value that is equal to or less than a. GenericUDFFloor
bigint ceil(double a), ceiling(double a) Returns the minimum bigint value that is equal to or greater than a. GenericUDFCeil
double rand(), rand(INT seed) Returns a random number (that changes from row to row) that is distributed uniformly from 0 to 1. Specifying the seed will make sure the generated random number sequence is deterministic. UDFRand
double exp(double a), exp(decimal a) Returns ea where e is the base of the natural logarithm. UDFExp
double ln(double a), ln(decimal a) Returns the natural logarithm of the argument a. UDFLn
double log10(double a), log10(decimal a) Returns the base-10 logarithm of the argument a. UDFLog10
double log2(double a), log2(decimal a) Returns the base-2 logarithm of the argument a UDFLog2
double log(double base, double a) log(decimal base, decimal a) Returns the base-base logarithm of the argument a. UDFLog
double pow(double a, double p), power(double a, double p) Returns ap. GenericUDFPower
double sqrt(double a), sqrt(decimal a) Returns the square root of a. UDFSqrt
string bin(bigint a) Returns the number in binary format. UDFBin
string hex(bigint a) hex(string a) hex(binary a) If the argument is an int or binary, hex returns the number as a string in hexadecimal format. Otherwise, if the number is a string, it converts each character into its hexadecimal representation and returns the resulting string.  UDFHex
binary unhex(STRING a) Inverse of hex.interprets each pair of characters as a hexadecimal number and converts to the byte representation of the number. UDFUnhex
string conv(bigint num,int from\_base,int to\_base), conv(STRING num,int from\_base,int to\_base) Converts a number from a given base to another. UDFConv
double abs(double a) Returns the absolute value. GenericUDFAbs
int or double pmod(INT a,int b), pmod(double a, double b) Returns the positive value of a mod b. GenericUDFOPMod
double sin(double a), sin(decimal a) Returns the sine of a (a is in radians). UDFSin
double asin(double a), asin(decimal a) Returns the arc sin of a if -1<=a<=1 or NULL otherwise.  UDFAsin
double cos(double a), cos(decimal a) Returns the cosine of a (a is in radians).  UDFCos
double acos(double a), acos(decimal a) Returns the arccosine of a if -1<=a<=1 or NULL otherwise. UDFAcos
double tan(double a), tan(decimal a) Returns the tangent of a (a is in radians). UDFTan
double atan(double a), atan(decimal a) Returns the arctangent of a. UDFAtan
double degrees(double a), degrees(decimal a) Converts value of a from radians to degrees.  UDFDegrees
double radians(double a), radians(double a) Converts value of a from degrees to radians.  UDFRadians
int or double positive(INT a), positive(double a) Returns a. GenericUDFOPPositive
int or double negative(INT a), negative(double a) Returns -a. GenericUDFOPNegative
double or int sign(double a), sign(decimal a) Returns the sign of a as ‘1.0’ (if a is positive) or ‘-1.0’ (if a is negative), ‘0.0’ otherwise. The decimal version returns int instead of double.  UDFSign
double e() Returns the value of e. UDFE
double pi() Returns the value of pi. UDFPI
bigint factorial(INT a) Returns the factorial of a Valid a is [0..20]. GenericUDFFactorial
double cbrt(double a) Returns the cube root of a double value. GenericUDFCbrt
int bigint shiftleft(TINYINT|SMALLINT|INT a,int b) shiftleft(bigint a,int b) Bitwise left shift. Shifts a b positions to the left.Returns int for tinyint, smallint andint a. Returns bigint for bigint a. UDFOPBitShiftLeft
int bigint shiftright(TINYINT|SMALLINT|INT a,int b) shiftright(bigint a,int b) Bitwise right shift. Shifts a b positions to the right.Returns int for tinyint, smallint andint a. Returns bigint for bigint a. UDFOPBitShiftRight
int bigint shiftrightunsigned(TINYINT|SMALLINT|INT a,int b), shiftrightunsigned(bigint a,int b) Bitwise unsigned right shift. Shifts a b positions to the right.Returns int for tinyint, smallint andint a. Returns bigint for bigint a. UDFOPBitShiftRightUnsigned
T greatest(T v1, T v2, ...) Returns the greatest value of the list of values. Fixed to return NULL when one or more arguments are NULL, and strict type restriction relaxed, consistent with “>” operator. GenericUDFGreatest
T least(T v1, T v2, ...) Returns the least value of the list of values. Fixed to return NULL when one or more arguments are NULL, and strict type restriction relaxed, consistent with “<” operator. GenericUDFLeast
int width\_bucket(NUMERIC expr, NUMERIC min\_value, NUMERIC max\_value,int num\_buckets) Returns an integer between 0 and num_buckets+1 by mapping expr into the ith equally sized bucket. Buckets are made by dividing [min_value, max_value]into equally sized regions. If expr < min_value, return 1, if expr > max_value return num_buckets+1. See https://docs.oracle.com/cd/B19306_01/server.102/b14200/functions214.htm GenericUDFWidthBucket
double cosh(double x) NEW Returns the hyperbolic cosine of x, where x is in radians. Example: cosh(0) Result: 1 UDFCosh
double tanh(double x) NEW Returns the hyperbolic tangent of x, where x is in radians. Example: tanh(0) Result: 1 UDFTanh

Collection Functions

The following built-in collection functions are supported in Hive. 

Return Type Name(Signature) Description OSS
int size(Map<K.V>) Returns the number of elements in the map type.
int size(Array<T>) Returns the number of elements in the array type.
array map\_keys(Map<K.V>) Returns an unordered array containing the keys of the input map.
array map\_values(Map<K.V>) Returns an unordered array containing the values of the input map.
boolean array\_contains(Array<T>, value) Returns TRUE if the array contains the provided parameter value.
array sort\_array(Array<T>) Sorts the input array in ascending order according to the natural ordering of the array elements and returns it.
array array(obj1, obj2, .... objN) NEW The function returns an array of the same type as the input array with distinct values. Example: array(‘b’, ’d', ’d', ‘a’) reurtns [‘b’, ’d', ‘a’]  GenericUDFArrayDistinct.java
array array\_slice(array, start, length) NEW Returns the subset or range of elements. Example: array-slice(array(1, 2, 3, 4), 2 , 2) Result: 3,4 GenericUDFArraySlice 
t array\_min((array(obj1, obj2, obj3...)) NEW The function returns the minimum value in the array with elements for which order is supported. Example: array_min(array(1, 3, 0, NULL)) Result: 0 GenericUDFArrayMin
t array\_max((array(obj1, obj2, obj3...)) NEW The function returns the maximum value in the array with elements for which order is supported. Example: array_max(array(1, 3, 0, NULL)) Result: 3 GenericUDFArrayMax
t array\_distinct(array(obj1, obj2, obj3...)) NEW The function returns an array of the same type as the input array with distinct values. Example: array_distinct(array(‘b’, ’d', ’d', ‘a’)) Result:  [‘b’, ’d', ‘a’] GenericUDFArrayDistinct
string array\_join(array, delimiter, replaceNull) NEW Concatenate the elements of an array with a specified delimiter. Example: array_join(array(1, 2, NULL, 4), ‘,’,':') Result: 1,2,:,4 GenericUDFArrayJoin
array array\_expect(array1, array2) NEW Returns an array of the elements in array1 but not in array2. Example: array_expect(array(1, 2, 3,4), array(2,3)) Result: [1,4] GenericUDFArrayExcept
array array\_intersect(array1, array2) NEW Returns an array of the elements in the intersection of array1 and array2, without duplicates. Example: array_intersect(array(1, 2, 3,4), array(1,2,3)) Result: [1,2,3] GenericUDFArrayIntersect
array array\_union(array1, array2) NEW Returns an array of the elements in the union of array1 and array2 without duplicates. Example: array_union(array(1, 2, 2, 4), array(2, 3)) Result: [1, 2, 3, 4] GenericUDFArrayUnion
array array\_remove(array, element) NEW Removes all occurrences of elements from the array. Example: array_remove(array(1, 2, 3, 4, 2), 2) Result: [1, 3, 4] GenericUDFArrayRemove

Type Conversion Functions

The following built-in type conversion functions are supported in Hive. 

Return Type Name(Signature) Description Source code
binary binary(string|binary) Casts the parameter into a binary. GenericUDFBaseBinary
Expected “=” to follow “type” cast(expr as <type>) Converts the results of the expression expr to <type>. For example, cast(‘1’ as bigint) will convert the string ‘1’ to its integral representation. A null is returned if the conversion does not succeed. If cast(expr as boolean) Hive returns true for a non-empty string.

Conditional Functions

The following built-in conditional functions are supported in Hive.

Return Type Name(Signature) Description
T if(boolean testCondition, T valueTrue, T valueFalseOrNull) Returns valueTrue when testCondition is true, returns valueFalseOrNull otherwise.
boolean isnull( a ) Returns true if a is NULL and false otherwise.
boolean isnotnull ( a ) Returns true if a is not NULL and false otherwise.
T nvl(T value, T default\_value) Returns default value if value is null else returns value.
T COALESCE(T v1, T v2, ...) Returns the first v that is not NULL, or NULL if all v’s are NULL.
T CASE a WHEN b THEN c [WHEN d THEN e]* [ELSE f] END When a = b, returns c; when a = d, returns e; else returns f.
T CASE WHEN a THEN b [WHEN c THEN d]* [ELSE e] END When a = true, returns b; when c = true, returns d; else returns e.
T nullif( a, b ) Returns NULL if a=b; otherwise returns a.Shorthand forCASE WHEN a = b then NULL else a
void assert\_true(boolean condition) Throw an exception if ‘condition’ is not true, otherwise, return null. For example, select assert_true (2<1).

Data Masking Functions

The following built-in data masking functions are supported in Hive:

Return Type Name(Signature) Description Source code
string mask(string str[,string upper[,string lower[,string number]]]) Returns a masked version of str. By default, upper case letters are converted to “X”, lower case letters are converted to “x” and numbers are converted to “n”. Example: mask(“abcd-EFGH-8765-4321”) results in xxxx-XXXX-nnnn-nnnn. You can override the characters used in the mask by supplying additional arguments: the second argument controls the mask character for upper case letters, the third argument for lower case letters, and the fourth argument for numbers. For example, mask(“abcd-EFGH-8765-4321”, “U”, “l”, “#") results in llll-UUUU-####-####. GenericUDFMask
string mask\_first\_n(string str[,int n]) Returns a masked version of str with the first n values masked. Upper case letters are converted to “X”, lower case letters are converted to “x” and numbers are converted to “n”. For example, mask_first_n(“1234-5678-8765-4321”, 4) results in nnnn-5678-8765-4321. GenericUDFMaskFirstN
string mask\_last\_n(string str[,int n]) Returns a masked version of str with the last n values masked. Upper case letters are converted to “X”, lower case letters are converted to “x” and numbers are converted to “n”. For example, mask_last_n(“1234-5678-8765-4321”, 4) results in 1234-5678-8765-nnnn. GenericUDFMaskLastN
string mask\_show\_first\_n(string str[,int n]) Returns a masked version of str, showing the first n characters unmasked. Upper case letters are converted to “X”, lower case letters are converted to “x” and numbers are converted to “n”. For example, mask_show_first_n(“1234-5678-8765-4321”, 4) results in 1234-nnnn-nnnn-nnnn. GenericUDFMaskShowFirstN
string mask\_show\_last\_n(string str[,int n]) Returns a masked version of str, showing the last n characters unmasked. Upper case letters are converted to “X”, lower case letters are converted to “x” and numbers are converted to “n”. For example, mask_show_last_n(“1234-5678-8765-4321”, 4) results in nnnn-nnnn-nnnn-4321. GenericUDFMaskShowLastN
string mask\_hash(string|char|varchar str) Returns a hashed value based on str. The hash is consistent and can be used to join masked values together across tables. This function returns null for non-string types. GenericUDFMaskHash

Miscellaneous Functions

In Hive several built-in functions do not belong to any categories above. These are the special functions that Hive has.

Return Type Name(Signature) Description Source code
varies java\_method(class, method[, arg1[, arg2..]]) Synonym for reflect. GenericUDFReflect
varies reflect(class, method[, arg1[, arg2..]]) Calls a Java method by matching the argument signature, using reflection. See Reflect (Generic) UDF for examples. GenericUDFReflect
int hash(a1[, a2...]) Returns a hash value of the arguments.  GenericUDFHash
string current\_user() Returns current user name from the configured authenticator manager. Could be the same as the user provided when connecting, but with some authentication managers (for example HadoopDefaultAuthenticator) it could be different. GenericUDFCurrentUser
string logged\_in\_user() Returns the current user name from the session state. This is the username provided when connecting to Hive. GenericUDFLoggedInUser
string current\_database() Returns current database name. GenericUDFCurrentDatabase
string md5(string/binary) Calculates an MD5 128-bit checksum for the string or binary. The value is returned as a string of 32 hex digits, or NULL if the argument was NULL. Example: md5(‘ABC’) = ‘902fbdd2b1df0c4f70b4a5d23525e932’. UDFMd5
string sha1(string/binary) sha(string/binary) Calculates the SHA-1 digest for string or binary and returns the value as a hex string. Example: sha1(‘ABC’) = ‘3c01bdbb26f358bab27f267924aa2c9a03fcfdb8’. UDFSha1
bigint crc32(string/binary) Computes a cyclic redundancy check value for string or binary argument and returns bigint value. Example: crc32(‘ABC’) = 2743272264. UDFCrc32
string sha2(string/binary,int) Calculates the SHA-2 family of hash functions (SHA-224, SHA-256, SHA-384, and SHA-512). The first argument is the string or binary to be hashed. The second argument indicates the desired bit length of the result, which must have a value of 224, 256, 384, 512, or 0 (which is equivalent to 256). SHA-224 is supported starting from Java 8. If either argument is NULL or the hash length is not one of the permitted values, the return value is NULL. Example: sha2(‘ABC’, 256) = ‘b5d4045c3f466fa91fe2cc6abe79232a1a57cdf104f7a26e716e0a1e2789df78’. GenericUDFSha2
binary aes\_encrypt(inputstring/binary, keystring/binary) Encrypt input using AES. Key lengths of 128, 192 or 256 bits can be used. 192 and 256 bits keys can be used if Java Cryptography Extension (JCE) Unlimited Strength Jurisdiction Policy Files are installed. If either argument is NULL or the key length is not one of the permitted values, the return value is NULL. Example: base64(aes_encrypt(‘ABC’, ‘1234567890123456’)) = ‘y6Ss+zCYObpCbgfWfyNWTw==’. GenericUDFAesEncrypt
binary aes\_decrypt(input binary, keystring/binary) Decrypt input using AES. Key lengths of 128, 192 or 256 bits can be used. 192 and 256 bits keys can be used if Java Cryptography Extension (JCE) Unlimited Strength Jurisdiction Policy Files are installed. If either argument is NULL or the key length is not one of the permitted values, the return value is NULL. Example: aes_decrypt(unbase64(‘y6Ss+zCYObpCbgfWfyNWTw=='), ‘1234567890123456’) = ‘ABC’. GenericUDFAesDecrypt
string version() Returns the Hive version. The string contains 2 fields, the first being a build number and the second being a build hash. Example: “select version();” might return “2.1.0.2.5.0.0-1245 r027527b9c5ce1a3d7d0b6d2e6de2378fb0c39232”. Actual results will depend on your build. UDFVersion
bigint surrogate\_key([write\_id\_bits, task\_id\_bits]) Automatically generate numerical Ids for rows as you enter data into a table. Can only be used as the default value for acid or insert-only tables. GenericUDFSurrogateKey
string typeof(x)  NEW Returns the type of the supplied argument GenericUDFTypeOf

Geospatial

NEW

Hive 4.0 provides ESRI-based standard geospatial UDFs.

The ESRI UDFs constitute an extensive list, and it’s important to note that the Hive documentation does not duplicate the entirety of the function documentation. Here, you can find ESRI UDFs documentation.

Blog about the Hive Geospatial support

Creating Custom UDF’s

Apache Hive offers a wide range of built-in User-Defined Functions (UDFs). However, for specific requirements not covered by the built-in functions, users can develop their own custom UDFs with just a basic understanding of Java.

Custom UDFs in Hive are categorized into three types based on the number of input and output rows. Each type of UDF corresponds to a different interface that needs to be implemented.

UDF UDAF UDTF
It is a function that receives only a single row as an input and returns a single row as an output.Like: length, or round functions org.apache.hadoop.hive.ql.exec.UDF; It is a function that receives multiple rows as input and returns a single row as output.Like: Count, Min, Max It is a function that receives a single row as input and returns multiple rows - result set or table - as output.Like: exploed, parse_url_tuple