| <!DOCTYPE html> |
| <!--[if IE 8]><html class="no-js lt-ie9" lang="en" > <![endif]--> |
| <!--[if gt IE 8]><!--> <html class="no-js" lang="en" > <!--<![endif]--> |
| <head> |
| <meta charset="utf-8"> |
| <meta http-equiv="X-UA-Compatible" content="IE=edge"> |
| <meta name="viewport" content="width=device-width, initial-scale=1.0"> |
| <meta name="description" content="None"> |
| |
| |
| <link rel="shortcut icon" href="img/favicon.ico"> |
| <title>Spark SQL, Built-in Functions</title> |
| <link rel="stylesheet" href="https://fonts.googleapis.com/css?family=Lato:400,700|Roboto+Slab:400,700|Inconsolata:400,700" /> |
| |
| <link rel="stylesheet" href="css/theme.css" /> |
| <link rel="stylesheet" href="css/theme_extra.css" /> |
| <link rel="stylesheet" href="https://cdnjs.cloudflare.com/ajax/libs/highlight.js/9.12.0/styles/github.min.css" /> |
| |
| <script> |
| // Current page data |
| var mkdocs_page_name = "Functions"; |
| var mkdocs_page_input_path = "index.md"; |
| var mkdocs_page_url = null; |
| </script> |
| |
| <script src="js/jquery-2.1.1.min.js" defer></script> |
| <script src="js/modernizr-2.8.3.min.js" defer></script> |
| <script src="https://cdnjs.cloudflare.com/ajax/libs/highlight.js/9.12.0/highlight.min.js"></script> |
| <script>hljs.initHighlightingOnLoad();</script> |
| |
| <!-- Matomo --> |
| <script type="text/javascript"> |
| var _paq = window._paq = window._paq || []; |
| /* tracker methods like "setCustomDimension" should be called before "trackPageView" */ |
| _paq.push(["disableCookies"]); |
| _paq.push(['trackPageView']); |
| _paq.push(['enableLinkTracking']); |
| (function() { |
| var u="https://analytics.apache.org/"; |
| _paq.push(['setTrackerUrl', u+'matomo.php']); |
| _paq.push(['setSiteId', '40']); |
| var d=document, g=d.createElement('script'), s=d.getElementsByTagName('script')[0]; |
| g.async=true; g.src=u+'matomo.js'; s.parentNode.insertBefore(g,s); |
| })(); |
| </script> |
| <!-- End Matomo Code --> |
| </head> |
| |
| <body class="wy-body-for-nav" role="document"> |
| |
| <div class="wy-grid-for-nav"> |
| |
| |
| <nav data-toggle="wy-nav-shift" class="wy-nav-side stickynav"> |
| <div class="wy-side-scroll"> |
| <div class="wy-side-nav-search"> |
| <a href="." class="icon icon-home"> Spark SQL, Built-in Functions</a> |
| <div role="search"> |
| <form id ="rtd-search-form" class="wy-form" action="./search.html" method="get"> |
| <input type="text" name="q" placeholder="Search docs" title="Type search term here" /> |
| </form> |
| </div> |
| </div> |
| |
| <div class="wy-menu wy-menu-vertical" data-spy="affix" role="navigation" aria-label="main navigation"> |
| <ul class="current"> |
| <li class="toctree-l1 current"><a class="reference internal current" href=".">Functions</a> |
| <ul class="current"> |
| <li class="toctree-l2"><a class="reference internal" href="#_1">!</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_2">%</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_3">&</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_4">*</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_5">+</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#-">-</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_6">/</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_7"><</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_8"><=</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_9"><=></a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_10">=</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_11">==</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_12">></a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_13">>=</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_14">^</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#abs">abs</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#acos">acos</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#acosh">acosh</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#add_months">add_months</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#aggregate">aggregate</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#and">and</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#any">any</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#approx_count_distinct">approx_count_distinct</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#approx_percentile">approx_percentile</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array">array</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_contains">array_contains</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_distinct">array_distinct</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_except">array_except</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_intersect">array_intersect</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_join">array_join</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_max">array_max</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_min">array_min</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_position">array_position</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_remove">array_remove</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_repeat">array_repeat</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_sort">array_sort</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#array_union">array_union</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#arrays_overlap">arrays_overlap</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#arrays_zip">arrays_zip</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#ascii">ascii</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#asin">asin</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#asinh">asinh</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#assert_true">assert_true</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#atan">atan</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#atan2">atan2</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#atanh">atanh</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#avg">avg</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#base64">base64</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bigint">bigint</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bin">bin</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#binary">binary</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bit_and">bit_and</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bit_count">bit_count</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bit_length">bit_length</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bit_or">bit_or</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bit_xor">bit_xor</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bool_and">bool_and</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bool_or">bool_or</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#boolean">boolean</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#bround">bround</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#cardinality">cardinality</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#cast">cast</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#cbrt">cbrt</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#ceil">ceil</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#ceiling">ceiling</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#char">char</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#char_length">char_length</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#character_length">character_length</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#chr">chr</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#coalesce">coalesce</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#collect_list">collect_list</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#collect_set">collect_set</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#concat">concat</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#concat_ws">concat_ws</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#conv">conv</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#corr">corr</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#cos">cos</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#cosh">cosh</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#cot">cot</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#count">count</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#count_if">count_if</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#count_min_sketch">count_min_sketch</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#covar_pop">covar_pop</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#covar_samp">covar_samp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#crc32">crc32</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#cube">cube</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#cume_dist">cume_dist</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#current_catalog">current_catalog</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#current_database">current_database</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#current_date">current_date</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#current_timestamp">current_timestamp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#current_timezone">current_timezone</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#date">date</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#date_add">date_add</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#date_format">date_format</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#date_from_unix_date">date_from_unix_date</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#date_part">date_part</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#date_sub">date_sub</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#date_trunc">date_trunc</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#datediff">datediff</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#day">day</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#dayofmonth">dayofmonth</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#dayofweek">dayofweek</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#dayofyear">dayofyear</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#decimal">decimal</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#decode">decode</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#degrees">degrees</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#dense_rank">dense_rank</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#div">div</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#double">double</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#e">e</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#element_at">element_at</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#elt">elt</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#encode">encode</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#every">every</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#exists">exists</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#exp">exp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#explode">explode</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#explode_outer">explode_outer</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#expm1">expm1</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#extract">extract</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#factorial">factorial</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#filter">filter</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#find_in_set">find_in_set</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#first">first</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#first_value">first_value</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#flatten">flatten</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#float">float</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#floor">floor</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#forall">forall</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#format_number">format_number</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#format_string">format_string</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#from_csv">from_csv</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#from_json">from_json</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#from_unixtime">from_unixtime</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#from_utc_timestamp">from_utc_timestamp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#get_json_object">get_json_object</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#greatest">greatest</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#grouping">grouping</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#grouping_id">grouping_id</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#hash">hash</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#hex">hex</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#hour">hour</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#hypot">hypot</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#if">if</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#ifnull">ifnull</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#in">in</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#initcap">initcap</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#inline">inline</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#inline_outer">inline_outer</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#input_file_block_length">input_file_block_length</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#input_file_block_start">input_file_block_start</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#input_file_name">input_file_name</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#instr">instr</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#int">int</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#isnan">isnan</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#isnotnull">isnotnull</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#isnull">isnull</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#java_method">java_method</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#json_array_length">json_array_length</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#json_object_keys">json_object_keys</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#json_tuple">json_tuple</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#kurtosis">kurtosis</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#lag">lag</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#last">last</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#last_day">last_day</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#last_value">last_value</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#lcase">lcase</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#lead">lead</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#least">least</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#left">left</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#length">length</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#levenshtein">levenshtein</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#like">like</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#ln">ln</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#locate">locate</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#log">log</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#log10">log10</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#log1p">log1p</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#log2">log2</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#lower">lower</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#lpad">lpad</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#ltrim">ltrim</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#make_date">make_date</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#make_interval">make_interval</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#make_timestamp">make_timestamp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map">map</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map_concat">map_concat</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map_entries">map_entries</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map_filter">map_filter</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map_from_arrays">map_from_arrays</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map_from_entries">map_from_entries</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map_keys">map_keys</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map_values">map_values</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#map_zip_with">map_zip_with</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#max">max</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#max_by">max_by</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#md5">md5</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#mean">mean</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#min">min</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#min_by">min_by</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#minute">minute</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#mod">mod</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#monotonically_increasing_id">monotonically_increasing_id</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#month">month</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#months_between">months_between</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#named_struct">named_struct</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#nanvl">nanvl</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#negative">negative</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#next_day">next_day</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#not">not</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#now">now</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#nth_value">nth_value</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#ntile">ntile</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#nullif">nullif</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#nvl">nvl</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#nvl2">nvl2</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#octet_length">octet_length</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#or">or</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#overlay">overlay</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#parse_url">parse_url</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#percent_rank">percent_rank</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#percentile">percentile</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#percentile_approx">percentile_approx</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#pi">pi</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#pmod">pmod</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#posexplode">posexplode</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#posexplode_outer">posexplode_outer</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#position">position</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#positive">positive</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#pow">pow</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#power">power</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#printf">printf</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#quarter">quarter</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#radians">radians</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#raise_error">raise_error</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#rand">rand</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#randn">randn</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#random">random</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#rank">rank</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#reflect">reflect</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#regexp_extract">regexp_extract</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#regexp_extract_all">regexp_extract_all</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#regexp_replace">regexp_replace</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#repeat">repeat</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#replace">replace</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#reverse">reverse</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#right">right</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#rint">rint</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#rlike">rlike</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#rollup">rollup</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#round">round</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#row_number">row_number</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#rpad">rpad</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#rtrim">rtrim</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#schema_of_csv">schema_of_csv</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#schema_of_json">schema_of_json</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#second">second</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sentences">sentences</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sequence">sequence</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sha">sha</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sha1">sha1</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sha2">sha2</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#shiftleft">shiftleft</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#shiftright">shiftright</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#shiftrightunsigned">shiftrightunsigned</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#shuffle">shuffle</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sign">sign</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#signum">signum</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sin">sin</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sinh">sinh</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#size">size</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#skewness">skewness</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#slice">slice</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#smallint">smallint</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#some">some</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sort_array">sort_array</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#soundex">soundex</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#space">space</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#spark_partition_id">spark_partition_id</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#split">split</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sqrt">sqrt</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#stack">stack</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#std">std</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#stddev">stddev</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#stddev_pop">stddev_pop</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#stddev_samp">stddev_samp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#str_to_map">str_to_map</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#string">string</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#struct">struct</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#substr">substr</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#substring">substring</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#substring_index">substring_index</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#sum">sum</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#tan">tan</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#tanh">tanh</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#timestamp">timestamp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#timestamp_micros">timestamp_micros</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#timestamp_millis">timestamp_millis</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#timestamp_seconds">timestamp_seconds</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#tinyint">tinyint</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#to_csv">to_csv</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#to_date">to_date</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#to_json">to_json</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#to_timestamp">to_timestamp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#to_unix_timestamp">to_unix_timestamp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#to_utc_timestamp">to_utc_timestamp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#transform">transform</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#transform_keys">transform_keys</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#transform_values">transform_values</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#translate">translate</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#trim">trim</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#trunc">trunc</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#typeof">typeof</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#ucase">ucase</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#unbase64">unbase64</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#unhex">unhex</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#unix_date">unix_date</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#unix_micros">unix_micros</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#unix_millis">unix_millis</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#unix_seconds">unix_seconds</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#unix_timestamp">unix_timestamp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#upper">upper</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#uuid">uuid</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#var_pop">var_pop</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#var_samp">var_samp</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#variance">variance</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#version">version</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#weekday">weekday</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#weekofyear">weekofyear</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#when">when</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#width_bucket">width_bucket</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#window">window</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath">xpath</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath_boolean">xpath_boolean</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath_double">xpath_double</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath_float">xpath_float</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath_int">xpath_int</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath_long">xpath_long</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath_number">xpath_number</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath_short">xpath_short</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xpath_string">xpath_string</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#xxhash64">xxhash64</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#year">year</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#zip_with">zip_with</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_15">|</a> |
| </li> |
| <li class="toctree-l2"><a class="reference internal" href="#_16">~</a> |
| </li> |
| </ul> |
| </li> |
| </ul> |
| </div> |
| </div> |
| </nav> |
| |
| <section data-toggle="wy-nav-shift" class="wy-nav-content-wrap"> |
| |
| |
| <nav class="wy-nav-top" role="navigation" aria-label="top navigation"> |
| <i data-toggle="wy-nav-top" class="fa fa-bars"></i> |
| <a href=".">Spark SQL, Built-in Functions</a> |
| </nav> |
| |
| |
| <div class="wy-nav-content"> |
| <div class="rst-content"> |
| <div role="navigation" aria-label="breadcrumbs navigation"> |
| <ul class="wy-breadcrumbs"> |
| <li><a href=".">Docs</a> »</li> |
| |
| |
| |
| <li>Functions</li> |
| <li class="wy-breadcrumbs-aside"> |
| |
| </li> |
| </ul> |
| |
| <hr/> |
| </div> |
| <div role="main"> |
| <div class="section"> |
| |
| <h1 id="built-in-functions"><a class="toclink" href="#built-in-functions">Built-in Functions</a></h1> |
| <h3 id="_1"><a class="toclink" href="#_1">!</a></h3> |
| <p>! expr - Logical not.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ! true; |
| false |
| > SELECT ! false; |
| true |
| > SELECT ! NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_2"><a class="toclink" href="#_2">%</a></h3> |
| <p>expr1 % expr2 - Returns the remainder after <code>expr1</code>/<code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 % 1.8; |
| 0.2 |
| > SELECT MOD(2, 1.8); |
| 0.2 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_3"><a class="toclink" href="#_3">&</a></h3> |
| <p>expr1 & expr2 - Returns the result of bitwise AND of <code>expr1</code> and <code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 3 & 5; |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="_4"><a class="toclink" href="#_4">*</a></h3> |
| <p>expr1 * expr2 - Returns <code>expr1</code>*<code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 * 3; |
| 6 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_5"><a class="toclink" href="#_5">+</a></h3> |
| <p>expr1 + expr2 - Returns <code>expr1</code>+<code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 1 + 2; |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="-"><a class="toclink" href="#-">-</a></h3> |
| <p>expr1 - expr2 - Returns <code>expr1</code>-<code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 - 1; |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_6"><a class="toclink" href="#_6">/</a></h3> |
| <p>expr1 / expr2 - Returns <code>expr1</code>/<code>expr2</code>. It always performs floating point division.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 3 / 2; |
| 1.5 |
| > SELECT 2L / 2L; |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_7"><a class="toclink" href="#_7"><</a></h3> |
| <p>expr1 < expr2 - Returns true if <code>expr1</code> is less than <code>expr2</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr2 - the two expressions must be same type or can be casted to a common type, |
| and must be a type that can be ordered. For example, map type is not orderable, so it |
| is not supported. For complex types such array/struct, the data types of fields must |
| be orderable.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 1 < 2; |
| true |
| > SELECT 1.1 < '1'; |
| false |
| > SELECT to_date('2009-07-30 04:17:52') < to_date('2009-07-30 04:17:52'); |
| false |
| > SELECT to_date('2009-07-30 04:17:52') < to_date('2009-08-01 04:17:52'); |
| true |
| > SELECT 1 < NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_8"><a class="toclink" href="#_8"><=</a></h3> |
| <p>expr1 <= expr2 - Returns true if <code>expr1</code> is less than or equal to <code>expr2</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr2 - the two expressions must be same type or can be casted to a common type, |
| and must be a type that can be ordered. For example, map type is not orderable, so it |
| is not supported. For complex types such array/struct, the data types of fields must |
| be orderable.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 <= 2; |
| true |
| > SELECT 1.0 <= '1'; |
| true |
| > SELECT to_date('2009-07-30 04:17:52') <= to_date('2009-07-30 04:17:52'); |
| true |
| > SELECT to_date('2009-07-30 04:17:52') <= to_date('2009-08-01 04:17:52'); |
| true |
| > SELECT 1 <= NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_9"><a class="toclink" href="#_9"><=></a></h3> |
| <p>expr1 <=> expr2 - Returns same result as the EQUAL(=) operator for non-null operands, |
| but returns true if both are null, false if one of the them is null.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr2 - the two expressions must be same type or can be casted to a common type, |
| and must be a type that can be used in equality comparison. Map type is not supported. |
| For complex types such array/struct, the data types of fields must be orderable.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 <=> 2; |
| true |
| > SELECT 1 <=> '1'; |
| true |
| > SELECT true <=> NULL; |
| false |
| > SELECT NULL <=> NULL; |
| true |
| </code></pre> |
| <p><strong>Since:</strong> 1.1.0</p> |
| <p><br/></p> |
| <h3 id="_10"><a class="toclink" href="#_10">=</a></h3> |
| <p>expr1 = expr2 - Returns true if <code>expr1</code> equals <code>expr2</code>, or false otherwise.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr2 - the two expressions must be same type or can be casted to a common type, |
| and must be a type that can be used in equality comparison. Map type is not supported. |
| For complex types such array/struct, the data types of fields must be orderable.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 = 2; |
| true |
| > SELECT 1 = '1'; |
| true |
| > SELECT true = NULL; |
| NULL |
| > SELECT NULL = NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_11"><a class="toclink" href="#_11">==</a></h3> |
| <p>expr1 == expr2 - Returns true if <code>expr1</code> equals <code>expr2</code>, or false otherwise.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr2 - the two expressions must be same type or can be casted to a common type, |
| and must be a type that can be used in equality comparison. Map type is not supported. |
| For complex types such array/struct, the data types of fields must be orderable.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 == 2; |
| true |
| > SELECT 1 == '1'; |
| true |
| > SELECT true == NULL; |
| NULL |
| > SELECT NULL == NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_12"><a class="toclink" href="#_12">></a></h3> |
| <p>expr1 > expr2 - Returns true if <code>expr1</code> is greater than <code>expr2</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr2 - the two expressions must be same type or can be casted to a common type, |
| and must be a type that can be ordered. For example, map type is not orderable, so it |
| is not supported. For complex types such array/struct, the data types of fields must |
| be orderable.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 > 1; |
| true |
| > SELECT 2 > '1.1'; |
| true |
| > SELECT to_date('2009-07-30 04:17:52') > to_date('2009-07-30 04:17:52'); |
| false |
| > SELECT to_date('2009-07-30 04:17:52') > to_date('2009-08-01 04:17:52'); |
| false |
| > SELECT 1 > NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_13"><a class="toclink" href="#_13">>=</a></h3> |
| <p>expr1 >= expr2 - Returns true if <code>expr1</code> is greater than or equal to <code>expr2</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr2 - the two expressions must be same type or can be casted to a common type, |
| and must be a type that can be ordered. For example, map type is not orderable, so it |
| is not supported. For complex types such array/struct, the data types of fields must |
| be orderable.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 >= 1; |
| true |
| > SELECT 2.0 >= '2.1'; |
| false |
| > SELECT to_date('2009-07-30 04:17:52') >= to_date('2009-07-30 04:17:52'); |
| true |
| > SELECT to_date('2009-07-30 04:17:52') >= to_date('2009-08-01 04:17:52'); |
| false |
| > SELECT 1 >= NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="_14"><a class="toclink" href="#_14">^</a></h3> |
| <p>expr1 ^ expr2 - Returns the result of bitwise exclusive OR of <code>expr1</code> and <code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 3 ^ 5; |
| 6 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="abs"><a class="toclink" href="#abs">abs</a></h3> |
| <p>abs(expr) - Returns the absolute value of the numeric value.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT abs(-1); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.2.0</p> |
| <p><br/></p> |
| <h3 id="acos"><a class="toclink" href="#acos">acos</a></h3> |
| <p>acos(expr) - Returns the inverse cosine (a.k.a. arc cosine) of <code>expr</code>, as if computed by |
| <code>java.lang.Math.acos</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT acos(1); |
| 0.0 |
| > SELECT acos(2); |
| NaN |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="acosh"><a class="toclink" href="#acosh">acosh</a></h3> |
| <p>acosh(expr) - Returns inverse hyperbolic cosine of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT acosh(1); |
| 0.0 |
| > SELECT acosh(0); |
| NaN |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="add_months"><a class="toclink" href="#add_months">add_months</a></h3> |
| <p>add_months(start_date, num_months) - Returns the date that is <code>num_months</code> after <code>start_date</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT add_months('2016-08-31', 1); |
| 2016-09-30 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="aggregate"><a class="toclink" href="#aggregate">aggregate</a></h3> |
| <p>aggregate(expr, start, merge, finish) - Applies a binary operator to an initial state and all |
| elements in the array, and reduces this to a single state. The final state is converted |
| into the final result by applying a finish function.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT aggregate(array(1, 2, 3), 0, (acc, x) -> acc + x); |
| 6 |
| > SELECT aggregate(array(1, 2, 3), 0, (acc, x) -> acc + x, acc -> acc * 10); |
| 60 |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="and"><a class="toclink" href="#and">and</a></h3> |
| <p>expr1 and expr2 - Logical AND.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT true and true; |
| true |
| > SELECT true and false; |
| false |
| > SELECT true and NULL; |
| NULL |
| > SELECT false and NULL; |
| false |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="any"><a class="toclink" href="#any">any</a></h3> |
| <p>any(expr) - Returns true if at least one value of <code>expr</code> is true.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT any(col) FROM VALUES (true), (false), (false) AS tab(col); |
| true |
| > SELECT any(col) FROM VALUES (NULL), (true), (false) AS tab(col); |
| true |
| > SELECT any(col) FROM VALUES (false), (false), (NULL) AS tab(col); |
| false |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="approx_count_distinct"><a class="toclink" href="#approx_count_distinct">approx_count_distinct</a></h3> |
| <p>approx_count_distinct(expr[, relativeSD]) - Returns the estimated cardinality by HyperLogLog++. |
| <code>relativeSD</code> defines the maximum relative standard deviation allowed.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT approx_count_distinct(col1) FROM VALUES (1), (1), (2), (2), (3) tab(col1); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="approx_percentile"><a class="toclink" href="#approx_percentile">approx_percentile</a></h3> |
| <p>approx_percentile(col, percentage [, accuracy]) - Returns the approximate <code>percentile</code> of the numeric |
| column <code>col</code> which is the smallest value in the ordered <code>col</code> values (sorted from least to |
| greatest) such that no more than <code>percentage</code> of <code>col</code> values is less than the value |
| or equal to that value. The value of percentage must be between 0.0 and 1.0. The <code>accuracy</code> |
| parameter (default: 10000) is a positive numeric literal which controls approximation accuracy |
| at the cost of memory. Higher value of <code>accuracy</code> yields better accuracy, <code>1.0/accuracy</code> is |
| the relative error of the approximation. |
| When <code>percentage</code> is an array, each value of the percentage array must be between 0.0 and 1.0. |
| In this case, returns the approximate percentile array of column <code>col</code> at the given |
| percentage array.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT approx_percentile(col, array(0.5, 0.4, 0.1), 100) FROM VALUES (0), (1), (2), (10) AS tab(col); |
| [1,1,0] |
| > SELECT approx_percentile(col, 0.5, 100) FROM VALUES (0), (6), (7), (9), (10) AS tab(col); |
| 7 |
| </code></pre> |
| <p><strong>Since:</strong> 2.1.0</p> |
| <p><br/></p> |
| <h3 id="array"><a class="toclink" href="#array">array</a></h3> |
| <p>array(expr, ...) - Returns an array with the given elements.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array(1, 2, 3); |
| [1,2,3] |
| </code></pre> |
| <p><strong>Since:</strong> 1.1.0</p> |
| <p><br/></p> |
| <h3 id="array_contains"><a class="toclink" href="#array_contains">array_contains</a></h3> |
| <p>array_contains(array, value) - Returns true if the array contains the value.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_contains(array(1, 2, 3), 2); |
| true |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="array_distinct"><a class="toclink" href="#array_distinct">array_distinct</a></h3> |
| <p>array_distinct(array) - Removes duplicate values from the array.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_distinct(array(1, 2, 3, null, 3)); |
| [1,2,3,null] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_except"><a class="toclink" href="#array_except">array_except</a></h3> |
| <p>array_except(array1, array2) - Returns an array of the elements in array1 but not in array2, |
| without duplicates.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_except(array(1, 2, 3), array(1, 3, 5)); |
| [2] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_intersect"><a class="toclink" href="#array_intersect">array_intersect</a></h3> |
| <p>array_intersect(array1, array2) - Returns an array of the elements in the intersection of array1 and |
| array2, without duplicates.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_intersect(array(1, 2, 3), array(1, 3, 5)); |
| [1,3] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_join"><a class="toclink" href="#array_join">array_join</a></h3> |
| <p>array_join(array, delimiter[, nullReplacement]) - Concatenates the elements of the given array |
| using the delimiter and an optional string to replace nulls. If no value is set for |
| nullReplacement, any null value is filtered.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_join(array('hello', 'world'), ' '); |
| hello world |
| > SELECT array_join(array('hello', null ,'world'), ' '); |
| hello world |
| > SELECT array_join(array('hello', null ,'world'), ' ', ','); |
| hello , world |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_max"><a class="toclink" href="#array_max">array_max</a></h3> |
| <p>array_max(array) - Returns the maximum value in the array. NULL elements are skipped.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_max(array(1, 20, null, 3)); |
| 20 |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_min"><a class="toclink" href="#array_min">array_min</a></h3> |
| <p>array_min(array) - Returns the minimum value in the array. NULL elements are skipped.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_min(array(1, 20, null, 3)); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_position"><a class="toclink" href="#array_position">array_position</a></h3> |
| <p>array_position(array, element) - Returns the (1-based) index of the first element of the array as long.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_position(array(3, 2, 1), 1); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_remove"><a class="toclink" href="#array_remove">array_remove</a></h3> |
| <p>array_remove(array, element) - Remove all elements that equal to element from array.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_remove(array(1, 2, 3, null, 3), 3); |
| [1,2,null] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_repeat"><a class="toclink" href="#array_repeat">array_repeat</a></h3> |
| <p>array_repeat(element, count) - Returns the array containing element count times.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_repeat('123', 2); |
| ["123","123"] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_sort"><a class="toclink" href="#array_sort">array_sort</a></h3> |
| <p>array_sort(expr, func) - Sorts the input array. If func is omitted, sort |
| in ascending order. The elements of the input array must be orderable. Null elements |
| will be placed at the end of the returned array. Since 3.0.0 this function also sorts |
| and returns the array based on the given comparator function. The comparator will |
| take two arguments representing two elements of the array. |
| It returns -1, 0, or 1 as the first element is less than, equal to, or greater |
| than the second element. If the comparator function returns other |
| values (including null), the function will fail and raise an error.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_sort(array(5, 6, 1), (left, right) -> case when left < right then -1 when left > right then 1 else 0 end); |
| [1,5,6] |
| > SELECT array_sort(array('bc', 'ab', 'dc'), (left, right) -> case when left is null and right is null then 0 when left is null then -1 when right is null then 1 when left < right then 1 when left > right then -1 else 0 end); |
| ["dc","bc","ab"] |
| > SELECT array_sort(array('b', 'd', null, 'c', 'a')); |
| ["a","b","c","d",null] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="array_union"><a class="toclink" href="#array_union">array_union</a></h3> |
| <p>array_union(array1, array2) - Returns an array of the elements in the union of array1 and array2, |
| without duplicates.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT array_union(array(1, 2, 3), array(1, 3, 5)); |
| [1,2,3,5] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="arrays_overlap"><a class="toclink" href="#arrays_overlap">arrays_overlap</a></h3> |
| <p>arrays_overlap(a1, a2) - Returns true if a1 contains at least a non-null element present also in a2. If the arrays have no common element and they are both non-empty and either of them contains a null element null is returned, false otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT arrays_overlap(array(1, 2, 3), array(3, 4, 5)); |
| true |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="arrays_zip"><a class="toclink" href="#arrays_zip">arrays_zip</a></h3> |
| <p>arrays_zip(a1, a2, ...) - Returns a merged array of structs in which the N-th struct contains all |
| N-th values of input arrays.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT arrays_zip(array(1, 2, 3), array(2, 3, 4)); |
| [{"0":1,"1":2},{"0":2,"1":3},{"0":3,"1":4}] |
| > SELECT arrays_zip(array(1, 2), array(2, 3), array(3, 4)); |
| [{"0":1,"1":2,"2":3},{"0":2,"1":3,"2":4}] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="ascii"><a class="toclink" href="#ascii">ascii</a></h3> |
| <p>ascii(str) - Returns the numeric value of the first character of <code>str</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ascii('222'); |
| 50 |
| > SELECT ascii(2); |
| 50 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="asin"><a class="toclink" href="#asin">asin</a></h3> |
| <p>asin(expr) - Returns the inverse sine (a.k.a. arc sine) the arc sin of <code>expr</code>, |
| as if computed by <code>java.lang.Math.asin</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT asin(0); |
| 0.0 |
| > SELECT asin(2); |
| NaN |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="asinh"><a class="toclink" href="#asinh">asinh</a></h3> |
| <p>asinh(expr) - Returns inverse hyperbolic sine of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT asinh(0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="assert_true"><a class="toclink" href="#assert_true">assert_true</a></h3> |
| <p>assert_true(expr) - Throws an exception if <code>expr</code> is not true.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT assert_true(0 < 1); |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="atan"><a class="toclink" href="#atan">atan</a></h3> |
| <p>atan(expr) - Returns the inverse tangent (a.k.a. arc tangent) of <code>expr</code>, as if computed by |
| <code>java.lang.Math.atan</code></p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT atan(0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="atan2"><a class="toclink" href="#atan2">atan2</a></h3> |
| <p>atan2(exprY, exprX) - Returns the angle in radians between the positive x-axis of a plane |
| and the point given by the coordinates (<code>exprX</code>, <code>exprY</code>), as if computed by |
| <code>java.lang.Math.atan2</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>exprY - coordinate on y-axis</li> |
| <li>exprX - coordinate on x-axis</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT atan2(0, 0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="atanh"><a class="toclink" href="#atanh">atanh</a></h3> |
| <p>atanh(expr) - Returns inverse hyperbolic tangent of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT atanh(0); |
| 0.0 |
| > SELECT atanh(2); |
| NaN |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="avg"><a class="toclink" href="#avg">avg</a></h3> |
| <p>avg(expr) - Returns the mean calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT avg(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 2.0 |
| > SELECT avg(col) FROM VALUES (1), (2), (NULL) AS tab(col); |
| 1.5 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="base64"><a class="toclink" href="#base64">base64</a></h3> |
| <p>base64(bin) - Converts the argument from a binary <code>bin</code> to a base 64 string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT base64('Spark SQL'); |
| U3BhcmsgU1FM |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="bigint"><a class="toclink" href="#bigint">bigint</a></h3> |
| <p>bigint(expr) - Casts the value <code>expr</code> to the target data type <code>bigint</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="bin"><a class="toclink" href="#bin">bin</a></h3> |
| <p>bin(expr) - Returns the string representation of the long value <code>expr</code> represented in binary.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bin(13); |
| 1101 |
| > SELECT bin(-13); |
| 1111111111111111111111111111111111111111111111111111111111110011 |
| > SELECT bin(13.3); |
| 1101 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="binary"><a class="toclink" href="#binary">binary</a></h3> |
| <p>binary(expr) - Casts the value <code>expr</code> to the target data type <code>binary</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="bit_and"><a class="toclink" href="#bit_and">bit_and</a></h3> |
| <p>bit_and(expr) - Returns the bitwise AND of all non-null input values, or null if none.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bit_and(col) FROM VALUES (3), (5) AS tab(col); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="bit_count"><a class="toclink" href="#bit_count">bit_count</a></h3> |
| <p>bit_count(expr) - Returns the number of bits that are set in the argument expr as an unsigned 64-bit integer, or NULL if the argument is NULL.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bit_count(0); |
| 0 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="bit_length"><a class="toclink" href="#bit_length">bit_length</a></h3> |
| <p>bit_length(expr) - Returns the bit length of string data or number of bits of binary data.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bit_length('Spark SQL'); |
| 72 |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="bit_or"><a class="toclink" href="#bit_or">bit_or</a></h3> |
| <p>bit_or(expr) - Returns the bitwise OR of all non-null input values, or null if none.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bit_or(col) FROM VALUES (3), (5) AS tab(col); |
| 7 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="bit_xor"><a class="toclink" href="#bit_xor">bit_xor</a></h3> |
| <p>bit_xor(expr) - Returns the bitwise XOR of all non-null input values, or null if none.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bit_xor(col) FROM VALUES (3), (5) AS tab(col); |
| 6 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="bool_and"><a class="toclink" href="#bool_and">bool_and</a></h3> |
| <p>bool_and(expr) - Returns true if all values of <code>expr</code> are true.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bool_and(col) FROM VALUES (true), (true), (true) AS tab(col); |
| true |
| > SELECT bool_and(col) FROM VALUES (NULL), (true), (true) AS tab(col); |
| true |
| > SELECT bool_and(col) FROM VALUES (true), (false), (true) AS tab(col); |
| false |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="bool_or"><a class="toclink" href="#bool_or">bool_or</a></h3> |
| <p>bool_or(expr) - Returns true if at least one value of <code>expr</code> is true.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bool_or(col) FROM VALUES (true), (false), (false) AS tab(col); |
| true |
| > SELECT bool_or(col) FROM VALUES (NULL), (true), (false) AS tab(col); |
| true |
| > SELECT bool_or(col) FROM VALUES (false), (false), (NULL) AS tab(col); |
| false |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="boolean"><a class="toclink" href="#boolean">boolean</a></h3> |
| <p>boolean(expr) - Casts the value <code>expr</code> to the target data type <code>boolean</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="bround"><a class="toclink" href="#bround">bround</a></h3> |
| <p>bround(expr, d) - Returns <code>expr</code> rounded to <code>d</code> decimal places using HALF_EVEN rounding mode.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT bround(2.5, 0); |
| 2 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="cardinality"><a class="toclink" href="#cardinality">cardinality</a></h3> |
| <p>cardinality(expr) - Returns the size of an array or a map. |
| The function returns null for null input if spark.sql.legacy.sizeOfNull is set to false or |
| spark.sql.ansi.enabled is set to true. Otherwise, the function returns -1 for null input. |
| With the default settings, the function returns -1 for null input.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT cardinality(array('b', 'd', 'c', 'a')); |
| 4 |
| > SELECT cardinality(map('a', 1, 'b', 2)); |
| 2 |
| > SELECT cardinality(NULL); |
| -1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="cast"><a class="toclink" href="#cast">cast</a></h3> |
| <p>cast(expr AS type) - Casts the value <code>expr</code> to the target data type <code>type</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT cast('10' as int); |
| 10 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="cbrt"><a class="toclink" href="#cbrt">cbrt</a></h3> |
| <p>cbrt(expr) - Returns the cube root of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT cbrt(27.0); |
| 3.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="ceil"><a class="toclink" href="#ceil">ceil</a></h3> |
| <p>ceil(expr) - Returns the smallest integer not smaller than <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ceil(-0.1); |
| 0 |
| > SELECT ceil(5); |
| 5 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="ceiling"><a class="toclink" href="#ceiling">ceiling</a></h3> |
| <p>ceiling(expr) - Returns the smallest integer not smaller than <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ceiling(-0.1); |
| 0 |
| > SELECT ceiling(5); |
| 5 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="char"><a class="toclink" href="#char">char</a></h3> |
| <p>char(expr) - Returns the ASCII character having the binary equivalent to <code>expr</code>. If n is larger than 256 the result is equivalent to chr(n % 256)</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT char(65); |
| A |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="char_length"><a class="toclink" href="#char_length">char_length</a></h3> |
| <p>char_length(expr) - Returns the character length of string data or number of bytes of binary data. The length of string data includes the trailing spaces. The length of binary data includes binary zeros.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT char_length('Spark SQL '); |
| 10 |
| > SELECT CHAR_LENGTH('Spark SQL '); |
| 10 |
| > SELECT CHARACTER_LENGTH('Spark SQL '); |
| 10 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="character_length"><a class="toclink" href="#character_length">character_length</a></h3> |
| <p>character_length(expr) - Returns the character length of string data or number of bytes of binary data. The length of string data includes the trailing spaces. The length of binary data includes binary zeros.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT character_length('Spark SQL '); |
| 10 |
| > SELECT CHAR_LENGTH('Spark SQL '); |
| 10 |
| > SELECT CHARACTER_LENGTH('Spark SQL '); |
| 10 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="chr"><a class="toclink" href="#chr">chr</a></h3> |
| <p>chr(expr) - Returns the ASCII character having the binary equivalent to <code>expr</code>. If n is larger than 256 the result is equivalent to chr(n % 256)</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT chr(65); |
| A |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="coalesce"><a class="toclink" href="#coalesce">coalesce</a></h3> |
| <p>coalesce(expr1, expr2, ...) - Returns the first non-null argument if exists. Otherwise, null.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT coalesce(NULL, 1, NULL); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="collect_list"><a class="toclink" href="#collect_list">collect_list</a></h3> |
| <p>collect_list(expr) - Collects and returns a list of non-unique elements.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT collect_list(col) FROM VALUES (1), (2), (1) AS tab(col); |
| [1,2,1] |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic because the order of collected results depends |
| on the order of the rows which may be non-deterministic after a shuffle.</p> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="collect_set"><a class="toclink" href="#collect_set">collect_set</a></h3> |
| <p>collect_set(expr) - Collects and returns a set of unique elements.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT collect_set(col) FROM VALUES (1), (2), (1) AS tab(col); |
| [1,2] |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic because the order of collected results depends |
| on the order of the rows which may be non-deterministic after a shuffle.</p> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="concat"><a class="toclink" href="#concat">concat</a></h3> |
| <p>concat(col1, col2, ..., colN) - Returns the concatenation of col1, col2, ..., colN.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT concat('Spark', 'SQL'); |
| SparkSQL |
| > SELECT concat(array(1, 2, 3), array(4, 5), array(6)); |
| [1,2,3,4,5,6] |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>Concat logic for arrays is available since 2.4.0.</p> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="concat_ws"><a class="toclink" href="#concat_ws">concat_ws</a></h3> |
| <p>concat_ws(sep[, str | array(str)]+) - Returns the concatenation of the strings separated by <code>sep</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT concat_ws(' ', 'Spark', 'SQL'); |
| Spark SQL |
| > SELECT concat_ws('s'); |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="conv"><a class="toclink" href="#conv">conv</a></h3> |
| <p>conv(num, from_base, to_base) - Convert <code>num</code> from <code>from_base</code> to <code>to_base</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT conv('100', 2, 10); |
| 4 |
| > SELECT conv(-10, 16, -10); |
| -16 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="corr"><a class="toclink" href="#corr">corr</a></h3> |
| <p>corr(expr1, expr2) - Returns Pearson coefficient of correlation between a set of number pairs.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT corr(c1, c2) FROM VALUES (3, 2), (3, 3), (6, 4) as tab(c1, c2); |
| 0.8660254037844387 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="cos"><a class="toclink" href="#cos">cos</a></h3> |
| <p>cos(expr) - Returns the cosine of <code>expr</code>, as if computed by |
| <code>java.lang.Math.cos</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - angle in radians</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT cos(0); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="cosh"><a class="toclink" href="#cosh">cosh</a></h3> |
| <p>cosh(expr) - Returns the hyperbolic cosine of <code>expr</code>, as if computed by |
| <code>java.lang.Math.cosh</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - hyperbolic angle</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT cosh(0); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="cot"><a class="toclink" href="#cot">cot</a></h3> |
| <p>cot(expr) - Returns the cotangent of <code>expr</code>, as if computed by <code>1/java.lang.Math.cot</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - angle in radians</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT cot(1); |
| 0.6420926159343306 |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="count"><a class="toclink" href="#count">count</a></h3> |
| <p>count(*) - Returns the total number of retrieved rows, including rows containing null.</p> |
| <p>count(expr[, expr...]) - Returns the number of rows for which the supplied expression(s) are all non-null.</p> |
| <p>count(DISTINCT expr[, expr...]) - Returns the number of rows for which the supplied expression(s) are unique and non-null.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT count(*) FROM VALUES (NULL), (5), (5), (20) AS tab(col); |
| 4 |
| > SELECT count(col) FROM VALUES (NULL), (5), (5), (20) AS tab(col); |
| 3 |
| > SELECT count(DISTINCT col) FROM VALUES (NULL), (5), (5), (10) AS tab(col); |
| 2 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="count_if"><a class="toclink" href="#count_if">count_if</a></h3> |
| <p>count_if(expr) - Returns the number of <code>TRUE</code> values for the expression.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT count_if(col % 2 = 0) FROM VALUES (NULL), (0), (1), (2), (3) AS tab(col); |
| 2 |
| > SELECT count_if(col IS NULL) FROM VALUES (NULL), (0), (1), (2), (3) AS tab(col); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="count_min_sketch"><a class="toclink" href="#count_min_sketch">count_min_sketch</a></h3> |
| <p>count_min_sketch(col, eps, confidence, seed) - Returns a count-min sketch of a column with the given esp, |
| confidence and seed. The result is an array of bytes, which can be deserialized to a |
| <code>CountMinSketch</code> before usage. Count-min sketch is a probabilistic data structure used for |
| cardinality estimation using sub-linear space.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT hex(count_min_sketch(col, 0.5d, 0.5d, 1)) FROM VALUES (1), (2), (1) AS tab(col); |
| 0000000100000000000000030000000100000004000000005D8D6AB90000000000000000000000000000000200000000000000010000000000000000 |
| </code></pre> |
| <p><strong>Since:</strong> 2.2.0</p> |
| <p><br/></p> |
| <h3 id="covar_pop"><a class="toclink" href="#covar_pop">covar_pop</a></h3> |
| <p>covar_pop(expr1, expr2) - Returns the population covariance of a set of number pairs.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT covar_pop(c1, c2) FROM VALUES (1,1), (2,2), (3,3) AS tab(c1, c2); |
| 0.6666666666666666 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="covar_samp"><a class="toclink" href="#covar_samp">covar_samp</a></h3> |
| <p>covar_samp(expr1, expr2) - Returns the sample covariance of a set of number pairs.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT covar_samp(c1, c2) FROM VALUES (1,1), (2,2), (3,3) AS tab(c1, c2); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="crc32"><a class="toclink" href="#crc32">crc32</a></h3> |
| <p>crc32(expr) - Returns a cyclic redundancy check value of the <code>expr</code> as a bigint.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT crc32('Spark'); |
| 1557323817 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="cube"><a class="toclink" href="#cube">cube</a></h3> |
| <p>cube([col1[, col2 ..]]) - create a multi-dimensional cube using the specified columns |
| so that we can run aggregation on them.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT name, age, count(*) FROM VALUES (2, 'Alice'), (5, 'Bob') people(age, name) GROUP BY cube(name, age); |
| Bob 5 1 |
| Alice 2 1 |
| Alice NULL 1 |
| NULL 2 1 |
| NULL NULL 2 |
| Bob NULL 1 |
| NULL 5 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="cume_dist"><a class="toclink" href="#cume_dist">cume_dist</a></h3> |
| <p>cume_dist() - Computes the position of a value relative to all values in the partition.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, cume_dist() OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 0.6666666666666666 |
| A1 1 0.6666666666666666 |
| A1 2 1.0 |
| A2 3 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="current_catalog"><a class="toclink" href="#current_catalog">current_catalog</a></h3> |
| <p>current_catalog() - Returns the current catalog.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT current_catalog(); |
| spark_catalog |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="current_database"><a class="toclink" href="#current_database">current_database</a></h3> |
| <p>current_database() - Returns the current database.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT current_database(); |
| default |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="current_date"><a class="toclink" href="#current_date">current_date</a></h3> |
| <p>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.</p> |
| <p>current_date - Returns the current date at the start of query evaluation.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT current_date(); |
| 2020-04-25 |
| > SELECT current_date; |
| 2020-04-25 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The syntax without braces has been supported since 2.0.1.</p> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="current_timestamp"><a class="toclink" href="#current_timestamp">current_timestamp</a></h3> |
| <p>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.</p> |
| <p>current_timestamp - Returns the current timestamp at the start of query evaluation.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT current_timestamp(); |
| 2020-04-25 15:49:11.914 |
| > SELECT current_timestamp; |
| 2020-04-25 15:49:11.914 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The syntax without braces has been supported since 2.0.1.</p> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="current_timezone"><a class="toclink" href="#current_timezone">current_timezone</a></h3> |
| <p>current_timezone() - Returns the current session local timezone.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT current_timezone(); |
| Asia/Shanghai |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="date"><a class="toclink" href="#date">date</a></h3> |
| <p>date(expr) - Casts the value <code>expr</code> to the target data type <code>date</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="date_add"><a class="toclink" href="#date_add">date_add</a></h3> |
| <p>date_add(start_date, num_days) - Returns the date that is <code>num_days</code> after <code>start_date</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT date_add('2016-07-30', 1); |
| 2016-07-31 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="date_format"><a class="toclink" href="#date_format">date_format</a></h3> |
| <p>date_format(timestamp, fmt) - Converts <code>timestamp</code> to a value of string in the format specified by the date format <code>fmt</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>timestamp - A date/timestamp or string to be converted to the given format.</li> |
| <li>fmt - Date/time format pattern to follow. See <a href="https://spark.apache.org/docs/latest/sql-ref-datetime-pattern.html">Datetime Patterns</a> for valid date |
| and time format patterns.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT date_format('2016-04-08', 'y'); |
| 2016 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="date_from_unix_date"><a class="toclink" href="#date_from_unix_date">date_from_unix_date</a></h3> |
| <p>date_from_unix_date(days) - Create date from the number of days since 1970-01-01.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT date_from_unix_date(1); |
| 1970-01-02 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="date_part"><a class="toclink" href="#date_part">date_part</a></h3> |
| <p>date_part(field, source) - Extracts a part of the date/timestamp or interval source.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>field - selects which part of the source should be extracted, and supported string values are as same as the fields of the equivalent function <code>EXTRACT</code>.</li> |
| <li>source - a date/timestamp or interval column from where <code>field</code> should be extracted</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT date_part('YEAR', TIMESTAMP '2019-08-12 01:00:00.123456'); |
| 2019 |
| > SELECT date_part('week', timestamp'2019-08-12 01:00:00.123456'); |
| 33 |
| > SELECT date_part('doy', DATE'2019-08-12'); |
| 224 |
| > SELECT date_part('SECONDS', timestamp'2019-10-01 00:00:01.000001'); |
| 1.000001 |
| > SELECT date_part('days', interval 1 year 10 months 5 days); |
| 5 |
| > SELECT date_part('seconds', interval 5 hours 30 seconds 1 milliseconds 1 microseconds); |
| 30.001001 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The date_part function is equivalent to the SQL-standard function <code>EXTRACT(field FROM source)</code></p> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="date_sub"><a class="toclink" href="#date_sub">date_sub</a></h3> |
| <p>date_sub(start_date, num_days) - Returns the date that is <code>num_days</code> before <code>start_date</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT date_sub('2016-07-30', 1); |
| 2016-07-29 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="date_trunc"><a class="toclink" href="#date_trunc">date_trunc</a></h3> |
| <p>date_trunc(fmt, ts) - Returns timestamp <code>ts</code> truncated to the unit specified by the format model <code>fmt</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>fmt - the format representing the unit to be truncated to<ul> |
| <li>"YEAR", "YYYY", "YY" - truncate to the first date of the year that the <code>ts</code> falls in, the time part will be zero out</li> |
| <li>"QUARTER" - truncate to the first date of the quarter that the <code>ts</code> falls in, the time part will be zero out</li> |
| <li>"MONTH", "MM", "MON" - truncate to the first date of the month that the <code>ts</code> falls in, the time part will be zero out</li> |
| <li>"WEEK" - truncate to the Monday of the week that the <code>ts</code> falls in, the time part will be zero out</li> |
| <li>"DAY", "DD" - zero out the time part</li> |
| <li>"HOUR" - zero out the minute and second with fraction part</li> |
| <li>"MINUTE"- zero out the second with fraction part</li> |
| <li>"SECOND" - zero out the second fraction part</li> |
| <li>"MILLISECOND" - zero out the microseconds</li> |
| <li>"MICROSECOND" - everything remains</li> |
| </ul> |
| </li> |
| <li>ts - datetime value or valid timestamp string</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT date_trunc('YEAR', '2015-03-05T09:32:05.359'); |
| 2015-01-01 00:00:00 |
| > SELECT date_trunc('MM', '2015-03-05T09:32:05.359'); |
| 2015-03-01 00:00:00 |
| > SELECT date_trunc('DD', '2015-03-05T09:32:05.359'); |
| 2015-03-05 00:00:00 |
| > SELECT date_trunc('HOUR', '2015-03-05T09:32:05.359'); |
| 2015-03-05 09:00:00 |
| > SELECT date_trunc('MILLISECOND', '2015-03-05T09:32:05.123456'); |
| 2015-03-05 09:32:05.123 |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="datediff"><a class="toclink" href="#datediff">datediff</a></h3> |
| <p>datediff(endDate, startDate) - Returns the number of days from <code>startDate</code> to <code>endDate</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT datediff('2009-07-31', '2009-07-30'); |
| 1 |
| |
| > SELECT datediff('2009-07-30', '2009-07-31'); |
| -1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="day"><a class="toclink" href="#day">day</a></h3> |
| <p>day(date) - Returns the day of month of the date/timestamp.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT day('2009-07-30'); |
| 30 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="dayofmonth"><a class="toclink" href="#dayofmonth">dayofmonth</a></h3> |
| <p>dayofmonth(date) - Returns the day of month of the date/timestamp.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT dayofmonth('2009-07-30'); |
| 30 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="dayofweek"><a class="toclink" href="#dayofweek">dayofweek</a></h3> |
| <p>dayofweek(date) - Returns the day of the week for date/timestamp (1 = Sunday, 2 = Monday, ..., 7 = Saturday).</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT dayofweek('2009-07-30'); |
| 5 |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="dayofyear"><a class="toclink" href="#dayofyear">dayofyear</a></h3> |
| <p>dayofyear(date) - Returns the day of year of the date/timestamp.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT dayofyear('2016-04-09'); |
| 100 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="decimal"><a class="toclink" href="#decimal">decimal</a></h3> |
| <p>decimal(expr) - Casts the value <code>expr</code> to the target data type <code>decimal</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="decode"><a class="toclink" href="#decode">decode</a></h3> |
| <p>decode(bin, charset) - Decodes the first argument using the second argument character set.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT decode(encode('abc', 'utf-8'), 'utf-8'); |
| abc |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="degrees"><a class="toclink" href="#degrees">degrees</a></h3> |
| <p>degrees(expr) - Converts radians to degrees.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - angle in radians</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT degrees(3.141592653589793); |
| 180.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="dense_rank"><a class="toclink" href="#dense_rank">dense_rank</a></h3> |
| <p>dense_rank() - Computes the rank of a value in a group of values. The result is one plus the |
| previously assigned rank value. Unlike the function rank, dense_rank will not produce gaps |
| in the ranking sequence.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>children - this is to base the rank on; a change in the value of one the children will |
| trigger a change in rank. This is an internal parameter and will be assigned by the |
| Analyser.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, dense_rank(b) OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 1 |
| A1 1 1 |
| A1 2 2 |
| A2 3 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="div"><a class="toclink" href="#div">div</a></h3> |
| <p>expr1 div expr2 - Divide <code>expr1</code> by <code>expr2</code>. It returns NULL if an operand is NULL or <code>expr2</code> is 0. The result is casted to long.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 3 div 2; |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="double"><a class="toclink" href="#double">double</a></h3> |
| <p>double(expr) - Casts the value <code>expr</code> to the target data type <code>double</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="e"><a class="toclink" href="#e">e</a></h3> |
| <p>e() - Returns Euler's number, e.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT e(); |
| 2.718281828459045 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="element_at"><a class="toclink" href="#element_at">element_at</a></h3> |
| <p>element_at(array, index) - Returns element of array at given (1-based) index. If index < 0, |
| accesses elements from the last to the first. The function returns NULL |
| if the index exceeds the length of the array and <code>spark.sql.ansi.enabled</code> is set to false. |
| If <code>spark.sql.ansi.enabled</code> is set to true, it throws ArrayIndexOutOfBoundsException |
| for invalid indices.</p> |
| <p>element_at(map, key) - Returns value for given key. The function returns NULL |
| if the key is not contained in the map and <code>spark.sql.ansi.enabled</code> is set to false. |
| If <code>spark.sql.ansi.enabled</code> is set to true, it throws NoSuchElementException instead.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT element_at(array(1, 2, 3), 2); |
| 2 |
| > SELECT element_at(map(1, 'a', 2, 'b'), 2); |
| b |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="elt"><a class="toclink" href="#elt">elt</a></h3> |
| <p>elt(n, input1, input2, ...) - Returns the <code>n</code>-th input, e.g., returns <code>input2</code> when <code>n</code> is 2. |
| The function returns NULL if the index exceeds the length of the array |
| and <code>spark.sql.ansi.enabled</code> is set to false. If <code>spark.sql.ansi.enabled</code> is set to true, |
| it throws ArrayIndexOutOfBoundsException for invalid indices.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT elt(1, 'scala', 'java'); |
| scala |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="encode"><a class="toclink" href="#encode">encode</a></h3> |
| <p>encode(str, charset) - Encodes the first argument using the second argument character set.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT encode('abc', 'utf-8'); |
| abc |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="every"><a class="toclink" href="#every">every</a></h3> |
| <p>every(expr) - Returns true if all values of <code>expr</code> are true.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT every(col) FROM VALUES (true), (true), (true) AS tab(col); |
| true |
| > SELECT every(col) FROM VALUES (NULL), (true), (true) AS tab(col); |
| true |
| > SELECT every(col) FROM VALUES (true), (false), (true) AS tab(col); |
| false |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="exists"><a class="toclink" href="#exists">exists</a></h3> |
| <p>exists(expr, pred) - Tests whether a predicate holds for one or more elements in the array.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT exists(array(1, 2, 3), x -> x % 2 == 0); |
| true |
| > SELECT exists(array(1, 2, 3), x -> x % 2 == 10); |
| false |
| > SELECT exists(array(1, null, 3), x -> x % 2 == 0); |
| NULL |
| > SELECT exists(array(0, null, 2, 3, null), x -> x IS NULL); |
| true |
| > SELECT exists(array(1, 2, 3), x -> x IS NULL); |
| false |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="exp"><a class="toclink" href="#exp">exp</a></h3> |
| <p>exp(expr) - Returns e to the power of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT exp(0); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="explode"><a class="toclink" href="#explode">explode</a></h3> |
| <p>explode(expr) - Separates the elements of array <code>expr</code> into multiple rows, or the elements of map <code>expr</code> into multiple rows and columns. Unless specified otherwise, uses the default column name <code>col</code> for elements of the array or <code>key</code> and <code>value</code> for the elements of the map.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT explode(array(10, 20)); |
| 10 |
| 20 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="explode_outer"><a class="toclink" href="#explode_outer">explode_outer</a></h3> |
| <p>explode_outer(expr) - Separates the elements of array <code>expr</code> into multiple rows, or the elements of map <code>expr</code> into multiple rows and columns. Unless specified otherwise, uses the default column name <code>col</code> for elements of the array or <code>key</code> and <code>value</code> for the elements of the map.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT explode_outer(array(10, 20)); |
| 10 |
| 20 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="expm1"><a class="toclink" href="#expm1">expm1</a></h3> |
| <p>expm1(expr) - Returns exp(<code>expr</code>) - 1.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT expm1(0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="extract"><a class="toclink" href="#extract">extract</a></h3> |
| <p>extract(field FROM source) - Extracts a part of the date/timestamp or interval source.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>field - selects which part of the source should be extracted<ul> |
| <li>Supported string values of <code>field</code> for dates and timestamps are(case insensitive):<ul> |
| <li>"YEAR", ("Y", "YEARS", "YR", "YRS") - the year field</li> |
| <li>"YEAROFWEEK" - the ISO 8601 week-numbering year that the datetime falls in. For example, 2005-01-02 is part of the 53rd week of year 2004, so the result is 2004</li> |
| <li>"QUARTER", ("QTR") - the quarter (1 - 4) of the year that the datetime falls in</li> |
| <li>"MONTH", ("MON", "MONS", "MONTHS") - the month field (1 - 12)</li> |
| <li>"WEEK", ("W", "WEEKS") - the number of the ISO 8601 week-of-week-based-year. A week is considered to start on a Monday and week 1 is the first week with >3 days. In the ISO week-numbering system, it is possible for early-January dates to be part of the 52nd or 53rd week of the previous year, and for late-December dates to be part of the first week of the next year. For example, 2005-01-02 is part of the 53rd week of year 2004, while 2012-12-31 is part of the first week of 2013</li> |
| <li>"DAY", ("D", "DAYS") - the day of the month field (1 - 31)</li> |
| <li>"DAYOFWEEK",("DOW") - the day of the week for datetime as Sunday(1) to Saturday(7)</li> |
| <li>"DAYOFWEEK_ISO",("DOW_ISO") - ISO 8601 based day of the week for datetime as Monday(1) to Sunday(7)</li> |
| <li>"DOY" - the day of the year (1 - 365/366)</li> |
| <li>"HOUR", ("H", "HOURS", "HR", "HRS") - The hour field (0 - 23)</li> |
| <li>"MINUTE", ("M", "MIN", "MINS", "MINUTES") - the minutes field (0 - 59)</li> |
| <li>"SECOND", ("S", "SEC", "SECONDS", "SECS") - the seconds field, including fractional parts</li> |
| </ul> |
| </li> |
| <li>Supported string values of <code>field</code> for interval(which consists of <code>months</code>, <code>days</code>, <code>microseconds</code>) are(case insensitive):<ul> |
| <li>"YEAR", ("Y", "YEARS", "YR", "YRS") - the total <code>months</code> / 12</li> |
| <li>"MONTH", ("MON", "MONS", "MONTHS") - the total <code>months</code> % 12</li> |
| <li>"DAY", ("D", "DAYS") - the <code>days</code> part of interval</li> |
| <li>"HOUR", ("H", "HOURS", "HR", "HRS") - how many hours the <code>microseconds</code> contains</li> |
| <li>"MINUTE", ("M", "MIN", "MINS", "MINUTES") - how many minutes left after taking hours from <code>microseconds</code></li> |
| <li>"SECOND", ("S", "SEC", "SECONDS", "SECS") - how many second with fractions left after taking hours and minutes from <code>microseconds</code></li> |
| </ul> |
| </li> |
| </ul> |
| </li> |
| <li>source - a date/timestamp or interval column from where <code>field</code> should be extracted</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT extract(YEAR FROM TIMESTAMP '2019-08-12 01:00:00.123456'); |
| 2019 |
| > SELECT extract(week FROM timestamp'2019-08-12 01:00:00.123456'); |
| 33 |
| > SELECT extract(doy FROM DATE'2019-08-12'); |
| 224 |
| > SELECT extract(SECONDS FROM timestamp'2019-10-01 00:00:01.000001'); |
| 1.000001 |
| > SELECT extract(days FROM interval 1 year 10 months 5 days); |
| 5 |
| > SELECT extract(seconds FROM interval 5 hours 30 seconds 1 milliseconds 1 microseconds); |
| 30.001001 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The extract function is equivalent to <code>date_part(field, source)</code>.</p> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="factorial"><a class="toclink" href="#factorial">factorial</a></h3> |
| <p>factorial(expr) - Returns the factorial of <code>expr</code>. <code>expr</code> is [0..20]. Otherwise, null.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT factorial(5); |
| 120 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="filter"><a class="toclink" href="#filter">filter</a></h3> |
| <p>filter(expr, func) - Filters the input array using the given predicate.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT filter(array(1, 2, 3), x -> x % 2 == 1); |
| [1,3] |
| > SELECT filter(array(0, 2, 3), (x, i) -> x > i); |
| [2,3] |
| > SELECT filter(array(0, null, 2, 3, null), x -> x IS NOT NULL); |
| [0,2,3] |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The inner function may use the index argument since 3.0.0.</p> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="find_in_set"><a class="toclink" href="#find_in_set">find_in_set</a></h3> |
| <p>find_in_set(str, str_array) - Returns the index (1-based) of the given string (<code>str</code>) in the comma-delimited list (<code>str_array</code>). |
| Returns 0, if the string was not found or if the given string (<code>str</code>) contains a comma.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT find_in_set('ab','abc,b,ab,c,def'); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="first"><a class="toclink" href="#first">first</a></h3> |
| <p>first(expr[, isIgnoreNull]) - Returns the first value of <code>expr</code> for a group of rows. |
| If <code>isIgnoreNull</code> is true, returns only non-null values.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT first(col) FROM VALUES (10), (5), (20) AS tab(col); |
| 10 |
| > SELECT first(col) FROM VALUES (NULL), (5), (20) AS tab(col); |
| NULL |
| > SELECT first(col, true) FROM VALUES (NULL), (5), (20) AS tab(col); |
| 5 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic because its results depends on the order of the rows |
| which may be non-deterministic after a shuffle.</p> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="first_value"><a class="toclink" href="#first_value">first_value</a></h3> |
| <p>first_value(expr[, isIgnoreNull]) - Returns the first value of <code>expr</code> for a group of rows. |
| If <code>isIgnoreNull</code> is true, returns only non-null values.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT first_value(col) FROM VALUES (10), (5), (20) AS tab(col); |
| 10 |
| > SELECT first_value(col) FROM VALUES (NULL), (5), (20) AS tab(col); |
| NULL |
| > SELECT first_value(col, true) FROM VALUES (NULL), (5), (20) AS tab(col); |
| 5 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic because its results depends on the order of the rows |
| which may be non-deterministic after a shuffle.</p> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="flatten"><a class="toclink" href="#flatten">flatten</a></h3> |
| <p>flatten(arrayOfArrays) - Transforms an array of arrays into a single array.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT flatten(array(array(1, 2), array(3, 4))); |
| [1,2,3,4] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="float"><a class="toclink" href="#float">float</a></h3> |
| <p>float(expr) - Casts the value <code>expr</code> to the target data type <code>float</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="floor"><a class="toclink" href="#floor">floor</a></h3> |
| <p>floor(expr) - Returns the largest integer not greater than <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT floor(-0.1); |
| -1 |
| > SELECT floor(5); |
| 5 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="forall"><a class="toclink" href="#forall">forall</a></h3> |
| <p>forall(expr, pred) - Tests whether a predicate holds for all elements in the array.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT forall(array(1, 2, 3), x -> x % 2 == 0); |
| false |
| > SELECT forall(array(2, 4, 8), x -> x % 2 == 0); |
| true |
| > SELECT forall(array(1, null, 3), x -> x % 2 == 0); |
| false |
| > SELECT forall(array(2, null, 8), x -> x % 2 == 0); |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="format_number"><a class="toclink" href="#format_number">format_number</a></h3> |
| <p>format_number(expr1, expr2) - Formats the number <code>expr1</code> like '#,###,###.##', rounded to <code>expr2</code> |
| decimal places. If <code>expr2</code> is 0, the result has no decimal point or fractional part. |
| <code>expr2</code> also accept a user specified format. |
| This is supposed to function like MySQL's FORMAT.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT format_number(12332.123456, 4); |
| 12,332.1235 |
| > SELECT format_number(12332.123456, '##################.###'); |
| 12332.123 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="format_string"><a class="toclink" href="#format_string">format_string</a></h3> |
| <p>format_string(strfmt, obj, ...) - Returns a formatted string from printf-style format strings.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT format_string("Hello World %d %s", 100, "days"); |
| Hello World 100 days |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="from_csv"><a class="toclink" href="#from_csv">from_csv</a></h3> |
| <p>from_csv(csvStr, schema[, options]) - Returns a struct value with the given <code>csvStr</code> and <code>schema</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT from_csv('1, 0.8', 'a INT, b DOUBLE'); |
| {"a":1,"b":0.8} |
| > SELECT from_csv('26/08/2015', 'time Timestamp', map('timestampFormat', 'dd/MM/yyyy')); |
| {"time":2015-08-26 00:00:00} |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="from_json"><a class="toclink" href="#from_json">from_json</a></h3> |
| <p>from_json(jsonStr, schema[, options]) - Returns a struct value with the given <code>jsonStr</code> and <code>schema</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT from_json('{"a":1, "b":0.8}', 'a INT, b DOUBLE'); |
| {"a":1,"b":0.8} |
| > SELECT from_json('{"time":"26/08/2015"}', 'time Timestamp', map('timestampFormat', 'dd/MM/yyyy')); |
| {"time":2015-08-26 00:00:00} |
| </code></pre> |
| <p><strong>Since:</strong> 2.2.0</p> |
| <p><br/></p> |
| <h3 id="from_unixtime"><a class="toclink" href="#from_unixtime">from_unixtime</a></h3> |
| <p>from_unixtime(unix_time[, fmt]) - Returns <code>unix_time</code> in the specified <code>fmt</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>unix_time - UNIX Timestamp to be converted to the provided format.</li> |
| <li>fmt - Date/time format pattern to follow. See <a href="https://spark.apache.org/docs/latest/sql-ref-datetime-pattern.html">Datetime Patterns</a> |
| for valid date and time format patterns. The 'yyyy-MM-dd HH:mm:ss' pattern is used if omitted.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT from_unixtime(0, 'yyyy-MM-dd HH:mm:ss'); |
| 1969-12-31 16:00:00 |
| |
| > SELECT from_unixtime(0); |
| 1969-12-31 16:00:00 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="from_utc_timestamp"><a class="toclink" href="#from_utc_timestamp">from_utc_timestamp</a></h3> |
| <p>from_utc_timestamp(timestamp, timezone) - Given a timestamp like '2017-07-14 02:40:00.0', interprets it as a time in UTC, and renders that time as a timestamp in the given time zone. For example, 'GMT+1' would yield '2017-07-14 03:40:00.0'.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT from_utc_timestamp('2016-08-31', 'Asia/Seoul'); |
| 2016-08-31 09:00:00 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="get_json_object"><a class="toclink" href="#get_json_object">get_json_object</a></h3> |
| <p>get_json_object(json_txt, path) - Extracts a json object from <code>path</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT get_json_object('{"a":"b"}', '$.a'); |
| b |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="greatest"><a class="toclink" href="#greatest">greatest</a></h3> |
| <p>greatest(expr, ...) - Returns the greatest value of all parameters, skipping null values.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT greatest(10, 9, 2, 4, 3); |
| 10 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="grouping"><a class="toclink" href="#grouping">grouping</a></h3> |
| <p>grouping(col) - indicates whether a specified column in a GROUP BY is aggregated or |
| not, returns 1 for aggregated or 0 for not aggregated in the result set.",</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT name, grouping(name), sum(age) FROM VALUES (2, 'Alice'), (5, 'Bob') people(age, name) GROUP BY cube(name); |
| Alice 0 2 |
| Bob 0 5 |
| NULL 1 7 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="grouping_id"><a class="toclink" href="#grouping_id">grouping_id</a></h3> |
| <p>grouping_id([col1[, col2 ..]]) - returns the level of grouping, equals to |
| <code>(grouping(c1) << (n-1)) + (grouping(c2) << (n-2)) + ... + grouping(cn)</code></p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT name, grouping_id(), sum(age), avg(height) FROM VALUES (2, 'Alice', 165), (5, 'Bob', 180) people(age, name, height) GROUP BY cube(name, height); |
| Alice 0 2 165.0 |
| Alice 1 2 165.0 |
| NULL 3 7 172.5 |
| Bob 0 5 180.0 |
| Bob 1 5 180.0 |
| NULL 2 2 165.0 |
| NULL 2 5 180.0 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>Input columns should match with grouping columns exactly, or empty (means all the grouping |
| columns).</p> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="hash"><a class="toclink" href="#hash">hash</a></h3> |
| <p>hash(expr1, expr2, ...) - Returns a hash value of the arguments.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT hash('Spark', array(123), 2); |
| -1321691492 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="hex"><a class="toclink" href="#hex">hex</a></h3> |
| <p>hex(expr) - Converts <code>expr</code> to hexadecimal.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT hex(17); |
| 11 |
| > SELECT hex('Spark SQL'); |
| 537061726B2053514C |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="hour"><a class="toclink" href="#hour">hour</a></h3> |
| <p>hour(timestamp) - Returns the hour component of the string/timestamp.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT hour('2009-07-30 12:58:59'); |
| 12 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="hypot"><a class="toclink" href="#hypot">hypot</a></h3> |
| <p>hypot(expr1, expr2) - Returns sqrt(<code>expr1</code><strong>2 + <code>expr2</code></strong>2).</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT hypot(3, 4); |
| 5.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="if"><a class="toclink" href="#if">if</a></h3> |
| <p>if(expr1, expr2, expr3) - If <code>expr1</code> evaluates to true, then returns <code>expr2</code>; otherwise returns <code>expr3</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT if(1 < 2, 'a', 'b'); |
| a |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="ifnull"><a class="toclink" href="#ifnull">ifnull</a></h3> |
| <p>ifnull(expr1, expr2) - Returns <code>expr2</code> if <code>expr1</code> is null, or <code>expr1</code> otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ifnull(NULL, array('2')); |
| ["2"] |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="in"><a class="toclink" href="#in">in</a></h3> |
| <p>expr1 in(expr2, expr3, ...) - Returns true if <code>expr</code> equals to any valN.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr2, expr3, ... - the arguments must be same type.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 1 in(1, 2, 3); |
| true |
| > SELECT 1 in(2, 3, 4); |
| false |
| > SELECT named_struct('a', 1, 'b', 2) in(named_struct('a', 1, 'b', 1), named_struct('a', 1, 'b', 3)); |
| false |
| > SELECT named_struct('a', 1, 'b', 2) in(named_struct('a', 1, 'b', 2), named_struct('a', 1, 'b', 3)); |
| true |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="initcap"><a class="toclink" href="#initcap">initcap</a></h3> |
| <p>initcap(str) - Returns <code>str</code> with the first letter of each word in uppercase. |
| All other letters are in lowercase. Words are delimited by white space.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT initcap('sPark sql'); |
| Spark Sql |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="inline"><a class="toclink" href="#inline">inline</a></h3> |
| <p>inline(expr) - Explodes an array of structs into a table. Uses column names col1, col2, etc. by default unless specified otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT inline(array(struct(1, 'a'), struct(2, 'b'))); |
| 1 a |
| 2 b |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="inline_outer"><a class="toclink" href="#inline_outer">inline_outer</a></h3> |
| <p>inline_outer(expr) - Explodes an array of structs into a table. Uses column names col1, col2, etc. by default unless specified otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT inline_outer(array(struct(1, 'a'), struct(2, 'b'))); |
| 1 a |
| 2 b |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="input_file_block_length"><a class="toclink" href="#input_file_block_length">input_file_block_length</a></h3> |
| <p>input_file_block_length() - Returns the length of the block being read, or -1 if not available.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT input_file_block_length(); |
| -1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.2.0</p> |
| <p><br/></p> |
| <h3 id="input_file_block_start"><a class="toclink" href="#input_file_block_start">input_file_block_start</a></h3> |
| <p>input_file_block_start() - Returns the start offset of the block being read, or -1 if not available.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT input_file_block_start(); |
| -1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.2.0</p> |
| <p><br/></p> |
| <h3 id="input_file_name"><a class="toclink" href="#input_file_name">input_file_name</a></h3> |
| <p>input_file_name() - Returns the name of the file being read, or empty string if not available.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT input_file_name(); |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="instr"><a class="toclink" href="#instr">instr</a></h3> |
| <p>instr(str, substr) - Returns the (1-based) index of the first occurrence of <code>substr</code> in <code>str</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT instr('SparkSQL', 'SQL'); |
| 6 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="int"><a class="toclink" href="#int">int</a></h3> |
| <p>int(expr) - Casts the value <code>expr</code> to the target data type <code>int</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="isnan"><a class="toclink" href="#isnan">isnan</a></h3> |
| <p>isnan(expr) - Returns true if <code>expr</code> is NaN, or false otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT isnan(cast('NaN' as double)); |
| true |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="isnotnull"><a class="toclink" href="#isnotnull">isnotnull</a></h3> |
| <p>isnotnull(expr) - Returns true if <code>expr</code> is not null, or false otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT isnotnull(1); |
| true |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="isnull"><a class="toclink" href="#isnull">isnull</a></h3> |
| <p>isnull(expr) - Returns true if <code>expr</code> is null, or false otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT isnull(1); |
| false |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="java_method"><a class="toclink" href="#java_method">java_method</a></h3> |
| <p>java_method(class, method[, arg1[, arg2 ..]]) - Calls a method with reflection.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT java_method('java.util.UUID', 'randomUUID'); |
| c33fb387-8500-4bfa-81d2-6e0e3e930df2 |
| > SELECT java_method('java.util.UUID', 'fromString', 'a5cf6c42-0c85-418f-af6c-3e4e5b1328f2'); |
| a5cf6c42-0c85-418f-af6c-3e4e5b1328f2 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="json_array_length"><a class="toclink" href="#json_array_length">json_array_length</a></h3> |
| <p>json_array_length(jsonArray) - Returns the number of elements in the outmost JSON array.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>jsonArray - A JSON array. <code>NULL</code> is returned in case of any other valid JSON string, |
| <code>NULL</code> or an invalid JSON.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT json_array_length('[1,2,3,4]'); |
| 4 |
| > SELECT json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]'); |
| 5 |
| > SELECT json_array_length('[1,2'); |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="json_object_keys"><a class="toclink" href="#json_object_keys">json_object_keys</a></h3> |
| <p>json_object_keys(json_object) - Returns all the keys of the outmost JSON object as an array.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>json_object - A JSON object. If a valid JSON object is given, all the keys of the outmost |
| object will be returned as an array. If it is any other valid JSON string, an invalid JSON |
| string or an empty string, the function returns null.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT json_object_keys('{}'); |
| [] |
| > SELECT json_object_keys('{"key": "value"}'); |
| ["key"] |
| > SELECT json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}'); |
| ["f1","f2"] |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="json_tuple"><a class="toclink" href="#json_tuple">json_tuple</a></h3> |
| <p>json_tuple(jsonStr, p1, p2, ..., pn) - Returns a tuple like the function get_json_object, but it takes multiple names. All the input parameters and output column types are string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT json_tuple('{"a":1, "b":2}', 'a', 'b'); |
| 1 2 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="kurtosis"><a class="toclink" href="#kurtosis">kurtosis</a></h3> |
| <p>kurtosis(expr) - Returns the kurtosis value calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT kurtosis(col) FROM VALUES (-10), (-20), (100), (1000) AS tab(col); |
| -0.7014368047529627 |
| > SELECT kurtosis(col) FROM VALUES (1), (10), (100), (10), (1) as tab(col); |
| 0.19432323191699075 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="lag"><a class="toclink" href="#lag">lag</a></h3> |
| <p>lag(input[, offset[, default]]) - Returns the value of <code>input</code> at the <code>offset</code>th row |
| before the current row in the window. The default value of <code>offset</code> is 1 and the default |
| value of <code>default</code> is null. If the value of <code>input</code> at the <code>offset</code>th row is null, |
| null is returned. If there is no such offset row (e.g., when the offset is 1, the first |
| row of the window does not have any previous row), <code>default</code> is returned.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>input - a string expression to evaluate <code>offset</code> rows before the current row.</li> |
| <li>offset - an int expression which is rows to jump back in the partition.</li> |
| <li>default - a string expression which is to use when the offset row does not exist.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, lag(b) OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 NULL |
| A1 1 1 |
| A1 2 1 |
| A2 3 NULL |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="last"><a class="toclink" href="#last">last</a></h3> |
| <p>last(expr[, isIgnoreNull]) - Returns the last value of <code>expr</code> for a group of rows. |
| If <code>isIgnoreNull</code> is true, returns only non-null values</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT last(col) FROM VALUES (10), (5), (20) AS tab(col); |
| 20 |
| > SELECT last(col) FROM VALUES (10), (5), (NULL) AS tab(col); |
| NULL |
| > SELECT last(col, true) FROM VALUES (10), (5), (NULL) AS tab(col); |
| 5 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic because its results depends on the order of the rows |
| which may be non-deterministic after a shuffle.</p> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="last_day"><a class="toclink" href="#last_day">last_day</a></h3> |
| <p>last_day(date) - Returns the last day of the month which the date belongs to.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT last_day('2009-01-12'); |
| 2009-01-31 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="last_value"><a class="toclink" href="#last_value">last_value</a></h3> |
| <p>last_value(expr[, isIgnoreNull]) - Returns the last value of <code>expr</code> for a group of rows. |
| If <code>isIgnoreNull</code> is true, returns only non-null values</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT last_value(col) FROM VALUES (10), (5), (20) AS tab(col); |
| 20 |
| > SELECT last_value(col) FROM VALUES (10), (5), (NULL) AS tab(col); |
| NULL |
| > SELECT last_value(col, true) FROM VALUES (10), (5), (NULL) AS tab(col); |
| 5 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic because its results depends on the order of the rows |
| which may be non-deterministic after a shuffle.</p> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="lcase"><a class="toclink" href="#lcase">lcase</a></h3> |
| <p>lcase(str) - Returns <code>str</code> with all characters changed to lowercase.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT lcase('SparkSql'); |
| sparksql |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.1</p> |
| <p><br/></p> |
| <h3 id="lead"><a class="toclink" href="#lead">lead</a></h3> |
| <p>lead(input[, offset[, default]]) - Returns the value of <code>input</code> at the <code>offset</code>th row |
| after the current row in the window. The default value of <code>offset</code> is 1 and the default |
| value of <code>default</code> is null. If the value of <code>input</code> at the <code>offset</code>th row is null, |
| null is returned. If there is no such an offset row (e.g., when the offset is 1, the last |
| row of the window does not have any subsequent row), <code>default</code> is returned.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>input - a string expression to evaluate <code>offset</code> rows after the current row.</li> |
| <li>offset - an int expression which is rows to jump ahead in the partition.</li> |
| <li>default - a string expression which is to use when the offset is larger than the window. |
| The default value is null.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, lead(b) OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 1 |
| A1 1 2 |
| A1 2 NULL |
| A2 3 NULL |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="least"><a class="toclink" href="#least">least</a></h3> |
| <p>least(expr, ...) - Returns the least value of all parameters, skipping null values.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT least(10, 9, 2, 4, 3); |
| 2 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="left"><a class="toclink" href="#left">left</a></h3> |
| <p>left(str, len) - Returns the leftmost <code>len</code>(<code>len</code> can be string type) characters from the string <code>str</code>,if <code>len</code> is less or equal than 0 the result is an empty string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT left('Spark SQL', 3); |
| Spa |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="length"><a class="toclink" href="#length">length</a></h3> |
| <p>length(expr) - Returns the character length of string data or number of bytes of binary data. The length of string data includes the trailing spaces. The length of binary data includes binary zeros.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT length('Spark SQL '); |
| 10 |
| > SELECT CHAR_LENGTH('Spark SQL '); |
| 10 |
| > SELECT CHARACTER_LENGTH('Spark SQL '); |
| 10 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="levenshtein"><a class="toclink" href="#levenshtein">levenshtein</a></h3> |
| <p>levenshtein(str1, str2) - Returns the Levenshtein distance between the two given strings.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT levenshtein('kitten', 'sitting'); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="like"><a class="toclink" href="#like">like</a></h3> |
| <p>str like pattern[ ESCAPE escape] - Returns true if str matches <code>pattern</code> with <code>escape</code>, null if any arguments are null, false otherwise.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression</li> |
| <li> |
| <p>pattern - a string expression. The pattern is a string which is matched literally, with |
| exception to the following special symbols:</p> |
| <p>_ matches any one character in the input (similar to . in posix regular expressions)</p> |
| <p>% matches zero or more characters in the input (similar to .* in posix regular |
| expressions)</p> |
| <p>Since Spark 2.0, string literals are unescaped in our SQL parser. For example, in order |
| to match "\abc", the pattern should be "\abc".</p> |
| <p>When SQL config 'spark.sql.parser.escapedStringLiterals' is enabled, it fallbacks |
| to Spark 1.6 behavior regarding string literal parsing. For example, if the config is |
| enabled, the pattern to match "\abc" should be "\abc". |
| * escape - an character added since Spark 3.0. The default escape character is the '\'. |
| If an escape character precedes a special symbol or another escape character, the |
| following character is matched literally. It is invalid to escape any other character.</p> |
| </li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT like('Spark', '_park'); |
| true |
| > SET spark.sql.parser.escapedStringLiterals=true; |
| spark.sql.parser.escapedStringLiterals true |
| > SELECT '%SystemDrive%\Users\John' like '\%SystemDrive\%\\Users%'; |
| true |
| > SET spark.sql.parser.escapedStringLiterals=false; |
| spark.sql.parser.escapedStringLiterals false |
| > SELECT '%SystemDrive%\\Users\\John' like '\%SystemDrive\%\\\\Users%'; |
| true |
| > SELECT '%SystemDrive%/Users/John' like '/%SystemDrive/%//Users%' ESCAPE '/'; |
| true |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>Use RLIKE to match with standard regular expressions.</p> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="ln"><a class="toclink" href="#ln">ln</a></h3> |
| <p>ln(expr) - Returns the natural logarithm (base e) of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ln(1); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="locate"><a class="toclink" href="#locate">locate</a></h3> |
| <p>locate(substr, str[, pos]) - Returns the position of the first occurrence of <code>substr</code> in <code>str</code> after position <code>pos</code>. |
| The given <code>pos</code> and return value are 1-based.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT locate('bar', 'foobarbar'); |
| 4 |
| > SELECT locate('bar', 'foobarbar', 5); |
| 7 |
| > SELECT POSITION('bar' IN 'foobarbar'); |
| 4 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="log"><a class="toclink" href="#log">log</a></h3> |
| <p>log(base, expr) - Returns the logarithm of <code>expr</code> with <code>base</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT log(10, 100); |
| 2.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="log10"><a class="toclink" href="#log10">log10</a></h3> |
| <p>log10(expr) - Returns the logarithm of <code>expr</code> with base 10.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT log10(10); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="log1p"><a class="toclink" href="#log1p">log1p</a></h3> |
| <p>log1p(expr) - Returns log(1 + <code>expr</code>).</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT log1p(0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="log2"><a class="toclink" href="#log2">log2</a></h3> |
| <p>log2(expr) - Returns the logarithm of <code>expr</code> with base 2.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT log2(2); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="lower"><a class="toclink" href="#lower">lower</a></h3> |
| <p>lower(str) - Returns <code>str</code> with all characters changed to lowercase.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT lower('SparkSql'); |
| sparksql |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.1</p> |
| <p><br/></p> |
| <h3 id="lpad"><a class="toclink" href="#lpad">lpad</a></h3> |
| <p>lpad(str, len[, pad]) - Returns <code>str</code>, left-padded with <code>pad</code> to a length of <code>len</code>. |
| If <code>str</code> is longer than <code>len</code>, the return value is shortened to <code>len</code> characters. |
| If <code>pad</code> is not specified, <code>str</code> will be padded to the left with space characters.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT lpad('hi', 5, '??'); |
| ???hi |
| > SELECT lpad('hi', 1, '??'); |
| h |
| > SELECT lpad('hi', 5); |
| hi |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="ltrim"><a class="toclink" href="#ltrim">ltrim</a></h3> |
| <p>ltrim(str) - Removes the leading space characters from <code>str</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression</li> |
| <li>trimStr - the trim string characters to trim, the default value is a single space</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ltrim(' SparkSQL '); |
| SparkSQL |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="make_date"><a class="toclink" href="#make_date">make_date</a></h3> |
| <p>make_date(year, month, day) - Create date from year, month and day fields.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>year - the year to represent, from 1 to 9999</li> |
| <li>month - the month-of-year to represent, from 1 (January) to 12 (December)</li> |
| <li>day - the day-of-month to represent, from 1 to 31</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT make_date(2013, 7, 15); |
| 2013-07-15 |
| > SELECT make_date(2019, 13, 1); |
| NULL |
| > SELECT make_date(2019, 7, NULL); |
| NULL |
| > SELECT make_date(2019, 2, 30); |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="make_interval"><a class="toclink" href="#make_interval">make_interval</a></h3> |
| <p>make_interval(years, months, weeks, days, hours, mins, secs) - Make interval from years, months, weeks, days, hours, mins and secs.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>years - the number of years, positive or negative</li> |
| <li>months - the number of months, positive or negative</li> |
| <li>weeks - the number of weeks, positive or negative</li> |
| <li>days - the number of days, positive or negative</li> |
| <li>hours - the number of hours, positive or negative</li> |
| <li>mins - the number of minutes, positive or negative</li> |
| <li>secs - the number of seconds with the fractional part in microsecond precision.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT make_interval(100, 11, 1, 1, 12, 30, 01.001001); |
| 100 years 11 months 8 days 12 hours 30 minutes 1.001001 seconds |
| > SELECT make_interval(100, null, 3); |
| NULL |
| > SELECT make_interval(0, 1, 0, 1, 0, 0, 100.000001); |
| 1 months 1 days 1 minutes 40.000001 seconds |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="make_timestamp"><a class="toclink" href="#make_timestamp">make_timestamp</a></h3> |
| <p>make_timestamp(year, month, day, hour, min, sec[, timezone]) - Create timestamp from year, month, day, hour, min, sec and timezone fields.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>year - the year to represent, from 1 to 9999</li> |
| <li>month - the month-of-year to represent, from 1 (January) to 12 (December)</li> |
| <li>day - the day-of-month to represent, from 1 to 31</li> |
| <li>hour - the hour-of-day to represent, from 0 to 23</li> |
| <li>min - the minute-of-hour to represent, from 0 to 59</li> |
| <li>sec - the second-of-minute and its micro-fraction to represent, from |
| 0 to 60. If the sec argument equals to 60, the seconds field is set |
| to 0 and 1 minute is added to the final timestamp.</li> |
| <li>timezone - the time zone identifier. For example, CET, UTC and etc.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT make_timestamp(2014, 12, 28, 6, 30, 45.887); |
| 2014-12-28 06:30:45.887 |
| > SELECT make_timestamp(2014, 12, 28, 6, 30, 45.887, 'CET'); |
| 2014-12-27 21:30:45.887 |
| > SELECT make_timestamp(2019, 6, 30, 23, 59, 60); |
| 2019-07-01 00:00:00 |
| > SELECT make_timestamp(2019, 13, 1, 10, 11, 12, 'PST'); |
| NULL |
| > SELECT make_timestamp(null, 7, 22, 15, 30, 0); |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="map"><a class="toclink" href="#map">map</a></h3> |
| <p>map(key0, value0, key1, value1, ...) - Creates a map with the given key/value pairs.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map(1.0, '2', 3.0, '4'); |
| {1.0:"2",3.0:"4"} |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="map_concat"><a class="toclink" href="#map_concat">map_concat</a></h3> |
| <p>map_concat(map, ...) - Returns the union of all the given maps</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map_concat(map(1, 'a', 2, 'b'), map(3, 'c')); |
| {1:"a",2:"b",3:"c"} |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="map_entries"><a class="toclink" href="#map_entries">map_entries</a></h3> |
| <p>map_entries(map) - Returns an unordered array of all entries in the given map.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map_entries(map(1, 'a', 2, 'b')); |
| [{"key":1,"value":"a"},{"key":2,"value":"b"}] |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="map_filter"><a class="toclink" href="#map_filter">map_filter</a></h3> |
| <p>map_filter(expr, func) - Filters entries in a map using the function.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map_filter(map(1, 0, 2, 2, 3, -1), (k, v) -> k > v); |
| {1:0,3:-1} |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="map_from_arrays"><a class="toclink" href="#map_from_arrays">map_from_arrays</a></h3> |
| <p>map_from_arrays(keys, values) - Creates a map with a pair of the given key/value arrays. All elements |
| in keys should not be null</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map_from_arrays(array(1.0, 3.0), array('2', '4')); |
| {1.0:"2",3.0:"4"} |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="map_from_entries"><a class="toclink" href="#map_from_entries">map_from_entries</a></h3> |
| <p>map_from_entries(arrayOfEntries) - Returns a map created from the given array of entries.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map_from_entries(array(struct(1, 'a'), struct(2, 'b'))); |
| {1:"a",2:"b"} |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="map_keys"><a class="toclink" href="#map_keys">map_keys</a></h3> |
| <p>map_keys(map) - Returns an unordered array containing the keys of the map.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map_keys(map(1, 'a', 2, 'b')); |
| [1,2] |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="map_values"><a class="toclink" href="#map_values">map_values</a></h3> |
| <p>map_values(map) - Returns an unordered array containing the values of the map.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map_values(map(1, 'a', 2, 'b')); |
| ["a","b"] |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="map_zip_with"><a class="toclink" href="#map_zip_with">map_zip_with</a></h3> |
| <p>map_zip_with(map1, map2, function) - Merges two given maps into a single map by applying |
| function to the pair of values with the same key. For keys only presented in one map, |
| NULL will be passed as the value for the missing key. If an input map contains duplicated |
| keys, only the first entry of the duplicated key is passed into the lambda function.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT map_zip_with(map(1, 'a', 2, 'b'), map(1, 'x', 2, 'y'), (k, v1, v2) -> concat(v1, v2)); |
| {1:"ax",2:"by"} |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="max"><a class="toclink" href="#max">max</a></h3> |
| <p>max(expr) - Returns the maximum value of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT max(col) FROM VALUES (10), (50), (20) AS tab(col); |
| 50 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="max_by"><a class="toclink" href="#max_by">max_by</a></h3> |
| <p>max_by(x, y) - Returns the value of <code>x</code> associated with the maximum value of <code>y</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT max_by(x, y) FROM VALUES (('a', 10)), (('b', 50)), (('c', 20)) AS tab(x, y); |
| b |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="md5"><a class="toclink" href="#md5">md5</a></h3> |
| <p>md5(expr) - Returns an MD5 128-bit checksum as a hex string of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT md5('Spark'); |
| 8cde774d6f7333752ed72cacddb05126 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="mean"><a class="toclink" href="#mean">mean</a></h3> |
| <p>mean(expr) - Returns the mean calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT mean(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 2.0 |
| > SELECT mean(col) FROM VALUES (1), (2), (NULL) AS tab(col); |
| 1.5 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="min"><a class="toclink" href="#min">min</a></h3> |
| <p>min(expr) - Returns the minimum value of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT min(col) FROM VALUES (10), (-1), (20) AS tab(col); |
| -1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="min_by"><a class="toclink" href="#min_by">min_by</a></h3> |
| <p>min_by(x, y) - Returns the value of <code>x</code> associated with the minimum value of <code>y</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT min_by(x, y) FROM VALUES (('a', 10)), (('b', 50)), (('c', 20)) AS tab(x, y); |
| a |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="minute"><a class="toclink" href="#minute">minute</a></h3> |
| <p>minute(timestamp) - Returns the minute component of the string/timestamp.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT minute('2009-07-30 12:58:59'); |
| 58 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="mod"><a class="toclink" href="#mod">mod</a></h3> |
| <p>expr1 mod expr2 - Returns the remainder after <code>expr1</code>/<code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 2 % 1.8; |
| 0.2 |
| > SELECT MOD(2, 1.8); |
| 0.2 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="monotonically_increasing_id"><a class="toclink" href="#monotonically_increasing_id">monotonically_increasing_id</a></h3> |
| <p>monotonically_increasing_id() - Returns monotonically increasing 64-bit integers. The generated ID is guaranteed |
| to be monotonically increasing and unique, but not consecutive. The current implementation |
| puts the partition ID in the upper 31 bits, and the lower 33 bits represent the record number |
| within each partition. The assumption is that the data frame has less than 1 billion |
| partitions, and each partition has less than 8 billion records. |
| The function is non-deterministic because its result depends on partition IDs.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT monotonically_increasing_id(); |
| 0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="month"><a class="toclink" href="#month">month</a></h3> |
| <p>month(date) - Returns the month component of the date/timestamp.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT month('2016-07-30'); |
| 7 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="months_between"><a class="toclink" href="#months_between">months_between</a></h3> |
| <p>months_between(timestamp1, timestamp2[, roundOff]) - If <code>timestamp1</code> is later than <code>timestamp2</code>, then the result |
| is positive. If <code>timestamp1</code> and <code>timestamp2</code> are on the same day of month, or both |
| are the last day of month, time of day will be ignored. Otherwise, the difference is |
| calculated based on 31 days per month, and rounded to 8 digits unless roundOff=false.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT months_between('1997-02-28 10:30:00', '1996-10-30'); |
| 3.94959677 |
| > SELECT months_between('1997-02-28 10:30:00', '1996-10-30', false); |
| 3.9495967741935485 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="named_struct"><a class="toclink" href="#named_struct">named_struct</a></h3> |
| <p>named_struct(name1, val1, name2, val2, ...) - Creates a struct with the given field names and values.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT named_struct("a", 1, "b", 2, "c", 3); |
| {"a":1,"b":2,"c":3} |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="nanvl"><a class="toclink" href="#nanvl">nanvl</a></h3> |
| <p>nanvl(expr1, expr2) - Returns <code>expr1</code> if it's not NaN, or <code>expr2</code> otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT nanvl(cast('NaN' as double), 123); |
| 123.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="negative"><a class="toclink" href="#negative">negative</a></h3> |
| <p>negative(expr) - Returns the negated value of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT negative(1); |
| -1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="next_day"><a class="toclink" href="#next_day">next_day</a></h3> |
| <p>next_day(start_date, day_of_week) - Returns the first date which is later than <code>start_date</code> and named as indicated.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT next_day('2015-01-14', 'TU'); |
| 2015-01-20 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="not"><a class="toclink" href="#not">not</a></h3> |
| <p>not expr - Logical not.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT not true; |
| false |
| > SELECT not false; |
| true |
| > SELECT not NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="now"><a class="toclink" href="#now">now</a></h3> |
| <p>now() - Returns the current timestamp at the start of query evaluation.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT now(); |
| 2020-04-25 15:49:11.914 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="nth_value"><a class="toclink" href="#nth_value">nth_value</a></h3> |
| <p>nth_value(input[, offset]) - Returns the value of <code>input</code> at the row that is the <code>offset</code>th row |
| from beginning of the window frame. Offset starts at 1. If ignoreNulls=true, we will skip |
| nulls when finding the <code>offset</code>th row. Otherwise, every row counts for the <code>offset</code>. If |
| there is no such an <code>offset</code>th row (e.g., when the offset is 10, size of the window frame |
| is less than 10), null is returned.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>input - the target column or expression that the function operates on.</li> |
| <li>offset - a positive int literal to indicate the offset in the window frame. It starts |
| with 1.</li> |
| <li>ignoreNulls - an optional specification that indicates the NthValue should skip null |
| values in the determination of which row to use.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, nth_value(b, 2) OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 1 |
| A1 1 1 |
| A1 2 1 |
| A2 3 NULL |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="ntile"><a class="toclink" href="#ntile">ntile</a></h3> |
| <p>ntile(n) - Divides the rows for each window partition into <code>n</code> buckets ranging |
| from 1 to at most <code>n</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>buckets - an int expression which is number of buckets to divide the rows in. |
| Default value is 1.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, ntile(2) OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 1 |
| A1 1 1 |
| A1 2 2 |
| A2 3 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="nullif"><a class="toclink" href="#nullif">nullif</a></h3> |
| <p>nullif(expr1, expr2) - Returns null if <code>expr1</code> equals to <code>expr2</code>, or <code>expr1</code> otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT nullif(2, 2); |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="nvl"><a class="toclink" href="#nvl">nvl</a></h3> |
| <p>nvl(expr1, expr2) - Returns <code>expr2</code> if <code>expr1</code> is null, or <code>expr1</code> otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT nvl(NULL, array('2')); |
| ["2"] |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="nvl2"><a class="toclink" href="#nvl2">nvl2</a></h3> |
| <p>nvl2(expr1, expr2, expr3) - Returns <code>expr2</code> if <code>expr1</code> is not null, or <code>expr3</code> otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT nvl2(NULL, 2, 1); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="octet_length"><a class="toclink" href="#octet_length">octet_length</a></h3> |
| <p>octet_length(expr) - Returns the byte length of string data or number of bytes of binary data.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT octet_length('Spark SQL'); |
| 9 |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="or"><a class="toclink" href="#or">or</a></h3> |
| <p>expr1 or expr2 - Logical OR.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT true or false; |
| true |
| > SELECT false or false; |
| false |
| > SELECT true or NULL; |
| true |
| > SELECT false or NULL; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="overlay"><a class="toclink" href="#overlay">overlay</a></h3> |
| <p>overlay(input, replace, pos[, len]) - Replace <code>input</code> with <code>replace</code> that starts at <code>pos</code> and is of length <code>len</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT overlay('Spark SQL' PLACING '_' FROM 6); |
| Spark_SQL |
| > SELECT overlay('Spark SQL' PLACING 'CORE' FROM 7); |
| Spark CORE |
| > SELECT overlay('Spark SQL' PLACING 'ANSI ' FROM 7 FOR 0); |
| Spark ANSI SQL |
| > SELECT overlay('Spark SQL' PLACING 'tructured' FROM 2 FOR 4); |
| Structured SQL |
| > SELECT overlay(encode('Spark SQL', 'utf-8') PLACING encode('_', 'utf-8') FROM 6); |
| Spark_SQL |
| > SELECT overlay(encode('Spark SQL', 'utf-8') PLACING encode('CORE', 'utf-8') FROM 7); |
| Spark CORE |
| > SELECT overlay(encode('Spark SQL', 'utf-8') PLACING encode('ANSI ', 'utf-8') FROM 7 FOR 0); |
| Spark ANSI SQL |
| > SELECT overlay(encode('Spark SQL', 'utf-8') PLACING encode('tructured', 'utf-8') FROM 2 FOR 4); |
| Structured SQL |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="parse_url"><a class="toclink" href="#parse_url">parse_url</a></h3> |
| <p>parse_url(url, partToExtract[, key]) - Extracts a part from a URL.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT parse_url('http://spark.apache.org/path?query=1', 'HOST'); |
| spark.apache.org |
| > SELECT parse_url('http://spark.apache.org/path?query=1', 'QUERY'); |
| query=1 |
| > SELECT parse_url('http://spark.apache.org/path?query=1', 'QUERY', 'query'); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="percent_rank"><a class="toclink" href="#percent_rank">percent_rank</a></h3> |
| <p>percent_rank() - Computes the percentage ranking of a value in a group of values.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>children - this is to base the rank on; a change in the value of one the children will |
| trigger a change in rank. This is an internal parameter and will be assigned by the |
| Analyser.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, percent_rank(b) OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 0.0 |
| A1 1 0.0 |
| A1 2 1.0 |
| A2 3 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="percentile"><a class="toclink" href="#percentile">percentile</a></h3> |
| <p>percentile(col, percentage [, frequency]) - Returns the exact percentile value of numeric column |
| <code>col</code> at the given percentage. The value of percentage must be between 0.0 and 1.0. The |
| value of frequency should be positive integral</p> |
| <p>percentile(col, array(percentage1 [, percentage2]...) [, frequency]) - Returns the exact |
| percentile value array of numeric column <code>col</code> at the given percentage(s). Each value |
| of the percentage array must be between 0.0 and 1.0. The value of frequency should be |
| positive integral</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT percentile(col, 0.3) FROM VALUES (0), (10) AS tab(col); |
| 3.0 |
| > SELECT percentile(col, array(0.25, 0.75)) FROM VALUES (0), (10) AS tab(col); |
| [2.5,7.5] |
| </code></pre> |
| <p><strong>Since:</strong> 2.1.0</p> |
| <p><br/></p> |
| <h3 id="percentile_approx"><a class="toclink" href="#percentile_approx">percentile_approx</a></h3> |
| <p>percentile_approx(col, percentage [, accuracy]) - Returns the approximate <code>percentile</code> of the numeric |
| column <code>col</code> which is the smallest value in the ordered <code>col</code> values (sorted from least to |
| greatest) such that no more than <code>percentage</code> of <code>col</code> values is less than the value |
| or equal to that value. The value of percentage must be between 0.0 and 1.0. The <code>accuracy</code> |
| parameter (default: 10000) is a positive numeric literal which controls approximation accuracy |
| at the cost of memory. Higher value of <code>accuracy</code> yields better accuracy, <code>1.0/accuracy</code> is |
| the relative error of the approximation. |
| When <code>percentage</code> is an array, each value of the percentage array must be between 0.0 and 1.0. |
| In this case, returns the approximate percentile array of column <code>col</code> at the given |
| percentage array.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT percentile_approx(col, array(0.5, 0.4, 0.1), 100) FROM VALUES (0), (1), (2), (10) AS tab(col); |
| [1,1,0] |
| > SELECT percentile_approx(col, 0.5, 100) FROM VALUES (0), (6), (7), (9), (10) AS tab(col); |
| 7 |
| </code></pre> |
| <p><strong>Since:</strong> 2.1.0</p> |
| <p><br/></p> |
| <h3 id="pi"><a class="toclink" href="#pi">pi</a></h3> |
| <p>pi() - Returns pi.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT pi(); |
| 3.141592653589793 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="pmod"><a class="toclink" href="#pmod">pmod</a></h3> |
| <p>pmod(expr1, expr2) - Returns the positive value of <code>expr1</code> mod <code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT pmod(10, 3); |
| 1 |
| > SELECT pmod(-10, 3); |
| 2 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="posexplode"><a class="toclink" href="#posexplode">posexplode</a></h3> |
| <p>posexplode(expr) - Separates the elements of array <code>expr</code> into multiple rows with positions, or the elements of map <code>expr</code> into multiple rows and columns with positions. Unless specified otherwise, uses the column name <code>pos</code> for position, <code>col</code> for elements of the array or <code>key</code> and <code>value</code> for elements of the map.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT posexplode(array(10,20)); |
| 0 10 |
| 1 20 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="posexplode_outer"><a class="toclink" href="#posexplode_outer">posexplode_outer</a></h3> |
| <p>posexplode_outer(expr) - Separates the elements of array <code>expr</code> into multiple rows with positions, or the elements of map <code>expr</code> into multiple rows and columns with positions. Unless specified otherwise, uses the column name <code>pos</code> for position, <code>col</code> for elements of the array or <code>key</code> and <code>value</code> for elements of the map.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT posexplode_outer(array(10,20)); |
| 0 10 |
| 1 20 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="position"><a class="toclink" href="#position">position</a></h3> |
| <p>position(substr, str[, pos]) - Returns the position of the first occurrence of <code>substr</code> in <code>str</code> after position <code>pos</code>. |
| The given <code>pos</code> and return value are 1-based.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT position('bar', 'foobarbar'); |
| 4 |
| > SELECT position('bar', 'foobarbar', 5); |
| 7 |
| > SELECT POSITION('bar' IN 'foobarbar'); |
| 4 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="positive"><a class="toclink" href="#positive">positive</a></h3> |
| <p>positive(expr) - Returns the value of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT positive(1); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="pow"><a class="toclink" href="#pow">pow</a></h3> |
| <p>pow(expr1, expr2) - Raises <code>expr1</code> to the power of <code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT pow(2, 3); |
| 8.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="power"><a class="toclink" href="#power">power</a></h3> |
| <p>power(expr1, expr2) - Raises <code>expr1</code> to the power of <code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT power(2, 3); |
| 8.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="printf"><a class="toclink" href="#printf">printf</a></h3> |
| <p>printf(strfmt, obj, ...) - Returns a formatted string from printf-style format strings.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT printf("Hello World %d %s", 100, "days"); |
| Hello World 100 days |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="quarter"><a class="toclink" href="#quarter">quarter</a></h3> |
| <p>quarter(date) - Returns the quarter of the year for date, in the range 1 to 4.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT quarter('2016-08-31'); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="radians"><a class="toclink" href="#radians">radians</a></h3> |
| <p>radians(expr) - Converts degrees to radians.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - angle in degrees</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT radians(180); |
| 3.141592653589793 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="raise_error"><a class="toclink" href="#raise_error">raise_error</a></h3> |
| <p>raise_error(expr) - Throws an exception with <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT raise_error('custom error message'); |
| java.lang.RuntimeException |
| custom error message |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="rand"><a class="toclink" href="#rand">rand</a></h3> |
| <p>rand([seed]) - Returns a random value with independent and identically distributed (i.i.d.) uniformly distributed values in [0, 1).</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT rand(); |
| 0.9629742951434543 |
| > SELECT rand(0); |
| 0.8446490682263027 |
| > SELECT rand(null); |
| 0.8446490682263027 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic in general case.</p> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="randn"><a class="toclink" href="#randn">randn</a></h3> |
| <p>randn([seed]) - Returns a random value with independent and identically distributed (i.i.d.) values drawn from the standard normal distribution.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT randn(); |
| -0.3254147983080288 |
| > SELECT randn(0); |
| 1.1164209726833079 |
| > SELECT randn(null); |
| 1.1164209726833079 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic in general case.</p> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="random"><a class="toclink" href="#random">random</a></h3> |
| <p>random([seed]) - Returns a random value with independent and identically distributed (i.i.d.) uniformly distributed values in [0, 1).</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT random(); |
| 0.9629742951434543 |
| > SELECT random(0); |
| 0.8446490682263027 |
| > SELECT random(null); |
| 0.8446490682263027 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic in general case.</p> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="rank"><a class="toclink" href="#rank">rank</a></h3> |
| <p>rank() - Computes the rank of a value in a group of values. The result is one plus the number |
| of rows preceding or equal to the current row in the ordering of the partition. The values |
| will produce gaps in the sequence.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>children - this is to base the rank on; a change in the value of one the children will |
| trigger a change in rank. This is an internal parameter and will be assigned by the |
| Analyser.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, rank(b) OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 1 |
| A1 1 1 |
| A1 2 3 |
| A2 3 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="reflect"><a class="toclink" href="#reflect">reflect</a></h3> |
| <p>reflect(class, method[, arg1[, arg2 ..]]) - Calls a method with reflection.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT reflect('java.util.UUID', 'randomUUID'); |
| c33fb387-8500-4bfa-81d2-6e0e3e930df2 |
| > SELECT reflect('java.util.UUID', 'fromString', 'a5cf6c42-0c85-418f-af6c-3e4e5b1328f2'); |
| a5cf6c42-0c85-418f-af6c-3e4e5b1328f2 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="regexp_extract"><a class="toclink" href="#regexp_extract">regexp_extract</a></h3> |
| <p>regexp_extract(str, regexp[, idx]) - Extract the first string in the <code>str</code> that match the <code>regexp</code> |
| expression and corresponding to the regex group index.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression.</li> |
| <li> |
| <p>regexp - a string representing a regular expression. The regex string should be a |
| Java regular expression.</p> |
| <p>Since Spark 2.0, string literals (including regex patterns) are unescaped in our SQL |
| parser. For example, to match "\abc", a regular expression for <code>regexp</code> can be |
| "^\abc$".</p> |
| <p>There is a SQL config 'spark.sql.parser.escapedStringLiterals' that can be used to |
| fallback to the Spark 1.6 behavior regarding string literal parsing. For example, |
| if the config is enabled, the <code>regexp</code> that can match "\abc" is "^\abc$". |
| * idx - an integer expression that representing the group index. The regex maybe contains |
| multiple groups. <code>idx</code> indicates which regex group to extract. The group index should |
| be non-negative. The minimum value of <code>idx</code> is 0, which means matching the entire |
| regular expression. If <code>idx</code> is not specified, the default group index value is 1. The |
| <code>idx</code> parameter is the Java regex Matcher group() method index.</p> |
| </li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT regexp_extract('100-200', '(\\d+)-(\\d+)', 1); |
| 100 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="regexp_extract_all"><a class="toclink" href="#regexp_extract_all">regexp_extract_all</a></h3> |
| <p>regexp_extract_all(str, regexp[, idx]) - Extract all strings in the <code>str</code> that match the <code>regexp</code> |
| expression and corresponding to the regex group index.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression.</li> |
| <li> |
| <p>regexp - a string representing a regular expression. The regex string should be a |
| Java regular expression.</p> |
| <p>Since Spark 2.0, string literals (including regex patterns) are unescaped in our SQL |
| parser. For example, to match "\abc", a regular expression for <code>regexp</code> can be |
| "^\abc$".</p> |
| <p>There is a SQL config 'spark.sql.parser.escapedStringLiterals' that can be used to |
| fallback to the Spark 1.6 behavior regarding string literal parsing. For example, |
| if the config is enabled, the <code>regexp</code> that can match "\abc" is "^\abc$". |
| * idx - an integer expression that representing the group index. The regex may contains |
| multiple groups. <code>idx</code> indicates which regex group to extract. The group index should |
| be non-negative. The minimum value of <code>idx</code> is 0, which means matching the entire |
| regular expression. If <code>idx</code> is not specified, the default group index value is 1. The |
| <code>idx</code> parameter is the Java regex Matcher group() method index.</p> |
| </li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT regexp_extract_all('100-200, 300-400', '(\\d+)-(\\d+)', 1); |
| ["100","300"] |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="regexp_replace"><a class="toclink" href="#regexp_replace">regexp_replace</a></h3> |
| <p>regexp_replace(str, regexp, rep[, position]) - Replaces all substrings of <code>str</code> that match <code>regexp</code> with <code>rep</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression to search for a regular expression pattern match.</li> |
| <li> |
| <p>regexp - a string representing a regular expression. The regex string should be a |
| Java regular expression.</p> |
| <p>Since Spark 2.0, string literals (including regex patterns) are unescaped in our SQL |
| parser. For example, to match "\abc", a regular expression for <code>regexp</code> can be |
| "^\abc$".</p> |
| <p>There is a SQL config 'spark.sql.parser.escapedStringLiterals' that can be used to |
| fallback to the Spark 1.6 behavior regarding string literal parsing. For example, |
| if the config is enabled, the <code>regexp</code> that can match "\abc" is "^\abc$". |
| * rep - a string expression to replace matched substrings. |
| * position - a positive integer literal that indicates the position within <code>str</code> to begin searching. |
| The default is 1. If position is greater than the number of characters in <code>str</code>, the result is <code>str</code>.</p> |
| </li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT regexp_replace('100-200', '(\\d+)', 'num'); |
| num-num |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="repeat"><a class="toclink" href="#repeat">repeat</a></h3> |
| <p>repeat(str, n) - Returns the string which repeats the given string value n times.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT repeat('123', 2); |
| 123123 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="replace"><a class="toclink" href="#replace">replace</a></h3> |
| <p>replace(str, search[, replace]) - Replaces all occurrences of <code>search</code> with <code>replace</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression</li> |
| <li>search - a string expression. If <code>search</code> is not found in <code>str</code>, <code>str</code> is returned unchanged.</li> |
| <li>replace - a string expression. If <code>replace</code> is not specified or is an empty string, nothing replaces |
| the string that is removed from <code>str</code>.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT replace('ABCabc', 'abc', 'DEF'); |
| ABCDEF |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="reverse"><a class="toclink" href="#reverse">reverse</a></h3> |
| <p>reverse(array) - Returns a reversed string or an array with reverse order of elements.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT reverse('Spark SQL'); |
| LQS krapS |
| > SELECT reverse(array(2, 1, 4, 3)); |
| [3,4,1,2] |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>Reverse logic for arrays is available since 2.4.0.</p> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="right"><a class="toclink" href="#right">right</a></h3> |
| <p>right(str, len) - Returns the rightmost <code>len</code>(<code>len</code> can be string type) characters from the string <code>str</code>,if <code>len</code> is less or equal than 0 the result is an empty string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT right('Spark SQL', 3); |
| SQL |
| </code></pre> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="rint"><a class="toclink" href="#rint">rint</a></h3> |
| <p>rint(expr) - Returns the double value that is closest in value to the argument and is equal to a mathematical integer.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT rint(12.3456); |
| 12.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="rlike"><a class="toclink" href="#rlike">rlike</a></h3> |
| <p>str rlike regexp - Returns true if <code>str</code> matches <code>regexp</code>, or false otherwise.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression</li> |
| <li> |
| <p>regexp - a string expression. The regex string should be a Java regular expression.</p> |
| <p>Since Spark 2.0, string literals (including regex patterns) are unescaped in our SQL |
| parser. For example, to match "\abc", a regular expression for <code>regexp</code> can be |
| "^\abc$".</p> |
| <p>There is a SQL config 'spark.sql.parser.escapedStringLiterals' that can be used to |
| fallback to the Spark 1.6 behavior regarding string literal parsing. For example, |
| if the config is enabled, the <code>regexp</code> that can match "\abc" is "^\abc$".</p> |
| </li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SET spark.sql.parser.escapedStringLiterals=true; |
| spark.sql.parser.escapedStringLiterals true |
| > SELECT '%SystemDrive%\Users\John' rlike '%SystemDrive%\\Users.*'; |
| true |
| > SET spark.sql.parser.escapedStringLiterals=false; |
| spark.sql.parser.escapedStringLiterals false |
| > SELECT '%SystemDrive%\\Users\\John' rlike '%SystemDrive%\\\\Users.*'; |
| true |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>Use LIKE to match with simple string pattern.</p> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="rollup"><a class="toclink" href="#rollup">rollup</a></h3> |
| <p>rollup([col1[, col2 ..]]) - create a multi-dimensional rollup using the specified columns |
| so that we can run aggregation on them.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT name, age, count(*) FROM VALUES (2, 'Alice'), (5, 'Bob') people(age, name) GROUP BY rollup(name, age); |
| Bob 5 1 |
| Alice 2 1 |
| Alice NULL 1 |
| NULL NULL 2 |
| Bob NULL 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="round"><a class="toclink" href="#round">round</a></h3> |
| <p>round(expr, d) - Returns <code>expr</code> rounded to <code>d</code> decimal places using HALF_UP rounding mode.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT round(2.5, 0); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="row_number"><a class="toclink" href="#row_number">row_number</a></h3> |
| <p>row_number() - Assigns a unique, sequential number to each row, starting with one, |
| according to the ordering of rows within the window partition.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT a, b, row_number() OVER (PARTITION BY a ORDER BY b) FROM VALUES ('A1', 2), ('A1', 1), ('A2', 3), ('A1', 1) tab(a, b); |
| A1 1 1 |
| A1 1 2 |
| A1 2 3 |
| A2 3 1 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="rpad"><a class="toclink" href="#rpad">rpad</a></h3> |
| <p>rpad(str, len[, pad]) - Returns <code>str</code>, right-padded with <code>pad</code> to a length of <code>len</code>. |
| If <code>str</code> is longer than <code>len</code>, the return value is shortened to <code>len</code> characters. |
| If <code>pad</code> is not specified, <code>str</code> will be padded to the right with space characters.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT rpad('hi', 5, '??'); |
| hi??? |
| > SELECT rpad('hi', 1, '??'); |
| h |
| > SELECT rpad('hi', 5); |
| hi |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="rtrim"><a class="toclink" href="#rtrim">rtrim</a></h3> |
| <p>rtrim(str) - Removes the trailing space characters from <code>str</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression</li> |
| <li>trimStr - the trim string characters to trim, the default value is a single space</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT rtrim(' SparkSQL '); |
| SparkSQL |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="schema_of_csv"><a class="toclink" href="#schema_of_csv">schema_of_csv</a></h3> |
| <p>schema_of_csv(csv[, options]) - Returns schema in the DDL format of CSV string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT schema_of_csv('1,abc'); |
| STRUCT<`_c0`: INT, `_c1`: STRING> |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="schema_of_json"><a class="toclink" href="#schema_of_json">schema_of_json</a></h3> |
| <p>schema_of_json(json[, options]) - Returns schema in the DDL format of JSON string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT schema_of_json('[{"col":0}]'); |
| ARRAY<STRUCT<`col`: BIGINT>> |
| > SELECT schema_of_json('[{"col":01}]', map('allowNumericLeadingZeros', 'true')); |
| ARRAY<STRUCT<`col`: BIGINT>> |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="second"><a class="toclink" href="#second">second</a></h3> |
| <p>second(timestamp) - Returns the second component of the string/timestamp.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT second('2009-07-30 12:58:59'); |
| 59 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="sentences"><a class="toclink" href="#sentences">sentences</a></h3> |
| <p>sentences(str[, lang, country]) - Splits <code>str</code> into an array of array of words.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sentences('Hi there! Good morning.'); |
| [["Hi","there"],["Good","morning"]] |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="sequence"><a class="toclink" href="#sequence">sequence</a></h3> |
| <p>sequence(start, stop, step) - Generates an array of elements from start to stop (inclusive), |
| incrementing by step. The type of the returned elements is the same as the type of argument |
| expressions.</p> |
| <p>Supported types are: byte, short, integer, long, date, timestamp.</p> |
| <p>The start and stop expressions must resolve to the same type. |
| If start and stop expressions resolve to the 'date' or 'timestamp' type |
| then the step expression must resolve to the 'interval' type, otherwise to the same type |
| as the start and stop expressions.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>start - an expression. The start of the range.</li> |
| <li>stop - an expression. The end the range (inclusive).</li> |
| <li>step - an optional expression. The step of the range. |
| By default step is 1 if start is less than or equal to stop, otherwise -1. |
| For the temporal sequences it's 1 day and -1 day respectively. |
| If start is greater than stop then the step must be negative, and vice versa.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sequence(1, 5); |
| [1,2,3,4,5] |
| > SELECT sequence(5, 1); |
| [5,4,3,2,1] |
| > SELECT sequence(to_date('2018-01-01'), to_date('2018-03-01'), interval 1 month); |
| [2018-01-01,2018-02-01,2018-03-01] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="sha"><a class="toclink" href="#sha">sha</a></h3> |
| <p>sha(expr) - Returns a sha1 hash value as a hex string of the <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sha('Spark'); |
| 85f5955f4b27a9a4c2aab6ffe5d7189fc298b92c |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="sha1"><a class="toclink" href="#sha1">sha1</a></h3> |
| <p>sha1(expr) - Returns a sha1 hash value as a hex string of the <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sha1('Spark'); |
| 85f5955f4b27a9a4c2aab6ffe5d7189fc298b92c |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="sha2"><a class="toclink" href="#sha2">sha2</a></h3> |
| <p>sha2(expr, bitLength) - Returns a checksum of SHA-2 family as a hex string of <code>expr</code>. |
| SHA-224, SHA-256, SHA-384, and SHA-512 are supported. Bit length of 0 is equivalent to 256.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sha2('Spark', 256); |
| 529bc3b07127ecb7e53a4dcf1991d9152c24537d919178022b2c42657f79a26b |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="shiftleft"><a class="toclink" href="#shiftleft">shiftleft</a></h3> |
| <p>shiftleft(base, expr) - Bitwise left shift.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT shiftleft(2, 1); |
| 4 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="shiftright"><a class="toclink" href="#shiftright">shiftright</a></h3> |
| <p>shiftright(base, expr) - Bitwise (signed) right shift.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT shiftright(4, 1); |
| 2 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="shiftrightunsigned"><a class="toclink" href="#shiftrightunsigned">shiftrightunsigned</a></h3> |
| <p>shiftrightunsigned(base, expr) - Bitwise unsigned right shift.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT shiftrightunsigned(4, 1); |
| 2 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="shuffle"><a class="toclink" href="#shuffle">shuffle</a></h3> |
| <p>shuffle(array) - Returns a random permutation of the given array.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT shuffle(array(1, 20, 3, 5)); |
| [3,1,5,20] |
| > SELECT shuffle(array(1, 20, null, 3)); |
| [20,null,3,1] |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic.</p> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="sign"><a class="toclink" href="#sign">sign</a></h3> |
| <p>sign(expr) - Returns -1.0, 0.0 or 1.0 as <code>expr</code> is negative, 0 or positive.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sign(40); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="signum"><a class="toclink" href="#signum">signum</a></h3> |
| <p>signum(expr) - Returns -1.0, 0.0 or 1.0 as <code>expr</code> is negative, 0 or positive.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT signum(40); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="sin"><a class="toclink" href="#sin">sin</a></h3> |
| <p>sin(expr) - Returns the sine of <code>expr</code>, as if computed by <code>java.lang.Math.sin</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - angle in radians</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sin(0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="sinh"><a class="toclink" href="#sinh">sinh</a></h3> |
| <p>sinh(expr) - Returns hyperbolic sine of <code>expr</code>, as if computed by <code>java.lang.Math.sinh</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - hyperbolic angle</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sinh(0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="size"><a class="toclink" href="#size">size</a></h3> |
| <p>size(expr) - Returns the size of an array or a map. |
| The function returns null for null input if spark.sql.legacy.sizeOfNull is set to false or |
| spark.sql.ansi.enabled is set to true. Otherwise, the function returns -1 for null input. |
| With the default settings, the function returns -1 for null input.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT size(array('b', 'd', 'c', 'a')); |
| 4 |
| > SELECT size(map('a', 1, 'b', 2)); |
| 2 |
| > SELECT size(NULL); |
| -1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="skewness"><a class="toclink" href="#skewness">skewness</a></h3> |
| <p>skewness(expr) - Returns the skewness value calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT skewness(col) FROM VALUES (-10), (-20), (100), (1000) AS tab(col); |
| 1.1135657469022011 |
| > SELECT skewness(col) FROM VALUES (-1000), (-100), (10), (20) AS tab(col); |
| -1.1135657469022011 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="slice"><a class="toclink" href="#slice">slice</a></h3> |
| <p>slice(x, start, length) - Subsets array x starting from index start (array indices start at 1, or starting from the end if start is negative) with the specified length.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT slice(array(1, 2, 3, 4), 2, 2); |
| [2,3] |
| > SELECT slice(array(1, 2, 3, 4), -2, 2); |
| [3,4] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="smallint"><a class="toclink" href="#smallint">smallint</a></h3> |
| <p>smallint(expr) - Casts the value <code>expr</code> to the target data type <code>smallint</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="some"><a class="toclink" href="#some">some</a></h3> |
| <p>some(expr) - Returns true if at least one value of <code>expr</code> is true.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT some(col) FROM VALUES (true), (false), (false) AS tab(col); |
| true |
| > SELECT some(col) FROM VALUES (NULL), (true), (false) AS tab(col); |
| true |
| > SELECT some(col) FROM VALUES (false), (false), (NULL) AS tab(col); |
| false |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="sort_array"><a class="toclink" href="#sort_array">sort_array</a></h3> |
| <p>sort_array(array[, ascendingOrder]) - Sorts the input array in ascending or descending order |
| according to the natural ordering of the array elements. Null elements will be placed |
| at the beginning of the returned array in ascending order or at the end of the returned |
| array in descending order.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sort_array(array('b', 'd', null, 'c', 'a'), true); |
| [null,"a","b","c","d"] |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="soundex"><a class="toclink" href="#soundex">soundex</a></h3> |
| <p>soundex(str) - Returns Soundex code of the string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT soundex('Miller'); |
| M460 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="space"><a class="toclink" href="#space">space</a></h3> |
| <p>space(n) - Returns a string consisting of <code>n</code> spaces.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT concat(space(2), '1'); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="spark_partition_id"><a class="toclink" href="#spark_partition_id">spark_partition_id</a></h3> |
| <p>spark_partition_id() - Returns the current partition id.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT spark_partition_id(); |
| 0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="split"><a class="toclink" href="#split">split</a></h3> |
| <p>split(str, regex, limit) - Splits <code>str</code> around occurrences that match <code>regex</code> and returns an array with a length of at most <code>limit</code></p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression to split.</li> |
| <li>regex - a string representing a regular expression. The regex string should be a |
| Java regular expression.</li> |
| <li>limit - an integer expression which controls the number of times the regex is applied.<ul> |
| <li>limit > 0: The resulting array's length will not be more than <code>limit</code>, |
| and the resulting array's last entry will contain all input |
| beyond the last matched regex.</li> |
| <li>limit <= 0: <code>regex</code> will be applied as many times as possible, and |
| the resulting array can be of any size.</li> |
| </ul> |
| </li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT split('oneAtwoBthreeC', '[ABC]'); |
| ["one","two","three",""] |
| > SELECT split('oneAtwoBthreeC', '[ABC]', -1); |
| ["one","two","three",""] |
| > SELECT split('oneAtwoBthreeC', '[ABC]', 2); |
| ["one","twoBthreeC"] |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="sqrt"><a class="toclink" href="#sqrt">sqrt</a></h3> |
| <p>sqrt(expr) - Returns the square root of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sqrt(4); |
| 2.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.1.1</p> |
| <p><br/></p> |
| <h3 id="stack"><a class="toclink" href="#stack">stack</a></h3> |
| <p>stack(n, expr1, ..., exprk) - Separates <code>expr1</code>, ..., <code>exprk</code> into <code>n</code> rows. Uses column names col0, col1, etc. by default unless specified otherwise.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT stack(2, 1, 2, 3); |
| 1 2 |
| 3 NULL |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="std"><a class="toclink" href="#std">std</a></h3> |
| <p>std(expr) - Returns the sample standard deviation calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT std(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="stddev"><a class="toclink" href="#stddev">stddev</a></h3> |
| <p>stddev(expr) - Returns the sample standard deviation calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT stddev(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="stddev_pop"><a class="toclink" href="#stddev_pop">stddev_pop</a></h3> |
| <p>stddev_pop(expr) - Returns the population standard deviation calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT stddev_pop(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 0.816496580927726 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="stddev_samp"><a class="toclink" href="#stddev_samp">stddev_samp</a></h3> |
| <p>stddev_samp(expr) - Returns the sample standard deviation calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT stddev_samp(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="str_to_map"><a class="toclink" href="#str_to_map">str_to_map</a></h3> |
| <p>str_to_map(text[, pairDelim[, keyValueDelim]]) - Creates a map after splitting the text into key/value pairs using delimiters. Default delimiters are ',' for <code>pairDelim</code> and ':' for <code>keyValueDelim</code>. Both <code>pairDelim</code> and <code>keyValueDelim</code> are treated as regular expressions.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT str_to_map('a:1,b:2,c:3', ',', ':'); |
| {"a":"1","b":"2","c":"3"} |
| > SELECT str_to_map('a'); |
| {"a":null} |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="string"><a class="toclink" href="#string">string</a></h3> |
| <p>string(expr) - Casts the value <code>expr</code> to the target data type <code>string</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="struct"><a class="toclink" href="#struct">struct</a></h3> |
| <p>struct(col1, col2, col3, ...) - Creates a struct with the given field values.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT struct(1, 2, 3); |
| {"col1":1,"col2":2,"col3":3} |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="substr"><a class="toclink" href="#substr">substr</a></h3> |
| <p>substr(str, pos[, len]) - Returns the substring of <code>str</code> that starts at <code>pos</code> and is of length <code>len</code>, or the slice of byte array that starts at <code>pos</code> and is of length <code>len</code>.</p> |
| <p>substr(str FROM pos[ FOR len]]) - Returns the substring of <code>str</code> that starts at <code>pos</code> and is of length <code>len</code>, or the slice of byte array that starts at <code>pos</code> and is of length <code>len</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT substr('Spark SQL', 5); |
| k SQL |
| > SELECT substr('Spark SQL', -3); |
| SQL |
| > SELECT substr('Spark SQL', 5, 1); |
| k |
| > SELECT substr('Spark SQL' FROM 5); |
| k SQL |
| > SELECT substr('Spark SQL' FROM -3); |
| SQL |
| > SELECT substr('Spark SQL' FROM 5 FOR 1); |
| k |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="substring"><a class="toclink" href="#substring">substring</a></h3> |
| <p>substring(str, pos[, len]) - Returns the substring of <code>str</code> that starts at <code>pos</code> and is of length <code>len</code>, or the slice of byte array that starts at <code>pos</code> and is of length <code>len</code>.</p> |
| <p>substring(str FROM pos[ FOR len]]) - Returns the substring of <code>str</code> that starts at <code>pos</code> and is of length <code>len</code>, or the slice of byte array that starts at <code>pos</code> and is of length <code>len</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT substring('Spark SQL', 5); |
| k SQL |
| > SELECT substring('Spark SQL', -3); |
| SQL |
| > SELECT substring('Spark SQL', 5, 1); |
| k |
| > SELECT substring('Spark SQL' FROM 5); |
| k SQL |
| > SELECT substring('Spark SQL' FROM -3); |
| SQL |
| > SELECT substring('Spark SQL' FROM 5 FOR 1); |
| k |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="substring_index"><a class="toclink" href="#substring_index">substring_index</a></h3> |
| <p>substring_index(str, delim, count) - Returns the substring from <code>str</code> before <code>count</code> occurrences of the delimiter <code>delim</code>. |
| If <code>count</code> is positive, everything to the left of the final delimiter (counting from the |
| left) is returned. If <code>count</code> is negative, everything to the right of the final delimiter |
| (counting from the right) is returned. The function substring_index performs a case-sensitive match |
| when searching for <code>delim</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT substring_index('www.apache.org', '.', 2); |
| www.apache |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="sum"><a class="toclink" href="#sum">sum</a></h3> |
| <p>sum(expr) - Returns the sum calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT sum(col) FROM VALUES (5), (10), (15) AS tab(col); |
| 30 |
| > SELECT sum(col) FROM VALUES (NULL), (10), (15) AS tab(col); |
| 25 |
| > SELECT sum(col) FROM VALUES (NULL), (NULL) AS tab(col); |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.0</p> |
| <p><br/></p> |
| <h3 id="tan"><a class="toclink" href="#tan">tan</a></h3> |
| <p>tan(expr) - Returns the tangent of <code>expr</code>, as if computed by <code>java.lang.Math.tan</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - angle in radians</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT tan(0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="tanh"><a class="toclink" href="#tanh">tanh</a></h3> |
| <p>tanh(expr) - Returns the hyperbolic tangent of <code>expr</code>, as if computed by |
| <code>java.lang.Math.tanh</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr - hyperbolic angle</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT tanh(0); |
| 0.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="timestamp"><a class="toclink" href="#timestamp">timestamp</a></h3> |
| <p>timestamp(expr) - Casts the value <code>expr</code> to the target data type <code>timestamp</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="timestamp_micros"><a class="toclink" href="#timestamp_micros">timestamp_micros</a></h3> |
| <p>timestamp_micros(microseconds) - Creates timestamp from the number of microseconds since UTC epoch.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT timestamp_micros(1230219000123123); |
| 2008-12-25 07:30:00.123123 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="timestamp_millis"><a class="toclink" href="#timestamp_millis">timestamp_millis</a></h3> |
| <p>timestamp_millis(milliseconds) - Creates timestamp from the number of milliseconds since UTC epoch.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT timestamp_millis(1230219000123); |
| 2008-12-25 07:30:00.123 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="timestamp_seconds"><a class="toclink" href="#timestamp_seconds">timestamp_seconds</a></h3> |
| <p>timestamp_seconds(seconds) - Creates timestamp from the number of seconds (can be fractional) since UTC epoch.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT timestamp_seconds(1230219000); |
| 2008-12-25 07:30:00 |
| > SELECT timestamp_seconds(1230219000.123); |
| 2008-12-25 07:30:00.123 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="tinyint"><a class="toclink" href="#tinyint">tinyint</a></h3> |
| <p>tinyint(expr) - Casts the value <code>expr</code> to the target data type <code>tinyint</code>.</p> |
| <p><strong>Since:</strong> 2.0.1</p> |
| <p><br/></p> |
| <h3 id="to_csv"><a class="toclink" href="#to_csv">to_csv</a></h3> |
| <p>to_csv(expr[, options]) - Returns a CSV string with a given struct value</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT to_csv(named_struct('a', 1, 'b', 2)); |
| 1,2 |
| > SELECT to_csv(named_struct('time', to_timestamp('2015-08-26', 'yyyy-MM-dd')), map('timestampFormat', 'dd/MM/yyyy')); |
| 26/08/2015 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="to_date"><a class="toclink" href="#to_date">to_date</a></h3> |
| <p>to_date(date_str[, fmt]) - Parses the <code>date_str</code> expression with the <code>fmt</code> expression to |
| a date. Returns null with invalid input. By default, it follows casting rules to a date if |
| the <code>fmt</code> is omitted.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>date_str - A string to be parsed to date.</li> |
| <li>fmt - Date format pattern to follow. See <a href="https://spark.apache.org/docs/latest/sql-ref-datetime-pattern.html">Datetime Patterns</a> for valid |
| date and time format patterns.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT to_date('2009-07-30 04:17:52'); |
| 2009-07-30 |
| > SELECT to_date('2016-12-31', 'yyyy-MM-dd'); |
| 2016-12-31 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="to_json"><a class="toclink" href="#to_json">to_json</a></h3> |
| <p>to_json(expr[, options]) - Returns a JSON string with a given struct value</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT to_json(named_struct('a', 1, 'b', 2)); |
| {"a":1,"b":2} |
| > SELECT to_json(named_struct('time', to_timestamp('2015-08-26', 'yyyy-MM-dd')), map('timestampFormat', 'dd/MM/yyyy')); |
| {"time":"26/08/2015"} |
| > SELECT to_json(array(named_struct('a', 1, 'b', 2))); |
| [{"a":1,"b":2}] |
| > SELECT to_json(map('a', named_struct('b', 1))); |
| {"a":{"b":1}} |
| > SELECT to_json(map(named_struct('a', 1),named_struct('b', 2))); |
| {"[1]":{"b":2}} |
| > SELECT to_json(map('a', 1)); |
| {"a":1} |
| > SELECT to_json(array((map('a', 1)))); |
| [{"a":1}] |
| </code></pre> |
| <p><strong>Since:</strong> 2.2.0</p> |
| <p><br/></p> |
| <h3 id="to_timestamp"><a class="toclink" href="#to_timestamp">to_timestamp</a></h3> |
| <p>to_timestamp(timestamp_str[, fmt]) - Parses the <code>timestamp_str</code> expression with the <code>fmt</code> expression |
| to a timestamp. Returns null with invalid input. By default, it follows casting rules to |
| a timestamp if the <code>fmt</code> is omitted.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>timestamp_str - A string to be parsed to timestamp.</li> |
| <li>fmt - Timestamp format pattern to follow. See <a href="https://spark.apache.org/docs/latest/sql-ref-datetime-pattern.html">Datetime Patterns</a> for valid |
| date and time format patterns.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT to_timestamp('2016-12-31 00:12:00'); |
| 2016-12-31 00:12:00 |
| > SELECT to_timestamp('2016-12-31', 'yyyy-MM-dd'); |
| 2016-12-31 00:00:00 |
| </code></pre> |
| <p><strong>Since:</strong> 2.2.0</p> |
| <p><br/></p> |
| <h3 id="to_unix_timestamp"><a class="toclink" href="#to_unix_timestamp">to_unix_timestamp</a></h3> |
| <p>to_unix_timestamp(timeExp[, fmt]) - Returns the UNIX timestamp of the given time.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>timeExp - A date/timestamp or string which is returned as a UNIX timestamp.</li> |
| <li>fmt - Date/time format pattern to follow. Ignored if <code>timeExp</code> is not a string. |
| Default value is "yyyy-MM-dd HH:mm:ss". See <a href="https://spark.apache.org/docs/latest/sql-ref-datetime-pattern.html">Datetime Patterns</a> |
| for valid date and time format patterns.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT to_unix_timestamp('2016-04-08', 'yyyy-MM-dd'); |
| 1460098800 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="to_utc_timestamp"><a class="toclink" href="#to_utc_timestamp">to_utc_timestamp</a></h3> |
| <p>to_utc_timestamp(timestamp, timezone) - Given a timestamp like '2017-07-14 02:40:00.0', interprets it as a time in the given time zone, and renders that time as a timestamp in UTC. For example, 'GMT+1' would yield '2017-07-14 01:40:00.0'.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT to_utc_timestamp('2016-08-31', 'Asia/Seoul'); |
| 2016-08-30 15:00:00 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="transform"><a class="toclink" href="#transform">transform</a></h3> |
| <p>transform(expr, func) - Transforms elements in an array using the function.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT transform(array(1, 2, 3), x -> x + 1); |
| [2,3,4] |
| > SELECT transform(array(1, 2, 3), (x, i) -> x + i); |
| [1,3,5] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="transform_keys"><a class="toclink" href="#transform_keys">transform_keys</a></h3> |
| <p>transform_keys(expr, func) - Transforms elements in a map using the function.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT transform_keys(map_from_arrays(array(1, 2, 3), array(1, 2, 3)), (k, v) -> k + 1); |
| {2:1,3:2,4:3} |
| > SELECT transform_keys(map_from_arrays(array(1, 2, 3), array(1, 2, 3)), (k, v) -> k + v); |
| {2:1,4:2,6:3} |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="transform_values"><a class="toclink" href="#transform_values">transform_values</a></h3> |
| <p>transform_values(expr, func) - Transforms values in the map using the function.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT transform_values(map_from_arrays(array(1, 2, 3), array(1, 2, 3)), (k, v) -> v + 1); |
| {1:2,2:3,3:4} |
| > SELECT transform_values(map_from_arrays(array(1, 2, 3), array(1, 2, 3)), (k, v) -> k + v); |
| {1:2,2:4,3:6} |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="translate"><a class="toclink" href="#translate">translate</a></h3> |
| <p>translate(input, from, to) - Translates the <code>input</code> string by replacing the characters present in the <code>from</code> string with the corresponding characters in the <code>to</code> string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT translate('AaBbCc', 'abc', '123'); |
| A1B2C3 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="trim"><a class="toclink" href="#trim">trim</a></h3> |
| <p>trim(str) - Removes the leading and trailing space characters from <code>str</code>.</p> |
| <p>trim(BOTH FROM str) - Removes the leading and trailing space characters from <code>str</code>.</p> |
| <p>trim(LEADING FROM str) - Removes the leading space characters from <code>str</code>.</p> |
| <p>trim(TRAILING FROM str) - Removes the trailing space characters from <code>str</code>.</p> |
| <p>trim(trimStr FROM str) - Remove the leading and trailing <code>trimStr</code> characters from <code>str</code>.</p> |
| <p>trim(BOTH trimStr FROM str) - Remove the leading and trailing <code>trimStr</code> characters from <code>str</code>.</p> |
| <p>trim(LEADING trimStr FROM str) - Remove the leading <code>trimStr</code> characters from <code>str</code>.</p> |
| <p>trim(TRAILING trimStr FROM str) - Remove the trailing <code>trimStr</code> characters from <code>str</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>str - a string expression</li> |
| <li>trimStr - the trim string characters to trim, the default value is a single space</li> |
| <li>BOTH, FROM - these are keywords to specify trimming string characters from both ends of |
| the string</li> |
| <li>LEADING, FROM - these are keywords to specify trimming string characters from the left |
| end of the string</li> |
| <li>TRAILING, FROM - these are keywords to specify trimming string characters from the right |
| end of the string</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT trim(' SparkSQL '); |
| SparkSQL |
| > SELECT trim(BOTH FROM ' SparkSQL '); |
| SparkSQL |
| > SELECT trim(LEADING FROM ' SparkSQL '); |
| SparkSQL |
| > SELECT trim(TRAILING FROM ' SparkSQL '); |
| SparkSQL |
| > SELECT trim('SL' FROM 'SSparkSQLS'); |
| parkSQ |
| > SELECT trim(BOTH 'SL' FROM 'SSparkSQLS'); |
| parkSQ |
| > SELECT trim(LEADING 'SL' FROM 'SSparkSQLS'); |
| parkSQLS |
| > SELECT trim(TRAILING 'SL' FROM 'SSparkSQLS'); |
| SSparkSQ |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="trunc"><a class="toclink" href="#trunc">trunc</a></h3> |
| <p>trunc(date, fmt) - Returns <code>date</code> with the time portion of the day truncated to the unit specified by the format model <code>fmt</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>date - date value or valid date string</li> |
| <li>fmt - the format representing the unit to be truncated to<ul> |
| <li>"YEAR", "YYYY", "YY" - truncate to the first date of the year that the <code>date</code> falls in</li> |
| <li>"QUARTER" - truncate to the first date of the quarter that the <code>date</code> falls in</li> |
| <li>"MONTH", "MM", "MON" - truncate to the first date of the month that the <code>date</code> falls in</li> |
| <li>"WEEK" - truncate to the Monday of the week that the <code>date</code> falls in</li> |
| </ul> |
| </li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT trunc('2019-08-04', 'week'); |
| 2019-07-29 |
| > SELECT trunc('2019-08-04', 'quarter'); |
| 2019-07-01 |
| > SELECT trunc('2009-02-12', 'MM'); |
| 2009-02-01 |
| > SELECT trunc('2015-10-27', 'YEAR'); |
| 2015-01-01 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="typeof"><a class="toclink" href="#typeof">typeof</a></h3> |
| <p>typeof(expr) - Return DDL-formatted type string for the data type of the input.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT typeof(1); |
| int |
| > SELECT typeof(array(1)); |
| array<int> |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="ucase"><a class="toclink" href="#ucase">ucase</a></h3> |
| <p>ucase(str) - Returns <code>str</code> with all characters changed to uppercase.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ucase('SparkSql'); |
| SPARKSQL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.1</p> |
| <p><br/></p> |
| <h3 id="unbase64"><a class="toclink" href="#unbase64">unbase64</a></h3> |
| <p>unbase64(str) - Converts the argument from a base 64 string <code>str</code> to a binary.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT unbase64('U3BhcmsgU1FM'); |
| Spark SQL |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="unhex"><a class="toclink" href="#unhex">unhex</a></h3> |
| <p>unhex(expr) - Converts hexadecimal <code>expr</code> to binary.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT decode(unhex('537061726B2053514C'), 'UTF-8'); |
| Spark SQL |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="unix_date"><a class="toclink" href="#unix_date">unix_date</a></h3> |
| <p>unix_date(date) - Returns the number of days since 1970-01-01.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT unix_date(DATE("1970-01-02")); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="unix_micros"><a class="toclink" href="#unix_micros">unix_micros</a></h3> |
| <p>unix_micros(timestamp) - Returns the number of microseconds since 1970-01-01 00:00:00 UTC.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT unix_micros(TIMESTAMP('1970-01-01 00:00:01Z')); |
| 1000000 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="unix_millis"><a class="toclink" href="#unix_millis">unix_millis</a></h3> |
| <p>unix_millis(timestamp) - Returns the number of milliseconds since 1970-01-01 00:00:00 UTC. Truncates higher levels of precision.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT unix_millis(TIMESTAMP('1970-01-01 00:00:01Z')); |
| 1000 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="unix_seconds"><a class="toclink" href="#unix_seconds">unix_seconds</a></h3> |
| <p>unix_seconds(timestamp) - Returns the number of seconds since 1970-01-01 00:00:00 UTC. Truncates higher levels of precision.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT unix_seconds(TIMESTAMP('1970-01-01 00:00:01Z')); |
| 1 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="unix_timestamp"><a class="toclink" href="#unix_timestamp">unix_timestamp</a></h3> |
| <p>unix_timestamp([timeExp[, fmt]]) - Returns the UNIX timestamp of current or specified time.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>timeExp - A date/timestamp or string. If not provided, this defaults to current time.</li> |
| <li>fmt - Date/time format pattern to follow. Ignored if <code>timeExp</code> is not a string. |
| Default value is "yyyy-MM-dd HH:mm:ss". See <a href="https://spark.apache.org/docs/latest/sql-ref-datetime-pattern.html"> Datetime Patterns</a> |
| for valid date and time format patterns.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT unix_timestamp(); |
| 1476884637 |
| > SELECT unix_timestamp('2016-04-08', 'yyyy-MM-dd'); |
| 1460041200 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="upper"><a class="toclink" href="#upper">upper</a></h3> |
| <p>upper(str) - Returns <code>str</code> with all characters changed to uppercase.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT upper('SparkSql'); |
| SPARKSQL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.1</p> |
| <p><br/></p> |
| <h3 id="uuid"><a class="toclink" href="#uuid">uuid</a></h3> |
| <p>uuid() - Returns an universally unique identifier (UUID) string. The value is returned as a canonical UUID 36-character string.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT uuid(); |
| 46707d92-02f4-4817-8116-a4c3b23e6266 |
| </code></pre> |
| <p><strong>Note:</strong></p> |
| <p>The function is non-deterministic.</p> |
| <p><strong>Since:</strong> 2.3.0</p> |
| <p><br/></p> |
| <h3 id="var_pop"><a class="toclink" href="#var_pop">var_pop</a></h3> |
| <p>var_pop(expr) - Returns the population variance calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT var_pop(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 0.6666666666666666 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="var_samp"><a class="toclink" href="#var_samp">var_samp</a></h3> |
| <p>var_samp(expr) - Returns the sample variance calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT var_samp(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="variance"><a class="toclink" href="#variance">variance</a></h3> |
| <p>variance(expr) - Returns the sample variance calculated from values of a group.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT variance(col) FROM VALUES (1), (2), (3) AS tab(col); |
| 1.0 |
| </code></pre> |
| <p><strong>Since:</strong> 1.6.0</p> |
| <p><br/></p> |
| <h3 id="version"><a class="toclink" href="#version">version</a></h3> |
| <p>version() - Returns the Spark version. The string contains 2 fields, the first being a release version and the second being a git revision.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT version(); |
| 3.1.0 a6d6ea3efedbad14d99c24143834cd4e2e52fb40 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="weekday"><a class="toclink" href="#weekday">weekday</a></h3> |
| <p>weekday(date) - Returns the day of the week for date/timestamp (0 = Monday, 1 = Tuesday, ..., 6 = Sunday).</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT weekday('2009-07-30'); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="weekofyear"><a class="toclink" href="#weekofyear">weekofyear</a></h3> |
| <p>weekofyear(date) - Returns the week of the year of the given date. A week is considered to start on a Monday and week 1 is the first week with >3 days.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT weekofyear('2008-02-20'); |
| 8 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="when"><a class="toclink" href="#when">when</a></h3> |
| <p>CASE WHEN expr1 THEN expr2 [WHEN expr3 THEN expr4]* [ELSE expr5] END - When <code>expr1</code> = true, returns <code>expr2</code>; else when <code>expr3</code> = true, returns <code>expr4</code>; else returns <code>expr5</code>.</p> |
| <p><strong>Arguments:</strong></p> |
| <ul> |
| <li>expr1, expr3 - the branch condition expressions should all be boolean type.</li> |
| <li>expr2, expr4, expr5 - the branch value expressions and else value expression should all be |
| same type or coercible to a common type.</li> |
| </ul> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT CASE WHEN 1 > 0 THEN 1 WHEN 2 > 0 THEN 2.0 ELSE 1.2 END; |
| 1.0 |
| > SELECT CASE WHEN 1 < 0 THEN 1 WHEN 2 > 0 THEN 2.0 ELSE 1.2 END; |
| 2.0 |
| > SELECT CASE WHEN 1 < 0 THEN 1 WHEN 2 < 0 THEN 2.0 END; |
| NULL |
| </code></pre> |
| <p><strong>Since:</strong> 1.0.1</p> |
| <p><br/></p> |
| <h3 id="width_bucket"><a class="toclink" href="#width_bucket">width_bucket</a></h3> |
| <p>width_bucket(value, min_value, max_value, num_bucket) - Returns the bucket number to which |
| <code>value</code> would be assigned in an equiwidth histogram with <code>num_bucket</code> buckets, |
| in the range <code>min_value</code> to <code>max_value</code>."</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT width_bucket(5.3, 0.2, 10.6, 5); |
| 3 |
| > SELECT width_bucket(-2.1, 1.3, 3.4, 3); |
| 0 |
| > SELECT width_bucket(8.1, 0.0, 5.7, 4); |
| 5 |
| > SELECT width_bucket(-0.9, 5.2, 0.5, 2); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 3.1.0</p> |
| <p><br/></p> |
| <h3 id="window"><a class="toclink" href="#window">window</a></h3> |
| <p>N/A.</p> |
| <p><br/></p> |
| <h3 id="xpath"><a class="toclink" href="#xpath">xpath</a></h3> |
| <p>xpath(xml, xpath) - Returns a string array of values within the nodes of xml that match the XPath expression.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath('<a><b>b1</b><b>b2</b><b>b3</b><c>c1</c><c>c2</c></a>','a/b/text()'); |
| ["b1","b2","b3"] |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xpath_boolean"><a class="toclink" href="#xpath_boolean">xpath_boolean</a></h3> |
| <p>xpath_boolean(xml, xpath) - Returns true if the XPath expression evaluates to true, or if a matching node is found.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath_boolean('<a><b>1</b></a>','a/b'); |
| true |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xpath_double"><a class="toclink" href="#xpath_double">xpath_double</a></h3> |
| <p>xpath_double(xml, xpath) - Returns a double value, the value zero if no match is found, or NaN if a match is found but the value is non-numeric.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath_double('<a><b>1</b><b>2</b></a>', 'sum(a/b)'); |
| 3.0 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xpath_float"><a class="toclink" href="#xpath_float">xpath_float</a></h3> |
| <p>xpath_float(xml, xpath) - Returns a float value, the value zero if no match is found, or NaN if a match is found but the value is non-numeric.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath_float('<a><b>1</b><b>2</b></a>', 'sum(a/b)'); |
| 3.0 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xpath_int"><a class="toclink" href="#xpath_int">xpath_int</a></h3> |
| <p>xpath_int(xml, xpath) - Returns an integer value, or the value zero if no match is found, or a match is found but the value is non-numeric.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath_int('<a><b>1</b><b>2</b></a>', 'sum(a/b)'); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xpath_long"><a class="toclink" href="#xpath_long">xpath_long</a></h3> |
| <p>xpath_long(xml, xpath) - Returns a long integer value, or the value zero if no match is found, or a match is found but the value is non-numeric.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath_long('<a><b>1</b><b>2</b></a>', 'sum(a/b)'); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xpath_number"><a class="toclink" href="#xpath_number">xpath_number</a></h3> |
| <p>xpath_number(xml, xpath) - Returns a double value, the value zero if no match is found, or NaN if a match is found but the value is non-numeric.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath_number('<a><b>1</b><b>2</b></a>', 'sum(a/b)'); |
| 3.0 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xpath_short"><a class="toclink" href="#xpath_short">xpath_short</a></h3> |
| <p>xpath_short(xml, xpath) - Returns a short integer value, or the value zero if no match is found, or a match is found but the value is non-numeric.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath_short('<a><b>1</b><b>2</b></a>', 'sum(a/b)'); |
| 3 |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xpath_string"><a class="toclink" href="#xpath_string">xpath_string</a></h3> |
| <p>xpath_string(xml, xpath) - Returns the text contents of the first xml node that matches the XPath expression.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xpath_string('<a><b>b</b><c>cc</c></a>','a/c'); |
| cc |
| </code></pre> |
| <p><strong>Since:</strong> 2.0.0</p> |
| <p><br/></p> |
| <h3 id="xxhash64"><a class="toclink" href="#xxhash64">xxhash64</a></h3> |
| <p>xxhash64(expr1, expr2, ...) - Returns a 64-bit hash value of the arguments.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT xxhash64('Spark', array(123), 2); |
| 5602566077635097486 |
| </code></pre> |
| <p><strong>Since:</strong> 3.0.0</p> |
| <p><br/></p> |
| <h3 id="year"><a class="toclink" href="#year">year</a></h3> |
| <p>year(date) - Returns the year component of the date/timestamp.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT year('2016-07-30'); |
| 2016 |
| </code></pre> |
| <p><strong>Since:</strong> 1.5.0</p> |
| <p><br/></p> |
| <h3 id="zip_with"><a class="toclink" href="#zip_with">zip_with</a></h3> |
| <p>zip_with(left, right, func) - Merges the two given arrays, element-wise, into a single array using function. If one array is shorter, nulls are appended at the end to match the length of the longer array, before applying function.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT zip_with(array(1, 2, 3), array('a', 'b', 'c'), (x, y) -> (y, x)); |
| [{"y":"a","x":1},{"y":"b","x":2},{"y":"c","x":3}] |
| > SELECT zip_with(array(1, 2), array(3, 4), (x, y) -> x + y); |
| [4,6] |
| > SELECT zip_with(array('a', 'b', 'c'), array('d', 'e', 'f'), (x, y) -> concat(x, y)); |
| ["ad","be","cf"] |
| </code></pre> |
| <p><strong>Since:</strong> 2.4.0</p> |
| <p><br/></p> |
| <h3 id="_15"><a class="toclink" href="#_15">|</a></h3> |
| <p>expr1 | expr2 - Returns the result of bitwise OR of <code>expr1</code> and <code>expr2</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT 3 | 5; |
| 7 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| <h3 id="_16"><a class="toclink" href="#_16">~</a></h3> |
| <p>~ expr - Returns the result of bitwise NOT of <code>expr</code>.</p> |
| <p><strong>Examples:</strong></p> |
| <pre><code>> SELECT ~ 0; |
| -1 |
| </code></pre> |
| <p><strong>Since:</strong> 1.4.0</p> |
| <p><br/></p> |
| |
| </div> |
| </div> |
| <footer> |
| |
| |
| <hr/> |
| |
| <div role="contentinfo"> |
| <!-- Copyright etc --> |
| |
| </div> |
| |
| Built with <a href="https://www.mkdocs.org/">MkDocs</a> using a <a href="https://github.com/snide/sphinx_rtd_theme">theme</a> provided by <a href="https://readthedocs.org">Read the Docs</a>. |
| </footer> |
| |
| </div> |
| </div> |
| |
| </section> |
| |
| </div> |
| |
| <div class="rst-versions" role="note" aria-label="versions"> |
| <span class="rst-current-version" data-toggle="rst-current-version"> |
| |
| |
| |
| </span> |
| </div> |
| <script>var base_url = '.';</script> |
| <script src="js/theme.js" defer></script> |
| <script src="search/main.js" defer></script> |
| <script defer> |
| window.onload = function () { |
| SphinxRtdTheme.Navigation.enable(true); |
| }; |
| </script> |
| |
| </body> |
| </html> |
| |
| <!-- |
| MkDocs version : 1.1.2 |
| Build Date UTC : 2021-02-22 03:03:26.040613+00:00 |
| --> |