blob: e9ef5e04525551dde6b22bb829edb33a1f8d0cde [file] [log] [blame]
<!DOCTYPE html>
<html lang="en">
<head>
<meta charset="UTF-8">
<!--[if IE]><meta http-equiv="X-UA-Compatible" content="IE=edge"><![endif]-->
<meta name="viewport" content="width=device-width, initial-scale=1.0">
<meta name="generator" content="Asciidoctor 1.5.4">
<title>SQL Reference Manual</title>
<style>
/**
* @@@ START COPYRIGHT @@@
*
* Licensed to the Apache Software Foundation (ASF) under one
* or more contributor license agreements. See the NOTICE file
* distributed with this work for additional information
* regarding copyright ownership. The ASF licenses this file
* to you under the Apache License, Version 2.0 (the
* "License"); you may not use this file except in compliance
* with the License. You may obtain a copy of the License at
*
* http://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing,
* software distributed under the License is distributed on an
* "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
* KIND, either express or implied. See the License for the
* specific language governing permissions and limitations
* under the License.
*
* @@@ END COPYRIGHT @@@
*/
/* Asciidoctor default stylesheet | MIT License | http://asciidoctor.org */
/* Remove the comments around the @import statement below when using this as a custom stylesheet */
/*@import "https://fonts.googleapis.com/css?family=Open+Sans:300,300italic,400,400italic,600,600italic%7CNoto+Serif:400,400italic,700,700italic%7CDroid+Sans+Mono:400";*/
article,aside,details,figcaption,figure,footer,header,hgroup,main,nav,section,summary{display:block}
audio,canvas,video{display:inline-block}
audio:not([controls]){display:none;height:0}
[hidden],template{display:none}
script{display:none!important}
html{font-family:sans-serif;-ms-text-size-adjust:100%;-webkit-text-size-adjust:100%}
body{margin:0}
a{background:transparent}
a:focus{outline:thin dotted}
a:active,a:hover{outline:0}
h1{font-size:2em;margin:.67em 0}
abbr[title]{border-bottom:1px dotted}
b,strong{font-weight:bold}
dfn{font-style:italic}
hr{-moz-box-sizing:content-box;box-sizing:content-box;height:0}
mark{background:#ff0;color:#000}
code,kbd,pre,samp{font-family:monospace;font-size:1em}
pre{white-space:pre-wrap}
q{quotes:"\201C" "\201D" "\2018" "\2019"}
small{font-size:80%}
sub,sup{font-size:75%;line-height:0;position:relative;vertical-align:baseline}
sup{top:-.5em}
sub{bottom:-.25em}
img{border:0}
svg:not(:root){overflow:hidden}
figure{margin:0}
fieldset{border:1px solid silver;margin:0 2px;padding:.35em .625em .75em}
legend{border:0;padding:0}
button,input,select,textarea{font-family:inherit;font-size:100%;margin:0}
button,input{line-height:normal}
button,select{text-transform:none}
button,html input[type="button"],input[type="reset"],input[type="submit"]{-webkit-appearance:button;cursor:pointer}
button[disabled],html input[disabled]{cursor:default}
input[type="checkbox"],input[type="radio"]{box-sizing:border-box;padding:0}
input[type="search"]{-webkit-appearance:textfield;-moz-box-sizing:content-box;-webkit-box-sizing:content-box;box-sizing:content-box}
input[type="search"]::-webkit-search-cancel-button,input[type="search"]::-webkit-search-decoration{-webkit-appearance:none}
button::-moz-focus-inner,input::-moz-focus-inner{border:0;padding:0}
textarea{overflow:auto;vertical-align:top}
table{border-collapse:collapse;border-spacing:0}
*,*:before,*:after{-moz-box-sizing:border-box;-webkit-box-sizing:border-box;box-sizing:border-box}
html,body{font-size:100%}
body{background:#fff;color:rgba(0,0,0,.8);padding:0;margin:0;font-family:"Helvetica Neue",Helvetica,Arial,sans-serif,serif;font-weight:400;font-style:normal;line-height:1;position:relative;cursor:auto}
a:hover{cursor:pointer}
img,object,embed{max-width:100%;height:auto}
object,embed{height:100%}
img{-ms-interpolation-mode:bicubic}
#map_canvas img,#map_canvas embed,#map_canvas object,.map_canvas img,.map_canvas embed,.map_canvas object{max-width:none!important}
.left{float:left!important}
.right{float:right!important}
.text-left{text-align:left!important}
.text-right{text-align:right!important}
.text-center{text-align:center!important}
.text-justify{text-align:justify!important}
.hide{display:none}
.antialiased,body{-webkit-font-smoothing:antialiased}
img{display:inline-block;vertical-align:middle}
textarea{height:auto;min-height:50px}
select{width:100%}
p.lead,.paragraph.lead>p,#preamble>.sectionbody>.paragraph:first-of-type p{font-size:1.21875em;line-height:1.6}
.subheader,.admonitionblock td.content>.title,.audioblock>.title,.exampleblock>.title,.imageblock>.title,.listingblock>.title,.literalblock>.title,.stemblock>.title,.openblock>.title,.paragraph>.title,.quoteblock>.title,table.tableblock>.title,.verseblock>.title,.videoblock>.title,.dlist>.title,.olist>.title,.ulist>.title,.qlist>.title,.hdlist>.title{line-height:1.45;color:#3188ac;font-weight:400;margin-top:0;margin-bottom:.25em}
div,dl,dt,dd,ul,ol,li,h1,h2,h3,#toctitle,.sidebarblock>.content>.title,h4,h5,h6,pre,form,p,blockquote,th,td{margin:0;padding:0;direction:ltr}
a{color:#2156a5;text-decoration:underline;line-height:inherit}
a:hover,a:focus{color:#1d4b8f}
a img{border:none}
p{font-family:inherit;font-weight:400;font-size:1em;line-height:1.6;margin-bottom:1.25em;text-rendering:optimizeLegibility}
p aside{font-size:.875em;line-height:1.35;font-style:italic}
/* Defines headings */
h1,h2,h3,#toctitle,.sidebarblock>.content>.title,h4,h5,h6{font-family:"Helvetica Neue",Helvetica,Arial,sans-serif;font-weight:bold;font-style:normal;color:#3188ac;text-rendering:optimizeLegibility;margin-top:1em;margin-bottom:.5em;line-height:1.0125em}
h1 small,h2 small,h3 small,#toctitle small,.sidebarblock>.content>.title small,h4 small,h5 small,h6 small{font-size:60%;color:#e99b8f;line-height:0}
h1{font-size:2.125em}
h2{font-size:1.6875em}
h3,#toctitle,.sidebarblock>.content>.title{font-size:1.375em}
h4,h5{font-size:1.125em}
h6{font-size:1em}
hr{border:solid #ddddd8;border-width:1px 0 0;clear:both;margin:1.25em 0 1.1875em;height:0}
em,i{font-style:italic;line-height:inherit}
strong,b{font-weight:bold;line-height:inherit}
small{font-size:60%;line-height:inherit}
/* Defines the `text` (passthru) format */
code{font-family:"Droid Sans Mono","DejaVu Sans Mono",monospace;font-weight:bold;color:#3188ac}
ul,ol,dl{font-size:1em;line-height:1.6;margin-bottom:1.25em;list-style-position:outside;font-family:inherit}
ul,ol,ul.no-bullet,ol.no-bullet{margin-left:1.5em}
ul li ul,ul li ol{margin-left:1.25em;margin-bottom:0;font-size:1em}
ul.square li ul,ul.circle li ul,ul.disc li ul{list-style:inherit}
ul.square{list-style-type:square}
ul.circle{list-style-type:circle}
ul.disc{list-style-type:disc}
ul.no-bullet{list-style:none}
ol li ul,ol li ol{margin-left:1.25em;margin-bottom:0}
dl dt{margin-bottom:.3125em;font-weight:bold}
dl dd{margin-bottom:1.25em}
abbr,acronym{text-transform:uppercase;font-size:90%;color:rgba(0,0,0,.8);border-bottom:1px dotted #ddd;cursor:help}
abbr{text-transform:none}
blockquote{margin:0 0 1.25em;padding:.5625em 1.25em 0 1.1875em;border-left:1px solid #ddd}
blockquote cite{display:block;font-size:.9375em;color:rgba(0,0,0,.6)}
blockquote cite:before{content:"\2014 \0020"}
blockquote cite a,blockquote cite a:visited{color:rgba(0,0,0,.6)}
blockquote,blockquote p{line-height:1.6;color:rgba(0,0,0,.85)}
@media only screen and (min-width:768px){h1,h2,h3,#toctitle,.sidebarblock>.content>.title,h4,h5,h6{line-height:1.2}
h1{font-size:2.75em}
h2{font-size:2.3125em}
h3,#toctitle,.sidebarblock>.content>.title{font-size:1.6875em}
h4{font-size:1.4375em}}table{background:#fff;margin-bottom:1.25em;border:solid 1px #dedede}
table thead,table tfoot{background:#f7f8f7;font-weight:bold}
table thead tr th,table thead tr td,table tfoot tr th,table tfoot tr td{padding:.5em .625em .625em;font-size:inherit;color:rgba(0,0,0,.8);text-align:left}
table tr th,table tr td{padding:.5625em .625em;font-size:inherit;color:rgba(0,0,0,.8)}
table tr.even,table tr.alt,table tr:nth-of-type(even){background:#f8f8f7}
table thead tr th,table tfoot tr th,table tbody tr td,table tr td,table tfoot tr td{display:table-cell;line-height:1.6}
h1,h2,h3,#toctitle,.sidebarblock>.content>.title,h4,h5,h6{line-height:1.2;word-spacing:-.05em}
h1 strong,h2 strong,h3 strong,#toctitle strong,.sidebarblock>.content>.title strong,h4 strong,h5 strong,h6 strong{font-weight:400}
.clearfix:before,.clearfix:after,.float-group:before,.float-group:after{content:" ";display:table}
.clearfix:after,.float-group:after{clear:both}
*:not(pre)>code{font-size:1.0em;font-style:normal!important;letter-spacing:0;padding:.1em .5ex;word-spacing:-.15em;-webkit-border-radius:4px;border-radius:4px;line-height:1.45;text-rendering:optimizeSpeed}
/**:not(pre)>code{font-size:.9375em;font-style:normal!important;letter-spacing:0;padding:.1em .5ex;word-spacing:-.15em;background-color:#f7f7f8;-webkit-border-radius:4px;border-radius:4px;line-height:1.45;text-rendering:optimizeSpeed}*/
pre,pre>code{line-height:1.45;color:rgba(0,0,0,.9);font-family:"Droid Sans Mono","DejaVu Sans Mono",monospace;font-weight:400;text-rendering:optimizeSpeed}
.keyseq{color:rgba(51,51,51,.8)}
kbd{display:inline-block;color:rgba(0,0,0,.8);font-size:.75em;line-height:1.4;background-color:#f7f7f7;border:1px solid #ccc;-webkit-border-radius:3px;border-radius:3px;-webkit-box-shadow:0 1px 0 rgba(0,0,0,.2),0 0 0 .1em white inset;box-shadow:0 1px 0 rgba(0,0,0,.2),0 0 0 .1em #fff inset;margin:-.15em .15em 0 .15em;padding:.2em .6em .2em .5em;vertical-align:middle;white-space:nowrap}
.keyseq kbd:first-child{margin-left:0}
.keyseq kbd:last-child{margin-right:0}
.menuseq,.menu{color:rgba(0,0,0,.8)}
b.button:before,b.button:after{position:relative;top:-1px;font-weight:400}
b.button:before{content:"[";padding:0 3px 0 2px}
b.button:after{content:"]";padding:0 2px 0 3px}
p a>code:hover{color:rgba(0,0,0,.9)}
#header,#content,#footnotes,#footer{width:100%;margin-left:auto;margin-right:auto;margin-top:0;margin-bottom:0;max-width:62.5em;*zoom:1;position:relative;padding-left:.9375em;padding-right:.9375em}
#header:before,#header:after,#content:before,#content:after,#footnotes:before,#footnotes:after,#footer:before,#footer:after{content:" ";display:table}
#header:after,#content:after,#footnotes:after,#footer:after{clear:both}
#content{margin-top:1.25em}
#content:before{content:none}
/* #header>h1:first-child{color:rgba(0,0,0,.85);margin-top:2.25rem;margin-bottom:0} */
#header>h1:first-child{color:#3188ac;margin-top:2.25rem;margin-bottom:0}
#header>h1:first-child+#toc{margin-top:8px;border-top:1px solid #ddddd8}
#header>h1:only-child,body.toc2 #header>h1:nth-last-child(2){border-bottom:1px solid #ddddd8;padding-bottom:8px}
#header .details{border-bottom:1px solid #ddddd8;line-height:1.45;padding-top:.25em;padding-bottom:.25em;padding-left:.25em;color:rgba(0,0,0,.6);display:-ms-flexbox;display:-webkit-flex;display:flex;-ms-flex-flow:row wrap;-webkit-flex-flow:row wrap;flex-flow:row wrap}
#header .details span:first-child{margin-left:-.125em}
#header .details span.email a{color:rgba(0,0,0,.85)}
#header .details br{display:none}
#header .details br+span:before{content:"\00a0\2013\00a0"}
#header .details br+span.author:before{content:"\00a0\22c5\00a0";color:rgba(0,0,0,.85)}
#header .details br+span#revremark:before{content:"\00a0|\00a0"}
#header #revnumber{text-transform:capitalize}
#header #revnumber:after{content:"\00a0"}
#content>h1:first-child:not([class]){color:rgba(0,0,0,.85);border-bottom:1px solid #ddddd8;padding-bottom:8px;margin-top:0;padding-top:1rem;margin-bottom:1.25rem}
#toc{border-bottom:1px solid #efefed;padding-bottom:.5em}
#toc>ul{margin-left:.125em}
#toc ul.sectlevel0>li>a{font-style:italic}
#toc ul.sectlevel0 ul.sectlevel1{margin:.5em 0}
#toc ul{font-family:"Open Sans","DejaVu Sans",sans-serif;list-style-type:none}
#toc a{text-decoration:none}
#toc a:active{text-decoration:underline}
#toctitle{color:#3188ac;font-size:1.2em}
@media only screen and (min-width:768px){#toctitle{font-size:1.375em}
body.toc2{padding-left:15em;padding-right:0}
#toc.toc2{margin-top:0!important;background-color:#f8f8f7;position:fixed;width:15em;left:0;top:0;border-right:1px solid #efefed;border-top-width:0!important;border-bottom-width:0!important;z-index:1000;padding:1.25em 1em;height:100%;overflow:auto}
#toc.toc2 #toctitle{margin-top:0;font-size:1.2em}
#toc.toc2>ul{font-size:.9em;margin-bottom:0}
#toc.toc2 ul ul{margin-left:0;padding-left:1em}
#toc.toc2 ul.sectlevel0 ul.sectlevel1{padding-left:0;margin-top:.5em;margin-bottom:.5em}
body.toc2.toc-right{padding-left:0;padding-right:15em}
body.toc2.toc-right #toc.toc2{border-right-width:0;border-left:1px solid #efefed;left:auto;right:0}}@media only screen and (min-width:1280px){body.toc2{padding-left:20em;padding-right:0}
/* Controls width of panel */
#toc.toc2{width:20em}
#toc.toc2 #toctitle{font-size:1.375em}
#toc.toc2>ul{font-size:.95em}
#toc.toc2 ul ul{padding-left:1.25em}
body.toc2.toc-right{padding-left:0;padding-right:20em}}#content #toc{border-style:solid;border-width:1px;border-color:#e0e0dc;margin-bottom:1.25em;padding:1.25em;background:#f8f8f7;-webkit-border-radius:4px;border-radius:4px}
#content #toc>:first-child{margin-top:0}
#content #toc>:last-child{margin-bottom:0}
#footer{max-width:100%;background-color:rgba(0,0,0,.8);padding:1.25em}
#footer-text,#footer_nav{color:rgba(255,255,255,.8);line-height:1.44}
#footer a{color: #990000}
.sect1{padding-bottom:.625em}
@media only screen and (min-width:768px){.sect1{padding-bottom:1.25em}}.sect1+.sect1{border-top:1px solid #efefed}
#content h1>a.anchor,h2>a.anchor,h3>a.anchor,#toctitle>a.anchor,.sidebarblock>.content>.title>a.anchor,h4>a.anchor,h5>a.anchor,h6>a.anchor{position:absolute;z-index:1001;width:1.5ex;margin-left:-1.5ex;display:block;text-decoration:none!important;visibility:hidden;text-align:center;font-weight:400}
#content h1>a.anchor:before,h2>a.anchor:before,h3>a.anchor:before,#toctitle>a.anchor:before,.sidebarblock>.content>.title>a.anchor:before,h4>a.anchor:before,h5>a.anchor:before,h6>a.anchor:before{content:"\00A7";font-size:.85em;display:block;padding-top:.1em}
#content h1:hover>a.anchor,#content h1>a.anchor:hover,h2:hover>a.anchor,h2>a.anchor:hover,h3:hover>a.anchor,#toctitle:hover>a.anchor,.sidebarblock>.content>.title:hover>a.anchor,h3>a.anchor:hover,#toctitle>a.anchor:hover,.sidebarblock>.content>.title>a.anchor:hover,h4:hover>a.anchor,h4>a.anchor:hover,h5:hover>a.anchor,h5>a.anchor:hover,h6:hover>a.anchor,h6>a.anchor:hover{visibility:visible}
#content h1>a.link,h2>a.link,h3>a.link,#toctitle>a.link,.sidebarblock>.content>.title>a.link,h4>a.link,h5>a.link,h6>a.link{color:#990000;text-decoration:none}
#content h1>a.link:hover,h2>a.link:hover,h3>a.link:hover,#toctitle>a.link:hover,.sidebarblock>.content>.title>a.link:hover,h4>a.link:hover,h5>a.link:hover,h6>a.link:hover{color:#a53221}
.audioblock,.imageblock,.literalblock,.listingblock,.stemblock,.videoblock{margin-bottom:1.25em}
.admonitionblock td.content>.title,.audioblock>.title,.exampleblock>.title,.imageblock>.title,.listingblock>.title,.literalblock>.title,.stemblock>.title,.openblock>.title,.paragraph>.title,.quoteblock>.title,table.tableblock>.title,.verseblock>.title,.videoblock>.title,.dlist>.title,.olist>.title,.ulist>.title,.qlist>.title,.hdlist>.title{text-rendering:optimizeLegibility;text-align:left;font-family:"Helvetica Neue",Helvetica,Arial,sans-serif,serif;font-size:1rem;font-weight:bold}
/* Here */
table.tableblock>caption.title{white-space:nowrap;overflow:visible;max-width:0}
.paragraph.lead>p,#preamble>.sectionbody>.paragraph:first-of-type p{color:rgba(0,0,0,.85)}
table.tableblock #preamble>.sectionbody>.paragraph:first-of-type p{font-size:inherit}
.admonitionblock>table{border-collapse:separate;border:0;background:none;width:100%}
.admonitionblock>table td.icon{text-align:center;width:80px}
.admonitionblock>table td.icon img{max-width:none}
.admonitionblock>table td.icon .title{font-weight:bold;font-family:"Open Sans","DejaVu Sans",sans-serif;text-transform:uppercase}
.admonitionblock>table td.content{padding-left:1.125em;padding-right:1.25em;border-left:1px solid #ddddd8;color:rgba(0,0,0,.6)}
.admonitionblock>table td.content>:last-child>:last-child{margin-bottom:0}
.exampleblock>.content{border-style:solid;border-width:1px;border-color:#e6e6e6;margin-bottom:1.25em;padding:1.25em;background:#fff;-webkit-border-radius:4px;border-radius:4px}
.exampleblock>.content>:first-child{margin-top:0}
.exampleblock>.content>:last-child{margin-bottom:0}
.sidebarblock{border-style:solid;border-width:1px;border-color:#e0e0dc;margin-bottom:1.25em;padding:1.25em;background:#f8f8f7;-webkit-border-radius:4px;border-radius:4px}
.sidebarblock>:first-child{margin-top:0}
.sidebarblock>:last-child{margin-bottom:0}
.sidebarblock>.content>.title{color:#7a2518;margin-top:0;text-align:center}
.exampleblock>.content>:last-child>:last-child,.exampleblock>.content .olist>ol>li:last-child>:last-child,.exampleblock>.content .ulist>ul>li:last-child>:last-child,.exampleblock>.content .qlist>ol>li:last-child>:last-child,.sidebarblock>.content>:last-child>:last-child,.sidebarblock>.content .olist>ol>li:last-child>:last-child,.sidebarblock>.content .ulist>ul>li:last-child>:last-child,.sidebarblock>.content .qlist>ol>li:last-child>:last-child{margin-bottom:0}
.literalblock pre,.listingblock pre:not(.highlight),.listingblock pre[class="highlight"],.listingblock pre[class^="highlight "],.listingblock pre.CodeRay,.listingblock pre.prettyprint{background:#f7f7f8}
.sidebarblock .literalblock pre,.sidebarblock .listingblock pre:not(.highlight),.sidebarblock .listingblock pre[class="highlight"],.sidebarblock .listingblock pre[class^="highlight "],.sidebarblock .listingblock pre.CodeRay,.sidebarblock .listingblock pre.prettyprint{background:#f2f1f1}
.literalblock pre,.literalblock pre[class],.listingblock pre,.listingblock pre[class]{-webkit-border-radius:4px;border-radius:4px;word-wrap:break-word;padding:1em;font-size:.8125em}
.literalblock pre.nowrap,.literalblock pre[class].nowrap,.listingblock pre.nowrap,.listingblock pre[class].nowrap{overflow-x:auto;white-space:pre;word-wrap:normal}
@media only screen and (min-width:768px){.literalblock pre,.literalblock pre[class],.listingblock pre,.listingblock pre[class]{font-size:.90625em}}@media only screen and (min-width:1280px){.literalblock pre,.literalblock pre[class],.listingblock pre,.listingblock pre[class]{font-size:1em}}.literalblock.output pre{color:#f7f7f8;background-color:rgba(0,0,0,.9)}
.listingblock pre.highlightjs{padding:0}
.listingblock pre.highlightjs>code{padding:1em;-webkit-border-radius:4px;border-radius:4px}
.listingblock pre.prettyprint{border-width:0}
.listingblock>.content{position:relative}
.listingblock code[data-lang]:before{display:none;content:attr(data-lang);position:absolute;font-size:.75em;top:.425rem;right:.5rem;line-height:1;text-transform:uppercase;color:#999}
.listingblock:hover code[data-lang]:before{display:block}
.listingblock.terminal pre .command:before{content:attr(data-prompt);padding-right:.5em;color:#999}
.listingblock.terminal pre .command:not([data-prompt]):before{content:"$"}
table.pyhltable{border-collapse:separate;border:0;margin-bottom:0;background:none}
table.pyhltable td{vertical-align:top;padding-top:0;padding-bottom:0}
table.pyhltable td.code{padding-left:.75em;padding-right:0}
pre.pygments .lineno,table.pyhltable td:not(.code){color:#999;padding-left:0;padding-right:.5em;border-right:1px solid #ddddd8}
pre.pygments .lineno{display:inline-block;margin-right:.25em}
table.pyhltable .linenodiv{background:none!important;padding-right:0!important}
.quoteblock{margin:0 1em 1.25em 1.5em;display:table}
.quoteblock>.title{margin-left:-1.5em;margin-bottom:.75em}
.quoteblock blockquote,.quoteblock blockquote p{color:rgba(0,0,0,.85);font-size:1.15rem;line-height:1.75;word-spacing:.1em;letter-spacing:0;font-style:italic;text-align:justify}
.quoteblock blockquote{margin:0;padding:0;border:0}
.quoteblock blockquote:before{content:"\201c";float:left;font-size:2.75em;font-weight:bold;line-height:.6em;margin-left:-.6em;color:#7a2518;text-shadow:0 1px 2px rgba(0,0,0,.1)}
.quoteblock blockquote>.paragraph:last-child p{margin-bottom:0}
.quoteblock .attribution{margin-top:.5em;margin-right:.5ex;text-align:right}
.quoteblock .quoteblock{margin-left:0;margin-right:0;padding:.5em 0;border-left:3px solid rgba(0,0,0,.6)}
.quoteblock .quoteblock blockquote{padding:0 0 0 .75em}
.quoteblock .quoteblock blockquote:before{display:none}
.verseblock{margin:0 1em 1.25em 1em}
.verseblock pre{font-family:"Open Sans","DejaVu Sans",sans;font-size:1.15rem;color:rgba(0,0,0,.85);font-weight:300;text-rendering:optimizeLegibility}
.verseblock pre strong{font-weight:400}
.verseblock .attribution{margin-top:1.25rem;margin-left:.5ex}
.quoteblock .attribution,.verseblock .attribution{font-size:.9375em;line-height:1.45;font-style:italic}
.quoteblock .attribution br,.verseblock .attribution br{display:none}
.quoteblock .attribution cite,.verseblock .attribution cite{display:block;letter-spacing:-.05em;color:rgba(0,0,0,.6)}
.quoteblock.abstract{margin:0 0 1.25em 0;display:block}
.quoteblock.abstract blockquote,.quoteblock.abstract blockquote p{text-align:left;word-spacing:0}
.quoteblock.abstract blockquote:before,.quoteblock.abstract blockquote p:first-of-type:before{display:none}
table.tableblock{max-width:100%;border-collapse:separate}
table.tableblock td>.paragraph:last-child p>p:last-child,table.tableblock th>p:last-child,table.tableblock td>p:last-child{margin-bottom:0}
table.spread{width:100%}
table.tableblock,th.tableblock,td.tableblock{border:0 solid #dedede}
table.grid-all th.tableblock,table.grid-all td.tableblock{border-width:0 1px 1px 0}
table.grid-all tfoot>tr>th.tableblock,table.grid-all tfoot>tr>td.tableblock{border-width:1px 1px 0 0}
table.grid-cols th.tableblock,table.grid-cols td.tableblock{border-width:0 1px 0 0}
table.grid-all *>tr>.tableblock:last-child,table.grid-cols *>tr>.tableblock:last-child{border-right-width:0}
table.grid-rows th.tableblock,table.grid-rows td.tableblock{border-width:0 0 1px 0}
table.grid-all tbody>tr:last-child>th.tableblock,table.grid-all tbody>tr:last-child>td.tableblock,table.grid-all thead:last-child>tr>th.tableblock,table.grid-rows tbody>tr:last-child>th.tableblock,table.grid-rows tbody>tr:last-child>td.tableblock,table.grid-rows thead:last-child>tr>th.tableblock{border-bottom-width:0}
table.grid-rows tfoot>tr>th.tableblock,table.grid-rows tfoot>tr>td.tableblock{border-width:1px 0 0 0}
table.frame-all{border-width:1px}
table.frame-sides{border-width:0 1px}
table.frame-topbot{border-width:1px 0}
th.halign-left,td.halign-left{text-align:left}
th.halign-right,td.halign-right{text-align:right}
th.halign-center,td.halign-center{text-align:center}
th.valign-top,td.valign-top{vertical-align:top}
th.valign-bottom,td.valign-bottom{vertical-align:bottom}
th.valign-middle,td.valign-middle{vertical-align:middle}
table thead th,table tfoot th{font-weight:bold}
tbody tr th{display:table-cell;line-height:1.6;background:#f7f8f7}
tbody tr th,tbody tr th p,tfoot tr th,tfoot tr th p{color:rgba(0,0,0,.8);font-weight:bold}
p.tableblock>code:only-child{background:none;padding:0}
p.tableblock{font-size:1em}
td>div.verse{white-space:pre}
ol{margin-left:1.75em}
ul li ol{margin-left:1.5em}
dl dd{margin-left:1.125em}
dl dd:last-child,dl dd:last-child>:last-child{margin-bottom:0}
ol>li p,ul>li p,ul dd,ol dd,.olist .olist,.ulist .ulist,.ulist .olist,.olist .ulist{margin-bottom:.625em}
ul.unstyled,ol.unnumbered,ul.checklist,ul.none{list-style-type:none}
ul.unstyled,ol.unnumbered,ul.checklist{margin-left:.625em}
ul.checklist li>p:first-child>.fa-square-o:first-child,ul.checklist li>p:first-child>.fa-check-square-o:first-child{width:1em;font-size:.85em}
ul.checklist li>p:first-child>input[type="checkbox"]:first-child{width:1em;position:relative;top:1px}
ul.inline{margin:0 auto .625em auto;margin-left:-1.375em;margin-right:0;padding:0;list-style:none;overflow:hidden}
ul.inline>li{list-style:none;float:left;margin-left:1.375em;display:block}
ul.inline>li>*{display:block}
.unstyled dl dt{font-weight:400;font-style:normal}
ol.arabic{list-style-type:decimal}
ol.decimal{list-style-type:decimal-leading-zero}
ol.loweralpha{list-style-type:lower-alpha}
ol.upperalpha{list-style-type:upper-alpha}
ol.lowerroman{list-style-type:lower-roman}
ol.upperroman{list-style-type:upper-roman}
ol.lowergreek{list-style-type:lower-greek}
.hdlist>table,.colist>table{border:0;background:none}
.hdlist>table>tbody>tr,.colist>table>tbody>tr{background:none}
td.hdlist1{padding-right:.75em;font-weight:bold}
td.hdlist1,td.hdlist2{vertical-align:top}
.literalblock+.colist,.listingblock+.colist{margin-top:-.5em}
.colist>table tr>td:first-of-type{padding:0 .75em;line-height:1}
.colist>table tr>td:last-of-type{padding:.25em 0}
.thumb,.th{line-height:0;display:inline-block;border:solid 4px #fff;-webkit-box-shadow:0 0 0 1px #ddd;box-shadow:0 0 0 1px #ddd}
.imageblock.left,.imageblock[style*="float: left"]{margin:.25em .625em 1.25em 0}
.imageblock.right,.imageblock[style*="float: right"]{margin:.25em 0 1.25em .625em}
.imageblock>.title{margin-bottom:0}
.imageblock.thumb,.imageblock.th{border-width:6px}
.imageblock.thumb>.title,.imageblock.th>.title{padding:0 .125em}
.image.left,.image.right{margin-top:.25em;margin-bottom:.25em;display:inline-block;line-height:0}
.image.left{margin-right:.625em}
.image.right{margin-left:.625em}
a.image{text-decoration:none}
span.footnote,span.footnoteref{vertical-align:super;font-size:.875em}
span.footnote a,span.footnoteref a{text-decoration:none}
span.footnote a:active,span.footnoteref a:active{text-decoration:underline}
#footnotes{padding-top:.75em;padding-bottom:.75em;margin-bottom:.625em}
#footnotes hr{width:20%;min-width:6.25em;margin:-.25em 0 .75em 0;border-width:1px 0 0 0}
#footnotes .footnote{padding:0 .375em;line-height:1.3;font-size:.875em;margin-left:1.2em;text-indent:-1.2em;margin-bottom:.2em}
#footnotes .footnote a:first-of-type{font-weight:bold;text-decoration:none}
#footnotes .footnote:last-of-type{margin-bottom:0}
#content #footnotes{margin-top:-.625em;margin-bottom:0;padding:.75em 0}
.gist .file-data>table{border:0;background:#fff;width:100%;margin-bottom:0}
.gist .file-data>table td.line-data{width:99%}
div.unbreakable{page-break-inside:avoid}
.big{font-size:larger}
.small{font-size:smaller}
.underline{text-decoration:underline}
.overline{text-decoration:overline}
.line-through{text-decoration:line-through}
.aqua{color:#00bfbf}
.aqua-background{background-color:#00fafa}
.black{color:#000}
.black-background{background-color:#000}
.blue{color:#0000bf}
.blue-background{background-color:#0000fa}
.fuchsia{color:#bf00bf}
.fuchsia-background{background-color:#fa00fa}
.gray{color:#606060}
.gray-background{background-color:#7d7d7d}
.green{color:#006000}
.green-background{background-color:#007d00}
.lime{color:#00bf00}
.lime-background{background-color:#00fa00}
.maroon{color:#600000}
.maroon-background{background-color:#7d0000}
.navy{color:#000060}
.navy-background{background-color:#00007d}
.olive{color:#606000}
.olive-background{background-color:#7d7d00}
.purple{color:#600060}
.purple-background{background-color:#7d007d}
.red{color:#bf0000}
.red-background{background-color:#fa0000}
.silver{color:#909090}
.silver-background{background-color:#bcbcbc}
.teal{color:#006060}
.teal-background{background-color:#007d7d}
.white{color:#bfbfbf}
.white-background{background-color:#fafafa}
.yellow{color:#bfbf00}
.yellow-background{background-color:#fafa00}
span.icon>.fa{cursor:default}
.admonitionblock td.icon [class^="fa icon-"]{font-size:2.5em;text-shadow:1px 1px 2px rgba(0,0,0,.5);cursor:default}
.admonitionblock td.icon .icon-note:before{content:"\f05a";color:#19407c}
.admonitionblock td.icon .icon-tip:before{content:"\f0eb";text-shadow:1px 1px 2px rgba(155,155,0,.8);color:#111}
.admonitionblock td.icon .icon-warning:before{content:"\f071";color:#bf6900}
.admonitionblock td.icon .icon-caution:before{content:"\f06d";color:#bf3400}
.admonitionblock td.icon .icon-important:before{content:"\f06a";color:#bf0000}
.conum[data-value]{display:inline-block;color:#fff!important;background-color:rgba(0,0,0,.8);-webkit-border-radius:100px;border-radius:100px;text-align:center;font-size:.75em;width:1.67em;height:1.67em;line-height:1.67em;font-family:"Open Sans","DejaVu Sans",sans-serif;font-style:normal;font-weight:bold}
.conum[data-value] *{color:#fff!important}
.conum[data-value]+b{display:none}
.conum[data-value]:after{content:attr(data-value)}
pre .conum[data-value]{position:relative;top:-.125em}
b.conum *{color:inherit!important}
.conum:not([data-value]):empty{display:none}
h1,h2{letter-spacing:-.01em}
dt,th.tableblock,td.content{text-rendering:optimizeLegibility}
p,td.content{letter-spacing:-.01em}
p strong,td.content strong{letter-spacing:-.005em}
p,blockquote,dt,td.content{font-size:1.0625rem}
p{margin-bottom:1.25rem}
.sidebarblock p,.sidebarblock dt,.sidebarblock td.content,p.tableblock{font-size:1em}
.exampleblock>.content{background-color:#fffef7;border-color:#e0e0dc;-webkit-box-shadow:0 1px 4px #e0e0dc;box-shadow:0 1px 4px #e0e0dc}
.print-only{display:none!important}
@media print{@page{margin:1.25cm .75cm}
*{-webkit-box-shadow:none!important;box-shadow:none!important;text-shadow:none!important}
a{color:inherit!important;text-decoration:underline!important}
a.bare,a[href^="#"],a[href^="mailto:"]{text-decoration:none!important}
a[href^="http:"]:not(.bare):after,a[href^="https:"]:not(.bare):after{content:"(" attr(href) ")";display:inline-block;font-size:.875em;padding-left:.25em}
abbr[title]:after{content:" (" attr(title) ")"}
pre,blockquote,tr,img{page-break-inside:avoid}
thead{display:table-header-group}
img{max-width:100%!important}
p,blockquote,dt,td.content{font-size:1em;orphans:3;widows:3}
h2,h3,#toctitle,.sidebarblock>.content>.title{page-break-after:avoid}
#toc,.sidebarblock,.exampleblock>.content{background:none!important}
#toc{border-bottom:1px solid #ddddd8!important;padding-bottom:0!important}
.sect1{padding-bottom:0!important}
.sect1+.sect1{border:0!important}
#header>h1:first-child{margin-top:1.25rem}
body.book #header{text-align:center}
body.book #header>h1:first-child{border:0!important;margin:2.5em 0 1em 0}
body.book #header .details{border:0!important;display:block;padding:0!important}
body.book #header .details span:first-child{margin-left:0!important}
body.book #header .details br{display:block}
body.book #header .details br+span:before{content:none!important}
body.book #toc{border:0!important;text-align:left!important;padding:0!important;margin:0!important}
body.book #toc,body.book #preamble,body.book h1.sect0,body.book .sect1>h2{page-break-before:always}
.listingblock code[data-lang]:before{display:block}
#footer{background:none!important;padding:0 .9375em}
#footer-text{color:rgba(0,0,0,.6)!important;font-size:.9em}
.hide-on-print{display:none!important}
.print-only{display:block!important}
.hide-for-print{display:none!important}
.show-for-print{display:inherit!important}}
div.paragraph.indented p {padding-left: 3em;}
div.paragraph.indented2 p {padding-left: 6em;}
div.paragraph.indented3 p {padding-left: 9em;}
</style>
<link rel="stylesheet" href="https://cdnjs.cloudflare.com/ajax/libs/font-awesome/4.5.0/css/font-awesome.min.css">
<style>
/* Stylesheet for CodeRay to match GitHub theme | MIT License | http://foundation.zurb.com */
/*pre.CodeRay {background-color:#f7f7f8;}*/
.CodeRay .line-numbers{border-right:1px solid #d8d8d8;padding:0 0.5em 0 .25em}
.CodeRay span.line-numbers{display:inline-block;margin-right:.5em;color:rgba(0,0,0,.3)}
.CodeRay .line-numbers strong{color:rgba(0,0,0,.4)}
table.CodeRay{border-collapse:separate;border-spacing:0;margin-bottom:0;border:0;background:none}
table.CodeRay td{vertical-align: top;line-height:1.45}
table.CodeRay td.line-numbers{text-align:right}
table.CodeRay td.line-numbers>pre{padding:0;color:rgba(0,0,0,.3)}
table.CodeRay td.code{padding:0 0 0 .5em}
table.CodeRay td.code>pre{padding:0}
.CodeRay .debug{color:#fff !important;background:#000080 !important}
.CodeRay .annotation{color:#007}
.CodeRay .attribute-name{color:#000080}
.CodeRay .attribute-value{color:#700}
.CodeRay .binary{color:#509}
.CodeRay .comment{color:#998;font-style:italic}
.CodeRay .char{color:#04d}
.CodeRay .char .content{color:#04d}
.CodeRay .char .delimiter{color:#039}
.CodeRay .class{color:#458;font-weight:bold}
.CodeRay .complex{color:#a08}
.CodeRay .constant,.CodeRay .predefined-constant{color:#008080}
.CodeRay .color{color:#099}
.CodeRay .class-variable{color:#369}
.CodeRay .decorator{color:#b0b}
.CodeRay .definition{color:#099}
.CodeRay .delimiter{color:#000}
.CodeRay .doc{color:#970}
.CodeRay .doctype{color:#34b}
.CodeRay .doc-string{color:#d42}
.CodeRay .escape{color:#666}
.CodeRay .entity{color:#800}
.CodeRay .error{color:#808}
.CodeRay .exception{color:inherit}
.CodeRay .filename{color:#099}
.CodeRay .function{color:#900;font-weight:bold}
.CodeRay .global-variable{color:#008080}
.CodeRay .hex{color:#058}
.CodeRay .integer,.CodeRay .float{color:#099}
.CodeRay .include{color:#555}
.CodeRay .inline{color:#000}
.CodeRay .inline .inline{background:#ccc}
.CodeRay .inline .inline .inline{background:#bbb}
.CodeRay .inline .inline-delimiter{color:#d14}
.CodeRay .inline-delimiter{color:#d14}
.CodeRay .important{color:#555;font-weight:bold}
.CodeRay .interpreted{color:#b2b}
.CodeRay .instance-variable{color:#008080}
.CodeRay .label{color:#970}
.CodeRay .local-variable{color:#963}
.CodeRay .octal{color:#40e}
.CodeRay .predefined{color:#369}
.CodeRay .preprocessor{color:#579}
.CodeRay .pseudo-class{color:#555}
.CodeRay .directive{font-weight:bold}
.CodeRay .type{font-weight:bold}
.CodeRay .predefined-type{color:inherit}
.CodeRay .reserved,.CodeRay .keyword {color:#000;font-weight:bold}
.CodeRay .key{color:#808}
.CodeRay .key .delimiter{color:#606}
.CodeRay .key .char{color:#80f}
.CodeRay .value{color:#088}
.CodeRay .regexp .delimiter{color:#808}
.CodeRay .regexp .content{color:#808}
.CodeRay .regexp .modifier{color:#808}
.CodeRay .regexp .char{color:#d14}
.CodeRay .regexp .function{color:#404;font-weight:bold}
.CodeRay .string{color:#d20}
.CodeRay .string .string .string{background:#ffd0d0}
.CodeRay .string .content{color:#d14}
.CodeRay .string .char{color:#d14}
.CodeRay .string .delimiter{color:#d14}
.CodeRay .shell{color:#d14}
.CodeRay .shell .delimiter{color:#d14}
.CodeRay .symbol{color:#990073}
.CodeRay .symbol .content{color:#a60}
.CodeRay .symbol .delimiter{color:#630}
.CodeRay .tag{color:#008080}
.CodeRay .tag-special{color:#d70}
.CodeRay .variable{color:#036}
.CodeRay .insert{background:#afa}
.CodeRay .delete{background:#faa}
.CodeRay .change{color:#aaf;background:#007}
.CodeRay .head{color:#f8f;background:#505}
.CodeRay .insert .insert{color:#080}
.CodeRay .delete .delete{color:#800}
.CodeRay .change .change{color:#66f}
.CodeRay .head .head{color:#f4f}
</style>
</head>
<body class="book toc2 toc-left">
<div id="header">
<h1>SQL Reference Manual</h1>
<div class="details">
<span id="revnumber">version 2.2.0</span>
</div>
<div id="toc" class="toc2">
<div id="toctitle">Table of Contents</div>
<ul class="sectlevel1">
<li><a href="#About_This_Document">1. About This Document</a>
<ul class="sectlevel2">
<li><a href="#Intended_Audience">1.1. Intended Audience</a></li>
<li><a href="#New_and_Changed_Information">1.2. New and Changed Information</a></li>
<li><a href="#Document_Organization">1.3. Document Organization</a></li>
<li><a href="#_notation_conventions">1.4. Notation Conventions</a></li>
<li><a href="#_comments_encouraged">1.5. Comments Encouraged</a></li>
</ul>
</li>
<li><a href="#introduction">2. Introduction</a>
<ul class="sectlevel2">
<li><a href="#sql_language">2.1. SQL Language</a></li>
<li><a href="#using_trafodion_sql_to_access_hbase_tables">2.2. Using Trafodion SQL to Access HBase Tables</a>
<ul class="sectlevel3">
<li><a href="#ways_to_access_hbase_tables">2.2.1. Ways to Access HBase Tables</a></li>
<li><a href="#trafodion_sql_tables_versus_native_hbase_tables">2.2.2. Trafodion SQL Tables Versus Native HBase Tables</a></li>
<li><a href="#supported_sql_statements_with_hbase_tables">2.2.3. Supported SQL Statements With HBase Tables</a></li>
</ul>
</li>
<li><a href="#using_trafodion_sql_to_access_hive_tables">2.3. Using Trafodion SQL to Access Hive Tables</a>
<ul class="sectlevel3">
<li><a href="#ansi_names_for_hive_tables">2.3.1. ANSI Names for Hive Tables</a></li>
<li><a href="#type_mapping_from_hive_to_trafodion_sql">2.3.2. Type Mapping From Hive to Trafodion SQL</a></li>
<li><a href="#supported_sql_statements_with_hive_tables">2.3.3. Supported SQL Statements With Hive Tables</a></li>
</ul>
</li>
<li><a href="#data_consistency_and_access_options">2.4. Data Consistency and Access Options</a>
<ul class="sectlevel3">
<li><a href="#read_committed">2.4.1. READ COMMITTED</a></li>
</ul>
</li>
<li><a href="#transaction_management">2.5. Transaction Management</a>
<ul class="sectlevel3">
<li><a href="#user_defined_and_system_defined_transactions">2.5.1. User-Defined and System-Defined Transactions</a></li>
<li><a href="#rules_for_dml_statements">2.5.2. Rules for DML Statements</a></li>
<li><a href="#effect_of_autocommit_option">2.5.3. Effect of AUTOCOMMIT Option</a></li>
<li><a href="#concurrency">2.5.4. Concurrency</a></li>
<li><a href="#transaction_isolation_levels">2.5.5. Transaction Isolation Levels</a></li>
</ul>
</li>
<li><a href="#ansi_compliance_and_trafodion_sql_extensions">2.6. ANSI Compliance and Trafodion SQL Extensions</a>
<ul class="sectlevel3">
<li><a href="#ansi_compliant_statements">2.6.1. ANSI-Compliant Statements</a></li>
<li><a href="#statements_that_are_trafodion_sql_extensions">2.6.2. Statements That Are Trafodion SQL Extensions</a></li>
<li><a href="#ansi_compliant_functions">2.6.3. ANSI-Compliant Functions</a></li>
</ul>
</li>
<li><a href="#_trafodion_sql_error_messages">2.7. Trafodion SQL Error Messages</a></li>
</ul>
</li>
<li><a href="#sql_statements">3. SQL Statements</a>
<ul class="sectlevel2">
<li><a href="#sql_statements_categories">3.1. Categories</a>
<ul class="sectlevel3">
<li><a href="#data_definition_language_statements">3.1.1. Data Definition Language (DDL) Statements</a></li>
<li><a href="#data_manipulation_language_statements">3.1.2. Data Manipulation Language (DML) Statements</a></li>
<li><a href="#transaction_control_statements">3.1.3. Transaction Control Statements</a></li>
<li><a href="#data_control_and_security_statements">3.1.4. Data Control and Security Statements</a></li>
<li><a href="#stored_procedure_and_user_defined_function_statements">3.1.5. Stored Procedure and User-Defined Function Statements</a></li>
<li><a href="#prepared_statements">3.1.6. Prepared Statements</a></li>
<li><a href="#control_statements">3.1.7. Control Statements</a></li>
<li><a href="#object_naming_statements">3.1.8. Object Naming Statements</a></li>
<li><a href="#show_get_and_explain_statements">3.1.9. SHOW, GET, and EXPLAIN Statements</a></li>
</ul>
</li>
<li><a href="#alter_sequence_statement">3.2. ALTER SEQUENCE Statement</a>
<ul class="sectlevel3">
<li><a href="#alter_sequence_syntax">3.2.1. Syntax Description of ALTER SEQUENCE</a></li>
<li><a href="#alter_sequence_considerations">3.2.2. Considerations for ALTER SEQUENCE</a></li>
<li><a href="#alter_sequence_examples">3.2.3. Examples of ALTER SEQUENCE</a></li>
</ul>
</li>
<li><a href="#alter_table_statement">3.3. ALTER TABLE Statement</a>
<ul class="sectlevel3">
<li><a href="#alter_table_syntax">3.3.1. Syntax Description of ALTER TABLE</a></li>
<li><a href="#alter_table_considerations">3.3.2. Considerations for ALTER TABLE</a></li>
<li><a href="#alter_table_examples">3.3.3. Example of ALTER TABLE</a></li>
</ul>
</li>
<li><a href="#alter_user_statement">3.4. ALTER USER Statement</a>
<ul class="sectlevel3">
<li><a href="#alter_user_syntax">3.4.1. Syntax Description of ALTER USER</a></li>
<li><a href="#alter_user_considerations">3.4.2. Considerations for ALTER USER</a></li>
<li><a href="#alter_user_examples">3.4.3. Examples of ALTER USER</a></li>
</ul>
</li>
<li><a href="#begin_work_statement">3.5. BEGIN WORK Statement</a>
<ul class="sectlevel3">
<li><a href="#begin_work_considerations">3.5.1. Considerations for BEGIN WORK</a></li>
<li><a href="#begin_work_examples">3.5.2. Example of BEGIN WORK</a></li>
</ul>
</li>
<li><a href="#call_statement">3.6. CALL Statement</a>
<ul class="sectlevel3">
<li><a href="#call_syntax">3.6.1. Syntax Description of CALL</a></li>
<li><a href="#call_considerations">3.6.2. Considerations for CALL</a></li>
<li><a href="#call_examples">3.6.3. Examples of CALL</a></li>
</ul>
</li>
<li><a href="#commit_work_statement">3.7. COMMIT WORK Statement</a>
<ul class="sectlevel3">
<li><a href="#commit_work_considerations">3.7.1. Considerations for COMMIT WORK</a></li>
<li><a href="#commit_work_examples">3.7.2. Example of COMMIT WORK</a></li>
</ul>
</li>
<li><a href="#control_query_cancel_statement">3.8. CONTROL QUERY CANCEL Statement</a>
<ul class="sectlevel3">
<li><a href="#control_query_cancel_syntax">3.8.1. Syntax Description of CONTROL QUERY CANCEL</a></li>
<li><a href="#control_query_cancel_considerations">3.8.2. Considerations for CONTROL QUERY CANCEL</a></li>
<li><a href="#control_query_cancel_examples">3.8.3. Example of CONTROL QUERY CANCEL</a></li>
</ul>
</li>
<li><a href="#control_query_default_statement">3.9. CONTROL QUERY DEFAULT Statement</a>
<ul class="sectlevel3">
<li><a href="#control_query_default_syntax">3.9.1. Syntax Description of CONTROL QUERY DEFAULT</a></li>
<li><a href="#control_query_default_considerations">3.9.2. Considerations for CONTROL QUERY DEFAULT</a></li>
<li><a href="#control_query_default_examples">3.9.3. Examples of CONTROL QUERY DEFAULT</a></li>
</ul>
</li>
<li><a href="#create_function_statement">3.10. CREATE FUNCTION Statement</a>
<ul class="sectlevel3">
<li><a href="#create_function_syntax">3.10.1. Syntax Description of CREATE FUNCTION</a></li>
<li><a href="#create_function_considerations">3.10.2. Considerations for CREATE FUNCTION</a></li>
<li><a href="#create_function_examples">3.10.3. Examples of CREATE FUNCTION</a></li>
</ul>
</li>
<li><a href="#create_index_statement">3.11. CREATE INDEX Statement</a>
<ul class="sectlevel3">
<li><a href="#create_index_syntax">3.11.1. Syntax Description of CREATE INDEX</a></li>
<li><a href="#create_index_considerations">3.11.2. Considerations for CREATE INDEX</a></li>
<li><a href="#create_index_examples">3.11.3. Examples of CREATE INDEX</a></li>
</ul>
</li>
<li><a href="#create_library_statement">3.12. CREATE LIBRARY Statement</a>
<ul class="sectlevel3">
<li><a href="#create_library_syntax">3.12.1. Syntax Description of CREATE LIBRARY</a></li>
<li><a href="#create_library_considerations">3.12.2. Considerations for CREATE LIBRARY</a></li>
<li><a href="#create_library_examples">3.12.3. Examples of CREATE LIBRARY</a></li>
</ul>
</li>
<li><a href="#create_procedure_statement">3.13. CREATE PROCEDURE Statement</a>
<ul class="sectlevel3">
<li><a href="#create_procedure_syntax">3.13.1. Syntax Description of CREATE PROCEDURE</a></li>
<li><a href="#create_procedure_considerations">3.13.2. Considerations for CREATE PROCEDURE</a></li>
<li><a href="#create_procedure_examples">3.13.3. Examples of CREATE PROCEDURE</a></li>
</ul>
</li>
<li><a href="#create_role_statement">3.14. CREATE ROLE Statement</a>
<ul class="sectlevel3">
<li><a href="#create_role_syntax">3.14.1. Syntax Description of CREATE ROLE</a></li>
<li><a href="#create_role_considerations">3.14.2. Considerations for CREATE ROLE</a></li>
<li><a href="#create_role_examples">3.14.3. Examples of CREATE ROLE</a></li>
</ul>
</li>
<li><a href="#create_schema_statement">3.15. CREATE SCHEMA Statement</a>
<ul class="sectlevel3">
<li><a href="#create_schema_syntax">3.15.1. Syntax Description of CREATE SCHEMA</a></li>
<li><a href="#create_schema_considerations">3.15.2. Considerations for CREATE SCHEMA</a></li>
<li><a href="#create_schema_examples">3.15.3. Examples of CREATE SCHEMA</a></li>
</ul>
</li>
<li><a href="#create_sequence_statement">3.16. CREATE SEQUENCE Statement</a>
<ul class="sectlevel3">
<li><a href="#create_sequence_syntax">3.16.1. Syntax Description of CREATE SEQUENCE</a></li>
<li><a href="#create_sequence_considerations">3.16.2. Considerations for CREATE SEQUENCE</a></li>
<li><a href="#create_sequence_examples">3.16.3. Examples of CREATE SEQUENCE</a></li>
</ul>
</li>
<li><a href="#create_table_statement">3.17. CREATE TABLE Statement</a>
<ul class="sectlevel3">
<li><a href="#create_table_syntax">3.17.1. Syntax Description of CREATE TABLE</a></li>
<li><a href="#create_table_considerations">3.17.2. Considerations for CREATE TABLE</a></li>
<li><a href="#create_table_trafodion_sql_extensions_to_create_table">3.17.3. Trafodion SQL Extensions to CREATE TABLE</a></li>
<li><a href="#create_table_examples">3.17.4. Examples of CREATE TABLE</a></li>
</ul>
</li>
<li><a href="#create_view_statement">3.18. CREATE VIEW Statement</a>
<ul class="sectlevel3">
<li><a href="#create_view_syntax">3.18.1. Syntax Description of CREATE VIEW</a></li>
<li><a href="#create_view_considerations">3.18.2. Considerations for CREATE VIEW</a></li>
<li><a href="#create_view_examples">3.18.3. Examples of CREATE VIEW</a></li>
</ul>
</li>
<li><a href="#delete_statement">3.19. DELETE Statement</a>
<ul class="sectlevel3">
<li><a href="#delete_syntax">3.19.1. Syntax Description of DELETE</a></li>
<li><a href="#delete_considerations">3.19.2. Considerations for DELETE</a></li>
<li><a href="#delete_examples">3.19.3. Examples of DELETE</a></li>
</ul>
</li>
<li><a href="#drop_function_statement">3.20. DROP FUNCTION Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_function_syntax">3.20.1. Syntax Description of DROP FUNCTION</a></li>
<li><a href="#drop_function_considerations">3.20.2. Considerations for DROP FUNCTION</a></li>
<li><a href="#drop_function_examples">3.20.3. Examples of DROP FUNCTION</a></li>
</ul>
</li>
<li><a href="#drop_index_statement">3.21. DROP INDEX Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_index_syntax">3.21.1. Syntax Description of DROP INDEX</a></li>
<li><a href="#drop_index_considerations">3.21.2. Considerations for DROP INDEX</a></li>
<li><a href="#drop_index_examples">3.21.3. Examples of DROP INDEX</a></li>
</ul>
</li>
<li><a href="#drop_library_statement">3.22. DROP LIBRARY Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_library_syntax">3.22.1. Syntax Description of DROP LIBRARY</a></li>
<li><a href="#drop_library_considerations">3.22.2. Considerations for DROP LIBRARY</a></li>
<li><a href="#drop_library_examples">3.22.3. Examples of DROP LIBRARY</a></li>
</ul>
</li>
<li><a href="#drop_procedure_statement">3.23. DROP PROCEDURE Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_procedure_syntax">3.23.1. Syntax Description of DROP PROCEDURE</a></li>
<li><a href="#drop_procedure_considerations">3.23.2. Considerations for DROP PROCEDURE</a></li>
<li><a href="#drop_procedure_examples">3.23.3. Examples of DROP PROCEDURE</a></li>
</ul>
</li>
<li><a href="#drop_role_statement">3.24. DROP ROLE Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_role_syntax">3.24.1. Syntax Description of DROP ROLE</a></li>
<li><a href="#drop_role_considerations">3.24.2. Considerations for DROP ROLE</a></li>
<li><a href="#drop_role_examples">3.24.3. Examples of DROP ROLE</a></li>
</ul>
</li>
<li><a href="#drop_schema_statement">3.25. DROP SCHEMA Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_schema_syntax">3.25.1. Syntax Description of DROP SCHEMA</a></li>
<li><a href="#drop_schema_considerations">3.25.2. Considerations for DROP SCHEMA</a></li>
<li><a href="#drop_schema_examples">3.25.3. Example of DROP SCHEMA</a></li>
</ul>
</li>
<li><a href="#drop_sequence_statement">3.26. DROP SEQUENCE Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_sequence_syntax">3.26.1. Syntax Description of DROP SEQUENCE</a></li>
<li><a href="#drop_sequence_considerations">3.26.2. Considerations for DROP SEQUENCE</a></li>
<li><a href="#drop_sequence_examples">3.26.3. Examples of DROP SEQUENCE</a></li>
</ul>
</li>
<li><a href="#drop_table_statement">3.27. DROP TABLE Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_table_syntax">3.27.1. Syntax Description of DROP TABLE</a></li>
<li><a href="#drop_table_considerations">3.27.2. Considerations for DROP TABLE</a></li>
<li><a href="#drop_table_examples">3.27.3. Examples of DROP TABLE</a></li>
</ul>
</li>
<li><a href="#drop_view_statement">3.28. DROP VIEW Statement</a>
<ul class="sectlevel3">
<li><a href="#drop_view_syntax">3.28.1. Syntax Description of DROP VIEW</a></li>
<li><a href="#drop_view_considerations">3.28.2. Considerations for DROP VIEW</a></li>
<li><a href="#drop_view_examples">3.28.3. Example of DROP VIEW</a></li>
</ul>
</li>
<li><a href="#execute_statement">3.29. Execute Statement</a>
<ul class="sectlevel3">
<li><a href="#execute_syntax">3.29.1. Syntax Description of EXECUTE</a></li>
<li><a href="#execute_considerations">3.29.2. Considerations for EXECUTE</a></li>
<li><a href="#execute_examples">3.29.3. Examples of EXECUTE</a></li>
</ul>
</li>
<li><a href="#explain_statement">3.30. EXPLAIN Statement</a>
<ul class="sectlevel3">
<li><a href="#explain_syntax">3.30.1. Syntax Description of EXPLAIN</a></li>
<li><a href="#explain_considerations">3.30.2. Considerations for EXPLAIN</a></li>
</ul>
</li>
<li><a href="#get_statement">3.31. GET Statement</a>
<ul class="sectlevel3">
<li><a href="#get_syntax">3.31.1. Syntax Description of GET</a></li>
<li><a href="#get_considerations">3.31.2. Considerations for GET</a></li>
<li><a href="#get_examples">3.31.3. Examples of GET</a></li>
</ul>
</li>
<li><a href="#get_hbase_objects_statement">3.32. GET HBASE OBJECTS Statement</a>
<ul class="sectlevel3">
<li><a href="#get_hbase_objects_syntax">3.32.1. Syntax Description of GET HBASE OBJECTS</a></li>
<li><a href="#get_hbase_objects_examples">3.32.2. Examples of GET HBASE OBJECTS</a></li>
</ul>
</li>
<li><a href="#get_version_of_metadata_statement">3.33. GET VERSION OF METADATA Statement</a>
<ul class="sectlevel3">
<li><a href="#get_version_of_metadata_considerations">3.33.1. Considerations for GET VERSION OF METADATA</a></li>
<li><a href="#get_version_of_metadata_examples">3.33.2. Examples of GET VERSION OF METADATA</a></li>
</ul>
</li>
<li><a href="#get_version_of_software_statement">3.34. GET VERSION OF SOFTWARE Statement</a>
<ul class="sectlevel3">
<li><a href="#get_version_of_software_considerations">3.34.1. Considerations for GET VERSION OF SOFTWARE</a></li>
<li><a href="#get_version_of_software_examples">3.34.2. Examples of GET VERSION OF SOFTWARE</a></li>
</ul>
</li>
<li><a href="#grant_statement">3.35. GRANT Statement</a>
<ul class="sectlevel3">
<li><a href="#_syntax_description_of_grant">3.35.1. syntax description of grant</a></li>
<li><a href="#grant_considerations">3.35.2. Considerations for GRANT</a></li>
<li><a href="#grant_examples">3.35.3. Examples of GRANT</a></li>
</ul>
</li>
<li><a href="#grant_component_privilege_statement">3.36. GRANT COMPONENT PRIVILEGE Statement</a>
<ul class="sectlevel3">
<li><a href="#grant_component_privilege_syntax">3.36.1. Syntax Description of GRANT COMPONENT PRIVILEGE</a></li>
<li><a href="#grant_component_privilege_considerations">3.36.2. Considerations for GRANT COMPONENT PRIVILEGE</a></li>
<li><a href="#grant_component_privilege_considerations">3.36.3. Examples of GRANT COMPONENT PRIVILEGE</a></li>
</ul>
</li>
<li><a href="#grant_role_statement">3.37. GRANT ROLE Statement</a>
<ul class="sectlevel3">
<li><a href="#grant_role_syntax">3.37.1. Syntax Description of GRANT ROLE</a></li>
<li><a href="#grant_role_considerations">3.37.2. Considerations for GRANT ROLE</a></li>
<li><a href="#grant_role_examples">3.37.3. Examples of GRANT ROLE</a></li>
</ul>
</li>
<li><a href="#insert_statement">3.38. INSERT Statement</a>
<ul class="sectlevel3">
<li><a href="#insert_syntax">3.38.1. Syntax Description of INSERT</a></li>
<li><a href="#insert_considerations">3.38.2. Considerations for INSERT</a></li>
<li><a href="#insert_examples">3.38.3. Examples of INSERT</a></li>
</ul>
</li>
<li><a href="#invoke_statement">3.39. INVOKE Statement</a>
<ul class="sectlevel3">
<li><a href="#invoke_syntax">3.39.1. Syntax Description of INVOKE</a></li>
<li><a href="#invoke_considerations">3.39.2. Considerations for INVOKE</a></li>
<li><a href="#invoke_required_privileges">3.39.3. Required Privileges</a></li>
<li><a href="#invoke_examples">3.39.4. Examples of INVOKE</a></li>
</ul>
</li>
<li><a href="#merge_statement">3.40. MERGE Statement</a>
<ul class="sectlevel3">
<li><a href="#merge_syntax">3.40.1. Syntax Description of MERGE</a></li>
<li><a href="#merge_considerations">3.40.2. Considerations for MERGE</a></li>
<li><a href="#merge_upsert_using_single_row">3.40.3. Upsert Using Single Row</a></li>
<li><a href="#merge_examples">3.40.4. Examples of MERGE</a></li>
</ul>
</li>
<li><a href="#prepare_statement">3.41. PREPARE Statement</a>
<ul class="sectlevel3">
<li><a href="#prepare_syntax">3.41.1. Syntax Description of PREPARE</a></li>
<li><a href="#prepare_considerations">3.41.2. Considerations for PREPARE</a></li>
<li><a href="#prepare_examples">3.41.3. Examples of PREPARE</a></li>
</ul>
</li>
<li><a href="#register_user_statement">3.42. REGISTER USER Statement</a>
<ul class="sectlevel3">
<li><a href="#register_user_syntax">3.42.1. Syntax Description of REGISTER USER</a></li>
<li><a href="#register_user_register_user_considerations">3.42.2. Considerations for REGISTER USER</a></li>
<li><a href="#register_user_examples">3.42.3. Examples of REGISTER USER</a></li>
</ul>
</li>
<li><a href="#_revoke_statement">3.43. REVOKE Statement</a>
<ul class="sectlevel3">
<li><a href="#_syntax_description_of_revoke">3.43.1. Syntax Description of REVOKE</a></li>
<li><a href="#revoke_considerations">3.43.2. Considerations for REVOKE</a></li>
<li><a href="#revoke_examples">3.43.3. Examples of REVOKE</a></li>
</ul>
</li>
<li><a href="#revoke_component_privilege_statement">3.44. REVOKE COMPONENT PRIVILEGE Statement</a>
<ul class="sectlevel3">
<li><a href="#_syntax_description_of_revoke_component_privilege">3.44.1. Syntax Description of REVOKE COMPONENT PRIVILEGE</a></li>
<li><a href="#revoke_component_privilege_considerations">3.44.2. Considerations for REVOKE COMPONENT PRIVILEGE</a></li>
<li><a href="#revoke_component_examples">3.44.3. Examples of REVOKE COMPONENT PRIVILEGE</a></li>
</ul>
</li>
<li><a href="#revoke_role_statement">3.45. REVOKE ROLE Statement</a>
<ul class="sectlevel3">
<li><a href="#revoke_role_syntax">3.45.1. Syntax Description of REVOKE ROLE</a></li>
<li><a href="#revoke_role_considerations">3.45.2. Considerations for REVOKE ROLE</a></li>
<li><a href="#revoke_role_examples">3.45.3. Examples of REVOKE ROLE</a></li>
</ul>
</li>
<li><a href="#rollback_work_statement">3.46. ROLLBACK WORK Statement</a>
<ul class="sectlevel3">
<li><a href="#rollback_work_syntax">3.46.1. Syntax Description of ROLLBACK WORK</a></li>
<li><a href="#rollback_work_considerations">3.46.2. Considerations for ROLLBACK WORK</a></li>
<li><a href="#rollback_work_examples">3.46.3. Example of ROLLBACK WORK</a></li>
</ul>
</li>
<li><a href="#select_statement">3.47. SELECT Statement</a>
<ul class="sectlevel3">
<li><a href="#select_syntax">3.47.1. Syntax Description of SELECT</a></li>
<li><a href="#select_considerations">3.47.2. Considerations for SELECT</a></li>
<li><a href="#select_examples">3.47.3. Examples of SELECT</a></li>
</ul>
</li>
<li><a href="#set_schema_statement">3.48. SET SCHEMA Statement</a>
<ul class="sectlevel3">
<li><a href="#set_schema_syntax">3.48.1. Syntax Description of SET SCHEMA</a></li>
<li><a href="#set_schema_considerations">3.48.2. Considerations for SET SCHEMA</a></li>
<li><a href="#set_schema_examples">3.48.3. Examples of SET SCHEMA</a></li>
</ul>
</li>
<li><a href="#set_transaction_statement">3.49. SET TRANSACTION Statement</a>
<ul class="sectlevel3">
<li><a href="#set_transaction_syntax">3.49.1. Syntax Description of SET TRANSACTION</a></li>
<li><a href="#set_transaction_consideration">3.49.2. Considerations for SET TRANSACTION</a></li>
<li><a href="#set_transaction_examples">3.49.3. Examples of SET TRANSACTION</a></li>
</ul>
</li>
<li><a href="#showcontrol_statement">3.50. SHOWCONTROL Statement</a>
<ul class="sectlevel3">
<li><a href="#showcontrol_syntax">3.50.1. Syntax Description of SHOWCONTROL</a></li>
<li><a href="#showcontrol_examples">3.50.2. Examples of SHOWCONTROL</a></li>
</ul>
</li>
<li><a href="#showddl_statement">3.51. SHOWDDL Statement</a>
<ul class="sectlevel3">
<li><a href="#showddl_syntax">3.51.1. Syntax Description of SHOWDDL</a></li>
<li><a href="#showddl_considerations">3.51.2. Considerations for SHOWDDL</a></li>
<li><a href="#showddl_examples">3.51.3. Examples of SHOWDDL</a></li>
</ul>
</li>
<li><a href="#showddl_schema_statement">3.52. SHOWDDL SCHEMA Statement</a>
<ul class="sectlevel3">
<li><a href="#showddl_schema_syntax">3.52.1. Syntax Description for SHOWDDL SCHEMA</a></li>
<li><a href="#showddl_schema_considerations">3.52.2. Considerations for SHOWDDL SCHEMA</a></li>
<li><a href="#showddl_schema_examples">3.52.3. Examples of SHOWDDL SCHEMA</a></li>
</ul>
</li>
<li><a href="#_showstats_statement">3.53. SHOWSTATS Statement</a>
<ul class="sectlevel3">
<li><a href="#showstats_syntax">3.53.1. Syntax Description of SHOWSTATS</a></li>
<li><a href="#showstats_considerations">3.53.2. Considerations for SHOWSTATS</a></li>
<li><a href="#showstats_examples">3.53.3. Examples of SHOWSTATS</a></li>
</ul>
</li>
<li><a href="#table_statement">3.54. TABLE Statement</a>
<ul class="sectlevel3">
<li><a href="#table_syntax">3.54.1. Syntax Description of Table Statement</a></li>
<li><a href="#_considerations_for_table">3.54.2. Considerations for TABLE</a></li>
<li><a href="#_examples_of_table_statement">3.54.3. Examples of TABLE Statement</a></li>
</ul>
</li>
<li><a href="#unregister_user_statement">3.55. UNREGISTER USER Statement</a>
<ul class="sectlevel3">
<li><a href="#unregister_user_syntax">3.55.1. Syntax Description of UNREGISTER USER</a></li>
<li><a href="#unregister_user_considerations">3.55.2. Considerations for UNREGISTER USER</a></li>
<li><a href="#unregister_user_examples">3.55.3. Examples of UNREGISTER USER</a></li>
</ul>
</li>
<li><a href="#update_statement">3.56. UPDATE Statement</a>
<ul class="sectlevel3">
<li><a href="#update_syntax">3.56.1. Syntax Description of UPDATE</a></li>
<li><a href="#update_considerations">3.56.2. Considerations for UPDATE</a></li>
<li><a href="#update_examples">3.56.3. Examples of UPDATE</a></li>
</ul>
</li>
<li><a href="#upsert_statement">3.57. UPSERT Statement</a>
<ul class="sectlevel3">
<li><a href="#upsert_syntax">3.57.1. Syntax Description of UPSERT</a></li>
<li><a href="#upsert_examples">3.57.2. Examples of UPSERT</a></li>
</ul>
</li>
<li><a href="#values_statement">3.58. VALUES Statement</a>
<ul class="sectlevel3">
<li><a href="#values_syntax">3.58.1. Syntax Description of VALUES</a></li>
<li><a href="#values_considerations">3.58.2. Considerations for VALUES</a></li>
<li><a href="#values_examples">3.58.3. Examples of VALUES</a></li>
</ul>
</li>
</ul>
</li>
<li><a href="#sql_utilities">4. SQL Utilities</a>
<ul class="sectlevel2">
<li><a href="#cleanup_statement">4.1. CLEANUP Statement</a>
<ul class="sectlevel3">
<li><a href="#cleanup_syntax">4.1.1. Syntax Description of CLEANUP Statement</a></li>
<li><a href="#cleanup_considerations">4.1.2. Considerations for CLEANUP Statement</a></li>
<li><a href="#cleanup_examples">4.1.3. Examples of CLEANUP Statement</a></li>
</ul>
</li>
<li><a href="#load_statement">4.2. LOAD Statement</a>
<ul class="sectlevel3">
<li><a href="#load_syntax">4.2.1. Syntax Description of LOAD</a></li>
<li><a href="#load_considerations">4.2.2. Considerations for LOAD</a></li>
<li><a href="#load_examples">4.2.3. Examples of LOAD</a></li>
</ul>
</li>
<li><a href="#populate_index_utility">4.3. POPULATE INDEX Utility</a>
<ul class="sectlevel3">
<li><a href="#populate_index_syntax">4.3.1. Syntax Description of POPULATE INDEX</a></li>
<li><a href="#populate_index_considerations">4.3.2. Considerations for POPULATE INDEX</a></li>
<li><a href="#populate_index_examples">4.3.3. Examples of POPULATE INDEX</a></li>
</ul>
</li>
<li><a href="#purgedata_utility">4.4. PURGEDATA Utility</a>
<ul class="sectlevel3">
<li><a href="#purgedata_syntax">4.4.1. Syntax Description of PURGEDATA</a></li>
<li><a href="#purgedata_considerations">4.4.2. Considerations for PURGEDATA</a></li>
<li><a href="#purgedata_examples">4.4.3. Examples of PURGEDATA</a></li>
</ul>
</li>
<li><a href="#unload_statement">4.5. UNLOAD Statement</a>
<ul class="sectlevel3">
<li><a href="#unload_syntax">4.5.1. Syntax Description of UNLOAD</a></li>
<li><a href="#unload_considerations">4.5.2. Considerations for UNLOAD</a></li>
<li><a href="#unload_examples">4.5.3. Examples of UNLOAD</a></li>
</ul>
</li>
<li><a href="#update_statistics_statement">4.6. UPDATE STATISTICS Statement</a>
<ul class="sectlevel3">
<li><a href="#update_statistics_syntax">4.6.1. Syntax Description of UPDATE STATISTICS</a></li>
<li><a href="#update_statistics_considerations">4.6.2. Considerations for UPDATE STATISTICS</a></li>
<li><a href="#update_statistics_examples">4.6.3. Examples of UPDATE STATISTICS</a></li>
</ul>
</li>
</ul>
</li>
<li><a href="#sql_language_elements">5. SQL Language Elements</a>
<ul class="sectlevel2">
<li><a href="#_authorization_ids">5.1. Authorization IDs</a></li>
<li><a href="#character_sets">5.2. Character Sets</a></li>
<li><a href="#columns">5.3. Columns</a>
<ul class="sectlevel3">
<li><a href="#column_references">5.3.1. Column References</a></li>
<li><a href="#derived_column_names">5.3.2. Derived Column Names</a></li>
<li><a href="#column_default_settings">5.3.3. Column Default Settings</a></li>
</ul>
</li>
<li><a href="#constraints">5.4. Constraints</a>
<ul class="sectlevel3">
<li><a href="#creating_or_adding_constraints_on_sql_tables">5.4.1. Creating or Adding Constraints on SQL Tables</a></li>
<li><a href="#constraint_names">5.4.2. Constraint Names</a></li>
</ul>
</li>
<li><a href="#correlation_names">5.5. Correlation Names</a>
<ul class="sectlevel3">
<li><a href="#explicit_correlation_names">5.5.1. Explicit Correlation Names</a></li>
<li><a href="#implicit_correlation_names">5.5.2. Implicit Correlation Names</a></li>
<li><a href="#examples_of_correlation_names">5.5.3. Examples of Correlation Names</a></li>
</ul>
</li>
<li><a href="#database_objects">5.6. Database Objects</a>
<ul class="sectlevel3">
<li><a href="#ownership">5.6.1. Ownership</a></li>
</ul>
</li>
<li><a href="#database_object_names">5.7. Database Object Names</a>
<ul class="sectlevel3">
<li><a href="#logical_names_for_sql_objects">5.7.1. Logical Names for SQL Objects</a></li>
<li><a href="#sql_object_namespaces">5.7.2. SQL Object Namespaces</a></li>
</ul>
</li>
<li><a href="#data_types">5.8. Data Types</a>
<ul class="sectlevel3">
<li><a href="#comparable_and_compatible_data_types">5.8.1. Comparable and Compatible Data Types</a></li>
<li><a href="#character_string_data_types">5.8.2. Character String Data Types</a></li>
<li><a href="#datetime_data_types">5.8.3. Datetime Data Types</a></li>
<li><a href="#interval_data_types">5.8.4. Interval Data Types</a></li>
<li><a href="#numeric_data_types">5.8.5. Numeric Data Types</a></li>
</ul>
</li>
<li><a href="#expressions">5.9. Expressions</a>
<ul class="sectlevel3">
<li><a href="#character_value_expressions">5.9.1. Character Value Expressions</a></li>
<li><a href="#datetime_value_expressions">5.9.2. Datetime Value Expressions</a></li>
<li><a href="#interval_value_expressions">5.9.3. Interval Value Expressions</a></li>
<li><a href="#numeric_value_expressions">5.9.4. Numeric Value Expressions</a></li>
</ul>
</li>
<li><a href="#identifiers">5.10. Identifiers</a>
<ul class="sectlevel3">
<li><a href="#regular_identifiers">5.10.1. Regular Identifiers</a></li>
<li><a href="#delimited_identifiers">5.10.2. Delimited Identifiers</a></li>
<li><a href="#case_insensitive_delimited_identifiers">5.10.3. Case-Insensitive Delimited Identifiers</a></li>
<li><a href="#examples_of_identifiers">5.10.4. Examples of Identifiers</a></li>
</ul>
</li>
<li><a href="#identity_column">5.11. Identity Column</a>
<ul class="sectlevel3">
<li><a href="#syntax_description_of_identity_column">5.11.1. Syntax Description of Identity Column</a></li>
<li><a href="#examples_of_identity_column">5.11.2. Examples of Identity Column</a></li>
</ul>
</li>
<li><a href="#indexes">5.12. Indexes</a>
<ul class="sectlevel3">
<li><a href="#sql_indexes">5.12.1. SQL Indexes</a></li>
</ul>
</li>
<li><a href="#keys">5.13. Keys</a>
<ul class="sectlevel3">
<li><a href="#clustering_keys">5.13.1. Clustering Keys</a></li>
<li><a href="#syskey">5.13.2. SYSKEY</a></li>
<li><a href="#index_keys">5.13.3. Index Keys</a></li>
<li><a href="#primary_keys">5.13.4. Primary Keys</a></li>
</ul>
</li>
<li><a href="#literals">5.14. Literals</a>
<ul class="sectlevel3">
<li><a href="#character_string_literals">5.14.1. Character String Literals</a></li>
<li><a href="#datetime_literals">5.14.2. Datetime Literals</a></li>
<li><a href="#interval_literals">5.14.3. Interval Literals</a></li>
<li><a href="#numeric_literals">5.14.4. Numeric Literals</a></li>
</ul>
</li>
<li><a href="#null">5.15. Null</a>
<ul class="sectlevel3">
<li><a href="#using_null_versus_default_values">5.15.1. Using Null Versus Default Values</a></li>
<li><a href="#defining_columns_that_allow_or_prohibit_null">5.15.2. Defining Columns That Allow or Prohibit Null</a></li>
</ul>
</li>
<li><a href="#predicates">5.16. Predicates</a>
<ul class="sectlevel3">
<li><a href="#between_predicate">5.16.1. BETWEEN Predicate</a></li>
<li><a href="#comparison_predicates">5.16.2. Comparison Predicates</a></li>
<li><a href="#exists_predicate">5.16.3. EXISTS Predicate</a></li>
<li><a href="#in_predicate">5.16.4. IN Predicate</a></li>
<li><a href="#like_predicate">5.16.5. LIKE Predicate</a></li>
<li><a href="#regexp_predicate">5.16.6. REGEXP Predicate</a></li>
<li><a href="#null_predicate">5.16.7. NULL Predicate</a></li>
<li><a href="#quantified_comparison_predicates">5.16.8. Quantified Comparison Predicates</a></li>
</ul>
</li>
<li><a href="#privileges">5.17. Privileges</a></li>
<li><a href="#roles">5.18. Roles</a></li>
<li><a href="#schemas">5.19. Schemas</a>
<ul class="sectlevel3">
<li><a href="#creating_and_dropping_schemas">5.19.1. Creating and Dropping Schemas</a></li>
</ul>
</li>
<li><a href="#search_condition">5.20. Search Condition</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_search_condition">5.20.1. Considerations for Search Condition</a></li>
<li><a href="#examples_of_search_condition">5.20.2. Examples of Search Condition</a></li>
</ul>
</li>
<li><a href="#subquery">5.21. Subquery</a>
<ul class="sectlevel3">
<li><a href="#select_form_of_a_subquery">5.21.1. SELECT Form of a Subquery</a></li>
<li><a href="#using_subqueries_to_provide_comparison_values">5.21.2. Using Subqueries to Provide Comparison Values</a></li>
<li><a href="#nested_subqueries_when_providing_comparison_values">5.21.3. Nested Subqueries When Providing Comparison Values</a></li>
<li><a href="#correlated_subqueries_when_providing_comparison_values">5.21.4. Correlated Subqueries When Providing Comparison Values</a></li>
</ul>
</li>
<li><a href="#tables">5.22. Tables</a>
<ul class="sectlevel3">
<li><a href="#base_tables_and_views">5.22.1. Base Tables and Views</a></li>
<li><a href="#example_of_a_base_table">5.22.2. Example of a Base Table</a></li>
</ul>
</li>
<li><a href="#views">5.23. Views</a>
<ul class="sectlevel3">
<li><a href="#sql_views">5.23.1. SQL Views</a></li>
<li><a href="#example_of_a_view">5.23.2. Example of a View</a></li>
</ul>
</li>
</ul>
</li>
<li><a href="#sql_clauses">6. SQL Clauses</a>
<ul class="sectlevel2">
<li><a href="#default_clause">6.1. DEFAULT Clause</a>
<ul class="sectlevel3">
<li><a href="#syntax_for_default_clause">6.1.1. Syntax for Default Clause</a></li>
<li><a href="#examples_of_default">6.1.2. Examples of DEFAULT</a></li>
</ul>
</li>
<li><a href="#format_clause">6.2. FORMAT Clause</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_date_formats">6.2.1. Considerations for Date Formats</a></li>
<li><a href="#examples_of_format">6.2.2. Examples of FORMAT</a></li>
</ul>
</li>
<li><a href="#sample_clause">6.3. SAMPLE Clause</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_sample">6.3.1. Considerations for SAMPLE</a></li>
<li><a href="#examples_of_sample">6.3.2. Examples of SAMPLE</a></li>
</ul>
</li>
<li><a href="#sequence_by_clause">6.4. SEQUENCE BY Clause</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_sequence_by">6.4.1. Considerations for SEQUENCE BY</a></li>
<li><a href="#examples_of_sequence_by">6.4.2. Examples of SEQUENCE BY</a></li>
</ul>
</li>
<li><a href="#transpose_clause">6.5. TRANSPOSE Clause</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_transpose">6.5.1. Considerations for TRANSPOSE</a></li>
<li><a href="#examples_of_transpose">6.5.2. Examples of TRANSPOSE</a></li>
</ul>
</li>
</ul>
</li>
<li><a href="#sql_functions_and_expressions">7. SQL Functions and Expressions</a>
<ul class="sectlevel2">
<li><a href="#standard_normalization">7.1. Standard Normalization</a></li>
<li><a href="#_aggregate_set_functions">7.2. Aggregate (Set) Functions</a></li>
<li><a href="#character_string_functions">7.3. Character String Functions</a></li>
<li><a href="#datetime_functions">7.4. Datetime Functions</a></li>
<li><a href="#mathematical_functions">7.5. Mathematical Functions</a></li>
<li><a href="#sequence_functions">7.6. Sequence Functions</a>
<ul class="sectlevel3">
<li><a href="#difference_sequence_functions">7.6.1. Difference sequence functions</a></li>
<li><a href="#moving_sequence_functions">7.6.2. Moving sequence functions</a></li>
<li><a href="#running_sequence_functions">7.6.3. Running sequence functions</a></li>
<li><a href="#other_sequence_functions">7.6.4. Other sequence functions</a></li>
</ul>
</li>
<li><a href="#other_functions_and_expressions">7.7. Other Functions and Expressions</a></li>
<li><a href="#abs_function">7.8. ABS Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_abs">7.8.1. Examples of ABS</a></li>
</ul>
</li>
<li><a href="#acos_function">7.9. ACOS Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_acos">7.9.1. Examples of ACOS</a></li>
<li><a href="#add_months_function">7.9.2. ADD_MONTHS Function</a></li>
<li><a href="#examples_of_add_months">7.9.3. Examples of ADD_MONTHS</a></li>
</ul>
</li>
<li><a href="#ascii_function">7.10. ASCII Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_ascii">7.10.1. Considerations For ASCII</a></li>
<li><a href="#examples_of_ascii">7.10.2. Examples of ASCII</a></li>
</ul>
</li>
<li><a href="#asin_function">7.11. ASIN Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_ascii">7.11.1. Considerations for ASCII</a></li>
<li><a href="#examples_of_ascii">7.11.2. Examples of ASCII</a></li>
</ul>
</li>
<li><a href="#asin_function">7.12. ASIN Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_asin">7.12.1. Examples of ASIN</a></li>
</ul>
</li>
<li><a href="#atan_function">7.13. ATAN Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_atan">7.13.1. Examples of ATAN</a></li>
</ul>
</li>
<li><a href="#atan2_function">7.14. ATAN2 Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_atan2">7.14.1. Examples of ATAN2</a></li>
</ul>
</li>
<li><a href="#authname_function">7.15. AUTHNAME Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_authname">7.15.1. Considerations for AUTHNAME</a></li>
<li><a href="#examples_of_authname">7.15.2. Examples of AUTHNAME</a></li>
</ul>
</li>
<li><a href="#avg_function">7.16. AVG Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_avg">7.16.1. Considerations for AVG</a></li>
</ul>
</li>
<li><a href="#bitand_function">7.17. BITAND Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_bitand">7.17.1. Considerations for BITAND</a></li>
<li><a href="#examples_of_bitand">7.17.2. Examples of BITAND</a></li>
</ul>
</li>
<li><a href="#case_expression">7.18. CASE (Conditional) Expression</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_case">7.18.1. Considerations for CASE</a></li>
<li><a href="#examples_of_case">7.18.2. Examples of CASE</a></li>
</ul>
</li>
<li><a href="#cast_expression">7.19. CAST Expression</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_cast">7.19.1. Considerations for CAST</a></li>
<li><a href="#examples_of_cast">7.19.2. Examples of CAST</a></li>
</ul>
</li>
<li><a href="#ceiling_function">7.20. CEILING Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_ceiling">7.20.1. Examples of CEILING</a></li>
<li><a href="#char_function">7.20.2. CHAR Function</a></li>
<li><a href="#considerations_for_char">7.20.3. Considerations for CHAR</a></li>
<li><a href="#examples_of_char">7.20.4. Examples of CHAR</a></li>
</ul>
</li>
<li><a href="#char_length_function">7.21. CHAR_LENGTH Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_char_length">7.21.1. Considerations for CHAR_LENGTH</a></li>
<li><a href="#examples_of_char_length">7.21.2. Examples of CHAR_LENGTH</a></li>
</ul>
</li>
<li><a href="#coalesce_function">7.22. COALESCE Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_coalesce">7.22.1. Examples of COALESCE</a></li>
</ul>
</li>
<li><a href="#code_value_function">7.23. CODE_VALUE Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_code_value_function">7.23.1. Examples of CODE_VALUE Function</a></li>
<li><a href="#concat_function">7.23.2. CONCAT Function</a></li>
<li><a href="#concatenation_operator">7.23.3. Concatenation Operator (||)</a></li>
<li><a href="#considerations_for_concat">7.23.4. Considerations for CONCAT</a></li>
<li><a href="#operands">7.23.5. Operands</a></li>
<li><a href="#sql-parameters">7.23.6. SQL Parameters</a></li>
<li><a href="#examples_of_concat">7.23.7. Examples of CONCAT</a></li>
</ul>
</li>
<li><a href="#converttohex_function">7.24. CONVERTTOHEX Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_converttohex">7.24.1. Considerations for CONVERTTOHEX</a></li>
<li><a href="#examples_of_converttohex">7.24.2. Examples of CONVERTTOHEX</a></li>
</ul>
</li>
<li><a href="#converttimestamp_function">7.25. CONVERTTIMESTAMP Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_converttimestamp">7.25.1. Considerations for CONVERTTIMESTAMP</a></li>
<li><a href="#examples_of_converttimestamp">7.25.2. Examples of CONVERTTIMESTAMP</a></li>
</ul>
</li>
<li><a href="#cos_function">7.26. COS Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_cos">7.26.1. Examples of COS</a></li>
<li><a href="#cosh_function">7.26.2. COSH Function</a></li>
<li><a href="#examples_of_cosh">7.26.3. Examples of COSH</a></li>
<li><a href="#count_function">7.26.4. COUNT Function</a></li>
<li><a href="#considerations_for_count">7.26.5. Considerations for COUNT</a></li>
<li><a href="#examples_of_count">7.26.6. Examples of COUNT</a></li>
<li><a href="#examples_of_crc32">7.26.7. examples of CR32</a></li>
</ul>
</li>
<li><a href="#current_function">7.27. CURRENT Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_current">7.27.1. Examples of CURRENT</a></li>
</ul>
</li>
<li><a href="#current_date_function">7.28. CURRENT_DATE Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_current_date">7.28.1. Examples of CURRENT_DATE</a></li>
</ul>
</li>
<li><a href="#current_time_function">7.29. CURRENT_TIME Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_current_time">7.29.1. Examples of CURRENT_TIME</a></li>
</ul>
</li>
<li><a href="#current_timestamp_function">7.30. CURRENT_TIMESTAMP Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_current_timestamp">7.30.1. Examples of CURRENT_TIMESTAMP</a></li>
</ul>
</li>
<li><a href="#current_user_function">7.31. CURRENT_USER Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_current_user">7.31.1. Considerations for CURRENT_USER</a></li>
<li><a href="#examples_of_current_user">7.31.2. Examples of CURRENT_USER</a></li>
</ul>
</li>
<li><a href="#date_add_function">7.32. DATE_ADD Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_date_add">7.32.1. Examples of DATE_ADD</a></li>
</ul>
</li>
<li><a href="#date_sub_function">7.33. DATE_SUB Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_date_sub">7.33.1. Examples of DATE_SUB</a></li>
</ul>
</li>
<li><a href="#dateadd_function">7.34. DATEADD Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_dateadd">7.34.1. Examples of DATEADD</a></li>
</ul>
</li>
<li><a href="#datediff_function">7.35. DATEDIFF Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_datediff">7.35.1. Examples of DATEDIFF</a></li>
<li><a href="#dateformat_function">7.35.2. DATEFORMAT Function</a></li>
<li><a href="#considerations_for_dateformat">7.35.3. Considerations for DATEFORMAT</a></li>
<li><a href="#examples_of_dateformat">7.35.4. Examples of DATEFORMAT</a></li>
</ul>
</li>
<li><a href="#date_part_function_of_an_interval">7.36. DATE_PART Function (of an Interval)</a>
<ul class="sectlevel3">
<li><a href="#examples_of_date_part">7.36.1. Examples of DATE_PART</a></li>
</ul>
</li>
<li><a href="#date_part_function_of_a_timestamp">7.37. DATE_PART Function (of a Timestamp)</a>
<ul class="sectlevel3">
<li><a href="#examples_of_date_part">7.37.1. Examples of DATE_PART</a></li>
</ul>
</li>
<li><a href="#date_trunc_function">7.38. DATE_TRUNC Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_date_trunc">7.38.1. Examples of DATE_TRUNC</a></li>
</ul>
</li>
<li><a href="#day_function">7.39. DAY Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_day">7.39.1. Examples of Day</a></li>
</ul>
</li>
<li><a href="#dayname_function">7.40. DAYNAME Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_dayname">7.40.1. Considerations for DAYNAME</a></li>
<li><a href="#examples_of_dayname">7.40.2. Examples of DAYNAME</a></li>
</ul>
</li>
<li><a href="#dayofmonth_function">7.41. DAYOFMONTH Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_dayofmonth">7.41.1. Examples of DAYOFMONTH</a></li>
</ul>
</li>
<li><a href="#dayofweek_function">7.42. DAYOFWEEK Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_dayofweek">7.42.1. Examples of DAYOFWEEK</a></li>
</ul>
</li>
<li><a href="#dayofyear_function">7.43. DAYOFYEAR Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_dayofyear">7.43.1. Examples of DAYOFYEAR</a></li>
</ul>
</li>
<li><a href="#Decode_function">7.44. DECODE Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_decode">7.44.1. Considerations for DECODE</a></li>
<li><a href="#_examples_of_decode">7.44.2. Examples of DECODE</a></li>
</ul>
</li>
<li><a href="#degrees_function">7.45. DEGREES Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_degrees">7.45.1. Examples of Degrees</a></li>
</ul>
</li>
<li><a href="#diff1_function">7.46. DIFF1 Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_diff1">7.46.1. Considerations for DIFF1</a></li>
<li><a href="#examples_of_diff1">7.46.2. Examples of DIFF1</a></li>
</ul>
</li>
<li><a href="#diff2_function">7.47. DIFF2 Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_diff2">7.47.1. Considerations for DIFF2</a></li>
<li><a href="#examples_of_diff2">7.47.2. Examples of DIFF2</a></li>
</ul>
</li>
<li><a href="#exp_function">7.48. EXP Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_exp">7.48.1. Examples of EXP</a></li>
</ul>
</li>
<li><a href="#explain_function">7.49. EXPLAIN Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_explain_function">7.49.1. Considerations for EXPLAIN Function</a></li>
<li><a href="#examples_of_explain_function">7.49.2. Examples of EXPLAIN Function</a></li>
</ul>
</li>
<li><a href="#extract_function">7.50. EXTRACT Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_extract">7.50.1. Examples of EXTRACT</a></li>
<li><a href="#hour_function">7.50.2. HOUR Function</a></li>
<li><a href="#examples_of_hour">7.50.3. Examples of HOUR</a></li>
</ul>
</li>
<li><a href="#group_concat_function">7.51. GROUP_CONCAT Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_group_concat">7.51.1. Examples of GROUP_CONCAT</a></li>
</ul>
</li>
<li><a href="#insert_function">7.52. INSERT Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_insert">7.52.1. Examples of INSERT</a></li>
</ul>
</li>
<li><a href="#is_ipv4_function">7.53. IS_IPV4 Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_is_ipv4">7.53.1. Examples of IS_IPV4</a></li>
</ul>
</li>
<li><a href="#is_ipv6_function">7.54. IS_IPV6 Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_is_ipv6">7.54.1. Examples of IS_IPV6</a></li>
</ul>
</li>
<li><a href="#isnull_function">7.55. ISNULL Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_isnull">7.55.1. Examples of ISNULL</a></li>
</ul>
</li>
<li><a href="#juliantimestamp_function">7.56. JULIANTIMESTAMP Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_juliantimestamp">7.56.1. Considerations for JULIANTIMESTAMP</a></li>
<li><a href="#examples_of_juliantimestamp">7.56.2. Examples of JULIANTIMESTAMP</a></li>
</ul>
</li>
<li><a href="#lastnotnull_function">7.57. LASTNOTNULL Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_lastnotnull">7.57.1. Examples of LASTNOTNULL</a></li>
</ul>
</li>
<li><a href="#lcase_function">7.58. LCASE Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_lcase">7.58.1. Examples of LCASE</a></li>
<li><a href="#left_function">7.58.2. LEFT Function</a></li>
<li><a href="#examples_of_left">7.58.3. Examples of LEFT</a></li>
</ul>
</li>
<li><a href="#locate_function">7.59. LOCATE Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_locate">7.59.1. Considerations for LOCATE</a></li>
<li><a href="#examples_of_locate">7.59.2. Examples of LOCATE</a></li>
</ul>
</li>
<li><a href="#log_function">7.60. LOG Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_log">7.60.1. Examples of LOG</a></li>
<li><a href="#log10_function">7.60.2. LOG10 Function</a></li>
<li><a href="#examples_of_log10">7.60.3. Examples of LOG10</a></li>
</ul>
</li>
<li><a href="#lower_function">7.61. LOWER Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_lower">7.61.1. Considerations for LOWER</a></li>
<li><a href="#examples_of_lower">7.61.2. Examples of LOWER</a></li>
<li><a href="#lpad_function">7.61.3. LPAD Function</a></li>
<li><a href="#examples_of_lpad">7.61.4. Examples of LPAD</a></li>
</ul>
</li>
<li><a href="#ltrim_function">7.62. LTRIM Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_ltrim">7.62.1. Considerations for LTRIM</a></li>
<li><a href="#examples_of_ltrim">7.62.2. Examples of LTRIM</a></li>
</ul>
</li>
<li><a href="#max_function">7.63. MAX/MAXIMUM Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_max">7.63.1. Considerations for MAX/MAXIMUM</a></li>
<li><a href="#operands_of_the_expression">7.63.2. Operands of the Expression</a></li>
<li><a href="#examples_of_max">7.63.3. Examples of MAX/MAXIMUM</a></li>
</ul>
</li>
<li><a href="#md5_function">7.64. MD5 Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_md5">7.64.1. Examples of MD5</a></li>
</ul>
</li>
<li><a href="#min_function">7.65. MIN Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_min">7.65.1. Considerations for MIN</a></li>
<li><a href="#examples_of_min">7.65.2. Examples of MIN</a></li>
</ul>
</li>
<li><a href="#minute_function">7.66. MINUTE Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_minute">7.66.1. Examples of minute</a></li>
</ul>
</li>
<li><a href="#mod_function">7.67. MOD Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_mod">7.67.1. Examples of MOD</a></li>
</ul>
</li>
<li><a href="#month_function">7.68. MONTH Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_month">7.68.1. Examples of MONTH</a></li>
</ul>
</li>
<li><a href="#monthname_function">7.69. MONTHNAME Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_monthname">7.69.1. Considerations for MONTHNAME</a></li>
<li><a href="#examples_of_monthname">7.69.2. Examples of MONTHNAME</a></li>
</ul>
</li>
<li><a href="#movingavg_function">7.70. MOVINGAVG Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_movingavg">7.70.1. Examples of MOVINGAVG</a></li>
</ul>
</li>
<li><a href="#movingcount_function">7.71. MOVINGCOUNT Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_movingcount">7.71.1. Considerations for MOVINGCOUNT</a></li>
<li><a href="#examples_of_movingcount">7.71.2. Examples of MOVINGCOUNT</a></li>
</ul>
</li>
<li><a href="#movingmax_function">7.72. MOVINGMAX Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_movingmax">7.72.1. Examples of MOVINGMAX</a></li>
</ul>
</li>
<li><a href="#movingmin_function">7.73. MOVINGMIN Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_movingmin">7.73.1. Examples of MOVINGMIN</a></li>
</ul>
</li>
<li><a href="#movingstddev_function">7.74. MOVINGSTDDEV Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_movingstddev">7.74.1. Examples of MOVINGSTDDEV</a></li>
</ul>
</li>
<li><a href="#movingsum_function">7.75. MOVINGSUM Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_movingsum">7.75.1. Examples of MOVINGSUM</a></li>
</ul>
</li>
<li><a href="#movingvariance_function">7.76. MOVINGVARIANCE Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_movingvariance">7.76.1. Examples of MOVINGVARIANCE</a></li>
<li><a href="#nullif_function">7.76.2. NULLIF Function</a></li>
<li><a href="#examples_of_nullif">7.76.3. Examples of NULLIF</a></li>
</ul>
</li>
<li><a href="#nullifzero_function">7.77. NULLIFZERO Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_nullifzero">7.77.1. Examples of NULLIFZERO</a></li>
</ul>
</li>
<li><a href="#nvl_function">7.78. NVL Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_nvl">7.78.1. Examples of NVL</a></li>
</ul>
</li>
<li><a href="#octet_length_function">7.79. OCTET_LENGTH Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_octet_length">7.79.1. Considerations for OCTET_LENGTH</a></li>
<li><a href="#offset_function">7.79.2. OFFSET Function</a></li>
<li><a href="#examples_of_offset">7.79.3. Examples of OFFSET</a></li>
</ul>
</li>
<li><a href="#pi_function">7.80. PI Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_pi">7.80.1. Examples of PI</a></li>
</ul>
</li>
<li><a href="#position_function">7.81. POSITION Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_position">7.81.1. Considerations for POSITION</a></li>
<li><a href="#examples_of_position">7.81.2. Examples of POSITION</a></li>
</ul>
</li>
<li><a href="#power_function">7.82. POWER Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_power">7.82.1. Examples of POWER</a></li>
</ul>
</li>
<li><a href="#quarter_function">7.83. QUARTER Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_quarter">7.83.1. Examples of QUARTER</a></li>
</ul>
</li>
<li><a href="#radians_function">7.84. RADIANS Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_radians">7.84.1. Examples of RADIANS</a></li>
</ul>
</li>
<li><a href="#runningrank_function">7.85. RANK/RUNNINGRANK Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_runningrank">7.85.1. Considerations for RANK/RUNNINGRANK</a></li>
<li><a href="#examples_of_runningrank">7.85.2. Examples of RANK/RUNNINGRANK</a></li>
</ul>
</li>
<li><a href="#repeat_function">7.86. REPEAT Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_repeat">7.86.1. Examples of REPEAT</a></li>
</ul>
</li>
<li><a href="#replace_function">7.87. REPLACE Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_replace">7.87.1. Examples of REPLACE</a></li>
</ul>
</li>
<li><a href="#right_function">7.88. RIGHT Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_right">7.88.1. Examples of RIGHT</a></li>
</ul>
</li>
<li><a href="#round_function">7.89. ROUND Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_round">7.89.1. Examples of ROUND</a></li>
</ul>
</li>
<li><a href="#rows_since_function">7.90. ROWS SINCE Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_rows_since">7.90.1. Considerations for ROWS SINCE</a></li>
<li><a href="#examples_of_rows_since">7.90.2. Examples of ROWS SINCE</a></li>
</ul>
</li>
<li><a href="#rows_since_changed_function">7.91. ROWS SINCE CHANGED Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_rows_since_changed">7.91.1. Considerations for ROWS SINCE CHANGED</a></li>
<li><a href="#examples_of_rows_since_changed">7.91.2. Examples of ROWS SINCE CHANGED</a></li>
</ul>
</li>
<li><a href="#rpad_function">7.92. RPAD Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_rpad_function">7.92.1. Examples of RPAD Function</a></li>
</ul>
</li>
<li><a href="#rtrim_function">7.93. RTRIM Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_rtrim">7.93.1. Considerations for RTRIM</a></li>
<li><a href="#examples_of_rtrim">7.93.2. Examples of RTRIM</a></li>
</ul>
</li>
<li><a href="#runningavg_function">7.94. RUNNINGAVG Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_runningavg">7.94.1. Considerations for RUNNINGAVG</a></li>
<li><a href="#examples_of_runningavg">7.94.2. Examples of RUNNINGAVG</a></li>
</ul>
</li>
<li><a href="#runningcount_function">7.95. RUNNINGCOUNT Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_runningcount">7.95.1. Considerations for RUNNINGCOUNT</a></li>
<li><a href="#examples_of_runningcount">7.95.2. Examples of RUNNINGCOUNT</a></li>
</ul>
</li>
<li><a href="#runningmax_function">7.96. RUNNINGMAX Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_runningmax">7.96.1. Examples of RUNNINGMAX</a></li>
</ul>
</li>
<li><a href="#runningmin_function">7.97. RUNNINGMIN Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_runningmin">7.97.1. Examples of RUNNINGMIN</a></li>
<li><a href="#runningstddev_function">7.97.2. RUNNINGSTDDEV Function</a></li>
<li><a href="#considerations_for_runningstddev">7.97.3. Considerations for RUNNINGSTDDEV</a></li>
<li><a href="#examples_of_runningstddev">7.97.4. Examples of RUNNINGSTDDEV</a></li>
</ul>
</li>
<li><a href="#runningsum_function">7.98. RUNNINGSUM Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_runningsum">7.98.1. Examples of RUNNINGSUM</a></li>
</ul>
</li>
<li><a href="#runningvariance_function">7.99. RUNNINGVARIANCE Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_runningvariance">7.99.1. Examples of RUNNINGVARIANCE</a></li>
</ul>
</li>
<li><a href="#second_function">7.100. SECOND Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_second">7.100.1. Examples of SECOND</a></li>
</ul>
</li>
<li><a href="#sha_function">7.101. SHA Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_sha">7.101.1. examples of SHA</a></li>
</ul>
</li>
<li><a href="#sha2_function">7.102. SHA2 Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_sha2">7.102.1. examples of SHA2</a></li>
</ul>
</li>
<li><a href="#sign_function">7.103. SIGN Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_sign">7.103.1. Examples of SIGN</a></li>
</ul>
</li>
<li><a href="#sin_function">7.104. SIN Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_sin">7.104.1. Examples of SIN</a></li>
</ul>
</li>
<li><a href="#sinh_function">7.105. SINH Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_sinh">7.105.1. Examples of SINH</a></li>
<li><a href="#space_function">7.105.2. SPACE Function</a></li>
<li><a href="#examples_of_space">7.105.3. Examples of SPACE</a></li>
</ul>
</li>
<li><a href="#sqrt_function">7.106. SQRT Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_sqrt">7.106.1. Examples of SQRT</a></li>
</ul>
</li>
<li><a href="#stddev_function">7.107. STDDEV Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_stddev">7.107.1. Considerations for STDDEV</a></li>
<li><a href="#examples_of_stddev">7.107.2. Examples of STDDEV</a></li>
</ul>
</li>
<li><a href="#substring_function">7.108. SUBSTRING/SUBSTR Function</a>
<ul class="sectlevel3">
<li><a href="#alternative_forms">7.108.1. Alternative Forms</a></li>
<li><a href="#considerations_for_substring">7.108.2. Considerations for SUBSTRING/SUBSTR</a></li>
<li><a href="#examples_of_substring">7.108.3. Examples of SUBSTRING/SUBSTR</a></li>
</ul>
</li>
<li><a href="#sum_function">7.109. SUM Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_sum">7.109.1. Considerations for SUM</a></li>
<li><a href="#examples_of_sum">7.109.2. Examples of SUM</a></li>
</ul>
</li>
<li><a href="#tan_function">7.110. TAN Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_tan">7.110.1. Examples of TAN</a></li>
<li><a href="#tanh_function">7.110.2. TANH Function</a></li>
<li><a href="#examples_of_tanh">7.110.3. Examples of TANH</a></li>
</ul>
</li>
<li><a href="#this_function">7.111. THIS Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_this">7.111.1. Considerations for THIS</a></li>
<li><a href="#examples_of_this">7.111.2. Examples of THIS</a></li>
</ul>
</li>
<li><a href="#timestampadd_function">7.112. TIMESTAMPADD Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_timestampadd">7.112.1. Examples of TIMESTAMPADD</a></li>
</ul>
</li>
<li><a href="#timestampdiff_function">7.113. TIMESTAMPDIFF Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_timestampdiff">7.113.1. Examples of TIMESTAMPDIFF</a></li>
</ul>
</li>
<li><a href="#to_char_function">7.114. TO_CHAR Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_to_char">7.114.1. Considerations for TO_CHAR</a></li>
<li><a href="#examples_of_to_char">7.114.2. Examples of TO_CHAR</a></li>
</ul>
</li>
<li><a href="#to_date_function">7.115. TO_DATE Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_to_date">7.115.1. Considerations for TO_DATE</a></li>
<li><a href="#examples_of_to_date">7.115.2. Examples of TO_DATE</a></li>
</ul>
</li>
<li><a href="#to_time_function">7.116. TO_TIME Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_to_time">7.116.1. Examples of TO_TIME</a></li>
</ul>
</li>
<li><a href="#to_timestamp_function">7.117. TO_TIMESTAMP Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_to_timestamp">7.117.1. Example of TO_TIMESTAMP</a></li>
</ul>
</li>
<li><a href="#translate_function">7.118. TRANSLATE Function</a></li>
<li><a href="#trim_function">7.119. TRIM Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_trim">7.119.1. Considerations for TRIM</a></li>
<li><a href="#examples_of_trim">7.119.2. Examples of TRIM</a></li>
</ul>
</li>
<li><a href="#ucase_function">7.120. UCASE Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_ucase">7.120.1. Considerations for UCASE</a></li>
<li><a href="#examples_of_ucase">7.120.2. Examples of UCASE</a></li>
<li><a href="#upper_function">7.120.3. UPPER Function</a></li>
<li><a href="#examples_of_upper">7.120.4. Examples of UPPER</a></li>
<li><a href="#upshift_function">7.120.5. UPSHIFT Function</a></li>
<li><a href="#examples_of_upshift">7.120.6. Examples of UPSHIFT</a></li>
</ul>
</li>
<li><a href="#user_function">7.121. USER Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_user">7.121.1. Considerations for USER</a></li>
<li><a href="#examples_of_user">7.121.2. Examples of USER</a></li>
</ul>
</li>
<li><a href="#variance_function">7.122. VARIANCE Function</a>
<ul class="sectlevel3">
<li><a href="#considerations_for_variance">7.122.1. Considerations for VARIANCE</a></li>
<li><a href="#examples_of_variance">7.122.2. Examples of VARIANCE</a></li>
</ul>
</li>
<li><a href="#week_function">7.123. WEEK Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_week">7.123.1. Examples of WEEK</a></li>
</ul>
</li>
<li><a href="#year_function">7.124. YEAR Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_year">7.124.1. Examples of YEAR</a></li>
</ul>
</li>
<li><a href="#zeroifnull_function">7.125. ZEROIFNULL Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_zeroifnull">7.125.1. Examples of ZEROIFNULL</a></li>
</ul>
</li>
</ul>
</li>
<li><a href="#olap_functions">8. OLAP Functions</a>
<ul class="sectlevel2">
<li><a href="#considerations_for_window_functions">8.1. Considerations for Window Functions</a>
<ul class="sectlevel3">
<li><a href="#_nulls">8.1.1. Nulls</a></li>
</ul>
</li>
<li><a href="#order_by_clause_supports_expressions_for_olap_functions">8.2. ORDER BY Clause Supports Expressions For OLAP Functions</a></li>
<li><a href="#limitations_for_window_functions">8.3. Limitations for Window Functions</a></li>
<li><a href="#avg_window_function">8.4. AVG Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_avg_window_function">8.4.1. Examples of AVG Window Function</a></li>
</ul>
</li>
<li><a href="#count_window_function">8.5. COUNT Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_count_window_function">8.5.1. Examples of COUNT Window Function</a></li>
</ul>
</li>
<li><a href="#dense_rank_window_function">8.6. DENSE_RANK Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_dense_rank_window_function">8.6.1. Examples of DENSE_RANK Window Function</a></li>
</ul>
</li>
<li><a href="#first_value_window_function">8.7. FIRST_VALUE Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_first_value_window_function">8.7.1. Examples of FIRST_VALUE Window Function</a></li>
</ul>
</li>
<li><a href="#lag_window_function">8.8. LAG Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_lag_window_function">8.8.1. Examples of LAG Window Function</a></li>
</ul>
</li>
<li><a href="#last_value_window_function">8.9. LAST_VALUE Window Function</a></li>
<li><a href="#lead_window_function">8.10. LEAD Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_lead_window_function">8.10.1. Examples of LEAD Window Function</a></li>
</ul>
</li>
<li><a href="#max_window_function">8.11. MAX Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_max_window_function">8.11.1. Examples of MAX Window Function</a></li>
</ul>
</li>
<li><a href="#min_window_function">8.12. MIN Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_min_window_function">8.12.1. Examples of MIN Window Function</a></li>
</ul>
</li>
<li><a href="#rank_window_function">8.13. RANK Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_rank_window_function">8.13.1. Examples of RANK Window Function</a></li>
<li><a href="#row_number_window_function">8.13.2. ROW_NUMBER Window Function</a></li>
<li><a href="#examples_of_row_number_window_function">8.13.3. Examples of ROW_NUMBER Window Function</a></li>
<li><a href="#stddev_window_function">8.13.4. STDDEV Window Function</a></li>
<li><a href="#examples_of_stddev">8.13.5. Examples of STDDEV</a></li>
</ul>
</li>
<li><a href="#sum_window_function">8.14. SUM Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_sum_window_function">8.14.1. Examples of SUM Window Function</a></li>
</ul>
</li>
<li><a href="#variance_window_function">8.15. VARIANCE Window Function</a>
<ul class="sectlevel3">
<li><a href="#examples_of_variance_window_function">8.15.1. Examples of VARIANCE Window Function</a></li>
</ul>
</li>
</ul>
</li>
<li><a href="#sql_runtime_statistics">9. SQL Runtime Statistics</a>
<ul class="sectlevel2">
<li><a href="#_pertable_and_operator_statistics">9.1. PERTABLE and OPERATOR Statistics</a></li>
<li><a href="#adaptive_statistics_collection">9.2. Adaptive Statistics Collection</a></li>
<li><a href="#retrieving_sql_runtime_statistics">9.3. Retrieving SQL Runtime Statistics</a>
<ul class="sectlevel3">
<li><a href="#using_the_get_statistics_command">9.3.1. Using the GET STATISTICS Command</a></li>
<li><a href="#syntax_of_get_statistics">9.3.2. Syntax of GET STATISTICS</a></li>
<li><a href="#examples_of_get_statistics">9.3.3. Examples of GET STATISTICS</a></li>
</ul>
</li>
<li><a href="#displaying_sql_runtime_statistics">9.4. Displaying SQL Runtime Statistics</a>
<ul class="sectlevel3">
<li><a href="#examples_of_displaying_sql_runtime_statistics">9.4.1. Examples of Displaying SQL Runtime Statistics</a></li>
<li><a href="#pertable_statistics_of_an_executing_statement">9.4.2. PERTABLE Statistics of an Executing Statement</a></li>
<li><a href="#accumulated_statistics_of_an_executing_statement">9.4.3. ACCUMULATED Statistics of an Executing Statement</a></li>
<li><a href="#progress-statistics-of-an-executing-statement">9.4.4. PROGRESS Statistics of an Executing Statement</a></li>
<li><a href="#default_statistics_of_an_executing_statement">9.4.5. DEFAULT Statistics of an Executing Statement</a></li>
<li><a href="#using_the_parent_query_id">9.4.6. Using the Parent Query ID</a></li>
<li><a href="#child_query_id">9.4.7. Child Query ID</a></li>
</ul>
</li>
<li><a href="#_gathering_statistics_about_rms">9.5. Gathering Statistics About RMS</a></li>
<li><a href="#using_the_queryid_extract_function">9.6. Using the QUERYID_EXTRACT Function</a>
<ul class="sectlevel3">
<li><a href="#_syntax_of_queryid_extract">9.6.1. Syntax of QUERYID_EXTRACT</a></li>
<li><a href="#examples_of_queryid_extract">9.6.2. Examples of QUERYID_EXTRACT</a></li>
</ul>
</li>
<li><a href="#stats_each_fragment_instance_active_query">9.7. Statistics for Each Fragment-Instance of an Active Query</a>
<ul class="sectlevel3">
<li><a href="#syntax_of_statistics_table-valued_function">9.7.1. Syntax of STATISTICS Table-Valued Function</a></li>
<li><a href="#considerations_obtaining_stats_fragment">9.7.2. Considerations For Obtaining Statistics For Each Fragment-Instance of an Active Query</a></li>
</ul>
</li>
</ul>
</li>
<li><a href="#reserved_words">10. Reserved Words</a>
<ul class="sectlevel2">
<li><a href="#reserved_sql_identifiers_a">10.1. Reserved SQL Identifiers: A</a></li>
<li><a href="#reserved_sql_identifiers_b">10.2. Reserved SQL Identifiers: B</a></li>
<li><a href="#reserved_sql_identifiers_c">10.3. Reserved SQL Identifiers: C</a></li>
<li><a href="#reserved_sql_identifiers_d">10.4. Reserved SQL Identifiers: D</a></li>
<li><a href="#reserved_sql_identifiers_e">10.5. Reserved SQL Identifiers: E</a></li>
<li><a href="#_reserved_sql_identifers_f">10.6. Reserved SQL Identifers: F</a></li>
<li><a href="#reserved_sql_identifiers_g">10.7. Reserved SQL Identifiers G</a></li>
<li><a href="#reserved_sql_identifiers_h">10.8. Reserved SQL Identifiers: H</a></li>
<li><a href="#reserved_sql_identifiers_i">10.9. Reserved SQL Identifiers: I</a></li>
<li><a href="#reserved_sql_identifiers_j">10.10. Reserved SQL Identifiers J</a></li>
<li><a href="#reserved_sql_identifiers_k">10.11. Reserved SQL Identifiers: K</a></li>
<li><a href="#reserved_sql_identifiers_l">10.12. Reserved SQL Identifiers: L</a></li>
<li><a href="#reserved_sql_identifiers_m">10.13. Reserved SQL Identifiers: M</a></li>
<li><a href="#reserved_sql_identifiers_n">10.14. Reserved SQL Identifiers: N</a></li>
<li><a href="#reserved_sql_identifiers_o">10.15. Reserved SQL Identifiers: O</a></li>
<li><a href="#reserved_sql_identifiers_p">10.16. Reserved SQL Identifiers: P</a></li>
<li><a href="#reserved_sql_identifiers_q">10.17. Reserved SQL Identifiers: Q</a></li>
<li><a href="#reserved_sql_identifiers_r">10.18. Reserved SQL Identifiers: R</a></li>
<li><a href="#reserved_sql_identifiers_s">10.19. Reserved SQL Identifiers: S</a></li>
<li><a href="#reserved_sql_identifiers_t">10.20. Reserved SQL Identifiers: T</a></li>
<li><a href="#reserved_sql_identifiers_u">10.21. Reserved SQL Identifiers: U</a></li>
<li><a href="#reserved_sql_identifiers_v">10.22. Reserved SQL Identifiers: V</a></li>
<li><a href="#reserved_sql_identifiers_w">10.23. Reserved SQL Identifiers: W</a></li>
<li><a href="#reserved_sql_identifiers_y">10.24. Reserved SQL Identifiers Y</a></li>
<li><a href="#reserved_sql_identifiers_z">10.25. Reserved SQL Identifiers: Z</a></li>
</ul>
</li>
<li><a href="#limits">11. Limits</a></li>
</ul>
</div>
</div>
<div id="content">
<div id="preamble">
<div class="sectionbody">
<div class="paragraph">
<p><strong>License Statement</strong></p>
</div>
<div class="paragraph">
<p>Licensed to the Apache Software Foundation (ASF) under one or more contributor license agreements. See the NOTICE file
distributed with this work for additional information regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the "License"); you may not use this file except in compliance with
the License. You may obtain a copy of the License at <a href="http://www.apache.org/licenses/LICENSE-2.0" class="bare">http://www.apache.org/licenses/LICENSE-2.0</a></p>
</div>
<div class="paragraph">
<p>Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the
specific language governing permissions and limitations under the License.</p>
</div>
<div class="paragraph">
<p><strong>Disclaimer:</strong> <em>Apache Trafodion is an effort undergoing incubation at the Apache Software Foundation (ASF), sponsored by
the Apache Incubator PMC. Incubation is required of all newly accepted projects until a further review indicates that
the infrastructure, communications, and decision making process have stabilized in a manner consistent with other
successful ASF projects. While incubation status is not necessarily a reflection of the completeness or stability of the code,
it does indicate that the project has yet to be fully endorsed by the ASF.</em></p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p><strong>Acknowledgements</strong></p>
</div>
<div class="paragraph">
<p>Microsoft®, Windows®, Windows NT®, Windows® XP, and Windows Vista® are
U.S. registered trademarks of Microsoft Corporation. Intel® and Intel®
Itanium® are trademarks of Intel Corporation in the U.S. and other
countries. Java® is a registered trademark of Oracle and/or its
affiliates. Motif, OSF/1, UNIX®, X/Open®, and the X device is a
trademark of X/Open Company Ltd. in the UK and other countries.</p>
</div>
<div class="paragraph">
<p>OSF, OSF/1, OSF/Motif, Motif, and Open Software Foundation are trademarks of
the Open Software Foundation in the U.S. and other countries.
© 1990, 1991, 1992, 1993 Open Software Foundation, Inc.</p>
</div>
<div class="paragraph">
<p>The OSF documentation and the OSF software to which it relates are derived in
part from materials supplied by the following: © 1987, 1988, 1989
Carnegie-Mellon University. © 1989, 1990, 1991 Digital Equipment
Corporation. © 1985, 1988, 1989, 1990 Encore Computer Corporation. © 1988 Free
Software Foundation, Inc. © 1987, 1988, 1989, 1990, 1991 Hewlett-Packard
Company. © 1985, 1987, 1988, 1989, 1990, 1991, 1992 International
Business Machines Corporation. © 1988, 1989 Massachusetts Institute of
Technology. © 1988, 1989, 1990 Mentat Inc. © 1988 Microsoft Corporation.
© 1987, 1988, 1989, 1990, 1991,
1992 SecureWare, Inc. © 1990, 1991 Siemens Nixdorf Informations systeme
AG. © 1986, 1989, 1996, 1997 Sun Microsystems, Inc. © 1989, 1990, 1991
Transarc Corporation.</p>
</div>
<div class="paragraph">
<p>OSF software and documentation are based in part
on the Fourth Berkeley Software Distribution under license from The
Regents of the University of California. OSF acknowledges the following
individuals and institutions for their role in its development: Kenneth
C.R.C. Arnold, Gregory S. Couch, Conrad C. Huang, Ed James, Symmetric
Computer Systems, Robert Elz. © 1980, 1981, 1982, 1983, 1985, 1986,
1987, 1988, 1989 Regents of the University of California. OSF MAKES NO
WARRANTY OF ANY KIND WITH REGARD TO THE OSF MATERIAL PROVIDED HEREIN,
INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY
AND FITNESS FOR A PARTICULAR PURPOSE. OSF shall not be liable for errors
contained herein or for incidental consequential damages in connection
with the furnishing, performance, or use of this material.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p><strong>Revision History</strong></p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Version</th>
<th class="tableblock halign-left valign-top">Date</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2.1.0</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TBD</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2.0.1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">July 7, 2016</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2.0.0</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">June 6, 2016</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1.3.0</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">January, 2016</p></td>
</tr>
</tbody>
</table>
</div>
</div>
<div class="sect1">
<h2 id="About_This_Document">1. About This Document</h2>
<div class="sectionbody">
<div class="paragraph">
<p>This manual describes reference information about the syntax of SQL statements, functions, and other
SQL language elements supported by the Trafodion project’s database software.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL statements and utilities are entered interactively or from script files using a client-based tool,
such as the Trafodion Command Interface (TrafCI). To install and configure a client application that enables you
to connect to and use a Trafodion database, see the
<a href="http://trafodion.incubator.apache.org/docs/client_install/index.html"><em>Trafodion Client Installation Guide</em></a>.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In this manual, SQL language elements, statements, and clauses within statements are based on the
ANSI SQL:1999 standard.
</td>
</tr>
</table>
</div>
<div class="sect2">
<h3 id="Intended_Audience">1.1. Intended Audience</h3>
<div class="paragraph">
<p>This manual is intended for database administrators and application programmers who are using SQL to read, update,
and create Trafodion SQL tables, which map to HBase tables, and to access native HBase and Hive tables.</p>
</div>
<div class="paragraph">
<p>You should be familiar with structured query language (SQL) and with the American National Standard Database Language SQL:1999.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="New_and_Changed_Information">1.2. New and Changed Information</h3>
<div class="paragraph">
<p>This edition includes updates for these new features:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">New Feature</th>
<th class="tableblock halign-left valign-top">Location in the Manual</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Incremental UPDATE STATISTICS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#update_statistics_statement">UPDATE STATISTICS Statement</a></p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="Document_Organization">1.3. Document Organization</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Chapter or Appendix</th>
<th class="tableblock halign-left valign-top">Description</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#introduction">Introduction</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Introduces Trafodion SQL and covers topics such as data consistency,
transaction management, and ANSI compliance.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#SQL_Statements">SQL Statements</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes the SQL statements supported by Trafodion SQL.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#SQL_Utilities">SQL Utilities</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes the SQL utilities supported by Trafodion SQL.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#SQL_Language Elements">SQL Language Elements</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes parts of the language, such as database objects, data types,
expressions, identifiers, literals, and predicates, which occur within the syntax of Trafodion SQL statements.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#SQL_Clauses">SQL Clauses</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes clauses used by Trafodion SQL statements.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#SQL_Functions_and_Expressions">SQL Functions and Expressions</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes specific functions and expressions that you can use in
Trafodion SQL statements.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#SQL_Runtime_Statistics">SQL Runtime Statistics</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes how to gather statistics for active queries or for the Runtime
Management System (RMS) and describes the RMS counters that are returned.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#OLAP_Functions">OLAP Functions</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes specific on line analytical processing functions.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#Reserved_Words">Appendix A: Reserved Words</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Lists the words that are reserved in Trafodion SQL.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#limits">Appendix B: Limits</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes limits in Trafodion SQL.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="_notation_conventions">1.4. Notation Conventions</h3>
<div class="paragraph">
<p>This list summarizes the notation conventions for syntax presentation in this manual.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>UPPERCASE LETTERS</p>
<div class="paragraph">
<p>Uppercase letters indicate keywords and reserved words. Type these items exactly as shown. Items not enclosed in brackets are required.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT</code></pre>
</div>
</div>
</li>
<li>
<p>lowercase letters</p>
<div class="paragraph">
<p>Lowercase letters, regardless of font, indicate variable items that you supply. Items not enclosed in brackets are required.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">file-name</code></pre>
</div>
</div>
</li>
<li>
<p>&#91; &#93; Brackets</p>
<div class="paragraph">
<p>Brackets enclose optional syntax items.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATETIME [start-field TO] end-field</code></pre>
</div>
</div>
<div class="paragraph">
<p>A group of items enclosed in brackets is a list from which you can choose one item or none.</p>
</div>
<div class="paragraph">
<p>The items in the list can be arranged either vertically, with aligned brackets on each side of the list, or horizontally, enclosed in a pair of brackets and separated by vertical lines.</p>
</div>
<div class="paragraph">
<p>For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP SCHEMA schema [CASCADE]
DROP SCHEMA schema [ CASCADE | RESTRICT ]</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>{ } Braces</p>
<div class="paragraph">
<p>Braces enclose required syntax items.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">FROM { grantee [, grantee ] ... }</code></pre>
</div>
</div>
<div class="paragraph">
<p>A group of items enclosed in braces is a list from which you are required to choose one item.</p>
</div>
<div class="paragraph">
<p>The items in the list can be arranged either vertically, with aligned braces on each side of the list, or horizontally, enclosed in a pair of braces and separated by vertical lines.</p>
</div>
<div class="paragraph">
<p>For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INTERVAL { start-field TO end-field }
{ single-field }
INTERVAL { start-field TO end-field | single-field }</code></pre>
</div>
</div>
</li>
<li>
<p>| Vertical Line</p>
<div class="paragraph">
<p>A vertical line separates alternatives in a horizontal list that is enclosed in brackets or braces.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">{expression | NULL}</code></pre>
</div>
</div>
</li>
<li>
<p>&#8230; Ellipsis</p>
<div class="paragraph">
<p>An ellipsis immediately following a pair of brackets or braces indicates that you can repeat the enclosed sequence of syntax items any number of times.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ATTRIBUTE[S] attribute [, attribute] ...
{, sql-expression } ...</code></pre>
</div>
</div>
<div class="paragraph">
<p>An ellipsis immediately following a single syntax item indicates that you can repeat that syntax item any number of times.</p>
</div>
<div class="paragraph">
<p>For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">expression-n ...</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Punctuation</p>
<div class="paragraph">
<p>Parentheses, commas, semicolons, and other symbols not previously described must be typed as shown.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DAY (datetime-expression)
@script-file</code></pre>
</div>
</div>
<div class="paragraph">
<p>Quotation marks around a symbol such as a bracket or brace indicate the symbol is a required character that you must type as shown.</p>
</div>
<div class="paragraph">
<p>For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&quot;{&quot; module-name [, module-name] ... &quot;}&quot;</code></pre>
</div>
</div>
</li>
<li>
<p>Item Spacing</p>
<div class="paragraph">
<p>Spaces shown between items are required unless one of the items is a punctuation symbol such as a parenthesis or a comma.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DAY (datetime-expression) DAY(datetime-expression)</code></pre>
</div>
</div>
<div class="paragraph">
<p>If there is no space between two items, spaces are not permitted. In this example, no spaces are permitted between the period and any other items:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">myfile.sh</code></pre>
</div>
</div>
</li>
<li>
<p>Line Spacing</p>
<div class="paragraph">
<p>If the syntax of a command is too long to fit on a single line, each continuation line is indented three spaces and is separated from the preceding line by a blank line.</p>
</div>
<div class="paragraph">
<p>This spacing distinguishes items in a continuation line from items in a vertical list of selections.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">match-value [NOT] LIKE _pattern
[ESCAPE esc-char-expression]</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="_comments_encouraged">1.5. Comments Encouraged</h3>
<div class="paragraph">
<p>We encourage your comments concerning this document. We are committed to providing documentation that meets your
needs. Send any errors found, suggestions for improvement, or compliments to <a href="mailto:user@trafodion.incubator.apache.org">user@trafodion.incubator.apache.org</a>.</p>
</div>
<div class="paragraph">
<p>Include the document title and any comment, error found, or suggestion for improvement you have concerning this document.</p>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="introduction">2. Introduction</h2>
<div class="sectionbody">
<div class="paragraph">
<p>The Trafodion SQL database software allows you to use SQL statements, which comply closely to
ANSI SQL:1999, to access data in Trafodion SQL tables, which map to HBase tables, and to access
native HBase tables and Hive tables.</p>
</div>
<div class="paragraph">
<p>This introduction describes:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#sql_language">SQL Language</a></p>
</li>
<li>
<p><a href="#using_trafodion_sql_to_access_hbase_tables">Using Trafodion SQL to Access HBase Tables</a></p>
</li>
<li>
<p><a href="#using_trafodion_sql_to_access_hive_tables">Using Trafodion SQL to Access Hive Tables</a></p>
</li>
<li>
<p><a href="#data_consistency_and_access_options">Data Consistency and Access Options</a></p>
</li>
<li>
<p><a href="#transaction_management">Transaction Management</a></p>
</li>
<li>
<p><a href="#ansi_compliance_and_trafodion_sql_extensions">ANSI Compliance and Trafodion SQL Extensions</a></p>
</li>
<li>
<p><a href="#trafodion_sql_error_messages">Trafodion SQL Error Messages</a></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Other sections of this manual describe the syntax and semantics of individual statements, commands, and language elements.</p>
</div>
<div class="sect2">
<h3 id="sql_language">2.1. SQL Language</h3>
<div class="paragraph">
<p>The SQL language consists of statements and other language elements that you can use to access SQL
databases. For descriptions of individual SQL statements, see <a href="#sql_statements">SQL Statements</a>.</p>
</div>
<div class="paragraph">
<p>SQL language elements are part of statements and commands and include data types, expressions, functions,
identifiers, literals, and predicates. For more information, see:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#sql_language">SQL Language</a></p>
</li>
<li>
<p><a href="#elements">Elements</a></p>
</li>
<li>
<p><a href="#sql_clauses">SQL Clauses</a></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For information on specific functions and expressions, see:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#sql_functions_and_expressions">SQL Functions and Expressions</a></p>
</li>
<li>
<p><a href="#olap_functions">OLAP Functions</a></p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="using_trafodion_sql_to_access_hbase_tables">2.2. Using Trafodion SQL to Access HBase Tables</h3>
<div class="paragraph">
<p>You can use Trafodion SQL statements to read, update, and create HBase tables.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#initializing_the_trafodion_metadata">Initializing the Trafodion Metadata</a></p>
</li>
<li>
<p><a href="#ways_to_access_hbase_tables">Ways to Access HBase Tables</a></p>
</li>
<li>
<p><a href="#trafodion_sql_tables_versus_native_hbase_tables">Trafodion SQL Tables Versus Native HBase Tables</a></p>
</li>
<li>
<p><a href="#supported_sql_statements_with_hbase_tables">Supported SQL Statements With HBase Tables</a></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For a list of Control Query Default (CQD) settings for the HBase environment, see the
<a href="http://trafodion.incubator.apache.org/docs/cqd_reference/index.hmtl">Trafodion Control Query Default (CQD) Reference Guide</a>.</p>
</div>
<div class="sect3">
<h4 id="ways_to_access_hbase_tables">2.2.1. Ways to Access HBase Tables</h4>
<div class="paragraph">
<p>Trafodion SQL supports these ways to access HBase tables:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#accessing_trafodion_sql_tables">Accessing Trafodion SQL Tables</a></p>
</li>
<li>
<p><a href="#cell_per_row_access_to_hbase_tables">Cell-Per-Row Access to HBase Tables (Technology Preview)</a></p>
</li>
<li>
<p><a href="#rowwise_access_to_hbase_tables">Rowwise Access to HBase Tables (Technology Preview)</a></p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="accessing_trafodion_sql_tables">Accessing Trafodion SQL Tables</h5>
<div class="paragraph">
<p>A Trafodion SQL table is a relational SQL table generated by a <code>CREATE TABLE</code> statement and mapped
to an HBase table. Trafodion SQL tables have regular ANSI names in the catalog <code>TRAFODION</code>.
A Trafodion SQL table name can be a fully qualified ANSI name of the form
<code>TRAFODION.<em>schema-name.object-name</em></code>.</p>
</div>
<div class="paragraph">
<p>To access a Trafodion SQL table, specify its ANSI table name in a Trafodion SQL statement, similar
to how you would specify an ANSI table name when running SQL statements in a relational database.</p>
</div>
<div class="paragraph">
<p><strong>Example</strong></p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE trafodion.sales.odetail
( ordernum NUMERIC (6) UNSIGNED NO DEFAULT NOT NULL
, partnum NUMERIC (4) UNSIGNED NO DEFAULT NOT NULL
, unit_price NUMERIC (8,2) NO DEFAULT NOT NULL
, qty_ordered NUMERIC (5) UNSIGNED NO DEFAULT NOT NULL
, PRIMARY KEY (ordernum, partnum)
);
INSERT INTO trafodion.sales.odetail VALUES ( 900000, 7301, 425.00, 100 );
SET SCHEMA trafodion.sales;
SELECT * FROM odetail;</code></pre>
</div>
</div>
<div class="paragraph">
<p>For more information about Trafodion SQL tables, see
<a href="#trafodion_sql_tables_versus_native_hbase_tables">Trafodion SQL Tables Versus Native HBase Tables</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="cell_per_row_access_to_hbase_tables">Cell-Per-Row Access to HBase Tables (Technology Preview)</h5>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
This is a <em>Technology Preview (Complete But Not Tested)</em> feature, meaning that it is functionally
complete but has not been tested or debugged.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>To access HBase data using cell-per-row mode, specify the schema <code>HBASE."<em>CELL</em>"</code> and the full ANSI
name of the table as a delimited table name. You can specify the name of any HBase table, regardless of whether
it was created through Trafodion SQL.</p>
</div>
<div class="paragraph">
<p><strong>Example</strong></p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">select * from hbase.&quot;_CELL_&quot;.&quot;TRAFODION.MYSCH.MYTAB&quot;;
select * from hbase.&quot;_CELL_&quot;.&quot;table_created_in_HBase&quot;;</code></pre>
</div>
</div>
<div class="paragraph">
<p>All tables accessed through this schema have the same column layout:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;invoke hbase.&quot;_CELL_&quot;.&quot;table_created_in_HBase&quot;;
(
ROW_ID VARCHAR(100) ...
, COL_FAMILY VARCHAR(100) ...
, COL_NAME VARCHAR(100) ...
, COL_TIMESTAMP LARGEINT ...
, COL_VALUE VARCHAR(1000) ...
)
PRIMARY KEY (ROW_ID)
&gt;&gt;select * from hbase.&quot;_CELL_&quot;.&quot;mytab&quot;;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="rowwise_access_to_hbase_tables">Rowwise Access to HBase Tables (Technology Preview)</h5>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
This is a <em>Technology Preview (Complete But Not Tested)</em> feature, meaning that it is functionally
complete but has not been tested or debugged.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>To access HBase data using rowwise mode, specify the schema <code>HBASE."<em>ROW</em>"</code> and the full ANSI name of the
table as a delimited table name. You can specify the name of any HBase table, regardless of whether
it was created through Trafodion SQL.</p>
</div>
<div class="paragraph">
<p><strong>Example</strong></p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">select * from hbase.&quot;_ROW_&quot;.&quot;TRAFODION.MYSCH.MYTAB&quot;;
select * from hbase.&quot;_ROW_&quot;.&quot;table_created_in_HBase&quot;;</code></pre>
</div>
</div>
<div class="paragraph">
<p>All column values of the row are returned as a single, big varchar:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;invoke hbase.&quot;_ROW_&quot;.&quot;mytab&quot;;
(
ROW_ID VARCHAR(100) ...
, COLUMN_DETAILS VARCHAR(10000) ...
)
PRIMARY KEY (ROW_ID)
&gt;&gt;select * from hbase.&quot;_ROW_&quot;.&quot;mytab&quot;;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="trafodion_sql_tables_versus_native_hbase_tables">2.2.2. Trafodion SQL Tables Versus Native HBase Tables</h4>
<div class="paragraph">
<p>Trafodion SQL tables have many advantages over regular HBase tables:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>They can be made to look like regular, structured SQL tables with fixed columns.</p>
</li>
<li>
<p>They support the usual SQL data types supported in relational databases.</p>
</li>
<li>
<p>They support compound keys, unlike HBase tables that have a single row key (a string).</p>
</li>
<li>
<p>They support indexes.</p>
</li>
<li>
<p>They support <em>salting</em>, which is a technique of adding a hash value of the row key as a
key prefix to avoid hot spots for sequential keys. For the syntax,
see the <a href="#create_table_statement">CREATE TABLE Statement</a>.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>The problem with Trafodion SQL tables is that they use a fixed format to represent column values,
making it harder for native HBase applications to access them. Also, they have a fixed structure,
so users lose the flexibility of dynamic columns that comes with HBase.</p>
</div>
</div>
<div class="sect3">
<h4 id="supported_sql_statements_with_hbase_tables">2.2.3. Supported SQL Statements With HBase Tables</h4>
<div class="paragraph">
<p>You can use these SQL statements with HBase tables:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#select_statement">SELECT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#insert_statement">INSERT Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#update_statement">UPDATE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#delete_statement">DELETE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#merge_statement">MERGE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_statement">GET Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#invoke_statement">INVOKE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#alter_table_statement">ALTER TABLE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_index_statement">CREATE INDEX Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_table_statement">CREATE TABLE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_view_statement">CREATE VIEW Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_index_statement">DROP INDEX Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_table_statement">DROP TABLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_view_statement">DROP VIEW Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#grant_statement">GRANT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#revoke_statement">REVOKE Statement</a></p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="using_trafodion_sql_to_access_hive_tables">2.3. Using Trafodion SQL to Access Hive Tables</h3>
<div class="paragraph">
<p>You can use Trafodion SQL statements to access Hive tables.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#ansi_names_for_hive_tables">ANSI Names for Hive Tables</a></p>
</li>
<li>
<p><a href="#type_mapping_from_hive_to_trafodion_sql">Type Mapping From Hive to Trafodion SQL</a></p>
</li>
<li>
<p><a href="#supported_sql_statements_with_hive_tables">Supported SQL Statements With Hive Tables</a></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For a list of Control Query Default (CQD) settings for the Hive environment, see the
<a href="http://trafodion.incubator.apache.org/docs/cqd_reference/index.hmtl">Trafodion Control Query Default (CQD) Reference Guide</a>.</p>
</div>
<div class="sect3">
<h4 id="ansi_names_for_hive_tables">2.3.1. ANSI Names for Hive Tables</h4>
<div class="paragraph">
<p>Hive tables appear in the Trafodion Hive ANSI name space in a special catalog and schema named <code>HIVE.HIVE</code>.</p>
</div>
<div class="paragraph">
<p>To select from a Hive table named <code>T</code>, specify an implicit or explicit name, such as <code>HIVE.HIVE.T</code>,
in a Trafodion SQL statement.</p>
</div>
<div class="paragraph">
<p><strong>Example</strong>
This example should work if a Hive table named <code>T</code> has already been defined:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">set schema hive.hive;
CQD HIVE_MAX_STRING_LENGTH '20'; -- creates a more readable display
select * from t; -- implicit table name
set schema trafodion.seabase;
select * from hive.hive.t; -- explicit table name</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="type_mapping_from_hive_to_trafodion_sql">2.3.2. Type Mapping From Hive to Trafodion SQL</h4>
<div class="paragraph">
<p>Trafodion performs the following data-type mappings:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Hive Type</th>
<th class="tableblock halign-left valign-top">Trafodion SQL Type</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>tinyint</code></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>smallint</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>smallint</code></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>smallint</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>int</code></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>int</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>bigint</code></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>largeint</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>string</code></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>varchar(<em>n</em> bytes) character set utf8</code><sup>1</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>float</code></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>real</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>double</code></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>float(54)</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>timestamp</code></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><code>timestamp(6)</code><sup>2</sup></p></td>
</tr>
</tbody>
</table>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>The value <code><em>n</em></code> is determined by <code>CQD HIVE_MAX_STRING_LENGTH</code>. See the
<a href="http://trafodion.incubator.apache.org/docs/cqd_reference/index.hmtl">Trafodion Control Query Default (CQD) Reference Guide</a>.</p>
</li>
<li>
<p>Hive supports timestamps with nanosecond resolution (precision of 9). Trafodion SQL supports only microsecond resolution (precision 6).</p>
</li>
</ol>
</div>
</div>
<div class="sect3">
<h4 id="supported_sql_statements_with_hive_tables">2.3.3. Supported SQL Statements With Hive Tables</h4>
<div class="paragraph">
<p>You can use these SQL statements with Hive tables:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#select_statement">SELECT Statement</a></p>
</li>
<li>
<p><a href="#load_statement">LOAD Statement</a></p>
</li>
<li>
<p>GET TABLES (See the <a href="#get_statement">GET Statement</a>.)</p>
</li>
<li>
<p><a href="#invoke_statement">INVOKE Statement</a></p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="data_consistency_and_access_options">2.4. Data Consistency and Access Options</h3>
<div class="paragraph">
<p>Access options for DML statements affect the consistency of the data that your query accesses.</p>
</div>
<div class="paragraph">
<p>For any DML statement, you specify access options by using the <code>FOR <em>option</em> ACCESS</code> clause and,
for a <code>SELECT</code> statement, by using this same clause, you can also specify access options for individual
tables and views referenced in the FROM clause.</p>
</div>
<div class="paragraph">
<p>The possible settings for <code><em>option</em></code> in a DML statement are:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#read_committed">READ COMMITTED</a></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Specifies that the data accessed by the DML statement must be from committed rows.</p>
</div>
<div class="paragraph">
<p>The SQL default access option for DML statements is <code>READ COMMITTED</code>.</p>
</div>
<div class="paragraph">
<p>For related information about transactions, see
<a href="#transaction_isolation_levels">Transaction Isolation Levels</a>.</p>
</div>
<div class="sect3">
<h4 id="read_committed">2.4.1. READ COMMITTED</h4>
<div class="paragraph">
<p>This option allows you to access only committed data.</p>
</div>
<div class="paragraph">
<p>The implementation requires that a lock can be acquired on the data requested by the DML statement—but
does not actually lock the data, thereby reducing lock request conflicts. If a lock cannot be granted
(implying that the row contains uncommitted data), the DML statement request waits until the lock in
place is released.</p>
</div>
<div class="paragraph">
<p>READ COMMITTED provides the next higher level of data consistency (compared to READ UNCOMMITTED).
A statement executing with this access option does not allow dirty reads, but both non-repeatable reads
and phantoms are possible.</p>
</div>
<div class="paragraph">
<p>READ COMMITTED provides sufficient consistency for any process that does not require a repeatable read
capability.</p>
</div>
<div class="paragraph">
<p>READ COMMITTED is the default isolation level.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="transaction_management">2.5. Transaction Management</h3>
<div class="paragraph">
<p>A transaction (a set of database changes that must be completed as a group) is the basic recoverable unit
in case of a failure or transaction interruption. Transactions are controlled through client tools that
interact with the database using ODBC or JDBC.</p>
</div>
<div class="paragraph">
<p>The typical order of events is:</p>
</div>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>Transaction is started.</p>
</li>
<li>
<p>Database changes are made.</p>
</li>
<li>
<p>Transaction is committed.</p>
</li>
</ol>
</div>
<div class="paragraph">
<p>If, however, the changes cannot be made or if you do not want to complete the transaction, then you can abort
the transaction so that the database is rolled back to its original state.</p>
</div>
<div class="paragraph">
<p>This subsection discusses these considerations for transaction management:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#user_defined_and_system_defined_transactions">User-Defined and System-Defined Transactions</a></p>
</li>
<li>
<p><a href="#rules_for_dml_statements">Rules for DML Statements</a></p>
</li>
<li>
<p><a href="#effect_of_autocommit_option">Effect of AUTOCOMMIT Option</a></p>
</li>
<li>
<p><a href="#concurrency">Concurrency</a></p>
</li>
<li>
<p><a href="#transaction_isolation_levels">Transaction Isolation Levels</a></p>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="user_defined_and_system_defined_transactions">2.5.1. User-Defined and System-Defined Transactions</h4>
<div class="paragraph">
<p>Transactions you define are called <em>user-defined transactions</em>. To be sure that a sequence of statements executes
successfully or not at all, you can define one transaction consisting of these statements by using the BEGIN WORK
statement and COMMIT WORK statement. You can abort a transaction by using the ROLLBACK WORK statement.</p>
</div>
<div class="paragraph">
<p>If AUTOCOMMIT is on, then you do not have to end the transaction explicitly as Trafodion SQL will end the transaction
automatically. Sometimes an error occurs that requires the user-defined transaction to be aborted. Trafodion SQL
will automatically abort the transaction and return an error indicating that the transaction was rolled back.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="system_defined_transactions">System-Defined Transactions</h5>
<div class="paragraph">
<p>In some cases, Trafodion SQL defines transactions for you. These transactions are called <em>system-defined transactions</em>.
Most DML statements initiate transactions implicitly at the start of execution.
See <a href="#implicit_transactions">Implicit Transactions</a>.</p>
</div>
<div class="paragraph">
<p>However, even if a transaction is initiated implicitly, you must end a transaction explicitly with the COMMIT WORK
statement or the ROLLBACK WORK statement. If AUTOCOMMIT is on, you do not need to end a transaction explicitly.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="rules_for_dml_statements">2.5.2. Rules for DML Statements</h4>
<div class="paragraph">
<p>If deadlock occurs, the DML statement times out and receives an error.</p>
</div>
</div>
<div class="sect3">
<h4 id="effect_of_autocommit_option">2.5.3. Effect of AUTOCOMMIT Option</h4>
<div class="paragraph">
<p>AUTOCOMMIT is an option that can be set in a SET TRANSACTION statement. It specifies whether Trafodion SQL will commit
automatically, or roll back if an error occurs, at the end of statement execution. This option applies to any statement
for which the system initiates a transaction. See <a href="#set_transaction_statement">SET TRANSACTION Statement</a>.</p>
</div>
<div class="paragraph">
<p>If this option is set to ON, Trafodion SQL automatically commits any changes, or rolls back any changes, made to the
database at the end of statement execution.</p>
</div>
</div>
<div class="sect3">
<h4 id="concurrency">2.5.4. Concurrency</h4>
<div class="paragraph">
<p>Concurrency is defined by two or more processes accessing the same data at the same time. The degree of concurrency
available &#8212; whether a process that requests access to data that is already being accessed is given access or placed
in a wait queue &#8212; depends on the purpose of the access mode (read or update) and the isolation level. Currently, the only
isolation level is READ COMMITTED.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL provides concurrent database access for most operations and controls database access through concurrency
control and the mechanism for opening and closing tables. For DML operations, the access option affects the degree of
concurrency. See <a href="#data_consistency_and_access_options">Data Consistency and Access Options</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="transaction_isolation_levels">2.5.5. Transaction Isolation Levels</h4>
<div class="paragraph">
<p>A transaction has an isolation level that is <a href="#read_committed">READ COMMITTED</a>.</p>
</div>
<div class="sect4">
<h5 id="read_committed">READ COMMITTED</h5>
<div class="paragraph">
<p>This option, which is ANSI compliant, allows your transaction to access only committed data. No row locks are acquired
when READ COMMITTED is the specified isolation level.</p>
</div>
<div class="paragraph">
<p>READ COMMITTED provides the next level of data consistency. A transaction executing with this isolation level does not
allow dirty reads, but both non-repeatable reads and phantoms are possible.</p>
</div>
<div class="paragraph">
<p>READ COMMITTED provides sufficient consistency for any transaction that does not require a repeatable-read capability.</p>
</div>
<div class="paragraph">
<p>The default isolation level is READ COMMITTED.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="ansi_compliance_and_trafodion_sql_extensions">2.6. ANSI Compliance and Trafodion SQL Extensions</h3>
<div class="paragraph">
<p>Trafodion SQL complies most closely with Core SQL 99. Trafodion SQL also includes some features from SQL 99 and part of
the SQL 2003 standard, and special Trafodion SQL extensions to the SQL language.</p>
</div>
<div class="paragraph">
<p>Statements and SQL elements in this manual are ANSI compliant unless specified as Trafodion SQL extensions.</p>
</div>
<div class="sect3">
<h4 id="ansi_compliant_statements">2.6.1. ANSI-Compliant Statements</h4>
<div class="paragraph">
<p>These statements are ANSI compliant, but some might contain Trafodion SQL extensions:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#alter_table_statement">ALTER TABLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#call_statement">CALL Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#commit_work_statement">COMMIT WORK Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_function_statement">CREATE FUNCTION Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_procedure_statement">CREATE PROCEDURE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_role_statement">CREATE ROLE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_schema_statement">CREATE SCHEMA Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_table_statement">CREATE TABLE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_view_statement">CREATE VIEW Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#delete_statement">DELETE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_function_statement">DROP FUNCTION Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_procedure_statement">DROP PROCEDURE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_role_statement">DROP ROLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_schema_statement">DROP SCHEMA Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_table_statement">DROP TABLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_view_statement">DROP VIEW Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#execute_statement">EXECUTE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#grant_statement">GRANT Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#grant_role_statement">GRANT ROLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#insert_statement">INSERT Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#merge_statement">MERGE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#prepare_statement">PREPARE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#revoke_statement">REVOKE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#revoke_role_statement">REVOKE ROLE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#rollback_work_statement">ROLLBACK WORK Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#select_statement">SELECT Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#set_schema_statement">SET SCHEMA Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#set_transaction_statement">SET TRANSACTION Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#table_statement">TABLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#update_statement">UPDATE Statement</a></p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="statements_that_are_trafodion_sql_extensions">2.6.2. Statements That Are Trafodion SQL Extensions</h4>
<div class="paragraph">
<p>These statements are Trafodion SQL extensions to the ANSI standard.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#alter_library_statement">ALTER LIBRARY Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#alter_user_statement">ALTER USER Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#begin_work_statement">BEGIN WORK Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#control_query_cancel_statement">CONTROL QUERY CANCEL Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#control_query_default_statement">CONTROL QUERY DEFAULT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_index_statement">CREATE INDEX Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_library_statement">CREATE LIBRARY Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_index_statement">DROP INDEX Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_library_statement">DROP LIBRARY Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#explain_statement">EXPLAIN Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_statement">GET Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_hbase_objects_statement">GET HBASE OBJECTS Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_version_of_metadata_statement">GET VERSION OF METADATA Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_version_of_software_statement">GET VERSION OF SOFTWARE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#grant_component_privilege_statement">GRANT COMPONENT PRIVILEGE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#invoke_statement">INVOKE Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#load_statement">LOAD Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#register_user_statement">REGISTER USER Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#revoke_component_privilege_statement">REVOKE COMPONENT PRIVILEGE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#showcontrol_statement">SHOWCONTROL Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#showddl_statement">SHOWDDL Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#showddl_schema_statement">SHOWDDL SCHEMA Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#showstats_statement">SHOWSTATS Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#unload_statement">UNLOAD Statement</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#unregister_user_statement">UNREGISTER USER Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#update_statistics_statement">UPDATE STATISTICS Statement</a></p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="ansi_compliant_functions">2.6.3. ANSI-Compliant Functions</h4>
<div class="paragraph">
<p>These functions are ANSI compliant, but some might contain Trafodion SQL extensions:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#avg">AVG function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#case">CASE expression</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#cast">CAST expression</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#char_length">CHAR_LENGTH</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#coalesce">COALESCE</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#count">COUNT Function</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current">CURRENT</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_date">CURRENT_DATE</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_time">CURRENT_TIME</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_timestamp">CURRENT_TIMESTAMP</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_user">CURRENT_USER</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#extract">EXTRACT</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#lower">LOWER</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#max">MAX</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#min">MIN</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#nullif">NULLIF</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#octet_length">OCTET_LENGTH</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#position">POSITION</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#session_user">SESSION_USER</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#substring">SUBSTRING</a></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#sum">SUM</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#trim">TRIM</a></p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>All other functions are Trafodion SQL extensions.</p>
</div>
</div>
</div>
<div class="sect2">
<h3 id="_trafodion_sql_error_messages">2.7. Trafodion SQL Error Messages</h3>
<div class="paragraph">
<p>Trafodion SQL reports error messages and exception conditions. When an error condition occurs,
Trafodion SQL returns a message number and a brief description of the condition.</p>
</div>
<div class="paragraph">
<p><strong>Example</strong></p>
</div>
<div class="paragraph">
<p>Trafodion SQL might display this error message:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">*** ERROR[1000] A syntax error occurred.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The message number is the SQLCODE value (without the sign). In this example, the SQLCODE value is <code>1000</code>.</p>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="sql_statements">3. SQL Statements</h2>
<div class="sectionbody">
<div class="paragraph">
<p>This section describes the syntax and semantics of Trafodion SQL statements.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL statements are entered interactively or from script files using a client-based tool, such as the
Trafodion Command Interface (TrafCI). To install and configure a client application that enables you to connect
to and use a Trafodion database, see the
<a href="http://trafodion.incubator.apache.org/docs/client_install/index.html"><em>Trafodion Client Installation</em> <em>Guide</em></a>.</p>
</div>
<div class="sect2">
<h3 id="sql_statements_categories">3.1. Categories</h3>
<div class="paragraph">
<p>The statements are categorized according to their functionality:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#data_definition_language_statements">Data Definition Language (DDL) Statements</a></p>
</li>
<li>
<p><a href="#data_manipulation_language_statements">Data Manipulation Language (DML) Statements</a></p>
</li>
<li>
<p><a href="#transaction_control_statements">Transaction Control Statements</a></p>
</li>
<li>
<p><a href="#data_control_and_security_statements">Data Control and Security Statements</a></p>
</li>
<li>
<p><a href="#stored_procedure_and_user_defined_function_statements">Stored Procedure and User-Defined Function Statements</a></p>
</li>
<li>
<p><a href="#prepared_statements">Prepared Statements</a></p>
</li>
<li>
<p><a href="#control_statements">Control Statements</a></p>
</li>
<li>
<p><a href="#object_naming_statements">Object Naming Statements</a></p>
</li>
<li>
<p><a href="#show_get_and_explain_statements">SHOW, GET, and EXPLAIN Statements</a></p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="data_definition_language_statements">3.1.1. Data Definition Language (DDL) Statements</h4>
<div class="paragraph">
<p>Use these DDL statements to create, drop, or alter the definition of a Trafodion SQL schema or object.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run DDL statements inside a user-defined
transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run these statements, AUTOCOMMIT must be turned ON
(the default) for the session.
</td>
</tr>
</table>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Statement</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">What It Does</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#alter_table_statement">ALTER TABLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Changes attributes for a table.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#alter_user_statement">ALTER USER Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Changes attributes for a user.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_function_statement">CREATE FUNCTION Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Registers a user-defined function (UDF) written in C as a function within a Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_index_statement">CREATE INDEX Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Creates an index on a table.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_library_statement">CREATE LIBRARY Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Registers a library object in a Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_procedure_statement">CREATE PROCEDURE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Registers a Java method as a stored procedure in Java (SPJ) within a Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_role_statement">CREATE ROLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Creates a role.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_schema_statement">CREATE SCHEMA Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Creates a schema in the database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_table_statement">CREATE TABLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Creates a table.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_view_statement">CREATE VIEW Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Creates a view.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_function_statement">DROP FUNCTION Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes a user-defined function (UDF) from the Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_index_statement">DROP INDEX Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Drops an index.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_library_statement">DROP LIBRARY Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes a library object from the Trafodion database and also removes the library file
referenced by the library object.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_procedure_statement">DROP PROCEDURE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes a stored procedure in Java (SPJ) from the Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_role_statement">DROP ROLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Drops a role.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_schema_statement">DROP SCHEMA Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Drops a schema from the database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_table_statement">DROP TABLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Drops a table.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_view_statement">DROP VIEW Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Drops a view.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#register_user_statement">REGISTER USER Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Registers a user in the SQL database, associating the user&#8217;s login name
with a database user name.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#unregister_user_statement">UNREGISTER USER Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes a database user name from the SQL database.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="data_manipulation_language_statements">3.1.2. Data Manipulation Language (DML) Statements</h4>
<div class="paragraph">
<p>Use these DML statements to delete, insert, select, or update rows in one or more tables:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Statement</th>
<th class="tableblock halign-left valign-top">What It Does</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#delete_statement">DELETE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Deletes rows from a table or view.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#insert_statement">INSERT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Inserts data into tables and views.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#merge_statement">MERGE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Either performs an upsert operation (that is, updates a table if the row
exists or inserts into a table if the row does not exist) or updates (merges) matching rows from one table to another.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#select_statement">SELECT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Retrieves data from tables and views.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#table_statement">TABLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Equivalent to the query specification SELECT * FROM <em>table</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#update_statement">UPDATE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Updates values in columns of a table or view.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#upsert_statement">UPSERT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Updates a table if the row exists or inserts into a table if the row does not exist.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#values_statement">VALUES Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays the results of the evaluation of the expressions and the results of row subqueries
within the row value constructors.</p></td>
</tr>
</tbody>
</table>
</div>
<div class="sect3">
<h4 id="transaction_control_statements">3.1.3. Transaction Control Statements</h4>
<div class="paragraph">
<p>Use these statements to specify user-defined transactions and to set attributes for the next transaction:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Statement</th>
<th class="tableblock halign-left valign-top">What It Does</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#begin_work_statement">BEGIN WORK Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Starts a transaction.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#commit_work_statement">COMMIT WORK Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Commits changes made during a transaction and ends the transaction.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#rollback_work_statement">ROLLBACK WORK Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Undoes changes made during a transaction and ends the transaction.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#set_transaction_statement">SET TRANSACTION Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Sets attributes for the next SQL transaction — whether to automatically
commit database changes.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="data_control_and_security_statements">3.1.4. Data Control and Security Statements</h4>
<div class="paragraph">
<p>Use these statements to register users, create roles, and grant and revoke privileges:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Statement</th>
<th class="tableblock halign-left valign-top">What It Does</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#alter_user_statement">ALTER USER Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Changes attributes associated with a user who is registered in the database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_role_statement">CREATE ROLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Creates an SQL role.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_role_statement">DROP ROLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Deletes an SQL role.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#grant_statement">GRANT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Grants access privileges on an SQL object or an SQL object&#8217;s columns to specified users or roles.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#grant_component_privilege_statement">GRANT COMPONENT PRIVILEGE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Grants one or more component privileges to a user or role.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#grant_role_statement">GRANT ROLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Grants one or more roles to a user.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#register_user_statement">REGISTER USER Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Registers a user in the SQL database, associating the user&#8217;s login name with a database user name.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#revoke_statement">REVOKE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes access privileges on an SQL object from specified users or roles.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#revoke_component_privilege_statement">REVOKE COMPONENT PRIVILEGE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes one or more component privileges from a user or role.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#revoke_role_statement">REVOKE ROLE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes one or more roles from a user.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#unregister_user_statement">UNREGISTER USER Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes a database user name from the SQL database.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="stored_procedure_and_user_defined_function_statements">3.1.5. Stored Procedure and User-Defined Function Statements</h4>
<div class="paragraph">
<p>Use these statements to create and execute stored procedures in Java (SPJs) or create user-defined functions (UDFs) and to modify
authorization to access libraries or to execute SPJs or UDFs:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Statement</th>
<th class="tableblock halign-left valign-top">What It Does</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#call_statement">CALL Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Initiates the execution of a stored procedure in Java (SPJ) in a Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_function_statement">CREATE FUNCTION Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Registers a user-defined function (UDF) written in C as a function within a Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_library_statement">CREATE LIBRARY Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Registers a library object in a Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#create_procedure_statement">CREATE PROCEDURE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Registers a Java method as a stored procedure in Java (SPJ) within a Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_function_statement">DROP FUNCTION Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes a user-defined function (UDF) from the Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_library_statement">DROP LIBRARY Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes a library object from the Trafodion database and also removes the library file
referenced by the library object.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#drop_procedure_statement">DROP PROCEDURE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes a stored procedure in Java (SPJ) from the Trafodion database.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#grant_statement">GRANT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Grants privileges for accessing a library object or executing an SPJ or UDF to specified users.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#revoke_statement">REVOKE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes privileges for accessing a library object or executing an SPJ or UDF from specified users.
UDF from specified users.</p></td>
</tr>
</tbody>
</table>
</div>
<div class="sect3">
<h4 id="prepared_statements">3.1.6. Prepared Statements</h4>
<div class="paragraph">
<p>Use these statements to prepare and execute an SQL statement:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Statement</th>
<th class="tableblock halign-left valign-top">What It Does</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#execute_statement">EXECUTE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Executes an SQL statement previously compiled by a PREPARE statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#prepare_statement">PREPARE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Compiles an SQL statement for later use with the EXECUTE statement in the same session.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="control_statements">3.1.7. Control Statements</h4>
<div class="paragraph">
<p>Use these statements to control the execution, default options, plans, and performance of DML statements:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Statement</th>
<th class="tableblock halign-left valign-top">What It Does</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#control_query_cancel_statement">CONTROL QUERY CANCEL Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Cancels an executing query that you identify with a query ID.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#control_query_default_statement">CONTROL QUERY DEFAULT Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Changes a default attribute to influence a query plan.</p></td>
</tr>
</tbody>
</table>
</div>
<div class="sect3">
<h4 id="object_naming_statements">3.1.8. Object Naming Statements</h4>
<div class="paragraph">
<p>Use this statements to specify default ANSI names for the schema:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Statement</th>
<th class="tableblock halign-left valign-top">What It Does</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#set_schema_statement">SET SCHEMA Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Sets the default ANSI schema for unqualified object names for the current session.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="show_get_and_explain_statements">3.1.9. SHOW, GET, and EXPLAIN Statements</h4>
<div class="paragraph">
<p>Use these statements to display information about database objects or query execution plans:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Statement</th>
<th class="tableblock halign-left valign-top">What It Does</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#explain_statement">EXPLAIN Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays information contained in the query execution plan.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_statement">GET Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays the names of database objects, components, component
privileges, roles, or users that exist in the Trafodion instance.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_hbase_objects_statement">GET HBASE OBJECTS Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays a list of HBase objects through an SQL interface</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_version_of_metadata_statement">GET VERSION OF METADATA Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays the version of the metadata in the Trafodion instance and
indicates if the metadata is current.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#get_version_of_software_statement">GET VERSION OF SOFTWARE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays the version of the Trafodion software that is installed on the
system and indicates if it is current.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#invoke_statement">INVOKE Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Generates a record description that corresponds to a row in the
specified table or view.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#showcontrol_statement">SHOWCONTROL Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays the CONTROL QUERY DEFAULT attributes in effect.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#showddl_statement">SHOWDDL Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Describes the DDL syntax used to create an object as it exists in the
metadata, or it returns a description of a user, role, or component in the form of a GRANT statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#showddl_schema_statement">SHOWDDL SCHEMA Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays the DDL syntax used to create a schema as it exists in the
metadata and shows the authorization ID that owns the schema.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#showstats_statement">SHOWSTATS Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Displays the histogram statistics for one or more groups of columns
within a table. These statistics are used to devise optimized access plans.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="alter_sequence_statement">3.2. ALTER SEQUENCE Statement</h3>
<div class="paragraph">
<p>The ALTER SEQUENCE Statement changes the future behavior of exiting sequence, including INCREMENT, MAXVALUE, CACHE and CYCLE.</p>
</div>
<div class="paragraph">
<p>Multiple options can be concurrently specified and separated by a space. Any options not altered will
retain their previous settings.</p>
</div>
<div class="paragraph">
<p>ALTER SEQUENCE is a Trafodion SQL extension.</p>
</div>
<div class="paragraph">
<p>For more inforamation, see <a href="#create_sequence_statement">CREATE SEQUENCE Statement</a> or <a href="#drop_sequence_statement">DROP SEQUENCE Statement</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ALTER SEQUENCE [[catalog-name.]schema-name.]sequence
[INCREMENT BY integer]
[MAXVALUE integer | NO MAXVALUE]
[CACHE integer]
[CYCLE | NO CYCLE]</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="alter_sequence_syntax">3.2.1. Syntax Description of ALTER SEQUENCE</h4>
<div class="paragraph">
<p>The options above serve the same purposes as they serve when you create a sequence. For more information, see <a href="#create_sequence_statement">CREATE SEQUENCE Statement</a>.</p>
</div>
<div class="paragraph">
<p>NOTE:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>START WITH, MINVALUE, NO CACHE and DATA TYPE cannot be changed. Instead, drop and recreate the sequence specifying the desired options.</p>
</li>
<li>
<p>The unused preallocated values will be lost if a sequence is altered.</p>
</li>
<li>
<p>Some sequence values will be skipped if you change the INCREMENT BY before the first reference to <code>seqnum(SEQUENCE, next)</code>.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="alter_sequence_considerations">3.2.2. Considerations for ALTER SEQUENCE</h4>
<div class="paragraph">
<p>To issue an ALTER SEQUENCE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You have the ALTER or ALTER_SEQUENCE component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="alter_sequence_examples">3.2.3. Examples of ALTER SEQUENCE</h4>
<div class="paragraph">
<p>The following statement changes the MAXVALUE and CACHE for the sequence named <code>employee_seq</code>, which is created in <a href="#create_sequence_examples">Examples of CRAETE SEQUENCE</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ALTER SEQUENCE employee_seq
MAXVALUE 20000
CACHE 30</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="alter_table_statement">3.3. ALTER TABLE Statement</h3>
<div class="paragraph">
<p>The ALTER TABLE statement changes a Trafodion SQL table. See <a href="#tables">Tables</a>.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this
statement inside a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF.
To run this statement, AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ALTER TABLE name alter-action
alter-action is:
ADD [IF NOT EXISTS][COLUMN] column-definition
| ADD [CONSTRAINT constraint-name] table-constraint
| DROP CONSTRAINT constraint-name [RESTRICT]
| RENAME TO new-name
| DROP COLUMN [IF EXISTS] column-name
column-definition is:
column-name data-type
([DEFAULT default]
[[constraint constraint-name] column-constraint])
data-type is:
char[acter] [(length)[characters]]
[CHARACTER SET char-set-name]
[UPSHIFT] [[not] casespecific]
| char[acter] varying (length)
[character set char-set-name]
[upshift] [[not] casespecific]
| varchar (length) [character set char-set-name]
[upshift] [[not] casespecific]
| numeric [(precision [,scale])] [signed|unsigned]
| nchar [(length) [character set char-set-name]
[upshift] [[not] casespecific]
| nchar varying(length) [character set char-set-name]
[upshift] [[not] casespecific]
| smallint [signed|unsigned]
| int[eger] [signed|unsigned]
| largeint
| dec[imal] [(precision [,scale])] [signed|unsigned]
| float [(precision)]
| real
| double precision
| date
| time [(time-precision)]
| timestamp [(timestamp-precision)]
| interval { start-field to end-field | single-field }
default is:
literal
| null
| currentdate
| currenttime
| currenttimestamp }
column-constraint is:
not null
| unique
| check (condition)
| references ref-spec
table-constraint is:
unique (column-list)
| check (condition)
| foreign key (column-list) references ref-spec
ref-spec is:
referenced-table [(column-list)]
column-list is:
column-name[, column-name]...</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="alter_table_syntax">3.3.1. Syntax Description of ALTER TABLE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>name</em></code></p>
<div class="paragraph">
<p>specifies the current name of the object. See <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code>ADD [COLUMN] <em>column-definition</em></code></p>
<div class="paragraph">
<p>adds a column to <em>table</em>.</p>
</div>
<div class="paragraph">
<p>The clauses for the <em>column-definition</em> are:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-name</em></code></p>
<div class="paragraph">
<p>specifies the name for the new column in the table. <em>column-name</em> is an SQL identifier. <em>column-name</em> must be
unique among column names in the table. If the column name is a Trafodion SQL reserved word, you must
delimit it by enclosing it in double quotes. For example: <code>"sql".myview</code>. See <a href="#identifiers">Identifiers</a>.</p>
</div>
</li>
<li>
<p><code><em>data-type</em></code></p>
<div class="paragraph">
<p>specifies the data type of the values that can be stored in <em>column-name</em>. See <a href="#Data_Types">Data Types</a>
If a default is not specified, NULL is used.</p>
</div>
</li>
<li>
<p><code>DEFAULT <em>default</em></code></p>
<div class="paragraph">
<p>specifies a default value for the column or specifies that the column does not have a default value. You can declare the default value
explicitly by using the DEFAULT clause, or you can enable null to be used as the default by omitting both the DEFAULT and NOT NULL clauses.
If you omit the DEFAULT clause and specify NOT NULL, Trafodion SQL returns an error. For existing rows of the table, the added column takes
on its default value.</p>
</div>
<div class="paragraph">
<p>If you set the default to the datetime value CURRENT_DATE, CURRENT_TIME, or CURRENT_TIMESTAMP, Trafodion SQL uses January 1, 1 A.D.
12:00:00.000000 as the default date and time for the existing rows.</p>
</div>
<div class="paragraph">
<p>For any row that you add after the column is added, if no value is specified for the column as part of the add row operation, the column
receives a default value based on the current timestamp at the time the row is added.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>[[constraint <em>constraint-name</em>] <em>column-constraint</em>]</code></p>
<div class="paragraph">
<p>specifies a name for the column or table constraint. <em>constraint-name</em> must have the same schema as <em>table</em> and must be
unique among constraint names in its schema. if you omit the schema portions of the name you specify in <em>constraint-name</em>,
trafodion sql expands the constraint name by using the schema for <em>table</em>. see <a href="#database_object_names">database object names</a>.</p>
</div>
<div class="paragraph">
<p>if you do not specify a constraint name, trafodion sql constructs an sql identifier as the name for the constraint in the schema
for <em>table.</em> the identifier consists of the fully qualified table name concatenated with a system-generated unique identifier.
for example, a constraint on table a.b.c might be assigned a name such as a.b.c_123&#8230;_01&#8230;.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-constraint</em></code> options:</p>
<div class="ulist">
<ul>
<li>
<p><code>not null</code></p>
<div class="paragraph">
<p>is a column constraint that specifies that the column cannot contain nulls. if you omit not null, nulls are allowed in the column.
if you specify both not null and no default, then each row inserted in the table must include a value for the column. see <a href="#null">null</a>.</p>
</div>
</li>
<li>
<p><code>unique</code></p>
<div class="paragraph">
<p>is a column constraint that specifies that the column cannot contain more than one occurrence of the same value. if you omit unique,
duplicate values are allowed unless the column is part of the primary key. columns that you define as unique must be specified as not null.</p>
</div>
</li>
<li>
<p><code>check (<em>condition</em>)</code></p>
<div class="paragraph">
<p>is a constraint that specifies a condition that must be satisfied for each row in the table. see <a href="#search_condition">search condition</a>.
you cannot refer to the current_date, current_time, or current_timestamp function in a check constraint, and you cannot use
subqueries in a check constraint.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>references <em>ref-spec</em></code></p>
<div class="paragraph">
<p>specifies a references column constraint. the maximum combined length of the columns for a references constraint is 2048 bytes.<br></p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>ref-spec</em></code> is:</p>
<div class="paragraph">
<p><code><em>referenced-table</em> [(<em>column-list</em>)]</code></p>
</div>
<div class="paragraph">
<p><code><em>referenced-table</em></code> is the table referenced by the foreign key in a referential constraint. <em>referenced-table</em> cannot be a view.
<em>referenced-table</em> cannot be the same as <em>table</em>. <em>referenced-table</em> corresponds to the foreign key in the <em>table</em>.
<br>
<code><em>column-list</em></code> specifies the column or set of columns in the <em>referenced-table</em> that corresponds to the foreign key in <em>table</em>. the
columns in the column list associated with references must be in the same order as the columns in the column list associated with foreign
key. if <em>column-list</em> is omitted, the referenced table&#8217;s primary key columns are the referenced columns.</p>
</div>
<div class="paragraph">
<p>a table can have an unlimited number of referential constraints, and you can specify the same foreign key in more than one referential
constraint, but you must define each referential constraint separately. you cannot create self-referencing foreign key constraints.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>add [constraint <em>constraint-name</em>] <em>table-constraint</em></code></p>
<div class="paragraph">
<p>adds a constraint to the table and optionally specifies <em>constraint-name</em> as the name for the constraint. the new constraint
must be consistent with any data already present in the table.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>constraint <em>constraint-name</em></code></p>
<div class="paragraph">
<p>specifies a name for the column or table constraint. <em>constraint-name</em> must have the same schema as <em>table</em> and must be unique among constraint
names in its schema. if you omit the schema portions of the name you specify in <em>constraint-name</em>, trafodion sql expands the constraint
name by using the schema for table. see <a href="#database_object_names">database object names</a>.</p>
</div>
<div class="paragraph">
<p>if you do not specify a constraint name, trafodion sql constructs an sql identifier as the name for the constraint in the schema for table. the
identifier consists of the fully qualified table name concatenated with a system-generated unique identifier. for example, a constraint on table
a.b.c might be assigned a name such as a.b.c_123&#8230;_01&#8230;.</p>
</div>
</li>
<li>
<p><code><em>table-constraint</em></code> options:</p>
<div class="ulist">
<ul>
<li>
<p><code>unique (<em>column-list</em>)</code></p>
<div class="paragraph">
<p>is a table constraint that specifies that the column or set of columns cannot contain more
than one occurrence of the same value or set of values.</p>
</div>
<div class="paragraph">
<p><code><em>column-list</em></code> cannot include more than one occurrence of the same column. in addition, the set of columns that you specify on a unique
constraint cannot match the set of columns on any other unique constraint for the table or on the primary key constraint for the table.
all columns defined as unique must be specified as not null.</p>
</div>
<div class="paragraph">
<p>a unique constraint is enforced with a unique index. if there is already a unique index on <em>column-list</em>, trafodion sql uses that index. if a
unique index does not exist, the system creates a unique index.</p>
</div>
</li>
<li>
<p><code>check (<em>condition</em>)</code></p>
<div class="paragraph">
<p>is a constraint that specifies a condition that must be satisfied for each row in the table.
see <a href="#search_condition">search condition</a>. you cannot refer to the current_date, current_time, or current_timestamp function in a check
constraint, and you cannot use subqueries in a check constraint.</p>
</div>
</li>
<li>
<p><code>foreign key (<em>column-list</em>) references <em>ref-spec</em> not enforced</code></p>
<div class="paragraph">
<p>is a table constraint that specifies a referential constraint for the table, declaring that a column or set of columns (called a foreign key)
in <em>table</em> can contain only values that match those in a column or set of columns in the table specified in the references
clause. however, because not enforced is specified, this relationship is not checked.</p>
</div>
<div class="paragraph">
<p>the two columns or sets of columns must have the same characteristics (data type, length, scale, precision). without the foreign key clause,
the foreign key in <em>table</em> is the column being defined; with the foreign key clause, the foreign key is the column or set of columns specified in
the foreign key clause. for information about <em>ref-spec</em>, see references <em>ref-spec</em> not enforced.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>drop constraint <em>constraint-name</em> [restrict]</code></p>
<div class="paragraph">
<p>drops a constraint from the table.<br></p>
</div>
<div class="paragraph">
<p>if you drop a constraint, trafodion sql drops its dependent index if trafodion sql originally created the same index. if the constraint uses
an existing index, the index is not dropped.<br></p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>constraint <em>constraint-name</em></code></p>
<div class="paragraph">
<p>specifies a name for the column or table constraint. <em>constraint-name</em> must have the same schema as <em>table</em> and must be unique among constraint
names in its schema. if you omit the schema portions of the name you specify in <em>constraint-name</em>, trafodion sql expands the constraint
name by using the schema for table. see <a href="#database_object_names">database object names</a>.</p>
</div>
<div class="paragraph">
<p>if you do not specify a constraint name, trafodion sql constructs an sql identifier as the name for the constraint in the schema for table. the
identifier consists of the fully qualified table name concatenated with a system-generated unique identifier. for example, a constraint on table
a.b.c might be assigned a name such as a.b.c_123&#8230;_01&#8230;.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>rename to <em>new-name</em></code></p>
<div class="paragraph">
<p>changes the logical name of the object within the same schema.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>new-name</em></code></p>
<div class="paragraph">
<p>specifies the new name of the object after the rename to operation occurs.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>add if not exists <em>column-definition</em></code></p>
<div class="paragraph">
<p>adds a column to <em>table</em> if it does not already exist in the table.</p>
</div>
<div class="paragraph">
<p>the clauses for the <em>column-definition</em> are the same as described in add [column] <em>column-definition</em>.</p>
</div>
</li>
<li>
<p><code>drop column [if exists] <em>column-name</em></code></p>
<div class="paragraph">
<p>drops the specified column from <em>table</em>, including the column’s data. you cannot drop a primary key column.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="alter_table_considerations">3.3.2. Considerations for ALTER TABLE</h4>
<div class="sect4">
<h5 id="effect_of_adding_a_column_on_view_definitions">Effect of Adding a Column on View Definitions</h5>
<div class="paragraph">
<p>The addition of a column to a table has no effect on existing view definitions. Implicit column references specified by SELECT * in view
definitions are replaced by explicit column references when the definition clauses are originally evaluated.</p>
</div>
</div>
<div class="sect4">
<h5 id="authorization_and_availability_requirements">Authorization and Availability Requirements</h5>
<div class="paragraph">
<p>ALTER TABLE works only on user-created tables.</p>
</div>
<div class="sect5">
<h6 id="_required_privileges">Required Privileges</h6>
<div class="paragraph">
<p>To issue an ALTER TABLE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the table.</p>
</li>
<li>
<p>You have the ALTER or ALTER_TABLE component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="_privileges_needed_to_create_a_referential_integrity_constraint">Privileges Needed to Create a Referential Integrity Constraint</h6>
<div class="paragraph">
<p>To create a referential integrity constraint (that is, a constraint on the table that refers to a column in another table), one of the
following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the referencing and referenced tables.</p>
</li>
<li>
<p>You have these privileges on the referencing and referenced table:</p>
<div class="ulist">
<ul>
<li>
<p>For the referencing table, you have the ALTER or ALTER_TABLE component privilege for the SQL_OPERATIONS component.</p>
</li>
<li>
<p>For the referenced table, you have the REFERENCES (or ALL) privilege on the referenced table through your user name or through a granted role.</p>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>If the constraint refers to the other table in a query expression, you must also have SELECT privileges on the other table.</p>
</div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="alter_table_examples">3.3.3. Example of ALTER TABLE</h4>
<div class="paragraph">
<p>This example adds a column:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ALTER TABLE persnl.project
ADD COLUMN projlead
NUMERIC (4) UNSIGNED</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="alter_user_statement">3.4. ALTER USER Statement</h3>
<div class="paragraph">
<p>The ALTER USER statement changes attributes associated with a user who is registered in the database.</p>
</div>
<div class="paragraph">
<p>ALTER USER is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ALTER USER database-username alter-action[, alter-action]
alter-action is:
SET EXTERNAL NAME directory-service-username
| SET { ONLINE | OFFLINE }</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="alter_user_syntax">3.4.1. Syntax Description of ALTER USER</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>database-username</em></code></p>
<div class="paragraph">
<p>is the name of a currently registered database user.</p>
</div>
</li>
<li>
<p><code>SET EXTERNAL NAME</code></p>
<div class="paragraph">
<p>changes the name that identifies the user in the directory service. This is also the name the user specifies when
connecting to the database.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>directory-service-username</em></code></p>
<div class="paragraph">
<p>specifies the new name of the user in the directory service.</p>
</div>
</li>
<li>
<p><code><em>directory-service-username</em></code> is a regular or delimited case-insensitive
identifier. See <a href="#Case_Insensitive_Delimited_Identifiers">Case-Insensitive Delimited Identifiers</a>.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>SET { ONLINE | OFFLINE }</code></p>
<div class="paragraph">
<p>changes the attribute that controls whether the user is allowed to connect to the database.<br></p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ONLINE</code></p>
<div class="paragraph">
<p>specifies that the user is allowed to connect to the database.</p>
</div>
</li>
<li>
<p><code>OFFLINE</code></p>
<div class="paragraph">
<p>specifies that the user is not allowed to connect to the database.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="alter_user_considerations">3.4.2. Considerations for ALTER USER</h4>
<div class="paragraph">
<p>Only a user with user administrative privileges (that is, a user who has been granted the MANAGE_USERS component privilege)
can do the following:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Set the EXTERNAL NAME for any user</p>
</li>
<li>
<p>Set the ONLINE | OFFLINE attribute for any user</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Initially, DB_ROOT is the only database user who has been granted the MANAGE_USERS component privilege.</p>
</div>
</div>
<div class="sect3">
<h4 id="alter_user_examples">3.4.3. Examples of ALTER USER</h4>
<div class="ulist">
<ul>
<li>
<p>To change a user&#8217;s external name:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ALTER USER ajones SET EXTERNAL NAME &quot;Americas\ArturoJones&quot;;</code></pre>
</div>
</div>
</li>
<li>
<p>To change a user&#8217;s attribute to allow the user to connect to the database:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ALTER USER ajones SET ONLINE;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="begin_work_statement">3.5. BEGIN WORK Statement</h3>
<div class="paragraph">
<p>The BEGIN WORK statement enables you to start a transaction explicitly—where the transaction consists of the set of operations
defined by the sequence of SQL statements that begins immediately after BEGIN WORK and ends with the next COMMIT or ROLLBACK
statement. See <a href="#Transaction_Management">Transaction Management</a>. BEGIN WORK will raise an error if a transaction is currently active.</p>
</div>
<div class="paragraph">
<p>BEGIN WORK is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">BEGIN WORK</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="begin_work_considerations">3.5.1. Considerations for BEGIN WORK</h4>
<div class="paragraph">
<p>BEGIN WORK starts a transaction. COMMIT WORK or ROLLBACK WORK ends a transaction.</p>
</div>
</div>
<div class="sect3">
<h4 id="begin_work_examples">3.5.2. Example of BEGIN WORK</h4>
<div class="paragraph">
<p>Group three separate statements—two INSERT statements and an UPDATE statement—that update the database within a single transaction:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">--- This statement initiates a transaction.
BEGIN WORK;
--- SQL operation complete.
INSERT INTO sales.orders VALUES (125, DATE '2008-03-23', DAT '2008-03-30', 75, 7654);
--- 1 row(s) inserted.
INSERT INTO sales.odetail VALUES (125, 4102, 25000, 2);
--- 1 row(s) inserted.
UPDATE invent.partloc SET qty_on_hand = qty_on_hand - 2
WHERE partnum = 4102 AND loc_code = 'G45';
--- 1 row(s) updated.
--- This statement ends a transaction.
COMMIT WORK;
--- SQL operation complete.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="call_statement">3.6. CALL Statement</h3>
<div class="paragraph">
<p>The CALL statement invokes a stored procedure in Java (SPJ) in a Trafodion SQL database.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CALL procedure-ref ([argument-list])
procedure-ref is:
[[catalog-name.]schema-name.]procedure-name
argument-list is:
sql-expression[, sql-expression]...</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="call_syntax">3.6.1. Syntax Description of CALL</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>procedure-ref</em></code></p>
<div class="paragraph">
<p>specifies an ANSI logical name of the form:</p>
</div>
<div class="paragraph">
<p><code>[[_catalog-name_.]<em>schema-name</em>.]<em>procedure-name</em></code></p>
</div>
<div class="paragraph">
<p>where each part of the name is a valid sql identifier with a maximum of 128 characters. for more information, see
<a href="#identifiers">identifiers</a> and <a href="#database_object_names">database object names</a>.</p>
</div>
<div class="paragraph">
<p>if you do not fully qualify the procedure name, trafodion sql qualifies it according to the schema of the current session.</p>
</div>
</li>
<li>
<p><code><em>argument-list</em></code></p>
<div class="paragraph">
<p>accepts arguments for in, in-out, or out parameters. the arguments consist of sql expressions, including dynamic parameters,
separated by commas:</p>
</div>
<div class="paragraph">
<p><code><em>sql-expression</em>[{, <em>sql-expression</em>}&#8230;]</code></p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>each expression must evaluate to a value of one of these data types:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>character value</p>
</li>
<li>
<p>date-time value</p>
</li>
<li>
<p>numeric value</p>
<div class="paragraph">
<p>interval value expressions are disallowed in SPJs. for more information, see
<a href="#call_input_parameter_arguments">input parameter arguments</a> and
<a href="#call_output_parameter_arguments">output parameter arguments</a>.</p>
</div>
<div class="paragraph">
<p>do not specify result sets in the argument list.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="call_considerations">3.6.2. Considerations for CALL</h4>
<div class="sect4">
<h5 id="call_usage_restrictions">Usage Restrictions</h5>
<div class="paragraph">
<p>You can use a CALL statement as a stand-alone SQL statement in applications or command-line interfaces,
such as TrafCI. You cannot use a CALL statement inside a compound statement or with row sets.</p>
</div>
</div>
<div class="sect4">
<h5 id="call_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a CALL statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the stored procedure.</p>
</li>
<li>
<p>You have the EXECUTE (or ALL) privileges, either directly through your username or through a granted role.
For more information, see the <a href="#GRANT_Statement">GRANT Statement</a>.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>When the stored procedure executes, it executes as the Trafodion ID.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="call_input_parameter_argument">Input Parameter Arguments</h5>
<div class="paragraph">
<p>You pass data to an SPJ by using IN or INOUT parameters. For an IN
parameter argument, use one of these SQL expressions:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Literal</p>
</li>
<li>
<p>SQL function (including CASE and CAST expressions)</p>
</li>
<li>
<p>Arithmetic or concatenation operation</p>
</li>
<li>
<p>Scalar subquery</p>
</li>
<li>
<p>Dynamic parameter (for example, ?) in an application</p>
</li>
<li>
<p>Named (for example, ?param) or unnamed (for example, ?) parameter in TrafCI</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For an INOUT parameter argument, you can use only a dynamic, named, or unnamed parameter. For more information, see
<a href="#expressions">Expressions</a>.</p>
</div>
</div>
<div class="sect4">
<h5 id="call_output_parameter_arguments">Output Parameter Arguments</h5>
<div class="paragraph">
<p>An SPJ returns values in OUT and INOUT parameters. Output parameter arguments must be dynamic parameters in an
application (for example, ?) or named or unnamed parameters in DCI (for example, ?param or ?). Each
calling application defines the semantics of the OUT and INOUT parameters in its environment.</p>
</div>
</div>
<div class="sect4">
<h5 id="call_data_conversion_parameter_arguments">Data Conversion of Parameter Arguments</h5>
<div class="paragraph">
<p>Trafodion SQL performs an implicit data conversion when the data type of a parameter argument is compatible with
but does not match the formal data type of the stored procedure. For stored procedure input values,
the conversion is from the actual argument value to the formal parameter type. For stored procedure output values,
the conversion is from the actual output value, which has the data type of the formal parameter, to the declared
type of the dynamic parameter.</p>
</div>
</div>
<div class="sect4">
<h5 id="call_null_input_and_output">Null Input and Output</h5>
<div class="paragraph">
<p>You can pass a null value as input to or output from an SPJ, provided that the corresponding Java data type of the
parameter supports nulls. If a null is input or output for a parameter that does not support nulls, Trafodion SQL
returns an error.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="call_transaction_semantics">Transaction Semantics</h5>
<div class="paragraph">
<p>The CALL statement automatically initiates a transaction if no active transaction exists. However, the failure of
a CALL statement does not always automatically abort the transaction.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="call_examples">3.6.3. Examples of CALL</h4>
<div class="ulist">
<ul>
<li>
<p>In TrafCI, execute an SPJ named MONTHLYORDERS, which has one IN parameter represented by a literal and one OUT
parameter represented by an unnamed parameter, ?:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CALL sales.monthlyorders(3,?);</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This CALL statement executes a stored procedure, which accepts one IN parameter (a date literal), returns one OUT
parameter (a row from the column, NUM_ORDERS), and returns two result sets:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CALL sales.ordersummary('01/01/2001', ?);
NUM_ORDERS
--------------------
13
ORDERNUM NUM_PARTS AMOUNT ORDER_DATE LAST_NAME
---------- -------------- --------------- ---------- ------------------
100210 4 19020.00 2006-04-10 HUGHES
100250 4 22625.00 2006-01-23 HUGHES
101220 4 45525.00 2006-07-21 SCHNABL
200300 3 52000.00 2006-02-06 SCHAEFFER
200320 4 9195.00 2006-02-17 KARAJAN
200490 2 1065.00 2006-03-19 WEIGL
.
.
.
--- 13 row(s) selected.
ORDERNUM PARTNUM UNIT_PRICE QTY_ORDERED PARTDESC
---------- -------- ------------ ----------- ------------------
100210 2001 1100.00 3 GRAPHIC PRINTER,M1
100210 2403 620.00 6 DAISY PRINTER,T2
100210 244 3500.00 3 PC GOLD, 30 MB
100210 5100 150.00 10 MONITOR BW, TYPE 1
100250 6500 95.00 10 DISK CONTROLLER
100250 6301 245.00 15 GRAPHIC CARD, HR
.
.
.
--- 70 row(s) selected.
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="commit_work_statement">3.7. COMMIT WORK Statement</h3>
<div class="paragraph">
<p>The COMMIT WORK statement commits any changes to objects made during the current transaction and ends
the transaction. See <a href="#Transaction_Management">Transaction Management</a>.</p>
</div>
<div class="paragraph">
<p>WORK is an optional keyword that has no effect.</p>
</div>
<div class="paragraph">
<p>COMMIT WORK issued outside of an active transaction generates error 8605.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COMMIT [WORK]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="commit_work_considerations">3.7.1. Considerations for COMMIT WORK</h4>
<div class="paragraph">
<p>BEGIN WORK starts a transaction. COMMIT WORK or ROLLBACK WORK ends a transaction.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="commit_work_examples">3.7.2. Example of COMMIT WORK</h4>
<div class="paragraph">
<p>Suppose that your application adds information to the inventory. You have received 24 terminals from
a new supplier and want to add the supplier and update the quantity on hand. The part number for the
terminals is 5100, and the supplier is assigned supplier number 17. The cost of each terminal is $800.</p>
</div>
<div class="paragraph">
<p>The transaction must add the order for terminals to PARTSUPP, add the supplier to the SUPPLIER table,
and update QTY_ON_HAND in PARTLOC. After the INSERT and UPDATE statements execute successfully,
you commit the transaction, as shown:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">-- This statement initiates a transaction.
BEGIN WORK;
--- SQL operation complete.
-- This statement inserts a new entry into PARTSUPP.
INSERT INTO invent.partsupp
VALUES (5100, 17, 800.00, 24);
--- 1 row(s) inserted.
-- This statement inserts a new entry into SUPPLIER.
INSERT INTO invent.supplier
VALUES (17, 'Super Peripherals','751 Sanborn Way',
'Santa Rosa', 'California', '95405');
--- 1 row(s) inserted.
-- This statement updates the quantity in PARTLOC.
UPDATE invent.partloc
SET qty_on_hand = qty_on_hand + 24
WHERE partnum = 5100 AND loc_code = 'G43';
--- 1 row(s) updated.
-- This statement ends a transaction.
COMMIT WORK;
--- SQL operation complete.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="control_query_cancel_statement">3.8. CONTROL QUERY CANCEL Statement</h3>
<div class="paragraph">
<p>The CONTROL QUERY CANCEL statement cancels an executing query that you identify with a query ID.
You can execute the CONTROL QUERY CANCEL statement in a client-based tool like TrafCI or through any ODBC or JDBC
application.</p>
</div>
<div class="paragraph">
<p>CONTROL QUERY CANCEL is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CONTROL QUERY CANCEL QID query-id [COMMENT 'comment-text']</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="control_query_cancel_syntax">3.8.1. Syntax Description of CONTROL QUERY CANCEL</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>query-id</em></code></p>
<div class="paragraph">
<p>specifies the query ID of an executing query, which is a unique identifier generated by the SQL compiler.</p>
</div>
</li>
<li>
<p><code>'<em>comment-text</em>'</code></p>
<div class="paragraph">
<p>specifies an optional comment to be displayed in the canceled query’s error message.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="control_query_cancel_considerations">3.8.2. Considerations for CONTROL QUERY CANCEL</h4>
<div class="sect4">
<h5 id="control_query_cancel_benefitsl">Benefits of CONTROL QUERY CANCEL</h5>
<div class="paragraph">
<p>For many queries, the CONTROL QUERY CANCEL statement allows the termination of the query without stopping the
master executor process (MXOSRVR). This type of cancellation has these benefits over standard ODBC/JDBC cancel
methods:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>An ANSI-defined error message is returned to the client session, and SQLSTATE is set to HY008.</p>
</li>
<li>
<p>Important cached objects persist after the query is canceled, including the master executor process and its
compiler, the compiled statements cached in the master, and the compiler’s query cache and its cached metadata
and histograms.</p>
</li>
<li>
<p>The client does not need to reestablish its connection, and its prepared statements are preserved.</p>
</li>
<li>
<p>When clients share connections using a middle-tier application server, the effects of canceling one client’s
executing query no longer affect other clients sharing the same connection.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="control_query_cancel_restrictions">Restrictions on CONTROL QUERY CANCEL</h5>
<div class="paragraph">
<p>Some executing queries may not respond to a CONTROL QUERY CANCEL statement within a 60-second interval. For those
queries, Trafodion SQL stops their ESP processes if there are any. If this action allows the query to be canceled,
you will see all the benefits listed above.</p>
</div>
<div class="paragraph">
<p>If the executing query does not terminate within 120 seconds after the CONTROL QUERY CANCEL statement is issued,
Trafodion SQL stops the master executor process, terminating the query and generating a lost connection error.
In this case, you will not see any of the benefits listed above. Instead, you will lose your connection and will
need to reconnect and re-prepare the query. This situation often occurs with the CALL, DDL, and utility statements
and rarely with other statements.</p>
</div>
<div class="paragraph">
<p>The CONTROL QUERY CANCEL statement does not work with these statements:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Unique queries, which operate on a single row and a single partition</p>
</li>
<li>
<p>Queries that are not executing, such as a query that is being compiled</p>
</li>
<li>
<p>CONTROL QUERY DEFAULT, BEGIN WORK, COMMIT WORK, ROLLBACK WORK, and EXPLAIN statements</p>
</li>
<li>
<p>Statically compiled metadata queries</p>
</li>
<li>
<p>Queries executed in anomalous conditions, such as queries without runtime statistics or without a query ID</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="control_query_cancel_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a CONTROL QUERY CANCEL statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You own (that is, issued) the query.</p>
</li>
<li>
<p>You have the QUERY_CANCEL component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="control_query_cancel_examples">3.8.3. Example of CONTROL QUERY CANCEL</h4>
<div class="paragraph">
<p>This CONTROL QUERY CANCEL statement cancels a specified query and provides a comment concerning the cancel
operation:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">control query cancel qid
MXID11000010941212288634364991407000000003806U3333300_156016_S1 comment
'Query is consuming too many resources.';</code></pre>
</div>
</div>
<div class="paragraph">
<p>In a separate session, the client that issued the query will see this
error message indicating that the query has been canceled:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;execute s1;
*** ERROR[8007] The operation has been canceled. Query is consuming too many resources.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="control_query_default_statement">3.9. CONTROL QUERY DEFAULT Statement</h3>
<div class="paragraph">
<p>The CONTROL QUERY DEFAULT statement changes the default settings for the current process. You can execute
the CONTROL QUERY DEFAULT statement in a client-based tool like TrafCI or through any ODBC or JDBC application.</p>
</div>
<div class="paragraph">
<p>CONTROL QUERY DEFAULT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">{ CONTROL QUERY DEFAULT | CQD } control-default-option
control-default-option is:
attribute {'attr-value' | RESET}</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="control_query_default_syntax">3.9.1. Syntax Description of CONTROL QUERY DEFAULT</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>attribute</em></code></p>
<div class="paragraph">
<p>is a character string that represents an attribute name. For descriptions of these attributes,
see the <a href="http://trafodion.incubator.apache.org/docs/cqd_reference/index.html">Trafodion Control Query Default (CQD) Reference Guide</a>.</p>
</div>
</li>
<li>
<p><code><em>attr-value</em></code></p>
<div class="paragraph">
<p>is a character string that specifies an attribute value. You must specify <em>attr-value</em> as a quoted string—even
if the value is a number.</p>
</div>
</li>
<li>
<p><code>RESET</code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>specifies that the attribute that you set by using a CONTROL QUERY DEFAULT statement in the current session is
to be reset to the value or values in effect at the start of the current session.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="control_query_default_considerations">3.9.2. Considerations for CONTROL QUERY DEFAULT</h4>
<div class="sect4">
<h5 id="control_query_default_scope">Scope of CONTROL QUERY DEFAULT</h5>
<div class="paragraph">
<p>The result of the execution of a CONTROL QUERY DEFAULT statement stays in effect until the current process
terminates or until the execution of another statement for the same attribute overrides it.</p>
</div>
<div class="paragraph">
<p>CQDs are applied at compile time, so CQDs do not affect any statements that are already prepared. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">PREPARE x FROM SELECT * FROM t;
CONTROL QUERY DEFAULT SCHEMA 'myschema';
EXECUTE x; -- uses the default schema SEABASE
SELECT * FROM t2; -- uses MYSCHEMA;
PREPARE y FROM SELECT * FROM t3;
CONTROL QUERY DEFAULT SCHEMA 'seabase';
EXECUTE y; -- uses MYSCHEMA;</code></pre>
</div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="control_query_default_examples">3.9.3. Examples of CONTROL QUERY DEFAULT</h4>
<div class="ulist">
<ul>
<li>
<p>Increase the cache refresh time for the histogram cache to two hours (7,200 minutes).</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CONTROL QUERY DEFAULT CACHE_HISTOGRAMS_REFRESH_INTERVAL '7200';</code></pre>
</div>
</div>
</li>
<li>
<p>Reset the CACHE_HISTOGRAMS_REFRESH_INTERVAL attribute to its initial value in the current process:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CONTROL QUERY DEFAULT CACHE_HISTOGRAMS_REFRESH_INTERVAL RESET;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="create_function_statement">3.10. CREATE FUNCTION Statement</h3>
<div class="paragraph">
<p>The CREATE FUNCTION statement registers a user-defined function (UDF) written in C as a function within
a Trafodion database. Currently, Trafodion supports the creation of <em>scalar UDFs</em>, which return a single
value or row when invoked. Scalar UDFs are invoked as SQL expressions in the SELECT list or WHERE clause
of a SELECT statement.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this
statement inside a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run
this statement, AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE FUNCTION function-ref ([parameter-declaration[, parameter-declaration]...])
{RETURN | RETURNS}
(return-parameter-declaration[, return-parameter-declaration]...)
EXTERNAL NAME 'character-string-literal'
LIBRARY [[catalog-name.]schema-name.]library-name
[language c]
[parameter style sql]
[no sql]
[not deterministic | deterministic]
[final call | no final call]
[no state area | state area size]
[no parallelism | allow any parallelism]
function-ref is:
[[catalog-name.]schema-name.]function-name
parameter-declaration is:
[in] [sql-parameter-name] sql-datatype
return-parameter-declaration is:
[out] [sql-parameter-name] sql-datatype</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="create_function_syntax">3.10.1. Syntax Description of CREATE FUNCTION</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>function-ref</em> ( [<em>parameter-declaration</em>[,<em>parameter-declaration</em>]&#8230;] )</code></p>
<div class="paragraph">
<p>specifies the name of the function and any SQL parameters that correspond to the signature of the external function.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>function-ref</em></code></p>
<div class="paragraph">
<p>specifies an ANSI logical name of the form:</p>
</div>
<div class="paragraph">
<p><code>[[_catalog-name_.]<em>schema-name</em>.]<em>function-name</em></code></p>
</div>
<div class="paragraph">
<p>where each part of the name is a valid sql identifier with a maximum of 128 characters. for more information, see
<a href="#identifiers">identifiers</a> and <a href="#database_object_names">database object names</a>.</p>
</div>
<div class="paragraph">
<p>specify a name that is unique and does not exist for any procedure or function in the same schema.</p>
</div>
<div class="paragraph">
<p>if you do not fully qualify the function name, trafodion sql qualifies it according to the schema of the current session.</p>
</div>
</li>
<li>
<p><code><em>parameter-declaration</em></code></p>
<div class="paragraph">
<p>specifies an sql parameter that corresponds to the signature of the external function:</p>
</div>
<div class="paragraph">
<p><code>[in] [<em>sql-parameter-name</em>] <em>sql-datatype</em></code></p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>in</code></p>
<div class="paragraph">
<p>specifies that the parameter passes data to the function.</p>
</div>
</li>
<li>
<p><code><em>sql-parameter-name</em></code></p>
<div class="paragraph">
<p>specifies an sql identifier for the parameter. for more information, see <a href="#identifiers">identifiers</a>.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>sql-datatype</em></code></p>
<div class="paragraph">
<p>specifies an sql data type that corresponds to the data type of the parameter in the signature of the
external function. <em>sql-datatype</em> is one of the supported sql data types in trafodion. see
<a href="#data_types">data types</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>{return | returns} (<em>return-parameter-declaration</em>[,<em>return-parameter-declaration</em>]&#8230;)</code></p>
<div class="paragraph">
<p>specifies the type of output of the function.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>return-parameter-declaration</em></code></p>
<div class="paragraph">
<p>specifies an sql parameter for an output value:</p>
</div>
<div class="paragraph">
<p><code>[out] [<em>sql-parameter-name</em>] <em>sql-datatype</em></code></p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>out</code></p>
<div class="paragraph">
<p>specifies that the parameter accepts data from the function.</p>
</div>
</li>
<li>
<p><code><em>sql-parameter-name</em></code></p>
<div class="paragraph">
<p>specifies an sql identifier for the return parameter. for more information, see <a href="#identifiers">identifiers</a>.</p>
</div>
</li>
<li>
<p><code><em>sql-datatype</em></code></p>
<div class="paragraph">
<p>specifies an sql data type for the return parameter. <em>sql-datatype</em> is one of the supported sql data types in
trafodion. see <a href="#data_types">data types</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>external name '<em>method-name</em>'</code></p>
<div class="paragraph">
<p>specifies the case-sensitive name of the external function’s method.</p>
</div>
</li>
<li>
<p><code>library [[_catalog-name_.]<em>schema-name</em>.]<em>library-name</em></code></p>
<div class="paragraph">
<p>specifies the ANSI logical name of a library containing the external function. if you do not fully qualify the
library name, trafodion sql qualifies it according to the schema of the current session.</p>
</div>
</li>
<li>
<p><code>language c</code></p>
<div class="paragraph">
<p>specifies that the external function is written in the c language. this clause is optional.</p>
</div>
</li>
<li>
<p><code>parameter style sql</code></p>
<div class="paragraph">
<p>specifies that the run-time conventions for arguments passed to the external function are those of the sql
language. this clause is optional.</p>
</div>
</li>
<li>
<p><code>no sql</code></p>
<div class="paragraph">
<p>specifies that the function does not perform sql operations. this clause is optional.</p>
</div>
</li>
<li>
<p><code>deterministic | not deterministic</code></p>
<div class="paragraph">
<p>specifies whether the function always returns the same values for out parameters for a given set of argument
values (deterministic, the default behavior) or does not return the same values (not deterministic). if the
function is deterministic, trafodion sql is not required to execute the function each time to produce results;
instead, trafodion sql caches the results and reuses them during subsequent executions, thus optimizing the execution.</p>
</div>
</li>
<li>
<p><code>final call | no final call</code></p>
<div class="paragraph">
<p>specifies whether or not a final call is made to the function. a final call enables the function to free up
system resources. the default is final call.</p>
</div>
</li>
<li>
<p><code>no state area | state area <em>size</em></code></p>
<div class="paragraph">
<p>specifies whether or not a state area is allocated to the function. <em>size</em> is an integer denoting memory in
bytes. acceptable values range from 0 to 16000. the default is no state area.</p>
</div>
</li>
<li>
<p><code>no parallelism | allow any parallelism</code></p>
<div class="paragraph">
<p>specifies whether or not parallelism is applied when the function is invoked. the default is allow any parallelism.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="create_function_considerations">3.10.2. Considerations for CREATE FUNCTION</h4>
<div class="sect4">
<h5 id="create_function_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a CREATE FUNCTION statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are creating the function in a shared schema, and you have the USAGE (or ALL) privilege on the library that
will be used in the creation of the function. The USAGE privilege provides you with read access to the library’s
underlying library file.</p>
</li>
<li>
<p>You are the private schema owner and have the USAGE (or ALL) privilege on the library that will be used in the
creation of the function. The USAGE privilege provides you with read access to the library’s underlying library file.</p>
</li>
<li>
<p>You have the CREATE or CREATE_ROUTINE component level privilege for the SQL_OPERATIONS component and have the
USAGE (or ALL) privilege on the library that will be used in the creation of the function. The USAGE
privilege provides you with read access to the library’s underlying library file.</p>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In this case, if you create a function in a private schema, it will be owned by the schema owner.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="create_function_examples">3.10.3. Examples of CREATE FUNCTION</h4>
<div class="ulist">
<ul>
<li>
<p>This CREATE FUNCTION statement creates a function that adds two integers:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create function add2 (int, int)
returns (total_value int)
external name 'add2'
library myudflib;</code></pre>
</div>
</div>
</li>
<li>
<p>This CREATE FUNCTION statement creates a function that returns the minimum, maximum, and average values of
five input integers:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create function mma5 (int, int, int, int, int)
returns (min_value int, max_value int, avg_value int)
external name 'mma5'
library myudflib;</code></pre>
</div>
</div>
</li>
<li>
<p>This CREATE FUNCTION statement creates a function that reverses an input string of at most 32 characters:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create function reverse (varchar(32))
returns (reversed_string varchar(32))
external name 'reverse'
library myudflib;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="create_index_statement">3.11. CREATE INDEX Statement</h3>
<div class="paragraph">
<p>The CREATE INDEX statement creates an SQL index based on one or more columns of a table or table-like object.</p>
</div>
<div class="paragraph">
<p>CREATE INDEX is a Trafodion SQL extension.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this statement
inside a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement,
AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE [VOLATILE | UNIQUE] INDEX index ON table
(column-name [ASC[ENDING] | DESC[ENDING]]
[,column-name [ASC[ENDING] | DESC[ENDING]]]...)
[HBASE_OPTIONS (hbase-options-list)]
[SALT LIKE TABLE]
hbase-options-list is:
hbase-option = 'value'[, hbase-option = 'value']...</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="create_index_syntax">3.11.1. Syntax Description of CREATE INDEX</h4>
<div class="ulist">
<ul>
<li>
<p><code>VOLATILE</code></p>
<div class="paragraph">
<p>The CREATE VOLATILE INDEX statement creates an SQL index with a lifespan that is limited to the SQL session that the index is created. Volatile indexes are dropped automatically when the session ends. See <a href="#indexes">Indexes</a>.</p>
</div>
</li>
<li>
<p><code>UNIQUE</code></p>
<div class="paragraph">
<p>The CREATE UNIQUE INDEX statement creates a unique index on a table and enforces uniqueness for the indexed field, that is, it imposes the restriction that any duplicate column values are disallowed and must be eliminated before creating a unique index on a column.</p>
</div>
<div class="paragraph">
<p>Unique index not only improves the query performance, but also provides data integrity checking. The constraint is checked when rows of the table are inserted or updated.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
Multiple NULL values are treated as duplicate values for a column which can contain only one NULL value.
</td>
</tr>
</table>
</div>
</li>
<li>
<p><code><em>index</em></code></p>
<div class="paragraph">
<p>is an SQL identifier that specifies the simple name for the new index. You cannot qualify <em>index</em> with its schema
name. Indexes have their own name space within a schema, so an index name might be the same as a table or constraint
name. However, no two indexes in a schema can have the same name.</p>
</div>
</li>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>is the name of the table for which to create the index. See <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code><em>column-name</em> [ASC[ENDING] | DESC[ENDING]] [,<em>column-name</em> [ASC[ENDING] | DESC[ENDING]]]&#8230;</code></p>
<div class="paragraph">
<p>specifies the columns in <em>table</em> to include in the index. The order of the columns in the index need not correspond
to the order of the columns in the table.</p>
</div>
<div class="paragraph">
<p>ASCENDING or DESCENDING specifies the storage and retrieval order for rows in the index. The default is ASCENDING.</p>
</div>
<div class="paragraph">
<p>Rows are ordered by values in the first column specified for the index. If multiple index rows share the same value
for the first column, the values in the second column are used to order the rows, and so forth. If duplicate index
rows occur in a non-unique index, their order is based on the sequence specified for the columns of the key of the
underlying table. For ordering (but not for other purposes), nulls are greater than other values.</p>
</div>
</li>
<li>
<p><code>HBASE_OPTIONS (<em>hbase-option</em> = '<em>value</em>'[, <em>hbase-option</em> = '<em>value</em>']&#8230;)</code></p>
<div class="paragraph">
<p>a list of HBase options to set for the index. These options are applied independently of any HBase options set for
the index’s table.</p>
</div>
</li>
</ul>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>hbase-option</em> = '<em>value</em>'</code></p>
<div class="paragraph">
<p>is one of the these HBase options and its assigned value:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 35%;">
<col style="width: 65%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">HBase Option</th>
<th class="tableblock halign-left valign-top">Accepted Values<sup>1</sup></th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">BLOCKCACHE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">BLOCKSIZE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">*'65536'( | '<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">BLOOMFILTER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'NONE' | 'ROW' | 'ROWCOL'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CACHE_BLOOMS_ON_WRITE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CACHE_DATA_ON_WRITE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CACHE_INDEXES_ON_WRITE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">COMPACT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">COMPACT_COMPRESSION</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'GZ' | 'LZ4' | 'LZO' | 'NONE' | 'SNAPPY'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">COMPRESSION</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'GZ' | 'LZ4' | 'LZO' | 'NONE' | 'SNAPPY'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DATA_BLOCK_ENCODING</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'DIFF' | 'FAST_DIFF' | 'NONE' | 'PREFIX'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DURABILITY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'USE_DEFAULT' | 'SKIP_WAL' | 'ASYNC_WAL' | 'SYNC_WAL' | 'FSYNC_WAL'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">EVICT_BLOCKS_ON_CLOSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>'true'</strong> | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">IN_MEMORY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>'true'</strong> | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">KEEP_DELETED_CELLS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>'true'</strong> | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MAX_FILESIZE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MAX_VERSIONS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'1' | '<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MEMSTORE_FLUSH_SIZE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MIN_VERSIONS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'0' | '<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">PREFIX_LENGTH_KEY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'<em>positive-integer</em>', which should be less than maximum length of the key for the table.
It applies only if the SPLIT_POLICY is <code>KeyPrefixRegionSplitPolicy</code>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">REPLICATION_SCOPE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'0' | <strong>'1'</strong></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SPLIT_POLICY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'org.apache.hadoop.hbase.regionserver.<br>
ConstantSizeRegionSplitPolicy' |<br>
'org.apache.hadoop.hbase.regionserver.<br>
IncreasingToUpperBoundRegionSplitPolicy' |<br>
'org.apache.hadoop.hbase.regionserver.<br>
KeyPrefixRegionSplitPolicy'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">TTL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'-1' (forever) | '<em>positive-integer</em>'</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p><sup>1</sup> Values in boldface are default values.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>SALT LIKE TABLE</code></p>
<div class="paragraph">
<p>causes the index to use the same salting scheme (that is,
<code>SALT USING <em>num</em> PARTITIONS [ON (<em>column</em>[, <em>column</em>]&#8230;)])</code> as its base table.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="create_index_considerations">3.11.2. Considerations for CREATE INDEX</h4>
<div class="paragraph">
<p>Indexes are created under a single transaction. When an index is created, the following steps occur:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Transaction begins (either a user-started transaction or a system-started transaction).</p>
</li>
<li>
<p>Rows are written to the metadata.</p>
</li>
<li>
<p>Physical labels are created to hold the index (as non audited).</p>
</li>
<li>
<p>The base table is locked for read shared access which prevents inserts, updates, and deletes on the base table from occurring.</p>
</li>
<li>
<p>The index is loaded by reading the base table for read uncommitted access using side tree inserts.</p>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
A side tree insert is a fast way of loading data that can perform specialized optimizations because the
partitions are not audited and empty.
</td>
</tr>
</table>
</div>
</li>
<li>
<p>After load is complete, the index audit attribute is turned on and it is attached to the base table (to bring the index on-line).</p>
</li>
<li>
<p>The transaction is committed, either by the system or later by the requester.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>If the operation fails after basic semantic checks are performed, the index no longer exists and the entire transaction
is rolled back even if it is a user-started transaction.</p>
</div>
<div class="sect4">
<h5 id="create_index_authorization_and_availability_requirements">Authorization and Availability Requirements</h5>
<div class="paragraph">
<p>An index always has the same security as the table it indexes.</p>
</div>
<div class="paragraph">
<p>CREATE INDEX locks out INSERT, DELETE, and UPDATE operations on the table being indexed. If other processes have rows in the table locked
when the operation begins, CREATE INDEX waits until its lock request is granted or timeout occurs.</p>
</div>
<div class="paragraph">
<p>You cannot access an index directly.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="create_index_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a CREATE INDEX statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are creating the table in a shared schema.</p>
</li>
<li>
<p>You are the private schema owner.</p>
</li>
<li>
<p>You are the owner of the table.</p>
</li>
<li>
<p>You have the ALTER, ALTER_TABLE, CREATE, or CREATE_INDEX component privilege for the SQL_OPERATIONS component.</p>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In this case, if you create an index in a private schema, it will be owned by the schema owner.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="create_index_limits">Limits on Indexes</h5>
<div class="paragraph">
<p>For non-unique indexes, the sum of the lengths of the columns in the index plus the sum of the length of
the clustering key of the underlying table cannot exceed 2048 bytes.</p>
</div>
<div class="paragraph">
<p>No restriction exists on the number of indexes per table.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="create_index_examples">3.11.3. Examples of CREATE INDEX</h4>
<div class="ulist">
<ul>
<li>
<p>This example creates an index on two columns of a table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE INDEX xempname
ON persnl.employee (last_name, first_name);</code></pre>
</div>
</div>
</li>
<li>
<p>This example shows that a volatile index can be created only on a volatile table.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;create volatile table test2(c1 int);
--- SQL operation complete.
SQL&gt;create volatile index idx_test2 on test2(c1);
--- SQL operation complete.
SQL&gt;create table test1(c1 int);
--- SQL operation complete.
SQL&gt;create volatile index idx_test1 on test1 (c1);
*** ERROR[4082] Object TEST1 does not exist or is inaccessible. [2017-01-13 11:35:26]</code></pre>
</div>
</div>
</li>
<li>
<p>This example shows a unique index can be created on a table which has only one NULL value.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;select * from t25;
A B
----------- ----------
1 NULL
2 aaa
--- 2 row(s) selected.
SQL&gt;create unique index idx_t25 on t25(b);
--- SQL operation complete.
SQL&gt;showddl t25;
CREATE TABLE TRAFODION.SEABASE.T25
(
A INT DEFAULT NULL NOT SERIALIZED,
B CHAR(10) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL NOT SERIALIZED
)
ATTRIBUTES ALIGNED FORMAT;
CREATE UNIQUE INDEX IDX_T25 ON TRAFODION.SEABASE.T25
(
B ASC
)
ATTRIBUTES ALIGNED FORMAT;
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>This example shows a unique index cannot be created on a table which has multiple NULL values.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;select * from t25;
A B
----------- ----------
1 NULL
2 aaa
--- 2 row(s) selected.
SQL&gt;create unique index idx_t25 on t25(b);
*** ERROR[8110] Duplicate rows detected. [2017-01-12 17:17:51]
*** ERROR[1053] Unique index TRAFODION.SEABASE.IDX_T25 could not be created because the specified column(s) contain duplicate data. [2017-01-12 17:17:51]</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="create_library_statement">3.12. CREATE LIBRARY Statement</h3>
<div class="paragraph">
<p>The CREATE LIBRARY statement registers a library object in a Trafodion database. A library object
can be an SPJ&#8217;s JAR file or a UDF&#8217;s library file.</p>
</div>
<div class="paragraph">
<p>CREATE LIBRARY is a Trafodion SQL extension.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run
this statement inside a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT
is OFF. To run this statement, AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE LIBRARY [[catalog-name.]schema-name.]library-name
file 'library-filename'
[host name 'host-name']
[local file 'host-filename']</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="create_library_syntax">3.12.1. Syntax Description of CREATE LIBRARY</h4>
<div class="ulist">
<ul>
<li>
<p><code>[[_catalog-name_.]<em>schema-name</em>.]<em>library-name</em></code></p>
<div class="paragraph">
<p>specifies the ANSI logical name of the library object, where each part of the name is a valid sql
identifier with a maximum of 128 characters. specify a name that is unique and does not exist for
libraries in the same schema. if you do not fully qualify the library name, trafodion sq qualifies
it according to the schema of the current session. for more information, see <a href="#identifiers">identifiers</a>
and <a href="#database_object_names">database object names</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>file '<em>library-filename</em>'</code></p>
<div class="paragraph">
<p>specifies the full path of a deployed library file, which either an SPJ&#8217;s jar file or a UDF&#8217;s library file.</p>
</div>
<div class="paragraph">
<p>note: make sure to upload the library file to the trafodion cluster and then copy the library file to the
same directory on all the nodes in the cluster before running the create library statement. otherwise, you
will see an error message indicating that the jar or dll file was not found.</p>
</div>
</li>
<li>
<p><code>host name '<em>host-name</em>'</code></p>
<div class="paragraph">
<p>specifies the name of the client host machine where the deployed file resides.</p>
</div>
</li>
<li>
<p><code>local file '<em>host-filename</em>'</code></p>
<div class="paragraph">
<p>specifies the path on the client host machine where the deployed file is stored.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="create_library_considerations">3.12.2. Considerations for CREATE LIBRARY</h4>
<div class="ulist">
<ul>
<li>
<p>A library object cannot refer to a library file referenced by another library object. If the <em>library-filename</em>
is in use by another library object, the CREATE LIBRARY command will fail.</p>
</li>
<li>
<p>The <em>library-filename</em> must specify an existing file. Otherwise, the CREATE LIBRARY command will fail.</p>
</li>
<li>
<p>The CREATE LIBRARY command does not verify that the specified <em>library-filename</em> is a valid executable file.</p>
</li>
<li>
<p>HOST NAME and LOCAL FILE are position dependent.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="create_library_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a CREATE LIBRARY statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are creating the library in a shared schema and have the MANAGE_LIBRARY privilege.</p>
</li>
<li>
<p>You are the private schema owner and have the MANAGE_LIBRARY privilege.</p>
</li>
<li>
<p>You have the CREATE or CREATE_LIBRARY component privilege for the SQL_OPERATIONS component and have
the MANAGE_LIBRARY privilege.</p>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In this case, if you create a library in a private schema, it will be owned by the schema owner.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="create_library_examples">3.12.3. Examples of CREATE LIBRARY</h4>
<div class="ulist">
<ul>
<li>
<p>This CREATE LIBRARY statement registers a library named SALESLIB in the SALES schema for a JAR file (SPJs):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE LIBRARY sales.saleslib FILE '/opt/home/trafodion/spjjars/Sales.jar';</code></pre>
</div>
</div>
</li>
<li>
<p>This CREATE LIBRARY statement registers a library named MYUDFS in the default schema for a library file (UDFs):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE LIBRARY myudfs FILE $UDFLIB;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="create_procedure_statement">3.13. CREATE PROCEDURE Statement</h3>
<div class="paragraph">
<p>The CREATE PROCEDURE statement registers a Java method as a stored procedure in Java (SPJ) within a Trafodion database.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this statement
inside a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement,
AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE PROCEDURE procedure-ref([sql-parameter-list])
EXTERNAL NAME 'java-method-name [java-signature]'
LIBRARY [[catalog-name.]schema-name.]library-name
[external security external-security-type]
language java
parameter style java
[no sql | contains sql | modifies sql data | reads sql data]
[dynamic result sets integer]
[transaction required | no transaction required]
[deterministic | not deterministic]
[no isolate | isolate]
procedure-ref is:
[[catalog-name.]schema-name.]procedure-name
sql-parameter-list is:
sql-parameter[, sql-parameter]...
sql-parameter is:
[parameter-mode] [sql-identifier] sql-datatype
parameter-mode is:
in
| out
| inout
java-method-name is:
[package-name.]class-name.method-name
java-signature is:
([java-parameter-list])
java-parameter-list is:
java-datatype[, java-datatype]...
external-security-type is:
definer
| invoker</code></pre>
</div>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
delimited variables in this syntax diagram are case-sensitive. case-sensitive variables include <em>java-method-name</em>,
<em>java-signature</em>, and <em>class-file-path</em>, and any delimited part of the <em>procedure-ref</em>.
the remaining syntax is not case-sensitive.
</td>
</tr>
</table>
</div>
<div class="sect3">
<h4 id="create_procedure_syntax">3.13.1. Syntax Description of CREATE PROCEDURE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>procedure-ref</em>([<em>sql-parameter</em>[, <em>sql-parameter</em>]&#8230;])</code></p>
<div class="paragraph">
<p>specifies the name of the stored procedure in Java (SPJ) and any SQL parameters that correspond to the signature of
the SPJ method.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>procedure-ref</em></code></p>
<div class="paragraph">
<p>specifies an ANSI logical name of the form:</p>
</div>
<div class="paragraph">
<p><code>[[_catalog-name_.]<em>schema-name</em>.]<em>procedure-name</em></code></p>
</div>
<div class="paragraph">
<p>where each part of the name is a valid SQL identifier with a maximum of 128 characters. For more information,
see <a href="#identifiers">identifiers</a> and <a href="#database_object_names">database object names</a>.</p>
</div>
<div class="paragraph">
<p>specify a name that is unique and does not exist for any procedure or function in the same schema. Trafodion
does not support the overloading of procedure names. That is, you cannot register the same procedure name more than
once with different underlying SPJ methods.</p>
</div>
<div class="paragraph">
<p>If you do not fully qualify the procedure name, then Trafodion qualifies it according to the schema of the current session.</p>
</div>
</li>
<li>
<p><code><em>sql-parameter</em></code></p>
<div class="paragraph">
<p>specifies an SQL parameter that corresponds to the signature of the SPJ method:</p>
</div>
<div class="paragraph">
<p><code>[<em>parameter-mode</em>] [<em>sql-identifier</em>] <em>sql-datatype</em></code></p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>parameter-mode</em></code></p>
<div class="paragraph">
<p>specifies the mode <code>in</code>, <code>out</code>, or <code>inout</code> of a parameter. The default is <code>in</code>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>in</code></p>
<div class="paragraph">
<p>specifies a parameter that passes data to an SPJ.</p>
</div>
</li>
<li>
<p><code>out</code></p>
<div class="paragraph">
<p>specifies a parameter that accepts data from an SPJ. The parameter must be an array.</p>
</div>
</li>
<li>
<p><code>inout</code></p>
<div class="paragraph">
<p>specifies a parameter that passes data to and accepts data from an SPJ. The parameter must be an array.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code><em>sql-identifier</em></code></p>
<div class="paragraph">
<p>specifies an SQL identifier for the parameter. For more information, see <a href="#identifiers">identifiers</a>.</p>
</div>
</li>
<li>
<p><code><em>sql-datatype</em></code></p>
<div class="paragraph">
<p>specifies an SQL data type that corresponds to the Java parameter of the SPJ method.</p>
</div>
<div class="paragraph">
<p><em>sql-datatype</em> can be:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 60%;">
<col style="width: 40%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">sql data type</th>
<th class="tableblock halign-left valign-top">maps to java data type&#8230;</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">char[acter]<br>
char[acter] varying<br>
varchar<br>
pic[ture] x<sup>1</sup><br>
nchar<br>
nchar varying<br>
national char[acter]<br>
national char[acter] varying</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">java.lang.string</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">date</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">java.sql.date</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">time</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">java.sql.time</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">timestamp</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">java.sql.timestamp</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">dec<sup class="imal">2</sup><br>
pic[ture] s9<sup>3</sup><br>
numeric (including numeric with a precision greater than eighteen)<sup>2</sup></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">java.math.bigdecimal</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">smallint<sup>2</sup></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">short</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">int<sup class="eger">2</sup></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">int or java.lang.integer<sup>4</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">largeint<sup>2</sup></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">long or java.lang.long<sup>4</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">float</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">double or java.lang.double<sup>4</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">real</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">float or java.lang.float<sup>4</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">double precision</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">double or java.lang.double<sup>4</sup></p></td>
</tr>
</tbody>
</table>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>the trafodion database stores pic x as a char data type.</p>
</li>
<li>
<p>numeric data types of sql parameters must be signed, which is the default in the trafodion database.</p>
</li>
<li>
<p>the trafodion database stores pic s9 as a decimal or numeric data type.</p>
</li>
<li>
<p>by default, the sql data type maps to a java primitive type. the sql data type maps to a java wrapper class
only if you specify the wrapper class in the java signature of the external name clause.</p>
<div class="paragraph">
<p>for more information, see <a href="#data_types">data types</a>.</p>
</div>
</li>
</ol>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>external name '<em>java-method-name</em> [<em>java-signature</em>]'</code></p>
<div class="ulist">
<ul>
<li>
<p><code><em>java-method-name</em></code></p>
<div class="paragraph">
<p>specifies the case-sensitive name of the SPJ method of the form:</p>
</div>
<div class="paragraph">
<p><code><em class="_package-name_.">class-name</em>.<em>method-name</em></code></p>
</div>
<div class="paragraph">
<p>The Java method must exist in a Java class file, <em>class-name</em>.class, within a library registered in the database.
The Java method must be defined as <code>public</code> and <code>static</code> and have a return type of <code>void</code>.</p>
</div>
<div class="paragraph">
<p>If the class file that contains the SPJ method is part of a package, then you must also specify the package name.
If you do not specify the package name, the create procedure statement fails to register the SPJ.</p>
</div>
</li>
<li>
<p><code><em>java-signature</em></code></p>
<div class="paragraph">
<p>specifies the signature of the SPJ method and consists of:</p>
</div>
<div class="paragraph">
<p><code>([<em>java-datatype</em>[, <em>java-datatype</em>]&#8230;])</code></p>
</div>
<div class="paragraph">
<p>The Java signature is necessary only if you want to specify a Java wrapper class (for example, <code>java.lang.integer</code>) instead of a java
primitive data type (for example, <code>int</code>). An SQL data type maps to a Java primitive data type by default.</p>
</div>
<div class="paragraph">
<p>The Java signature is case-sensitive and must be placed within parentheses, such as <code>(java.lang.integer, java.lang.integer</code>).
The signature must specify each of the parameter data types in the order they appear in the Java method definition within
the class file. Each Java data type that corresponds to an out or inout parameter must be followed by empty square
brackets (<code>[ ]</code>), such as <code>java.lang.integer[]</code>.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>java-datatype</em></code></p>
<div class="paragraph">
<p>Specifies a mappable Java data type. For the mapping of the Java data types to SQL data types, see <em>sql-datatype</em>.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>library [[_catalog-name_.]<em>schema-name</em>.]<em>library-name</em></code></p>
<div class="paragraph">
<p>specifies the ANSI logical name of a library containing the SPJ method. If you do not fully qualify the library name,
then Trafodion qualifies it according to the schema of the current session.</p>
</div>
</li>
<li>
<p><code>external security <em>external-security-type</em></code></p>
<div class="paragraph">
<p>determines the privileges, or rights, that users have when executing (or calling) the SPJ. An SPJ can have one of these
types of external security:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>invoker</code> determines that users can execute, or invoke, the stored procedure using the privileges of the user who invokes
the stored procedure. This behavior is referred to as <em>invoker rights</em> and is the default behavior if external security is
not specified. Invoker rights allow a user who has the execute privilege on the SPJ to call the SPJ using his or her existing
privileges. In this case, the user must be granted privileges to access the underlying database objects on which the SPJ operates.</p>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
Granting a user privileges to the underlying database objects gives the user direct access to those database objects,
which could pose a risk to more sensitive or critical data to which users should not have access. For example, an SPJ
might operate on a subset of the data in an underlying database object but that database object might contain other
more sensitive or critical data to which users should not have access.
</td>
</tr>
</table>
</div>
</li>
<li>
<p><code>definer</code> determines that users can execute, or invoke, the stored procedure using the privileges of the user who created
the stored procedure. This behavior is referred to as <em>definer rights</em>. The advantage of definer rights is that users are
allowed to manipulate data by invoking the stored procedure without having to be granted privileges to the underlying
database objects. That way, users are restricted from directly accessing or manipulating more sensitive or critical data in
the database. However, be careful about the users to whom you grant execute privilege on an SPJ with definer external security
because those users will be able to execute the SPJ without requiring privileges to the underlying database objects.</p>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>language java</code></p>
<div class="paragraph">
<p>specifies that the external user-defined routine is written in the java language.</p>
</div>
</li>
<li>
<p><code>parameter style java</code></p>
<div class="paragraph">
<p>specifies that the run-time conventions for arguments passed to the external user-defined routine are those of the Java language.</p>
</div>
</li>
<li>
<p><code>no sql</code></p>
<div class="paragraph">
<p>specifies that the SPJ cannot perform SQL operations.</p>
</div>
</li>
<li>
<p><code>contains sql | modifies sql data | reads sql data</code></p>
<div class="paragraph">
<p>specifies that the SPJ can perform SQL operations. All these options behave the same as <code>contains sql</code>, meaning that the SPJ
can read and modify SQL data. Use one of these options to register a method that contains SQL statements. Ff you do not specify
an SQL access mode, then the default is <code>contains sql</code>.</p>
</div>
</li>
<li>
<p><code>dynamic result sets <em>integer</em></code></p>
<div class="paragraph">
<p>specifies the maximum number of result sets that the SPJ can return. This option is applicable only if the method signature
contains a <code>java.sql.resultset[]</code> object. If the method contains a result set object, then the valid range is 1 to 255 inclusive.
The actual number of result sets returned by the SPJ method can be fewer than or equal to this number. If you do not specify
this option, then the default value is 0 (zero), meaning that the SPJ does not return result sets.</p>
</div>
</li>
<li>
<p><code>transaction required | no transaction required</code></p>
<div class="paragraph">
<p>determines whether the SPJ must run in a transaction inherited from the calling application (<code>transaction required</code>, the default
option) or whether the SPJ runs without inheriting the calling application’s transaction (<code>no transaction required</code>). Typically,
you want the stored procedure to inherit the transaction from the calling application. However, if the SPJ method does
not access the database or if you want the stored procedure to manage its own transactions, then you should set the stored
procedure’s transaction attribute to no transaction required. For more information, see
<a href="#effects_of_the_transaction_attribute_on_spjs">effects of the transaction attribute on SPJs</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>deterministic | not deterministic</code></p>
<div class="paragraph">
<p>specifies whether the SPJ always returns the same values for out and inout parameters for a given set of argument values
(<code>deterministic</code>) or does not return the same values (<code>not deterministic</code>, the default option). If you specify <code>deterministic</code>,
Trafodion is not required to call the SPJ each time to produce results; instead, Trafodion caches the results and
reuses them during subsequent calls, thus optimizing the CALL statement.</p>
</div>
</li>
<li>
<p><code>no isolate | isolate</code></p>
<div class="paragraph">
<p>specifies that the SPJ executes either in the environment of the database server (<code>no isolate</code>) or in an isolated environment
(<code>isolate</code>, the default option). Trafodion allows both options but always executes the SPJ in the UDR server process (<code>isolate</code>).</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="create_procedure_considerations">3.13.2. Considerations for CREATE PROCEDURE</h4>
<div class="sect4">
<h5 id="create_procedure_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a CREATE PROCEDURE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are creating the procedure in a shared schema, and you have the USAGE (or ALL) privilege on the library that will be
used in the creation of the stored procedure. The USAGE privilege provides you with read access to the library’s underlying
JAR file, which contains the SPJ Java method.</p>
</li>
<li>
<p>You are the private schema owner and have the USAGE (or ALL) privilege on the library that will be used in the creation of
the stored procedure. The USAGE privilege provides you with read access to the library’s underlying JAR file, which contains
the SPJ Java method.</p>
</li>
<li>
<p>You have the CREATE or CREATE_ROUTINE component level privilege for the SQL_OPERATIONS component and have the USAGE (or ALL)
privilege on the library that will be used in the creation of the stored procedure. The USAGE privilege provides you with read
access to the library’s underlying JAR file, which contains the SPJ Java method.</p>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In this case, if you create a stored procedure in a private schema, it will be owned by the schema owner.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="effects_of_the_transaction_attribute_on_spjs">Effects of the Transaction Attribute on SPJs</h5>
<div class="sect5">
<h6 id="_transaction_required">Transaction Required</h6>
<div class="paragraph">
<p><em>Using Transaction Control Statements or Methods</em></p>
</div>
<div class="paragraph">
<p>If you specify TRANSACTION REQUIRED (the default option), a CALL statement automatically initiates a transaction if there is
no active transaction. In this case, you should not use transaction control statements (or equivalent JDBC transaction methods)
in the SPJ method. Transaction control statements include COMMIT WORK and ROLLBACK WORK, and the equivalent JDBC transaction
methods are <code>Connection.commit()</code> and <code>Connection.rollback()</code>. If you try to use transaction control statements or methods in an
SPJ method when the stored procedure’s transaction attribute is set to TRANSACTION REQUIRED, then the transaction control statements
or methods in the SPJ method are ignored, and the Java virtual machine (JVM) does not report any errors or warnings. When the
stored procedure’s transaction attribute is set to TRANSACTION REQUIRED, then you should rely on the transaction control statements
or methods in the application that calls the stored procedure and allow the calling application to manage the transactions.</p>
</div>
<div class="paragraph">
<p><em>Committing or Rolling Back a Transaction</em></p>
</div>
<div class="paragraph">
<p>If you do not use transaction control statements in the calling application, then the transaction initiated by the CALL statement
might not automatically commit or roll back changes to the database. When AUTOCOMMIT is ON (the default setting), the database
engine automatically commits or rolls back any changes made to the database at the end of the CALL statement execution. However,
when AUTOCOMMIT is OFF, the current transaction remains active until the end of the client session or until you explicitly commit
or roll back the transaction. To ensure an atomic unit of work when calling an SPJ, use the COMMIT WORK statement in the calling
application to commit the transaction when the CALL statement succeeds, and use the ROLLBACK WORK statement to roll back the
transaction when the CALL statement fails.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect5">
<h6 id="_no_transaction_required">No Transaction Required</h6>
<div class="paragraph">
<p>In some cases, you might not want the SPJ method to inherit the transaction from the calling application. Instead, you might want
the stored procedure to manage its own transactions or to run without a transaction. Not inheriting the calling application’s
transaction is useful in these cases:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The stored procedure performs several long-running operations, such as multiple DDL or table maintenance operations, on the
database. In this case, you might want to commit those operations periodically from within the SPJ method to avoid locking tables
for a long time.</p>
</li>
<li>
<p>The stored procedure performs certain SQL operations that must run without an active transaction. For example, INSERT, UPDATE,
and DELETE statements with the WITH NO ROLLBACK option are rejected when a transaction is already active, as is the case when a
stored procedure inherits a transaction from the calling application. The PURGEDATA utility is also rejected when a transaction
is already active.</p>
</li>
<li>
<p>The stored procedure does not access the database. In this case, the stored procedure does not need to inherit the transaction
from the calling application. By setting the stored procedure’s transaction attribute to NO TRANSACTION REQUIRED, you can avoid
the overhead of the calling application’s transaction being propagated to the stored procedure.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>In these cases, you should set the stored procedure’s transaction attribute to NO TRANSACTION REQUIRED when creating the stored
procedure.</p>
</div>
<div class="paragraph">
<p>If you specify NO TRANSACTION REQUIRED and if the SPJ method creates a JDBC default connection, that connection will have autocommit
enabled by default. You can either use the autocommit transactions or disable autocommit (conn.setAutoCommit(false);) and use the
JDBC transaction methods, <code>Connection.commit()</code> and <code>Connection.rollback()</code>, to commit or roll back work where needed.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="create_procedure_examples">3.13.3. Examples of CREATE PROCEDURE</h4>
<div class="ulist">
<ul>
<li>
<p>This CREATE PROCEDURE statement registers an SPJ named LOWERPRICE, which does not accept any arguments:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SET SCHEMA SALES;
CREATE PROCEDURE lowerprice()
EXTERNAL NAME 'Sales.lowerPrice'
LIBRARY saleslib
LANGUAGE JAVA
PARAMETER STYLE JAVA
MODIFIES SQL DATA;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Because the procedure name is not qualified by a catalog and schema, Trafodion qualifies it according to the current
session settings, where the catalog is TRAFODION (by default) and the schema is set to SALES. Since the procedure needs
to be able to read and modify SQL data, MODIFIES SQL DATA is specified in the CREATE PROCEDURE statement.</p>
</div>
<div class="paragraph">
<p>To call this SPJ, use this CALL statement:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CALL lowerprice();</code></pre>
</div>
</div>
<div class="paragraph">
<p>The LOWERPRICE procedure lowers the price of items with 50 or fewer orders by 10 percent in the database.</p>
</div>
</li>
<li>
<p>This CREATE PROCEDURE statement registers an SPJ named TOTALPRICE, which accepts three input parameters and returns a numeric value, the
total price to an INOUT parameter:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE PROCEDURE trafodion.sales.totalprice(IN qty NUMERIC (18),
IN rate VARCHAR (10),
INOUT price NUMERIC (18,2))
EXTERNAL NAME 'Sales.totalPrice'
LIBRARY sales.saleslib
LANGUAGE JAVA
PARAMETER STYLE JAVA
NO SQL;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>To call this SPJ in TrafCI, use these statements:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SET PARAM ?p 10.00;
CALL sales.totalprice(23, 'standard', ?p);
p
--------------------
253.97
--- SQL operation complete.</code></pre>
</div>
</div>
<div class="paragraph">
<p>Since the procedure does not read and modify any SQL data, NO SQL is specified in the CREATE PROCEDURE statement.</p>
</div>
</li>
<li>
<p>This CREATE PROCEDURE statement registers an SPJ named MONTHLYORDERS, which accepts an integer value for the month
and returns the number of orders:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE PROCEDURE sales.monthlyorders(IN INT, OUT number INT)
EXTERNAL NAME 'Sales.numMonthlyOrders (int, java.lang.Integer[])'
LIBRARY sales.saleslib
LANGUAGE JAVA
PARAMETER STYLE JAVA
READS SQL DATA;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Because the OUT parameter is supposed to map to the Java wrapper class, java.lang.Integer, you must specify the Java
signature in the EXTERNAL NAME clause. To invoke this SPJ, use this CALL statement:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CALL sales.monthlyorders(3, ?);
ORDERNUM
-----------
4
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This CREATE PROCEDURE statement registers an SPJ named ORDERSUMMARY, which accepts a date (formatted as a string) and
returns information about the orders on or after that date.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE PROCEDURE sales.ordersummary(IN on_or_after_date VARCHAR (20),
OUT num_orders LARGEINT)
EXTERNAL NAME 'Sales.orderSummary (int, long[])'
LIBRARY sales.saleslib
EXTERNAL SECURITY invoker
LANGUAGE JAVA
PARAMETER STYLE JAVA
READS SQL DATA
DYNAMIC RESULT SETS 2;</code></pre>
</div>
</div>
<div class="paragraph">
<p>To invoke this SPJ, use this CALL statement:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CALL trafodion.sales.ordersummary('01-01-2014', ?);</code></pre>
</div>
</div>
<div class="paragraph">
<p>The ORDERSUMMARY procedure returns this information about the orders on or after the specified date, 01-01-2014:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">NUM_ORDERS
--------------------
13
ORDERNUM NUM_PARTS AMOUNT ORDER_DATE LAST_NAME
-------- -------------------- -------------------- ---------- --------------------
100210 4 19020.00 2014-04-10 HUGHES
100250 4 22625.00 2014-01-23 HUGHES
101220 4 45525.00 2014-07-21 SCHNABL
... ... ... ... ...
--- 13 row(s) selected.
ORDERNUM PARTNUM UNIT_PRICE QTY_ORDERED PARTDESC
-------- ------- ---------- ----------- ------------------
100210 244 3500.00 3 PC GOLD, 30 MB
100210 2001 1100.00 3 GRAPHIC PRINTER,M1
100210 2403 620.00 6 DAISY PRINTER,T2
... ... ... ... ...
--- 70 row(s) selected.
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="create_role_statement">3.14. CREATE ROLE Statement</h3>
<div class="paragraph">
<p>The CREATE ROLE statement creates an SQL role. See <a href="#roles">Roles</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE ROLE role-name [ WITH ADMIN grantor ]
grantor is:
database-username</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="create_role_syntax">3.14.1. Syntax Description of CREATE ROLE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>role-name</em></code></p>
<div class="paragraph">
<p>is an SQL identifier that specifies the new role. <em>role-name</em> is a regular or delimited
case-insensitive identifier.
See <a href="#Case_Insensitive_Delimited_Identifiers">Case-Insensitive Delimited Identifiers</a>.
<em>role-name</em> cannot be an existing role name, and it cannot be a registered database username. However,
<em>role-name</em> can be a configured directory-service username.</p>
</div>
</li>
<li>
<p><code>WITH ADMIN <em>grantor</em></code></p>
<div class="paragraph">
<p>specifies a role owner other than the current user. This is an optional clause.</p>
</div>
</li>
<li>
<p><code><em>grantor</em></code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>specifies a registered database username to whom you assign the role owner.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="create_role_considerations">3.14.2. Considerations for CREATE ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>To create a role, you must either be DB ROOT or have been granted the MANAGE_ROLES component privilege for SQL_OPERATIONS.</p>
</li>
<li>
<p>PUBLIC, <em>SYSTEM, NONE, and database user names beginning with DB are reserved. You cannot specify a _role-name</em> with any such name.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="create_role_ownership">Role Ownership</h5>
<div class="paragraph">
<p>You can give role ownership to a user by specifying the user in the WITH ADMIN <em>grantor</em> clause with the <em>grantor</em> as the user.</p>
</div>
<div class="paragraph">
<p>The role owner can perform these operations:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Grant and revoke the role to users.</p>
</li>
<li>
<p>Drop the role.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Role ownership is permanent. After you create the role, the ownership of the role cannot be changed or assigned to another user.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="create_role_examples">3.14.3. Examples of CREATE ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>To create a role and assign the current user as the role owner:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE ROLE clerks;</code></pre>
</div>
</div>
</li>
<li>
<p>To create a role and assign another user as the role owner:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE ROLE sales WITH ADMIN cmiller;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="create_schema_statement">3.15. CREATE SCHEMA Statement</h3>
<div class="paragraph">
<p>The CREATE SCHEMA statement creates a schema in the database. See <a href="#schemas">Schemas</a>.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run DDL statements
inside a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run these statements,
AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE [schema-class] SCHEMA [IF NOT EXISTS] schema-clause
schema-class is:
[ PRIVATE | SHARED ]
schema-clause is:
{ schema-name [AUTHORIZATION authid] | AUTHORIZATION authid }</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="create_schema_syntax">3.15.1. Syntax Description of CREATE SCHEMA</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>schema-class</em></code></p>
<div class="paragraph">
<p>indicates whether access to the schema is restricted to the authorization ID by default (PRIVATE) or whether
any database user may add objects to the schema (SHARED). The default class is PRIVATE.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
Schemas created in Trafodion Release 0.9 or earlier are SHARED schemas.
</td>
</tr>
</table>
</div>
</li>
<li>
<p><code>IF NOT EXISTS</code></p>
<div class="paragraph">
<p>creates the schema if it does not already exist. If omitted, then an error will be raised if the schema
already exists.</p>
</div>
</li>
<li>
<p><code><em>schema-name</em></code></p>
<div class="paragraph">
<p>is a name for the new schema and is an SQL identifier that specifies a unique name that is not currently a schema name.
This parameter is optional. However, if you do not specify a schema name, you must specify the authorization clause. If
a schema name is not provided, the authorization ID is used for the schema name. If the authorization ID name matches an
existing schema, the CREATE SCHEMA command fails.</p>
</div>
</li>
<li>
<p><code><em>authid</em></code></p>
<div class="paragraph">
<p>is the name of the database user or role will own and administer the schema. If this clause is not present, the current
user becomes the schema owner.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="create_schema_considerations">3.15.2. Considerations for CREATE SCHEMA</h4>
<div class="sect4">
<h5 id="create_schema_reserved_schema_names">Reserved Schema Names</h5>
<div class="paragraph">
<p>Schema names that begin with a leading underscore (_) are reserved for future use.</p>
</div>
</div>
<div class="sect4">
<h5 id="create_schema_authorization_clause">AUTHORIZATION Clause</h5>
<div class="paragraph">
<p>The AUTHORIZATION clause is optional. If you omit this clause, the current user becomes the schema owner.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
An authorization ID is assigned to a schema name even if authorization is not enabled for the Trafodion database.
However, no enforcement occurs unless authorization is enabled.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>The schema owner can perform operations on the schema and on objects within the schema. For example:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Alter DDL of objects</p>
</li>
<li>
<p>Drop the schema</p>
</li>
<li>
<p>Drop objects</p>
</li>
<li>
<p>Manage objects with utility commands such as UPDATE STATISTICS and PURGEDATA</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="create_schema_who_can_create_a_schema">Who Can Create a Schema</h5>
<div class="paragraph">
<p>The privilege to create a schema is controlled by the component privilege CREATE_SCHEMA for the SQL_OPERATIONS component.
By default, this privilege is granted to PUBLIC, but it can be revoked by DB ROOT.</p>
</div>
<div class="paragraph">
<p>When authorization is initialized, these authorization IDs are granted the CREATE_SCHEMA privilege:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>PUBLIC</p>
</li>
<li>
<p>DB ROOT</p>
</li>
<li>
<p>DB ROOTROLE</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>DB ROOT or anyone granted the DB_ROOTROLE role can grant the CREATE_SCHEMA privilege.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="create_schema_examples">3.15.3. Examples of CREATE SCHEMA</h4>
<div class="ulist">
<ul>
<li>
<p>This example creates a private schema schema named MYSCHEMA, which will be owned by the current user:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE SCHEMA myschema;</code></pre>
</div>
</div>
</li>
<li>
<p>This example creates a shared schema and designates CliffG as the schema owner:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE SHARED SCHEMA hockey_league AUTHORIZATION &quot;CliffG&quot;;</code></pre>
</div>
</div>
</li>
<li>
<p>This example creates a private schema and designates the role DBA as the schema owner:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE PRIVATE SCHEMA contracts AUTHORIZATION DBA;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Users with the role DBA granted to them can grant access to objects in the CONTRACTS schema to other users and roles.</p>
</div>
</li>
<li>
<p>This example creates a schema named JSMITH:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE PRIVATE SCHEMA AUTHORIZATION JSmith;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="create_sequence_statement">3.16. CREATE SEQUENCE Statement</h3>
<div class="paragraph">
<p>The CREATE SEQUENCE Statement produces an automatic ascending sequence of numeric values, which can be used by multiple users as primary key values. For example, to generate only odd numbers in a sequence, you can create a sequence defined with START WITH=1, INCREMENT BY=2.</p>
</div>
<div class="paragraph">
<p>Multiple options can be concurrently specified and separated by a space.</p>
</div>
<div class="paragraph">
<p>There are two expressions can be used with sequence:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>seqnum(SEQUENCE, current)</code>: get the current value which is returned from the sequence on the current session rather than the current value of the sequence.</p>
<div class="paragraph">
<p>For example, a sequence object called <code>employee_seq</code> which starts with 1 and caches up to 25 with only three users.</p>
</div>
<div class="paragraph">
<p>If User A calls <code>seqnum(SEQUENCE, current)</code>, it will return 1 and reserve from 1 to 25, and User B immediately calls <code>seqnum(SEQUENCE, current)</code> and it will return 26 and reserve from 26 to 51, then User C immediately calls <code>seqnum(SEQUENCE, current)</code> and it will return 51 and reserve from 51 to 75.</p>
</div>
<div class="paragraph">
<p>Now, if User A immediately calls <code>seqnum(SEQUENCE, next)</code>, it will return 2 rather than 76. 76 will be returned if User A immediately calls <code>seqnum(SEQUENCE, next)</code> after achieving 25 where the cache for User A is exhausted.</p>
</div>
</li>
<li>
<p><code>seqnum(SEQUENCE, next)</code>: advance the sequence and retrieve the next value. For an ascending sequence, this value is increasing.</p>
<div class="paragraph">
<p>NOTE:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>It always returns the initial value of the sequence by calling <code>seqnum(SEQUENCE, current)</code> or <code>seqnum(SEQUENCE, next)</code> for the first time.</p>
</li>
<li>
<p>It returns a new incremented value of the sequence with each subsequent reference to <code>seqnum(SEQUENCE, next)</code>.</p>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>CREATE SEQUENCE is a Trafodion SQL extension.</p>
</div>
<div class="paragraph">
<p>For more inforamation, see <a href="#drop_sequence_statement">DROP SEQUENCE Statement</a> or <a href="#alter_sequence_statement">ALTER SEQUENCE Statement</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE SEQUENCE [[catalog-name.]schema-name.]sequence
[START WITH integer]
[INCREMENT BY integer]
[MAXVALUE integer | NOMAXVALUE]
[MINVALUE integer]
[CACHE integer | NO CACHE]
[CYCLE | NO CYCLE]
[DATA TYPE]</code></pre>
</div>
</div>
<div class="paragraph">
<p>By default, it is an ascending sequence that starts with 1, increments by 1, has cache value of 25 and the
maximum value of 2<sup>63</sup>-2, does not cycle and belongs to LARGEINT data type.</p>
</div>
<div class="sect3">
<h4 id="create_sequence_syntax">3.16.1. Syntax Description of CREATE SEQUENCE</h4>
<div class="ulist">
<ul>
<li>
<p><code>[[catalog-name.]schema-name.]sequence</code></p>
<div class="paragraph">
<p>Specifies the name of the sequence to be created, with optional catalog and schema name, where each part of the name is a valid sql identifier with a maximum of 128 characters.</p>
</div>
<div class="paragraph">
<p>The name should be unique and does not exist for any session in the same schema. Trafodion does not support the overloading of session names. That is, you cannot register the same session name more than once.</p>
</div>
<div class="paragraph">
<p>If you do not fully qualify the session name, Trafodion qualifies it according to the schema of the current session. For more information, see <a href="#identifiers">Identifiers</a> and <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code>START WITH</code></p>
<div class="paragraph">
<p>Specifies the initial value. This value can only be positive, and must be greater than or equal to MINVALUE (if NO CACHE is specified) and less than MAXVALUE.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
If the initial value is beyond the range specified by MINVALUE or MAXVALUE, an error will be raised.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>If not specified, the START WITH defaults to 1. For an ascending sequence, this value is MINVALUE.</p>
</div>
</li>
<li>
<p><code>INCREMENT BY</code></p>
<div class="paragraph">
<p>Specifies the increment value between consecutive sequence values.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
This value can only be positive, so that Trafodion only supports ascending sequence. The value must be smaller than or equal to the difference between MAXVALUE and MINVALUE.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>If not specified, the INCREMENT BY defaults to 1.</p>
</div>
</li>
<li>
<p><code>MAXVALUE</code></p>
<div class="paragraph">
<p>Specifies the maximum value where an ascending sequence stops generating values or cycles. The default is 2<sup>^63</sup>-2.</p>
</div>
<div class="paragraph">
<p>The MAXVALUE of a sequence depends on the maximum value supported by the data type, and you can also specify a MAXVALUE within the range.</p>
</div>
<div class="paragraph">
<p>NOTE:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>An error is returned if MAXVALUE is beyond supported range, or if subsequent value is generated for an ascending sequence when the MAXVALUE is exceeded with NO CYCLE specified.</p>
</li>
<li>
<p>MAXVALUE might not be same as the actual maximum value that the sequence generated if the INCREAMENT BY is a value other than 1. For example, when a sequence is specified with START WITH 3, INCREMENT 4 and MAXVALUE 12 will return a maximum value of 11.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>NONMAXVALUE</code></p>
<div class="paragraph">
<p>If NOMAXVALUE is specified, for an ascending sequence, the MAXVALUE is the value you specified or the maximum value supported by the data type.</p>
</div>
</li>
<li>
<p><code>MINVALUE</code></p>
<div class="paragraph">
<p>Specifies the minimum value where an ascending sequence cycles after hitting the maximum limit. The default is 1.</p>
</div>
<div class="paragraph">
<p>The MINVALUE of a sequence depends on the minimum value supported by the data type, and you can also specify a MINVALUE within the range.</p>
</div>
<div class="paragraph">
<p>If MINVALUE and START WITH are not specified, for an ascending sequence, the MINVALUE defaults to 1.</p>
</div>
</li>
<li>
<p><code>CYCLE</code></p>
<div class="paragraph">
<p>Specifies that the sequence exhausts its range and wraps around after reaching its MAXVALUE.</p>
</div>
<div class="paragraph">
<p>If specified, for an ascending sequence, it restarts from MINVALUE after reaching MAXVALUE.</p>
</div>
</li>
<li>
<p><code>NOCYCLE</code></p>
<div class="paragraph">
<p>Specifies that the sequence cannot cycle once the MAXVALUE is reached, and throws an exception when generating subsequent value if the limit is exceeded.</p>
</div>
<div class="paragraph">
<p>NOCYCLE is the default.</p>
</div>
</li>
<li>
<p><code>CACHE</code></p>
<div class="paragraph">
<p>Specifies the range of upcoming successive values preallocated and stored in memory for speeding up future request.</p>
</div>
<div class="paragraph">
<p>The default CACHE value is 25.</p>
</div>
<div class="paragraph">
<p>The minimum CACHE value is 2.</p>
</div>
<div class="paragraph">
<p>The CACHE value must be less than or equal to the value determined by following formula:</p>
</div>
<div class="paragraph">
<p><code>(MAXVALUE – START WITH + 1) / INCREMENT BY</code></p>
</div>
<div class="paragraph">
<p>The sequence cache will be repopulated when the cache is exhausted.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
The unused preallocated values will be lost and leave unintended gaps if unexpected shutdown occurs or the sequence object is manually restarted, Trafodion will continue to cache new values from where it left off, so that the same value will never appear twice unless CYCLE is specified.
</td>
</tr>
</table>
</div>
</li>
<li>
<p><code>NOCACHE</code></p>
<div class="paragraph">
<p>Specifies the values of the sequence are not preallocated, which lowers the risk of losing values even if it might cause performance degradation. In this case, every request for a new value will be synchronously updated in the system table.</p>
</div>
<div class="paragraph">
<p>If both CACHE and NOCACHE are not specified, it will cache 25 values by default.</p>
</div>
</li>
<li>
<p><code>DATA TYPE</code></p>
<div class="paragraph">
<p>A sequence can be specified as following data types:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 33.3333%;">
<col style="width: 33.3333%;">
<col style="width: 33.3334%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Type</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Minimum value</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Maximum value</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">UNSIGNED SMALLINT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2<sup>16</sup>-1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">UNSIGHED INTEGER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2<sup>32</sup>-1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">LARGEINT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2<sup>63</sup>-2</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>If not specified, the default data type is LARGEINT.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="create_sequence_considerations">3.16.2. Considerations for CREATE SEQUENCE</h4>
<div class="paragraph">
<p>To issue a CREATE SEQUENCE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are creating the sequence in a shared schema.</p>
</li>
<li>
<p>You are the private schema owner.</p>
</li>
<li>
<p>You have the CREATE or CREATE_SEQUENCE component privilege for the SQL_OPERATIONS component.</p>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In this case, if you create a sequence in a private schema, it will be owned by the schema owner.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="create_sequence_examples">3.16.3. Examples of CREATE SEQUENCE</h4>
<div class="paragraph">
<p>The following statement creates a sequence named <code>employee_seq</code>, that starts with 1, increments by 1, has maximum value of 10000, does not cycle, caches 20 at a time and belongs to UNSIGNED SAMLLINT.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE SEQUENCE employee_seq
START WITH 1
INCREMENT BY 1
MAXVALUE 10000
NOCYCLE
CACHE 20
UNSIGNED SMALLINT</code></pre>
</div>
</div>
<div class="paragraph">
<p>The first reference to <code>seqnum(empolyee_seq, next)</code> will return 10000, and the second reference will return 10001. Each subsequent reference will return a value 1 greater than the previous value.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="create_table_statement">3.17. CREATE TABLE Statement</h3>
<div class="paragraph">
<p>The CREATE TABLE statement creates a Trafodion SQL table, which is a mapping of a relational SQL table to an HBase table.
The CREATE VOLATILE TABLE statement creates a temporary Trafodion SQL table that exists only during an SQL session. The
CREATE TABLE AS statement creates a table based on the data attributes of a SELECT query and populates the table using the
data returned by the SELECT query. See <a href="#tables">Tables</a>.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That
means that you cannot run this statement inside a user-defined
transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run
this statement, AUTOCOMMIT must be turned ON (the default) for the
session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE [VOLATILE] TABLE [IF NOT EXISTS] table
table-spec
[SALT USING num PARTITIONS [ON (column[, column]...)]]
[STORE BY {PRIMARY KEY | (key-column-list)}]
[HBASE_OPTIONS (hbase-options-list)]
[LOAD IF EXISTS | NO LOAD]
[AS select-query]
CREATE [VOLATILE] TABLE [IF NOT EXISTS] table
like-spec
[SALT USING num PARTITIONS [ON (column[, column]...)]]
Note: Support for SALT on CREATE TABLE LIKE is added in Trafodion release 2.1.
table-spec is:
(table-element [,table-element]...)
table-element is:
column-definition
| [CONSTRAINT constraint-name] table-constraint
column-definition is:
column data-type
[DEFAULT default | NO DEFAULT]
[[constraint constraint-name] column-constraint]...</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">data-type is:
char[acter] [(length [characters])]
[character set char-set-name]
[upshift] [[not]casespecific]
| char[acter] varying (length [characters])
[character set char-set-name]
[upshift] [[not]casespecific]
| varchar (length) [character set char-set-name]
[upshift] [[not]casespecific]
| nchar (length) [characters] [upshift] [[not]casespecific]
| nchar varying(length [characters]) [upshift] [[not] casespecific]
| numeric [(precision [,scale])] [signed|unsigned]
| smallint [signed|unsigned]
| int[eger] [signed|unsigned]
| largeint
| dec[imal] [(precision [,scale])] [signed|unsigned]
| float [(precision)]
| real
| double precision
| date
| time [(time-precision)]
| timestamp [(timestamp-precision)]
| interval { start-field to end-field | single-field }
default is:
literal
| null
| currentdate
| currenttime
| currenttimestamp
column-constraint is:
not null
| unique
| primary key [asc[ending] | desc[ending]]
| CHECK (condition)
| REFERENCES ref-spec
table-constraint is:
UNIQUE (column-list)
| PRIMARY KEY (key-column-list)
| CHECK (condition)
| FOREIGN KEY (column-list) REFERENCES ref-spec
ref-spec is:
referenced-table [(column-list)]</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">column-list is:
column-name [,column-name]...
key-column-list is:
column-name [ASC[ENDING] | DESC[ENDING]]
[,column-name [ASC[ENDING] | DESC[ENDING]]]...
like-spec is:
LIKE source-table [include-option]...
hbase-options-list is:
hbase-option = 'value'[, hbase-option = 'value']...</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="create_table_syntax">3.17.1. Syntax Description of CREATE TABLE</h4>
<div class="ulist">
<ul>
<li>
<p><code>VOLATILE</code></p>
<div class="paragraph">
<p>specifies a volatile table, which is a table limited to the session that creates the table. After the session ends, the</p>
</div>
</li>
<li>
<p><code>IF NOT EXISTS</code></p>
<div class="paragraph">
<p>creates an HBase table if it does not already exist when the table is created. This option does not apply to volatile tables.</p>
</div>
</li>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>specifies the ANSI logical name of the table. See <a href="#database_object_names">Database Object Names</a>. This name must be
unique among names of tables and views within its schema.</p>
</div>
<div class="admonitionblock tip">
<table>
<tr>
<td class="icon">
<i class="fa icon-tip" title="Tip"></i>
</td>
<td class="content">
Avoid using table names that begin with "TRAF_SAMPLE_", as Trafodion SQL assumes that
such tables are persistent sample tables. See also <a href="#update_statistics_incremental_update_statistics">Incremental Update Statistics</a>.
</td>
</tr>
</table>
</div>
</li>
<li>
<p><code>SALT USING <em>num</em> PARTITIONS [ON (<em>column</em>[, <em>column</em>]&#8230;)]</code></p>
<div class="paragraph">
<p>pre-splits the table into multiple regions when the table is created. Salting adds a hash value of the row key as a key
prefix, thus avoiding hot spots for sequential keys. The number of partitions that you specify can be a function of the
number of region servers present in the HBase cluster. You can specify a number from 2 to 1024. If you do not specify
columns, the default is to use all primary key columns.</p>
</div>
<div class="paragraph">
<p>If SALT is specified with LIKE, then this specification overrides that of the <em>source-table</em>. Note:
this is a new feature in Trafodion 2.1. In earlier releases, the SALT clause is ignored if specified
with LIKE.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>STORE BY { PRIMARY KEY | (<em>key-column-list</em>)}</code></p>
<div class="paragraph">
<p>specifies a set of columns on which to base the clustering key. The clustering key determines the order of rows within
the physical file that holds the table. The storage order has an effect on how you can partition the object.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>PRIMARY KEY</code></p>
<div class="paragraph">
<p>bases the clustering key on the primary key columns.</p>
</div>
</li>
<li>
<p><code><em>key-column-list</em></code></p>
<div class="paragraph">
<p>bases the clustering key on the columns in the <em>key-column-list</em>. The key columns in <em>key-column-list</em> must be specified
as NOT NULL and must be the same as the primary key columns that are defined on the table. If STORE BY is not specified,
then the clustering key is the PRIMARY KEY.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>HBASE_OPTIONS (<em>hbase-option</em> = '<em>value</em>'[, <em>hbase-option</em> = '<em>value</em>']&#8230;)</code></p>
<div class="paragraph">
<p>a list of HBase options to set for the table.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>hbase-option</em> = '<em>value</em>'</code></p>
<div class="paragraph">
<p>is one of the these HBase options and its assigned value:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 35%;">
<col style="width: 65%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">HBase Option</th>
<th class="tableblock halign-left valign-top">Accepted Values<sup>1</sup></th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">BLOCKCACHE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">BLOCKSIZE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'65536' | '<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">BLOOMFILTER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'NONE' | 'ROW' | 'ROWCOL'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CACHE_BLOOMS_ON_WRITE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CACHE_DATA_ON_WRITE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CACHE_INDEXES_ON_WRITE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">COMPACT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'true' | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">COMPACT_COMPRESSION</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'GZ' | 'LZ4' | 'LZO' | 'NONE' | 'SNAPPY'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">COMPRESSION</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'GZ' | 'LZ4' | 'LZO' | 'NONE' | 'SNAPPY'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DATA_BLOCK_ENCODING</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'DIFF' | 'FAST_DIFF' | 'NONE' | 'PREFIX'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DURABILITY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'USE_DEFAULT' | 'SKIP_WAL' | 'ASYNC_WAL' | 'SYNC_WAL' | 'FSYNC_WAL'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">EVICT_BLOCKS_ON_CLOSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>'true'</strong> | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">IN_MEMORY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>'true'</strong> | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">KEEP_DELETED_CELLS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>'true'</strong> | 'false'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MAX_FILESIZE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MAX_VERSIONS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'1' | '<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MEMSTORE_FLUSH_SIZE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MIN_VERSIONS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'0' | '<em>positive-integer</em>'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">PREFIX_LENGTH_KEY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'<em>positive-integer</em>', which should be less than maximum length of the
key for the table. It applies only if the SPLIT_POLICY is <code>KeyPrefixRegionSplitPolicy</code>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">REPLICATION_SCOPE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'0' | '1'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SPLIT_POLICY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'org.apache.hadoop.hbase.regionserver.ConstantSizeRegionSplitPolicy' |
'org.apache.hadoop.hbase.regionserver.IncreasingToUpperBoundRegionSplitPolicy' |
'org.apache.hadoop.hbase.regionserver.KeyPrefixRegionSplitPolicy'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">TTL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">'-1' (forever) | '<em>positive-integer</em>'</p></td>
</tr>
</tbody>
</table>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>Values in boldface are default values.</p>
</li>
</ol>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>LOAD IF EXISTS</code></p>
<div class="paragraph">
<p>loads data into an existing table. Must be used with AS <em>select-query</em>.
See <a href="#create_table_considerations_for_load_if_exists_and_no_load_options_of_create_table_as">Considerations For LOAD IF EXISTS and NO LOAD options of CREATE TABLE AS</a>.</p>
</div>
</li>
<li>
<p><code>NO LOAD</code></p>
<div class="paragraph">
<p>creates a table with the CREATE TABLE AS statement, but does not load data into the table.
See <a href="#create_table_considerations_for_load_if_exists_and_no_load_options_of_create_table_as">Considerations for LOAD IF EXISTS and NO LOAD options of CREATE TABLE AS</a>.</p>
</div>
</li>
<li>
<p><code>AS <em>select-query</em></code></p>
<div class="paragraph">
<p>specifies a select query which is used to populate the created table. A select query can be any SQL select statement.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>column data-type</em></code></p>
<div class="paragraph">
<p>specifies the name and data type for a column in the table. At least one column definition is required in a
CREATE TABLE statement.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><em>column</em> is an SQL identifier. <em>column</em> must be unique among column names in the table. If the name is a Trafodion
SQL reserved word, you must delimit it by enclosing it in double quotes. Such delimited parts are case-sensitive.
For example: "join".</p>
</li>
<li>
<p><em>data-type</em> is the data type of the values that can be stored in <em>column</em>. A default value must be of the same type as
the column, including the character set for a character column. See "Data Types" Data type also includes case specific
information, such as UPSHIFT.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>[NOT] CASESPECIFIC</code></p>
<div class="paragraph">
<p>specifies that the column contains strings that are not case specific. The default is CASESPECIFIC. Comparison between two
values is done in a case insensitive way only if both are case insensitive. This applies to comparison in a binary predicate,
LIKE predicate, and POSITION/REPLACE string function searches.</p>
</div>
</li>
<li>
<p><code>DEFAULT <em>default</em> | NO DEFAULT</code></p>
<div class="paragraph">
<p>specifies a default value for the column or specifies that the column does not have a default value.
See <a href="#default_clause">DEFAULT Clause</a>.</p>
</div>
</li>
<li>
<p><code>CONSTRAINT <em>constraint-name</em></code></p>
<div class="paragraph">
<p>specifies a name for the column or table constraint. <em>constraint-name</em> must have the same schema as <em>table</em> and must be
unique among constraint names in its schema. If you omit the schema portions of the name you specify in <em>constraint-name</em>,
Trafodion SQL expands the constraint name by using the schema for <em>table</em>. See <a href="#constraint_names">Constraint Names</a> and
<a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code>NOT NULL</code></p>
<div class="paragraph">
<p>is a column constraint that specifies that the column cannot contain nulls. If you omit NOT NULL, nulls are allowed in
the column. If you specify both NOT NULL and NO DEFAULT, each row inserted in the table must include a value for the column.
See <a href="#null">Null</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>UNIQUE, or, UNIQUE (<em>column-list</em>)</code></p>
<div class="paragraph">
<p>is a column or table constraint, respectively, that specifies that the column or set of columns cannot contain more than
one occurrence of the same value or set of values. If you omit UNIQUE, duplicate values are allowed unless the column or set of columns is the PRIMARY KEY.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><em>column-list</em> cannot include more than one occurrence of the same column. In addition, the set of columns that you
specify on a UNIQUE constraint cannot match the set of columns on any other UNIQUE constraint for the table or on the
PRIMARY KEY constraint for the table. All columns defined as unique must be specified as NOT NULL.</p>
<div class="paragraph">
<p>A UNIQUE constraint is enforced with a unique index. If there is already a unique index on <em>column-list</em>, Trafodion SQL
uses that index. If a unique index does not exist, the system creates a unique index.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>PRIMARY KEY [ASC[ENDING] | DESC[ENDING]], or, PRIMARY KEY (<em>key-column-list</em>)</code></p>
<div class="paragraph">
<p>is a column or table constraint, respectively, that specifies a column or set of columns as the primary key for the table.
<em>key-column-list</em> cannot include more than one occurrence of the same column.</p>
</div>
<div class="paragraph">
<p>ASCENDING and DESCENDING specify the direction for entries in one column within the key. The default is ASCENDING.</p>
</div>
<div class="paragraph">
<p>The PRIMARY KEY value in each row of the table must be unique within the table. A PRIMARY KEY defined for a set of columns
implies that the column values are unique and not null. You can specify PRIMARY KEY only once on any CREATE TABLE statement.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL uses the primary key as the clustering key of the table to avoid creating a separate, unique index to implement
the primary key constraint.</p>
</div>
<div class="paragraph">
<p>A PRIMARY KEY constraint is required in Trafodion SQL.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>CHECK (<em>condition</em>)</code></p>
<div class="paragraph">
<p>is a constraint that specifies a condition that must be satisfied for each row in the table.
See <a href="#search_condition">Search Condition</a>.</p>
</div>
<div class="paragraph">
<p>You cannot refer to the CURRENT_DATE, CURRENT_TIME, or CURRENT_TIMESTAMP function in a CHECK constraint, and you cannot use
subqueries in a CHECK constraint.</p>
</div>
</li>
<li>
<p><code>REFERENCES <em>ref-spec</em></code></p>
<div class="paragraph">
<p>specifies a REFERENCES column constraint. The maximum combined length of the columns for a REFERENCES constraint is 2048 bytes.</p>
</div>
<div class="paragraph">
<p><em>ref-spec</em> is:</p>
</div>
<div class="paragraph">
<p><code><em>referenced-table</em> [(<em>column-list</em>)]</code></p>
</div>
<div class="ulist">
<ul>
<li>
<p><em>referenced-table</em> is the table referenced by the foreign key in a referential constraint. <em>referenced-table</em> cannot be a view.
<em>referenced-table</em> cannot be the same as <em>table</em>. <em>referenced-table</em> corresponds to the foreign key in the <em>table</em>.</p>
</li>
<li>
<p><em>column-list</em> specifies the column or set of columns in the <em>referenced-table</em> that corresponds to the foreign key in <em>table</em>.
The columns in the column list associated with REFERENCES must be in the same order as the columns in the column list associated
with FOREIGN KEY. If <em>column-list</em> is omitted, the referenced table&#8217;s PRIMARY KEY columns are the referenced columns.</p>
<div class="paragraph">
<p>A table can have an unlimited number of referential constraints, and you can specify the same foreign key in more than one
referential constraint, but you must define each referential constraint separately. You cannot create self-referencing foreign
key constraints.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>FOREIGN KEY (<em>column-list</em>) REFERENCES <em>ref-spec</em></code></p>
<div class="paragraph">
<p>is a table constraint that specifies a referential constraint for the table, declaring that a column or set of columns (called
a foreign key) in <em>table</em> can contain only values that match those in a column or set of columns in the table specified in the
REFERENCES clause.</p>
</div>
<div class="paragraph">
<p>The two columns or sets of columns must have the same characteristics (data type, length, scale, precision). Without the FOREIGN
KEY clause, the foreign key in <em>table</em> is the column being defined; with the FOREIGN KEY clause, the foreign key is the column or
set of columns specified in the FOREIGN KEY clause. For information about <em>ref-spec</em>, see REFERENCES <em>ref-spec</em>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>LIKE <em>source-table</em> [<em>include-option</em>]&#8230;</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to create a table like the existing table, <em>source-table</em>, omitting constraints (with the exception of the NOT
NULL and PRIMARY KEY constraints) and partitions unless the <em>include-option</em> clauses are specified.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>source-table</em></code></p>
<div class="paragraph">
<p>is the ANSI logical name for the existing table and must be unique among names of tables and views within its schema.</p>
</div>
</li>
<li>
<p><code><em>include-option</em></code></p>
<div class="ulist">
<ul>
<li>
<p><code>WITH CONSTRAINTS</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to use constraints from <em>source-table</em>. Constraint names for <em>table</em> are randomly generated unique names.</p>
</div>
<div class="paragraph">
<p>When you perform a CREATE TABLE LIKE, whether or not you include the WITH CONSTRAINTS clause, the target table will have all
the NOT NULL column constraints that exist for the source table with different constraint names.</p>
</div>
</li>
<li>
<p><code>WITH PARTITIONS</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to use partition definitions from <em>source-table</em>. Each new table partition resides on the same volume
as its original <em>source-table</em> counterpart. The new table partitions do not inherit partition names from the original table.
Instead, Trafodion SQL generates new names based on the physical file location.</p>
</div>
<div class="paragraph">
<p>If you specify the LIKE clause and the SALT USING <em>num</em> PARTITIONS clause, you cannot specify WITH PARTITIONS.</p>
</div>
</li>
<li>
<p><code>WITHOUT DIVISION</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to not use divisioning from <em>source-table</em>. If this clause is omitted, then
the <em>table</em> will have the same divisioning as the <em>source-table</em>.</p>
</div>
</li>
<li>
<p><code>WITHOUT SALT</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to not use salting for <em>table</em>. If this clause is omitted,
and no SALT clause is specified,
the <em>table</em> will have the same divisioning as the <em>source-table</em>.</p>
</div>
<div class="paragraph">
<p>This option cannot be specified if a SALT clause is also specified.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="create_table_considerations">3.17.2. Considerations for CREATE TABLE</h4>
<div class="paragraph">
<p>The following subsections provide considerations for various CREATE TABLE options:</p>
</div>
<div class="sect4">
<h5 id="create_table_authorization_and_availability_requirements">Authorization and Availability Requirements</h5>
<div class="sect5">
<h6 id="create_table_required_privileges">Required Privileges</h6>
<div class="paragraph">
<p>To issue a CREATE TABLE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are creating the table in a shared schema.</p>
</li>
<li>
<p>You are the private schema owner.</p>
</li>
<li>
<p>You have the CREATE or CREATE_TABLE component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In this case, if you create a table in a private schema, it will be owned by the schema owner.
</td>
</tr>
</table>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect5">
<h6 id="create_table_privileges_needed_to_create_a_referential_integrity_constraint">Privileges Needed to Create a Referential Integrity Constraint</h6>
<div class="paragraph">
<p>To create a referential integrity constraint (that is, a constraint on he table that refers to a column in another table),
one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the referencing and referenced tables.</p>
</li>
<li>
<p>You have these privileges on the referencing and referenced table:</p>
<div class="ulist">
<ul>
<li>
<p>For the referencing table, you have the CREATE or CREATE_TABLE component privilege for the SQL_OPERATIONS component.</p>
</li>
<li>
<p>For the referenced table, you have the REFERENCES (or ALL) privilege on the referenced table through your username
or through a granted role.</p>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>If the constraint refers to the other table in a query expression, you must also have SELECT privileges on the other table.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="create_volatile_table_considerations">Considerations for CREATE VOLATILE TABLE</h5>
<div class="ulist">
<ul>
<li>
<p>Volatile temporary tables are closely linked to the session. Their name space is unique across multiple concurrent
sessions, and therefore allow multiple sessions to use the same volatile temporary table names simultaneously without
any conflicts.</p>
</li>
<li>
<p>Volatile tables support creation of indexes. Volatile index can be created only on volatile table.</p>
</li>
<li>
<p>Volatile tables are partitioned by the system. The number of partitions is limited to four partitions by default.
The partitions will be distributed across the cluster. The default value is four partitions regardless of the system
configuration.</p>
</li>
<li>
<p>UPDATE STATISTICS is not supported for volatile tables. If you need statistics, you must use a non-volatile table instead.</p>
</li>
<li>
<p>Volatile tables can be created and accessed using one-part, two-part, or three-part names. However, you must use the
same name (one part, two part, or three part) for any further DDL or DML statements on the created volatile table.
See <a href="#create_table_examples">Examples of CREATE TABLE</a>.</p>
</li>
<li>
<p>Trafodion SQL allows users to explicitly specify primary key and STORE BY clauses on columns that contain null values.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Trafodion SQL does not require that the first column in a volatile table contain not null values and be the primary key.
Instead, Trafodion SQL attempts to partition the table, if possible, using an appropriate suitable key column as the
primary and partitioning key. For more information,
see <a href="#create_table_how_trafodion_sql_selects_suitable_keys_for_volatile_tables">How Trafodion SQL Selects Suitable Keys for Volatile Tables</a>.</p>
</li>
</ul>
</div>
<div class="sect5">
<h6 id="create_table_restrictions_for_create_volatile_table">Restrictions for CREATE VOLATILE TABLE</h6>
<div class="paragraph">
<p>These items are not supported for volatile tables:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>ALTER statement</p>
</li>
<li>
<p>User constraints</p>
</li>
<li>
<p>Creating views</p>
</li>
<li>
<p>Creating non-volatile indexes on a volatile table or a volatile index on a non-volatile table</p>
</li>
<li>
<p>CREATE TABLE LIKE operations</p>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="create_table_how_trafodion_sql_supports_nullable_keys_for_volatile_tables">How Trafodion SQL Supports Nullable Keys for Volatile Tables</h6>
<div class="ulist">
<ul>
<li>
<p>Allows nullable keys in primary key, STORE BY, and unique constraints.</p>
</li>
<li>
<p>A null value is treated as the highest value for that column.</p>
</li>
<li>
<p>A null value as equal to other null values and only one value is allowed for that column.</p>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="create_table_how_trafodion_sql_selects_suitable_keys_for_volatile_tables">How Trafodion SQL Selects Suitable Keys for Volatile Tables</h6>
<div class="paragraph">
<p>Trafodion SQL searches for the first suitable column in the list of columns of the table being created. Once the column
is located, the table is partitioned on it. The searched columns in the table might be explicitly specified (as in a
CREATE TABLE statement) or implicitly created (as in a CREATE TABLE AS SELECT statement).</p>
</div>
<div class="paragraph">
<p>The suitable key column is selected only if no primary key or STORE BY clause has been specified in the statement. If any
of these clauses have been specified, they are used to select the key columns.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>Trafodion SQL follows these guidelines to search for and select suitable keys:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>A suitable column can be a nullable column.</p>
</li>
<li>
<p>Certain data types in Trafodion SQL cannot be used as a partitioning key. Currently, this includes any floating point
columns (REAL, DOUBLE PRECISION, and FLOAT).</p>
</li>
<li>
<p>Trafodion SQL searches for a suitable column according to this predefined order:</p>
<div class="ulist">
<ul>
<li>
<p>Numeric columns are chosen first, followed by fixed CHAR, DATETIME, INTERVAL, and VARCHAR data types.</p>
</li>
<li>
<p>Within numeric data types, the order is binary NUMERIC (LARGEINT, INTEGER, SMALLINT), and DECIMAL.</p>
</li>
<li>
<p>An unsigned column is given preference over a signed column.</p>
</li>
<li>
<p>A non-nullable column is given preference over a nullable column.</p>
</li>
<li>
<p>If all data types are the same, the first column is selected.</p>
</li>
</ul>
</div>
</li>
<li>
<p>If a suitable column is not located, the volatile table becomes a non-partitioned table with a system-defined SYSKEY as its primary key.</p>
</li>
<li>
<p>If a suitable column is located, it becomes the partitioning key where the primary key is <em>suitable_column</em>, SYSKEY.
This causes the table to be partitioned while preventing the duplicate key and null-to-non-null errors.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>The list below shows the order of precedence, from low to high, of data types when Trafodion SQL searches for a suitable
key. A data type appearing later has precedence over previously-appearing data types. Data types that do not appear in
the list below cannot be chosen as a key column.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>Precedence of Data Types (From Low to High):</p>
</div>
<div class="ulist">
<ul>
<li>
<p>VARCHAR</p>
</li>
<li>
<p>INTERVAL</p>
</li>
<li>
<p>DATETIME</p>
</li>
<li>
<p>CHAR(ACTER)</p>
</li>
<li>
<p>DECIMAL (signed, unsigned)</p>
</li>
<li>
<p>SMALLINT (signed, unsigned)</p>
</li>
<li>
<p>INTEGER (signed,unsigned)</p>
</li>
<li>
<p>LARGEINT (signed only)</p>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="create_table_creating_nullable_constraints_in_a_volatile_table">Creating Nullable Constraints in a Volatile Table</h6>
<div class="paragraph">
<p>These examples show the creation of nullable constraints (primary key, STORE BY, and unique) in a volatile table:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a int, primary key(a));
create volatile table t (a int, store by primary key);
create volatile table t (a int unique);</code></pre>
</div>
</div>
</div>
<div class="sect5">
<h6 id="create_table_creating_a_volatile_table_with_a_nullable_primary_key">Creating a Volatile Table With a Nullable Primary Key</h6>
<div class="paragraph">
<p>This example creates a volatile table with a nullable primary key:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;create volatile table t (a int, primary key(a));
--- SQL operation complete.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>Only one unique null value is allowed:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;insert into t values (null);
--- 1 row(s) inserted.
&gt;&gt;insert into t values (null);
*** ERROR[8102] The operation is prevented by a unique constraint.
--- 0 row(s) inserted.</code></pre>
</div>
</div>
</div>
<div class="sect5">
<h6 id="create_table_examples_for_selecting_suitable_keys_for_volatile_tables">Examples for Selecting Suitable Keys for Volatile Tables</h6>
<div class="paragraph">
<p>These examples show the order by which Trafodion SQL selects a suitable key based on the precedence rules described in
<a href="#create_table_how_trafodion_sql_selects_suitable_keys_for_volatile_tables">How Trafodion SQL Selects Suitable Keys for Volatile Tables</a>:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Selects column a as the primary and partitioning key:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a int);</code></pre>
</div>
</div>
</li>
<li>
<p>Selects column b because int has a higher precedence than char:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a char(10), b int);</code></pre>
</div>
</div>
</li>
<li>
<p>Selects column b because not null has precedence over nullable columns:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a int, b int not null);</code></pre>
</div>
</div>
</li>
<li>
<p>Selects column b because int has precedence over decimal:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a decimal(10), b int);</code></pre>
</div>
</div>
</li>
<li>
<p>Selects the first column, a, because both columns have the same data type:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a int not null, b int not null);</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Selects column b because char has precedence over date:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a date, b char(10));</code></pre>
</div>
</div>
</li>
<li>
<p>Selects column b because the real data type is not part of the columns to be examined:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a real, b date);</code></pre>
</div>
</div>
</li>
<li>
<p>Does not select any column as the primary/partitioning key. SYSKEY is used automatically.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create volatile table t (a real, b double precision not null);</code></pre>
</div>
</div>
<div class="paragraph">
<p>Similar examples would be used for CREATE TABLE AS SELECT queries.</p>
</div>
</li>
</ul>
</div>
</div>
</div>
<div class="sect4">
<h5 id="create_table_considerations_for_create_table_like">Considerations for CREATE TABLE &#8230; LIKE</h5>
<div class="paragraph">
<p>The CREATE TABLE LIKE statement does not create views, owner information, or privileges for the new table based on the
source table. Privileges associated with a new table created by using the LIKE specification are defined as if the new
table is created explicitly by the current user.</p>
</div>
<div class="sect5">
<h6 id="create_table_like_and_file_attributes">CREATE TABLE &#8230; LIKE and File Attributes</h6>
<div class="paragraph">
<p>CREATE TABLE &#8230; LIKE creates a table like another table, with the exception of file attributes. File attributes
include COMPRESSION, and so on. If you do not include the attribute value as part of the CREATE TABLE &#8230; LIKE
command, SQL creates the table with the default value for the attributes and not the value from the source object.
For example, to create a table like another table that specifies compression, you must specify the compression attribute
value as part of the CREATE TABLE&#8230; LIKE statement. In the following example, the original CREATE TABLE statement
creates a table without compression. However, in the CREATE TABLE &#8230; LIKE statement, compression is specified.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">-- Original Table create table NPTEST
(FIRST_NAME CHAR(12) CHARACTER SET ISO88591 COLLATE DEFAULT NO DEFAULT NOT NULL
, LAST_NAME CHAR(24) CHARACTER SET ISO88591 COLLATE DEFAULT NO DEFAULT NOT NULL
, ADDRESS CHAR(128) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL
, ZIP INT DEFAULT 0
, PHONE CHAR(10) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL
, SSN LARGEINT NO DEFAULT NOT NULL
, INFO1 CHAR(128) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL
, INFO2 CHAR(128) CHARACTER SET ISO88591 COLLATE DEFAULT DEFAULT NULL
, primary key (SSN,first_name,last_name)
)
max table size 512
-- CREATE TABLE LIKE
create table LSCE002 like NPTEST ATTRIBUTE compression type hardware;</code></pre>
</div>
</div>
</div>
</div>
<div class="sect4">
<h5 id="create_table_considerations_for_create_table_as">Considerations for CREATE TABLE AS</h5>
<div class="paragraph">
<p>These considerations apply to CREATE TABLE AS:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Access to the table built by CREATE TABLE AS will be a full table scan because a primary and clustering key cannot
be easily defined.</p>
</li>
<li>
<p>Compile time estimates and runtime information is not generated for CREATE TABLE AS tables.</p>
</li>
<li>
<p>You cannot manage CREATE TABLE AS tables using WMS compile time or runtime rules.</p>
</li>
<li>
<p>You cannot specify a primary key for a CREATE TABLE AS table without explicitly defining all the columns in the
CREATE TABLE statement.</p>
</li>
<li>
<p>You cannot generate an explain plan for a CREATE TABLE AS &#8230;INSERT/SELECT statement. You can, however, use the
EXPLAIN plan for a CREATE TABLE AS &#8230; INSERT/SELECT statement if you use the NO LOAD option.</p>
</li>
<li>
<p>You cannot use the ORDER BY clause in a CREATE TABLE AS statement. The compiler transparently orders the selected
rows to improve the efficiency of the insert.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect5">
<h6 id="create_table_considerations_for_load_if_exists_and_no_load_options_of_create_table_as">Considerations for LOAD IF EXISTS and NO LOAD options of CREATE TABLE AS</h6>
<div class="paragraph">
<p>The LOAD IF EXISTS option in a CREATE TABLE AS statement causes data to be loaded into an existing table. If you do not
specify the LOAD IF EXISTS option and try to load data into an existing table, the CREATE TABLE AS statement fails to
execute. Use the LOAD IF EXISTS option with the AS clause in these scenarios:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Running CREATE TABLE AS without re-creating the table. The table must be empty. Otherwise, the CREATE TABLE AS statement
returns an error. Delete the data in the table by using a DELETE statement before issuing the CREATE TABLE AS statement.</p>
</li>
<li>
<p>Using CREATE TABLE AS to incrementally add data to an existing table. You must start a user-defined transaction before
issuing the CREATE TABLE AS statement. If you try to execute the CREATE TABLE AS statement without starting a user-defined
transaction, an error is returned, stating that data already exists in the table. With a user-defined transaction, newly
added rows are rolled back if an error occurs.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>The NO LOAD option in a CREATE TABLE AS statement creates a table with the CREATE TABLE AS statement, but does not load data
into the table. The option is useful if you must create a table to review its structure and to analyze the SELECT part of the
CREATE TABLE AS statement with the EXPLAIN statement. You can also use EXPLAIN to analyze the implicated INSERT/SELECT part of
the CREATE TABLE AS &#8230; NO LOAD statement. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE ttgt NO LOAD AS (SELECT ...);</code></pre>
</div>
</div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="create_table_trafodion_sql_extensions_to_create_table">3.17.3. Trafodion SQL Extensions to CREATE TABLE</h4>
<div class="paragraph">
<p>This statement is supported for compliance with ANSI SQL:1999 Entry Level. Trafodion SQL extensions to the CREATE TABLE
statement are ASCENDING, DESCENDING, and PARTITION clauses. CREATE TABLE LIKE is also an extension.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="create_table_examples">3.17.4. Examples of CREATE TABLE</h4>
<div class="ulist">
<ul>
<li>
<p>This example creates a table. The clustering key is the primary key.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE SALES.ODETAIL
( ordernum NUMERIC (6) UNSIGNED NO DEFAULT NOT NULL, partnum NUMERIC (4)
UNSIGNED NO DEFAULT NOT NULL, unit_price NUMERIC (8,2) NO DEFAULT NOT
NULL, qty_ordered NUMERIC (5) UNSIGNED NO DEFAULT NOT NULL,
PRIMARY KEY (ordernum, partnum) );</code></pre>
</div>
</div>
</li>
<li>
<p>This example creates a table like the JOB table with the same constraints:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE PERSNL.JOB_CORPORATE LIKE PERSNL.JOB WITH CONSTRAINTS;</code></pre>
</div>
</div>
</li>
<li>
<p>This is an example of NOT CASESPECIFIC usage:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE T (a char(10) NOT CASESPECIFIC, b char(10));
INSERT INTO T values ('a', 'A');</code></pre>
</div>
</div>
</li>
<li>
<p>A row is not returned in this example. Constant ‘A’ is case sensitive, whereas column ‘a’ is insensitive.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM T WHERE a = 'A';</code></pre>
</div>
</div>
</li>
<li>
<p>The row is returned in this example. Both sides are case sensitive.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM T WHERE a = 'A' (not casespecific);</code></pre>
</div>
</div>
</li>
<li>
<p>The row is returned in this example. A case sensitive comparison is done because column ‘b’ is case sensitive.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM T WHERE b = 'A';</code></pre>
</div>
</div>
</li>
<li>
<p>The row is returned in this example. A case sensitive comparison is done because column ‘b’ is case sensitive.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM T WHERE b = 'A' (not casespecific);</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="create_table_examples_create_table_as">Examples of CREATE TABLE AS</h5>
<div class="paragraph">
<p>This section shows the column attribute rules used to generate and specify the column names and data types of the table
being created.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>If <em>column-attributes</em> are not specified, the select list items of the select-query are used to generate the column
names and data attributes of the created table. If the select list item is a column, then it is used as the name of the
created column. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table t as select a,b from t1</code></pre>
</div>
</div>
<div class="paragraph">
<p>Table t has 2 columns named (a,b) and the same data attributes as columns from table t1.</p>
</div>
</li>
<li>
<p>If the select list item is an expression, it must be renamed with an AS clause. An error is returned if expressions are
not named. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table t as select a+1 as c from t1</code></pre>
</div>
</div>
<div class="paragraph">
<p>Table t has 1 column named (c) and data attribute of (a+1)</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table t as select a+1 from t1</code></pre>
</div>
</div>
<div class="paragraph">
<p>An error is returned, expression must be renamed.</p>
</div>
</li>
<li>
<p>If <em>column-attributes</em> are specified and contains <em>datatype-info</em>, then they override the attributes of the select items
in the select query. These data attributes must be compatible with the corresponding data attributes of the select list items
in the select-query.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table t(a int) as select b from t1</code></pre>
</div>
</div>
<div class="paragraph">
<p>Table t has one column named "a" with data type "int".</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table t(a char(10)) as select a+1 b from t1;</code></pre>
</div>
</div>
<div class="paragraph">
<p>An error is returned because the data attribute of column "a", a char, does not match the data attribute of the select list
item "b" a numeric.</p>
</div>
</li>
<li>
<p>If <em>column-attributes</em> are specified and they only contain <em>column-name</em>, then the specified column-name override any name
that was derived from the select query.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table t(c,d) as select a,b from t1</code></pre>
</div>
</div>
<div class="paragraph">
<p>Table t has 2 columns, c and d, which has the data attributes of columns a and b from table t1.</p>
</div>
</li>
<li>
<p>If <em>column-attributes</em> are specified, then they must contain attributes corresponding to all select list items in the
<em>select-query</em>. An error is returned, if a mismatch exists.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table t(a int) as select b,c from t1</code></pre>
</div>
</div>
<div class="paragraph">
<p>An error is returned. Two items need to be specified as part of the table-attributes.</p>
</div>
</li>
<li>
<p>The <em>column-attributes</em> must specify either the <em>column-name datatype-info</em> pair or just the <em>column-name</em> for all
columns. You cannot specify some columns with just the name and others with name and data type.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table t(a int, b) as select c,d from t1</code></pre>
</div>
</div>
<div class="paragraph">
<p>An error is returned.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>In the following example, table t1 is created. Table t2 is created using the CREATE TABLE AS syntax without table attributes:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE t1 (c1 int not null primary key, c2 char(50));
CREATE TABLE t2 (c1 int, c2 char (50) UPSHIFT NOT NULL) AS SELECT * FROM t1;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="create_view_statement">3.18. CREATE VIEW Statement</h3>
<div class="paragraph">
<p>The CREATE VIEW statement creates a Trafodion SQL view. See <a href="#views">Views</a>.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside
a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT
must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE [OR REPLACE] VIEW view
[(column-name ] [,column-name ...)]
AS query-expr [order-by-clause]
[WITH CHECK OPTION]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="create_view_syntax">3.18.1. Syntax Description of CREATE VIEW</h4>
<div class="ulist">
<ul>
<li>
<p><code>OR REPLACE</code></p>
<div class="paragraph">
<p>creates a view if one does not exist or replaces a view if a view of the same name exists. The view being replaced might
have the same view definition or a different view definition.</p>
</div>
</li>
<li>
<p><code><em>view</em></code></p>
<div class="paragraph">
<p>specifies the ANSI logical name of the view. See <a href="#database_object_names">Database Object Names</a>. This name must be unique
among names of tables and views within its schema.</p>
</div>
</li>
<li>
<p><code>(<em>column-name</em> [,<em>column-name</em> ]&#8230;)</code></p>
<div class="paragraph">
<p>specifies names for the columns of the view. Column names in the list must match one-for-one with columns in the table
specified by <em>query-expr</em>.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>If you omit this clause, columns in the view have the same names as the corresponding columns in <em>query-expr</em>. You must
specify this clause if any two columns in the table specified by <em>query-expr</em> have the same name or if any column of that
table does not have a name. For example, this query expression SELECT MAX(salary), AVG(salary) AS average_salary FROM
employee the first column does not have a name.</p>
</div>
<div class="paragraph">
<p>No two columns of the view can have the same name; if a view refers to more than one table and the select list refers to
columns from different tables with the same name, you must specify new names for columns that would otherwise have duplicate
names.</p>
</div>
</li>
<li>
<p><code>AS <em>query-expr</em></code></p>
<div class="paragraph">
<p>specifies the columns for the view and sets the selection criteria that determines the rows that make up the view. For
information about character string literals, see <a href="#character_string_literals">Character String Literals</a>.
For the syntax and syntax description of <em>query-expr</em>, see <a href="#select_statement">SELECT Statement</a>. The CREATE VIEW statement
provides this restriction with regard to the <em>query-expr</em> syntax: [ANY_N_], [FIRST <em>N</em>] select list items are not allowed
in a view.</p>
</div>
</li>
<li>
<p><code><em>order-by-clause</em></code></p>
<div class="paragraph">
<p>specifies the order in which to sort the rows of the final result table. For the syntax and syntax description of the
<em>order-by-clause</em>, see <a href="#select_statement">SELECT Statement</a>. The CREATE VIEW statement restricts the <em>order-by-clause</em>
with regard to the <em>access-clause</em> and <em>mode-clause</em>. The <em>access-mode</em> and <em>mode-clause</em> cannot follow the
<em>order-by-clause</em>.</p>
</div>
</li>
<li>
<p><code>WITH CHECK OPTION</code></p>
<div class="paragraph">
<p>specifies that no row can be inserted or updated in the database through the view unless the row satisfies the view
definition—that is, the search condition in the WHERE clause of the query expression must evaluate to true for any
row that is inserted or updated. This option is only allowed for updatable views.</p>
</div>
<div class="paragraph">
<p>If you omit this option, a newly inserted row or an updated row need not satisfy the view definition, which means that
such a row can be inserted or updated in the table but does not appear in the view. This check is performed each time a
row is inserted or updated.</p>
</div>
<div class="paragraph">
<p>WITH CHECK OPTION does not affect the query expression; rows must always satisfy the view definition.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="create_view_considerations">3.18.2. Considerations for CREATE VIEW</h4>
<div class="ulist">
<ul>
<li>
<p>If you specify CREATE OR REPLACE VIEW:</p>
<div class="ulist">
<ul>
<li>
<p>A new view is created if a view of the same name does not exist.</p>
</li>
<li>
<p>If a view of same name exists, the old view definition is dropped, and a view with a new definition is created. No check
will be done to see if the new view is identical to the view it is replacing. The CREATE OR REPLACE VIEW command will
unilaterally drop the old view definition and replace it with the new view definition.</p>
</li>
<li>
<p>The privileges granted on the old view will be re-granted on the new view. If the re-grant of privileges fails, the
CREATE OR REPLACE VIEW operation fails.</p>
</li>
<li>
<p>When CREATE OR REPLACE VIEW replaces an existing view, any dependent views will be dropped.</p>
</li>
</ul>
</div>
</li>
<li>
<p>You can specify GROUP BY using ordinals to refer to the relative position within the SELECT list.
For example, GROUP BY 3, 2, 1.</p>
</li>
<li>
<p>Dynamic parameters are not allowed.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="create_view_effect_of_adding_a_column_on_view_definitions">Effect of Adding a Column on View Definitions</h5>
<div class="paragraph">
<p>The addition of a column to a table has no effect on any existing view definitions or conditions included in constraint
definitions. Any implicit column references specified by SELECT * in view or constraint definitions are replaced by
explicit column references when the definition clauses are originally evaluated.</p>
</div>
</div>
<div class="sect4">
<h5 id="create_view_authorization_and_availability_requirements">Authorization and Availability Requirements</h5>
<div class="paragraph">
<p>To issue a CREATE VIEW statement, you must have SELECT privileges on the objects underlying the view or be the owner of
the objects underlying the view, and one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are creating the view in a shared schema.</p>
</li>
<li>
<p>You are the private schema owner.</p>
</li>
<li>
<p>You have the CREATE or CREATE_VIEW component privilege for the SQL_OPERATIONS component.</p>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In this case, if you create a view in a private schema, it will be owned by the schema owner.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>When you create a view on a single table, the owner of the view is automatically given all privileges WITH GRANT OPTION
on the view. However, when you create a view that spans multiple tables, the owner of the view is given only SELECT
privileges WITH GRANT OPTION. If you try to grant privileges to another user on the view other than SELECT, you will
receive a warning that you lack the grant option for that privilege.</p>
</div>
</div>
<div class="sect4">
<h5 id="create_view_updatable_and_non_updatable_views">Updatable and Non-Updatable Views</h5>
<div class="paragraph">
<p>Single table views can be updatable. Multi-table views cannot be updatable.</p>
</div>
<div class="paragraph">
<p>To define an updatable view, a query expression must also meet these requirements:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>It cannot contain a JOIN, UNION, or EXCEPT clause.</p>
</li>
<li>
<p>It cannot contain a GROUP BY or HAVING clause.</p>
</li>
<li>
<p>It cannot directly contain the keyword DISTINCT.</p>
</li>
<li>
<p>The FROM clause must refer to exactly one table or one updatable view.</p>
</li>
<li>
<p>It cannot contain a WHERE clause that contains a subquery.</p>
</li>
<li>
<p>The select list cannot include expressions or functions or duplicate column names.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="create_view_order_by_clause_guidelines">ORDER BY Clause Guidelines</h5>
<div class="paragraph">
<p>The ORDER BY clause can be specified in the SELECT portion of a CREATE VIEW definition. Any SELECT syntax that is valid
when the SELECT portion is specified on its own is also valid during the view definition. An ORDER BY clause can contain
either the column name from the SELECT list or from <em>select-list-index</em>.</p>
</div>
<div class="paragraph">
<p>When a DML statement is issued against the view, the rules documented in the following sections are used to apply the
ORDER BY clause.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="sect5">
<h6 id="_when_to_use_order_by">When to Use ORDER BY</h6>
<div class="paragraph">
<p>An ORDER BY clause is used in a view definition only when the clause is under the root of the Select query that uses that
view. If the ORDER BY clause appears in other intermediate locations or in a subquery, it is ignored.</p>
</div>
<div class="paragraph">
<p>Consider this CREATE VIEW statement:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create view v as select a from t order by a; select * from v x, v y;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Or this INSERT statement:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">insert into t1 select * from v;</code></pre>
</div>
</div>
<div class="paragraph">
<p>In these two examples, the ORDER BY clause is ignored during DML processing because the first appears as part of a
derived table and the second as a subquery selects, both created after the view expansion.</p>
</div>
<div class="paragraph">
<p>If the same query is issued using explicit derived tables instead of a view, a syntax error is returned:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">select * from (select a from t order by a) x, (select a from t order by a) y;</code></pre>
</div>
</div>
<div class="paragraph">
<p>This example returns a syntax error because an ORDER BY clause is not supported in a subquery.</p>
</div>
<div class="paragraph">
<p>The ORDER BY clause is ignored if it is part of a view and used in places where it is not supported. This is different
than returning an error when the same query was written with explicit ORDER BY clause, as is shown in the preceding examples.</p>
</div>
</div>
<div class="sect5">
<h6 id="_order_by_in_a_view_definition_with_no_override">ORDER BY in a View Definition With No Override</h6>
<div class="paragraph">
<p>If the SELECT query reads from the view with no explicit ORDER BY override, the ORDER BY semantics of the view definition
are used.</p>
</div>
<div class="paragraph">
<p>In this example, the ordering column is the one specified in the CREATE VIEW statement:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create view v as select * from t order by a Select * from v</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>The SELECT query becomes equivalent to:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">select * from t order by a;</code></pre>
</div>
</div>
</div>
<div class="sect5">
<h6 id="_order_by_in_a_view_definition_with_user_override">ORDER BY in a View Definition With User Override</h6>
<div class="paragraph">
<p>If a SELECT query contains an explicit ORDER BY clause, it overrides the ORDER BY clause specified in the view definition.</p>
</div>
<div class="paragraph">
<p>For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create view v as select a,b from t order by a; select * from v order by b;</code></pre>
</div>
</div>
<div class="paragraph">
<p>In this example, order by b overrides the order by a specified in the view definition. The SELECT query becomes equivalent to:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">select a,b from t order by b;</code></pre>
</div>
</div>
</div>
</div>
<div class="sect4">
<h5 id="_nested_view_definitions">Nested View Definitions</h5>
<div class="paragraph">
<p>In case of nested view definitions, the ORDER BY clause in the topmost view definition overrides the ORDER BY clause of any
nested view definitions.</p>
</div>
<div class="paragraph">
<p>For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create view v1 as select a,b from t1 order by a;
create view v2 as select a,b from v1 order by b;
select * from v2;</code></pre>
</div>
</div>
<div class="paragraph">
<p>In this example, the ORDER BY specified in the definition of view v2 overrides the ORDER BY specified in the definition of view v1.</p>
</div>
<div class="paragraph">
<p>The SELECT query becomes equivalent to:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">select a,b from (select a, b from t) x order by b;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="create_view_examples">3.18.3. Examples of CREATE VIEW</h4>
<div class="ulist">
<ul>
<li>
<p>This example creates a view on a single table without a view column list:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE VIEW SALES.MYVIEW1 AS
SELECT ordernum, qty_ordered FROM SALES.ODETAIL;</code></pre>
</div>
</div>
</li>
<li>
<p>This example replaces the view, MYVIEW1, with a different view definition:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE OR REPLACE VIEW SALES.MYVIEW1 AS
SELECT ordernum, qty_ordered
FROM SALES.ODETAIL WHERE unit_price &gt; 100;</code></pre>
</div>
</div>
</li>
<li>
<p>This example creates a view with a column list:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE VIEW SALES.MYVIEW2
(v_ordernum, t_partnum) AS SELECT v.ordernum, t.partnum
FROM SALES.MYVIEW1 v, SALES.ODETAIL t;</code></pre>
</div>
</div>
</li>
<li>
<p>This example creates a view from two tables by using an INNER JOIN:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE VIEW MYVIEW4 (v_ordernum, v_partnum) AS
SELECT od.ordernum, p.partnum
FROM SALES.ODETAIL OD INNER JOIN SALES.PARTS P
ON od.partnum = p.partnum;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="create_view_vertical_partition_example">Vertical Partition Example</h5>
<div class="paragraph">
<p>This example creates three logical vertical partitions for a table, vp0, vp1, and vp2 and then creates a view vp to access them.</p>
</div>
<div class="paragraph">
<p>A view can be used to obtain a composite representation of a set of closely related tables. In the following example
tables vp0, vp1 and vp2 all have a key column a. This key column is known to contain identical rows for all three tables.
The three tables vp0, vp1 and vp2 also contain columns b, c and d respectively. We can create a view vp that combines
these three tables and provides the interface of columns a, b, c and d belonging to a single object.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL has the ability to eliminate redundant joins in a query. Redundant joins occur when:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Output of join contains expressions from only one of its two children</p>
</li>
<li>
<p>Every row from this child will match one and only one row from the other child</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Suppose tables A and B denote generic tables. To check if the rule "every row from this child will match one and only one row
from the other child" is true, Trafodion SQL uses the fact that the join of Table A with table or subquery B preserves all the
rows of A if the join predicate contains an equi-join predicate that references a key of B, and one of the following is true:
The join is a left outer join where B is the inner table. In this example, for the join between vp0 and vp1,vp0 fills the role
of table A and vp1 fills the role of table B. For the join between vp1 and vp2, vp1 fills the role of table A and vp2 fills
the role of table B.</p>
</div>
<div class="paragraph">
<p>The view vp shown in this example uses left outer joins to combine the three underlying tables. Therefore, if the select list
in a query that accesses vp does not contain column d from vp2 then the join to table vp2 in the view vp will not be performed.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table vp0(a integer not null, b integer, primary key(a));
create table vp1(a integer not null, c integer, primary key(a));
create table vp2(a integer not null, d integer, primary key(a));
create view vp(a,b,c,d) as
select vp0.a, b, c, d
from vp0
left outer join vp1 on vp0.a=vp1.a
left outer join vp2 on vp0.a=vp2.a;
select a, b from vp; -- reads only vp0
select a, c from vp; -- reads vp0 and vp1
select d from vp; -- reads vp0 and vp2</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="delete_statement">3.19. DELETE Statement</h3>
<div class="paragraph">
<p>The DELETE statement is a DML statement that deletes a row or rows from a table or an updatable view. Deleting rows from
a view deletes the rows from the table on which the view is based. DELETE does not remove a table or view, even if you
delete the last row in the table or view.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL provides searched DELETE—deletes rows whose selection depends on a search condition.</p>
</div>
<div class="paragraph">
<p>For the searched DELETE form, if no WHERE clause exists, all rows are deleted from the table or view.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">Searched DELETE is:
DELETE FROM table
[WHERE search-condition ]
[[for] access-option access]
access-option is:
read committed</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="delete_syntax">3.19.1. Syntax Description of DELETE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>names the user table or view from which to delete rows. <em>table</em> must be a base table or an updatable view. To refer to a
table or view, use the ANSI logical name. See <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code>WHERE <em>search-condition</em></code></p>
<div class="paragraph">
<p>specifies a search condition that selects rows to delete. Within the search condition, any columns being compared are
columns in the table or view being deleted from. See <a href="#search_condition">Search Condition</a></p>
</div>
<div class="paragraph">
<p>If you do not specify a search condition, all rows in the table or view are deleted.</p>
</div>
</li>
<li>
<p><code>[FOR] <em>access-option</em> ACCESS</code></p>
<div class="paragraph">
<p>specifies the access option required for data used to evaluate the search condition.
See <a href="#data_consistency_and_access_options">Data Consistency and Access Options</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>`READ `COMMITTED</p>
<div class="paragraph">
<p>specifies that any data used to evaluate the search condition must come from committed rows.</p>
</div>
<div class="paragraph">
<p>The default access option is the isolation level of the containing transaction.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="delete_considerations">3.19.2. Considerations for DELETE</h4>
<div class="sect4">
<h5 id="delete_authorization_requirements">Authorization Requirements</h5>
<div class="paragraph">
<p>DELETE requires authority to read and write to the table or view being deleted from and authority to read tables or views
specified in subqueries used in the search condition.</p>
</div>
</div>
<div class="sect4">
<h5 id="delete_transaction-initiation-and-termination">Transaction Initiation and Termination</h5>
<div class="paragraph">
<p>The DELETE statement automatically initiates a transaction if no transaction is active. Otherwise, you can explicitly
initiate a transaction with the BEGIN WORK statement. When a transaction is started, the SQL statements execute within
that transaction until a COMMIT or ROLLBACK is encountered or an error occurs.</p>
</div>
</div>
<div class="sect4">
<h5 id="delete_isolation-levels-of-transactions-and-access-options-of-statements">Isolation Levels of Transactions and Access Options of Statements</h5>
<div class="paragraph">
<p>The isolation level of an SQL transaction defines the degree to which the operations on data within that transaction
are affected by operations of concurrent transactions. When you specify access options for the DML statements within
a transaction, you override the isolation level of the containing transaction. Each statement then executes with
its individual access option.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="delete_examples">3.19.3. Examples of DELETE</h4>
<div class="ulist">
<ul>
<li>
<p>Remove all rows from the JOB table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DELETE FROM persnl.job;
--- 10 row(s) deleted.</code></pre>
</div>
</div>
</li>
<li>
<p>Remove from the table ORDERS any orders placed with sales representative 220 by any customer except customer number 1234:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DELETE FROM sales.orders
WHERE salesrep = 220 AND custnum &lt;&gt; 1234;
--- 2 row(s) deleted.</code></pre>
</div>
</div>
</li>
<li>
<p>Remove all suppliers not in Texas from the table PARTSUPP:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DELETE FROM invent.partsupp WHERE suppnum IN
(SELECT suppnum FROM samdbcat.invent.supplier WHERE state &lt;&gt; 'TEXAS');
--- 41 row(s) deleted.</code></pre>
</div>
</div>
<div class="paragraph">
<p>This statement achieves the same result:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DELETE FROM invent.partsupp WHERE suppnum NOT IN
SELECT suppnum FROM samdbcat.invent.supplier WHERE state = 'TEXAS');
--- 41 row(s) deleted.</code></pre>
</div>
</div>
</li>
<li>
<p>This is an example of a self-referencing DELETE statement, where the table from which rows are deleted is scanned in a subquery:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">delete from table1 where a in (select a from table1 where b &gt; 200)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_function_statement">3.20. DROP FUNCTION Statement</h3>
<div class="paragraph">
<p>The DROP FUNCTION statement removes a user-defined function (UDF) from the Trafodion database.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside
a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT
must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP FUNCTION [[catalog-name.]schema-name.]function-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="drop_function_syntax">3.20.1. Syntax Description of DROP FUNCTION</h4>
<div class="ulist">
<ul>
<li>
<p><code>[[_catalog-name_.]<em>schema-name</em>.]<em>function-name</em></code></p>
<div class="paragraph">
<p>specifies the ANSI logical name of the function, where each part of the name is a valid sql identifier with a maximum of
128 characters. specify the name of a function that has already been registered in the schema. if you do not fully qualify
the function name, trafodion sql qualifies it according to the schema of the current session. for more information,
see <a href="#identifiers">identifiers</a> and <a href="#database_object_names">database object names</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="drop_function_considerations">3.20.2. Considerations for DROP FUNCTION</h4>
<div class="sect4">
<h5 id="drop_function_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a DROP FUNCTION statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the function.</p>
</li>
<li>
<p>You have the DROP or DROP_ROUTINE component privilege for SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="drop_function_examples">3.20.3. Examples of DROP FUNCTION</h4>
<div class="ulist">
<ul>
<li>
<p>This DROP FUNCTION statement removes the function named ADD2 from the default schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP FUNCTION add2;</code></pre>
</div>
</div>
</li>
<li>
<p>This DROP FUNCTION statement removes the function named MMA5 from the default schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP PROCEDURE mma5;</code></pre>
</div>
</div>
</li>
<li>
<p>This DROP FUNCTION statement removes the function named REVERSE from the default schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP PROCEDURE reverse;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_index_statement">3.21. DROP INDEX Statement</h3>
<div class="paragraph">
<p>The DROP INDEX statement drops a Trafodion SQL index. See <a href="#indexes">Indexes</a>.
DROP INDEX is a Trafodion SQL extension.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside
a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT
must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP [VOLATILE] INDEX index</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="drop_index_syntax">3.21.1. Syntax Description of DROP INDEX</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>index</em></code></p>
<div class="paragraph">
<p>is the index to drop.</p>
</div>
<div class="paragraph">
<p>For information, see <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="drop_index_considerations">3.21.2. Considerations for DROP INDEX</h4>
<div class="sect4">
<h5 id="drop_index_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a DROP INDEX statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the index or the table associated with the index.</p>
</li>
<li>
<p>You have the DROP or DROP_INDEX component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="drop_index_examples">3.21.3. Examples of DROP INDEX</h4>
<div class="ulist">
<ul>
<li>
<p>This example drops an index:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP INDEX myindex;</code></pre>
</div>
</div>
</li>
<li>
<p>This example drops a volatile index:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP VOLATILE INDEX vindex;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_library_statement">3.22. DROP LIBRARY Statement</h3>
<div class="paragraph">
<p>The DROP LIBRARY statement removes a library object from the Trafodion database and also removes the library file
referenced by the library object.</p>
</div>
<div class="paragraph">
<p>DROP LIBRARY is a Trafodion SQL extension.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this statement
inside a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement,
AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP LIBRARY [[catalog-name.]schema-name.]library-name [restrict | cascade]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="drop_library_syntax">3.22.1. Syntax Description of DROP LIBRARY</h4>
<div class="ulist">
<ul>
<li>
<p><code>[[_catalog-name_.]<em>schema-name</em>.]<em>library-name</em></code></p>
<div class="paragraph">
<p>specifies the ANSI logical name of the library object, where each part of the name is a valid sql identifier with a
maximum of 128 characters. specify the name of a library object that has already been registered in the schema. if
you do not fully qualify the library name, trafodion sql qualifies it according to the schema of the current session.
for more information, see <a href="#identifiers">identifiers</a> and <a href="#database_object_names">database object names</a>.</p>
</div>
</li>
<li>
<p><code>[restrict | cascade]</code></p>
<div class="paragraph">
<p>if you specify restrict, the drop library operation fails if any stored procedures in java (spjs) or user-defined
functions (UDFs) were created based on the specified library.</p>
</div>
<div class="paragraph">
<p>if you specify cascade, any such dependent procedures or functions are removed as part of the drop library operation.</p>
</div>
<div class="paragraph">
<p>the default value is restrict.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="drop_library_considerations">3.22.2. Considerations for DROP LIBRARY</h4>
<div class="ulist">
<ul>
<li>
<p>RESTRICT requires that all procedures and functions that refer to the library object be dropped before you drop the
library object. CASCADE automatically drops any procedures or functions that are using the library.</p>
</li>
<li>
<p>If the library filename referenced by the library object does not exist, Trafodion SQL issues a warning.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="drop_library_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a DROP LIBRARY statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the library.</p>
</li>
<li>
<p>You have the DROP or DROP_LIBRARY component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="drop_library_examples">3.22.3. Examples of DROP LIBRARY</h4>
<div class="ulist">
<ul>
<li>
<p>This DROP LIBRARY statement removes the library named SALESLIB from the SALES schema, removes the Sales2.jar file
referenced by the library, and drops any stored procedures in Java (SPJs) that were created based on this library:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP LIBRARY sales.saleslib CASCADE;</code></pre>
</div>
</div>
</li>
<li>
<p>This DROP LIBRARY statement removes the library named MYUDFS from the default schema and removes the $TMUDFS library
file referenced by the library:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP LIBRARY myudfs RESTRICT;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>RESTRICT prevents the DROP LIBRARY operation from dropping any user-defined functions (UDFs) that were created based on
this library. If any UDFs were created based on this library, the DROP LIBRARY operation fails.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_procedure_statement">3.23. DROP PROCEDURE Statement</h3>
<div class="paragraph">
<p>The DROP PROCEDURE statement removes a stored procedure in Java (SPJ) from the Trafodion database.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside
a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT
must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP PROCEDURE [[catalog-name.]schema-name.]procedure-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="drop_procedure_syntax">3.23.1. Syntax Description of DROP PROCEDURE</h4>
<div class="ulist">
<ul>
<li>
<p><code>[[_catalog-name_.]<em>schema-name</em>.]<em>procedure-name</em></code></p>
<div class="paragraph">
<p>specifies the ANSI logical name of the stored procedure in java (SPJ), where each part of the name is a valid sql
identifier with a maximum of 128 characters. specify the name of a procedure that has already been registered in the
schema. if you do not fully qualify the procedure name, trafodion sql qualifies it according to the schema of the
current session.</p>
</div>
<div class="paragraph">
<p>for more information, see <a href="#identifiers">identifiers</a> and <a href="#database_object_names">database object names</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="drop_procedure_considerations">3.23.2. Considerations for DROP PROCEDURE</h4>
<div class="sect4">
<h5 id="drop_procedure_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a DROP PROCEDURE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the procedure.</p>
</li>
<li>
<p>You have the DROP or DROP_ROUTINE component privilege for SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="drop_procedure_examples">3.23.3. Examples of DROP PROCEDURE</h4>
<div class="ulist">
<ul>
<li>
<p>This DROP PROCEDURE statement removes the procedure named LOWERPRICE from the SALES schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP PROCEDURE sales.lowerprice;</code></pre>
</div>
</div>
</li>
<li>
<p>This DROP PROCEDURE statement removes the procedure TOTALPRICE from the default schema for the session, which is the SALES schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SET SCHEMA sales;
DROP PROCEDURE totalprice;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_role_statement">3.24. DROP ROLE Statement</h3>
<div class="paragraph">
<p>The DROP ROLE statement deletes an SQL role. See <a href="#roles">Roles</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP ROLE role-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="drop_role_syntax">3.24.1. Syntax Description of DROP ROLE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>role-name</em></code></p>
<div class="paragraph">
<p>is an existing role name. The role cannot be dropped if any of the following are true:</p>
</div>
</li>
<li>
<p>Any privileges are granted to the role.</p>
</li>
<li>
<p>The role is granted to any users.</p>
</li>
<li>
<p>The role owns any schemas.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="drop_role_considerations">3.24.2. Considerations for DROP ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>To drop a role, you must own the role or have user administrative privileges for the role. You have user administrative
privileges for the role if you have been granted the MANAGE_ROLES component privilege. Initially, DB ROOT is the only
database user who has been granted the MANAGE_ROLES component privilege.</p>
</li>
<li>
<p>Role names beginning with DB are reserved and can only be dropped by DB ROOT.</p>
</li>
<li>
<p>You can determine all users to whom a role has been granted by using the SHOWDDL ROLE statement.
See the <a href="#showddl_statement">SHOWDDL Statement</a>.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="_before_you_drop_a_role">Before You Drop a Role</h5>
<div class="paragraph">
<p>Before dropping a role, follow these guidelines:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You must revoke all privileges granted to the role.</p>
</li>
<li>
<p>You must revoke the role from all users to whom it was granted.</p>
</li>
<li>
<p>You must drop all schemas the role is a manager (or owner) of.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>You can determine all users to whom a role has been granted with the SHOWDDL statement.
See the <a href="#showddl_statement">SHOWDDL Statement</a>.</p>
</div>
</div>
<div class="sect4">
<h5 id="_active_sessions_for_the_user">Active Sessions for the User</h5>
<div class="paragraph">
<p>When you revoke a role from a user, then the change in privileges is automatically propagated to and detected by
active sessions. There is no need for users to disconnect from and reconnect to a session to see the updated set of
privileges.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="drop_role_examples">3.24.3. Examples of DROP ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>To drop a role:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP ROLE clerks;</code></pre>
</div>
</div>
</li>
<li>
<p>To drop a role with dependent privileges:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">-- User administrator creates a role:
CREATE ROLE clerks;
-- User administrator grants privileges on a table to the role:
GRANT ALL PRIVILEGES ON TABLE invent.partloc TO clerks;
-- User administrator grants the role to a user:
GRANT ROLE clerks TO JSmith;
-- JSmith creates a view based upon the granted privilege:
CREATE VIEW invent.partlocView (partnum, loc_code)
AS SELECT partnum, loc_code FROM invent.partloc;
-- If the user administrator attempts to drop the role, this
-- would fail because of the view created based on
-- the granted privilege.
-- To successfully drop the role, the dependent view
-- and grant must be removed first. For this example:
-- 1. JSmith drops the view:
DROP VIEW invent.partlocView;
-- 2. User administrator revokes the role from the user:
REVOKE ROLE clerks FROM JSmith;
-- 3. User administrator revokes all privileges the role has been granted
REVOKE ALL ON invent.partloc FROM clerks;
-- 4. User administrator drops the role:
DROP ROLE clerks;
-- The DROP ROLE operation succeeds.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_schema_statement">3.25. DROP SCHEMA Statement</h3>
<div class="paragraph">
<p>The DROP SCHEMA statement drops a schema from the database. See <a href="#schemas">Schemas</a>.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run DDL statements
inside a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run these statements,
AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP SCHEMA [IF EXISTS] schema-name [RESTRICT|CASCADE]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="drop_schema_syntax">3.25.1. Syntax Description of DROP SCHEMA</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>schema-name</em></code></p>
<div class="paragraph">
<p>is the name of the schema to delete.</p>
</div>
</li>
<li>
<p><code>IF EXISTS</code></p>
<div class="paragraph">
<p>drops the schema if it exists. If omitted, an error is raised if the schema doesn&#8217;t exist.</p>
</div>
</li>
<li>
<p><code>RESTRICT</code></p>
<div class="paragraph">
<p>If you specify RESTRICT, an error is reported if the specified schema is not empty. The default is RESTRICT.</p>
</div>
</li>
<li>
<p><code>CASCADE</code></p>
<div class="paragraph">
<p>If you specify CASCADE, objects in the specified schema and the schema itself are dropped. Any objects in other schemas
that were dependent on objects in this schema are dropped as well.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="drop_schema_considerations">3.25.2. Considerations for DROP SCHEMA</h4>
<div class="sect4">
<h5 id="drop_schema_authorization_requirements">Authorization Requirements</h5>
<div class="paragraph">
<p>To drop a schema, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are the owner of the schema.</p>
</li>
<li>
<p>You have been granted the role that owns the schema.</p>
</li>
<li>
<p>You have been granted the DROP_SCHEMA privilege.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="drop_schema_examples">3.25.3. Example of DROP SCHEMA</h4>
<div class="ulist">
<ul>
<li>
<p>This example drops an empty schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP SCHEMA sales;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_sequence_statement">3.26. DROP SEQUENCE Statement</h3>
<div class="paragraph">
<p>The DROP SEQUENCE Statement removes a sequence from the Trafodion database.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run DDL statements inside a user-defined transaction (BEGIN WORK…COMMIT WORK) or when AUTOCOMMIT is OFF. To run these statements, AUTOCOMMIT must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>If you want to change the initial value of a sequence, you can drop and then recreate a sequence with the same name and different START WITH value.</p>
</div>
<div class="paragraph">
<p>DROP SEQUENCE is a Trafodion SQL extension.</p>
</div>
<div class="paragraph">
<p>For more inforamation, see <a href="#create_sequence_statement">CREATE SEQUENCE Statement</a> or <a href="#alter_sequence_statement">ALTER SEQUENCE Statement</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP SEQUENCE [[catalog-name.]schema-name.]sequence</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="drop_sequence_syntax">3.26.1. Syntax Description of DROP SEQUENCE</h4>
<div class="ulist">
<ul>
<li>
<p><code>[[catalog-name.]schema-name.]sequence</code></p>
<div class="paragraph">
<p>Specifies the name of the sequence to be dropped, with optional catalog and schema name, where each part of the name is a valid sql identifier with a maximum of 128 characters.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="drop_sequence_considerations">3.26.2. Considerations for DROP SEQUENCE</h4>
<div class="paragraph">
<p>To issue a DROP SEQUENCE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the sequence.</p>
</li>
<li>
<p>You have the DROP or DROP_SEQUENCE component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="drop_sequence_examples">3.26.3. Examples of DROP SEQUENCE</h4>
<div class="paragraph">
<p>The following statement drops the sequence named <code>employee_seq</code>, which is created in <a href="#create_sequence_examples">Examples of CRAETE SEQUENCE</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP SEQUENCE employee_seq</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_table_statement">3.27. DROP TABLE Statement</h3>
<div class="paragraph">
<p>The DROP TABLE statement deletes a Trafodion SQL table and its dependent objects such as indexes and constraints.
See <a href="#tables">Tables</a>.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That
means that you cannot run this statement inside a user-defined
transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run
this statement, AUTOCOMMIT must be turned ON (the default) for the
session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP [VOLATILE] TABLE [IF EXISTS] table [RESTRICT|CASCADE]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="drop_table_syntax">3.27.1. Syntax Description of DROP TABLE</h4>
<div class="ulist">
<ul>
<li>
<p><code>VOLATILE</code></p>
<div class="paragraph">
<p>specifies that the table to be dropped is a volatile table.</p>
</div>
</li>
<li>
<p><code>IF EXISTS</code></p>
<div class="paragraph">
<p>drops the HBase table if it exists. This option does not apply to volatile tables.</p>
</div>
</li>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>is the name of the table to delete.</p>
</div>
</li>
<li>
<p><code>RESTRICT</code></p>
<div class="paragraph">
<p>If you specify RESTRICT and the table is referenced by another object, the specified table cannot be dropped.
The default is RESTRICT.</p>
</div>
</li>
<li>
<p><code>CASCADE</code></p>
<div class="paragraph">
<p>If you specify CASCADE, the table and all objects referencing the table (such as a view) are dropped.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="drop_table_considerations">3.27.2. Considerations for DROP TABLE</h4>
<div class="sect4">
<h5 id="drop_table_authorization_requirements">Authorization Requirements</h5>
<div class="paragraph">
<p>To issue a DROP TABLE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the table.</p>
</li>
<li>
<p>You have the DROP or DROP_TABLE component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="drop_table_examples">3.27.3. Examples of DROP TABLE</h4>
<div class="ulist">
<ul>
<li>
<p>This example drops a table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP TABLE mysch.mytable;</code></pre>
</div>
</div>
</li>
<li>
<p>This example drops a volatile table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP VOLATILE TABLE vtable;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="drop_view_statement">3.28. DROP VIEW Statement</h3>
<div class="paragraph">
<p>The DROP VIEW statement deletes a Trafodion SQL view. See <a href="#views">Views</a>.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
DDL statements are not currently supported in transactions. That means that you cannot run this statement inside
a user-defined transaction (BEGIN WORK&#8230;COMMIT WORK) or when AUTOCOMMIT is OFF. To run this statement, AUTOCOMMIT
must be turned ON (the default) for the session.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP VIEW view [RESTRICT|CASCADE]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="drop_view_syntax">3.28.1. Syntax Description of DROP VIEW</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>view</em></code></p>
<div class="paragraph">
<p>is the name of the view to delete.</p>
</div>
</li>
<li>
<p><code>RESTRICT</code></p>
<div class="paragraph">
<p>If you specify RESTRICT, you cannot drop the specified view if it is referenced in the query expression of any other
view or in the search condition of another object&#8217;s constraint. The default is RESTRICT.</p>
</div>
</li>
<li>
<p><code>CASCADE</code></p>
<div class="paragraph">
<p>If you specify CASCADE, any dependent objects are dropped.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="drop_view_considerations">3.28.2. Considerations for DROP VIEW</h4>
<div class="sect4">
<h5 id="drop_view_authorization_requirements">Authorization Requirements</h5>
<div class="paragraph">
<p>To issue a DROP VIEW statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the view.</p>
</li>
<li>
<p>You have the DROP or DROP_VIEW component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="drop_view_examples">3.28.3. Example of DROP VIEW</h4>
<div class="ulist">
<ul>
<li>
<p>This example drops a view:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DROP VIEW mysch.myview;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="execute_statement">3.29. Execute Statement</h3>
<div class="paragraph">
<p>The EXECUTE statement executes an SQL statement previously compiled by a PREPARE statement in a Trafodion Command Interface
(TrafCI) session.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXECUTE statement-name
[ USING param [,param]...] ]
param is:
?param-name | literal-value</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="execute_syntax">3.29.1. Syntax Description of EXECUTE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>statement-name</em></code></p>
<div class="paragraph">
<p>is the name of a prepared SQL statement—that is, the statement name used in the PREPARE statement. <em>statement-name</em> is an
SQL identifier. See <a href="#identifiers">Identifiers</a>.</p>
</div>
</li>
<li>
<p><code>USING <em>param</em> [,<em>param</em>]&#8230;</code></p>
<div class="paragraph">
<p><code><em>param</em> is: ?<em>param-name</em> | <em>literal-value</em></code></p>
</div>
<div class="paragraph">
<p>specifies values for unnamed parameters (represented by ?) in the prepared statement in the form of either a parameter
name (?<em>param-name</em>) or a literal value (<em>literal-value</em>). The data type of a parameter value must be compatible with
the data type of the associated parameter in the prepared statement.</p>
</div>
<div class="paragraph">
<p>Parameter values (<em>param</em>) are substituted for unnamed parameters in the prepared statement by position—the i-th value
in the USING clause is the value for the i-th parameter in the statement. If fewer parameter values exist in the USING
clause than unnamed parameters in the PREPARE statement, Trafodion SQL returns an error. If more parameter values exist
in the USING clause than the unnamed parameters in the PREPARE statement, Trafodion SQL issues warning 15019.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>The USING clause does not set parameter values for named parameters (represented by ?<em>param-name</em>) in a prepared statement.
To set parameter values for named parameters, use the SET PARAM command. For more information, see the
<a href="http://trafodion.incubator.apache.org/docs/command_interface/index.html"><em>Trafodion Command Interface Guide</em></a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>?<em>param-name</em></code></p>
<div class="paragraph">
<p>The value for a ?<em>param-name</em> must be previously specified with the SET PARAM command. The <em>param-name</em> is case-sensitive.
For information about the SET PARAM command, see the
<a href="http://trafodion.incubator.apache.org/docs/command_interface/index.html"><em>Trafodion Command Interface Guide</em></a>.</p>
</div>
</li>
<li>
<p><code><em>literal-value</em></code></p>
<div class="paragraph">
<p>is a numeric or character literal that specifies the value for the unnamed parameter.</p>
</div>
<div class="paragraph">
<p>If <em>literal-value</em> is a character literal and the target column type is character, you do not have to enclose it in single
quotation marks. Its data type is determined from the data type of the column to which the literal is assigned. If the
<em>literal-value</em> contains leading or trailing spaces, commas, or if it matches any parameter names that are already
set, enclose the <em>literal-value</em> in single quotes.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>See the <a href="#prepare_statement">PREPARE Statement</a>. For information about the SET PARAM command, see the
<a href="http://trafodion.incubator.apache.org/docs/command_interface/index.html"><em>Trafodion Command Interface Guide</em></a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="execute_considerations">3.29.2. Considerations for EXECUTE</h4>
<div class="sect4">
<h5 id="execute_scope_of_execute">Scope of EXECUTE</h5>
<div class="paragraph">
<p>A statement must be compiled by PREPARE before you EXECUTE it, but after it is compiled, you can execute the statement
multiple times without recompiling it. The statement must have been compiled during the same TrafCI session as its
execution.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="execute_examples">3.29.3. Examples of EXECUTE</h4>
<div class="ulist">
<ul>
<li>
<p>Use PREPARE to compile a statement once, and then execute the statement multiple times with different parameter values.
This example uses the SET PARAM command to set parameter values for named parameters (represented by ?<em>param-name</em>) in
the prepared statement.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;prepare findemp from
+&gt;select * from persnl.employee
+&gt;where salary &gt; ?sal and jobcode = ?job;
--- SQL command prepared.
SQL&gt;set param ?sal 40000.00;
SQL&gt;set param ?job 450;
SQL&gt;execute findemp;
EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY
------ --------------- -------------- ------- ------- --------
232 THOMAS SPINNER 4000 450 45000.00
--- 1 row(s) selected.
SQL&gt;set param ?sal 20000.00;
SQL&gt;set param ?job 300;
SQL&gt;execute findemp;
EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY
------ --------------- -------------- ------- ------- --------
75 TIM WALKER 3000 300 32000.00
89 PETER SMITH 3300 300 37000.40
...
--- 13 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Specify literal values in the USING clause of the EXECUTE statement for unnamed parameters in the prepared statement:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;prepare findemp from
+&gt;select * from persnl.employee
+&gt;where salary &gt; ? and jobcode = ?;
--- SQL command prepared.
SQL&gt;execute findemp using 40000.00,450;
EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY
------ --------------- -------------- ------- ------- --------
232 THOMAS SPINNER 4000 450 45000.00
--- 1 row(s) selected.
SQL&gt;execute findemp using 20000.00, 300;
EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY
------ --------------- -------------- ------- ------- --------
75 TIM WALKER 3000 300 32000.00
89 PETER SMITH 3300 300 37000.40
...
--- 13 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Use SET PARAM to assign a value to a parameter name and specify both the parameter name and a literal value in the
EXECUTE USING clause:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;prepare findemp from
+&gt;select * from persnl.employee
+&gt;where salary &gt; ? and jobcode = ?;
--- SQL command prepared.
SQL&gt;set param ?Salary 40000.00;
SQL&gt;execute findemp using ?Salary, 450;
EMPNUM FIRST_NAME LAST_NAME DEPTNUM JOBCODE SALARY
------ --------------- -------------- ------- ------- --------
232 THOMAS SPINNER 4000 450 45000.00</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="explain_statement">3.30. EXPLAIN Statement</h3>
<div class="paragraph">
<p>The EXPLAIN statement helps you to review query execution plans. You can use the EXPLAIN statement anywhere you can
execute other SQL statements (for example, SELECT). For more information on the EXPLAIN function, see
<a href="#explain_function">EXPLAIN Function</a>.</p>
</div>
<div class="paragraph">
<p>EXPLAIN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXPLAIN [OPTIONS {'f'}] { FOR QID query-id | FOR QID CURRENT | prepared-stmt-name | query-text }</code></pre>
</div>
</div>
<div class="paragraph">
<p>Plans displayed by the EXPLAIN statement are ordered from top (root operator) to bottom (leaf operators).</p>
</div>
<div class="sect3">
<h4 id="explain_syntax">3.30.1. Syntax Description of EXPLAIN</h4>
<div class="ulist">
<ul>
<li>
<p><code>f</code></p>
<div class="paragraph">
<p>Provides the simple, basic information contained in the query execution plan. This information is formatted for
readability and limited to 79 characters (one line) per operator.
See <a href="#explain_formatted_considerations">Formatted [OPTIONS 'f'] Considerations</a>.</p>
</div>
</li>
<li>
<p><code><em>CURRENT</em></code></p>
<div class="paragraph">
<p>provide information for the latest compiled query.</p>
</div>
</li>
<li>
<p><code><em>query-id</em></code></p>
<div class="paragraph">
<p>specifies the query ID of a prepared or executing query, which is a unique identifier generated by the SQL compiler.</p>
</div>
</li>
<li>
<p><code><em>prepared-stmt-name</em></code></p>
<div class="paragraph">
<p>an SQL identifier containing the name of a statement already prepared in this session. An SQL identifier is
case-insensitive (will be in uppercase) unless it is double-quoted. It must be double-quoted if it contains blanks,
lowercase letters, or special characters. It must start with a letter. When you refer to the prepared query in a
SELECT statement, you must use uppercase.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Note: A few non-reserved words that can be used for prepared statement names cannot be used directly in EXPLAIN.
For example, 'EXPLAIN access;' results in a syntax error. You can still use the name, however, by using a
delimited identifier. That is, specify the name in upper case, surrounded by double-quotes. For example,
'EXPLAIN "ACCESS";' will work.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>query-text</em></code></p>
<div class="paragraph">
<p>specifies the text of a query.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="explain_considerations">3.30.2. Considerations for EXPLAIN</h4>
<div class="sect4">
<h5 id="explain_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue an EXPLAIN statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You own (that is, issued) the query specified in the EXPLAIN statement.</p>
</li>
<li>
<p>You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted
to PUBLIC by default.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="explain_obtaining_explain_plans">Obtaining EXPLAIN Plans While Queries Are Running</h5>
<div class="paragraph">
<p>Trafodion SQL provides the ability to capture an EXPLAIN plan for a query at any time while the query is running
with the FOR QID option. By default, this behavior is disabled for a Trafodion database session.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
Enable this feature before you start preparing and executing queries.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>After the feature is enabled, use the FOR QID option in an EXPLAIN statement to get the query execution plan of
a running query.</p>
</div>
<div class="paragraph">
<p>The EXPLAIN function or statement returns the plan that was generated when the query was prepared. EXPLAIN with
the FOR QID option retrieves all the information from the original plan of the executing query. The plan is available
until the query finishes executing and is removed or deallocated.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="explain_case_considerations">Case Considerations</h5>
<div class="paragraph">
<p>In most cases, words in the commands can be in uppercase or lowercase. The options letter must be single quoted and in
lowercase.</p>
</div>
</div>
<div class="sect4">
<h5 id="explain_number_considerations">Number Considerations</h5>
<div class="paragraph">
<p>Costs are given in a generic unit of effort. They show relative costs of an operation.</p>
</div>
<div class="paragraph">
<p>When trailing decimal digits are zero, they are dropped. For example, 6.4200 would display as
6.42 and 5.0 would display as 5, without a decimal point.</p>
</div>
</div>
<div class="sect4">
<h5 id="explain_formatted_considerations">Formatted [OPTIONS 'f'] Considerations</h5>
<div class="paragraph">
<p>The formatted option is the simplest option. It provides essential, brief information about the plan and shows the
operators and their order within the query execution plan.</p>
</div>
<div class="paragraph">
<p>OPTIONS 'f' formats the EXPLAIN output into these fields:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">LC</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Left child sequence number</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">RC</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Right child sequence number</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">OP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The sequence number of the operator in the query plan</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">OPERATOR</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The operator type</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">OPT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Query optimizations that were applied</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DESCRIPTION</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Additional information about the operator</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CARD</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Estimated number of rows returned by the plan. CARDINALITY and ROWS_OUT are the same.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>This example uses OPTIONS 'f ':</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;explain options 'f' for qid MXID11002015016212343685134956677000000000206U3333300_652_XX;
LC RC OP OPERATOR OPT DESCRIPTION CARD
---- ---- ---- -------------------- -------- -------------------- ---------
1 . 2 root 1.00E+000
. . 1 hbase_aggr 1.00E+000
--- SQL operation complete.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>To use the EXPLAIN statement with a prepared statement, first prepare the query. Then use the EXPLAIN statement:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">PREPARE q FROM SELECT * FROM REGION;
EXPLAIN options 'f' q;</code></pre>
</div>
</div>
<div class="paragraph">
<p>EXPLAIN can also be used with the query text directly:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXPLAIN options 'f' SELECT * FROM REGION;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="get_statement">3.31. GET Statement</h3>
<div class="paragraph">
<p>The GET statement displays the names of database objects, components, component privileges, roles, or users that exist
in the Trafodion instance.</p>
</div>
<div class="paragraph">
<p>GET is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET option
option is:
COMPONENT PRIVILEGES ON component-name [FOR auth-name]
| COMPONENTS
| FUNCTIONS FOR LIBRARY [[catalog-name.]schema-name.]library-name
| functions [in schema [catalog-name.]schema-name]
| libraries [in schema [catalog-name.]schema-name]
| procedures for library [[catalog-name.]schema-name.]library-name
| procedures [in schema [catalog-name.]schema-name]
| roles [for user database-username]
| schemas [in catalog catalog-name]
| schemas for [user | role] authorization-id
| tables [in schema [catalog-name.]schema-name]
| users [for role role-name]
| views [in schema [catalog-name.]schema-name]
| views on table [[catalog-name.]schema-name.]table-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="get_syntax">3.31.1. Syntax Description of GET</h4>
<div class="ulist">
<ul>
<li>
<p><code>COMPONENT PRIVILEGES ON <em>component-name</em></code></p>
<div class="paragraph">
<p>displays the names of the component privileges available for the specified component.</p>
</div>
</li>
<li>
<p><code>COMPONENT PRIVILEGES ON <em>component-name</em> FOR <em>auth-name</em></code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>displays the component privileges that have been granted to the specified authorization name for the specified component.
The <em>auth-name</em> is either a registered database username or an existing role name and can be a regular or delimited
case-insensitive identifier. See <a href="#case_insensitive_delimited_identifiers">Case-Insensitive Delimited Identifiers</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>COMPONENTS</code></p>
<div class="paragraph">
<p>displays a list of all the existing components.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>FUNCTIONS</code></p>
<div class="paragraph">
<p>displays the names of all the user-defined functions (UDFs) in the catalog and schema of the current session. By default,
the catalog is TRAFODION, and the schema is SEABASE.</p>
</div>
</li>
<li>
<p><code>FUNCTIONS FOR LIBRARY [[_catalog-name_.]<em>schema-name</em>.]<em>library-name</em></code></p>
<div class="paragraph">
<p>displays the UDFs that reference the specified library.</p>
</div>
</li>
<li>
<p><code>functions in schema <em class="_catalog-name_.">schema-name</em></code></p>
<div class="paragraph">
<p>displays the names of all the UDFs in the specified schema.</p>
</div>
</li>
<li>
<p><code>libraries</code></p>
<div class="paragraph">
<p>displays the names of all the libraries in the catalog and schema of the current session. by default, the catalog is trafodion,
and the schema is seabase.</p>
</div>
</li>
<li>
<p><code>libraries in schema <em class="_catalog-name_.">schema-name</em></code></p>
<div class="paragraph">
<p>displays the libraries in the specified schema.</p>
</div>
</li>
<li>
<p><code>procedures</code></p>
<div class="paragraph">
<p>displays the names of all the procedures in the catalog and schema of the current session. by default, the catalog is trafodion,
and the schema is seabase.</p>
</div>
</li>
<li>
<p><code>procedures for library [[_catalog-name_.]<em>schema-name</em>.]<em>library-name</em></code></p>
<div class="paragraph">
<p>displays the procedures that reference the specified library.</p>
</div>
</li>
<li>
<p><code>procedures in schema <em class="_catalog-name_.">schema-name</em></code></p>
<div class="paragraph">
<p>displays the names of all the procedures in the specified schema.</p>
</div>
</li>
<li>
<p><code>roles</code></p>
<div class="paragraph">
<p>displays a list of all the existing roles.</p>
</div>
</li>
<li>
<p><code>roles for user <em>database-username</em></code></p>
<div class="paragraph">
<p>displays all the roles that have been granted to the specified database user. the <em>database-username</em> can be a regular or delimited
case-insensitive identifier. see <a href="#case_insensitive_delimited_identifiers">case-insensitive delimited identifiers</a>.</p>
</div>
</li>
<li>
<p><code>schemas</code></p>
<div class="paragraph">
<p>displays the names of all the schemas in the catalog of the current session. by default, the catalog is trafodion.</p>
</div>
</li>
<li>
<p><code>schemas in catalog <em>catalog-name</em></code></p>
<div class="paragraph">
<p>displays the names of all the schemas in the specified catalog. for the <em>catalog-name</em>, you can specify only trafodion.</p>
</div>
</li>
<li>
<p><code>schemas for [user | role] <em>authorization-id</em></code></p>
<div class="paragraph">
<p>displays all the schemas managed (or owned) by a specified user or role.</p>
</div>
</li>
<li>
<p>`<em>authorization-id</em></p>
<div class="paragraph">
<p>is the name of a user or role. you may specify either user or role for users or roles.</p>
</div>
</li>
<li>
<p><code>tables</code></p>
<div class="paragraph">
<p>displays the names of all the tables in the catalog and schema of the current session. by default, the catalog is trafodion,
and the schema is seabase.</p>
</div>
</li>
<li>
<p><code>tables in schema <em class="_catalog-name_.">schema-name</em></code></p>
<div class="paragraph">
<p>displays the names of all the tables in the specified schema.</p>
</div>
</li>
<li>
<p><code>users</code></p>
<div class="paragraph">
<p>displays a list of all the registered database users.</p>
</div>
</li>
<li>
<p><code>users for role <em>role-name</em></code></p>
<div class="paragraph">
<p>displays all the database users who have been granted the specified role. the <em>role-name</em> can be a regular or delimited
case-insensitive identifier. see <a href="#case_insensitive_delimited_identifiers">case-insensitive delimited identifiers</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>views</code></p>
<div class="paragraph">
<p>displays the names of all the views in the catalog and schema of the current session. by default, the catalog is trafodion,
and the schema is seabase.</p>
</div>
</li>
<li>
<p><code>views in schema <em class="_catalog-name_.">schema-name</em></code></p>
<div class="paragraph">
<p>displays the names of all the views in the specified schema. for the <em>catalog-name</em>, you can specify only trafodion.</p>
</div>
</li>
<li>
<p><code>views on table [[_catalog-name_.]<em>schema-name</em>.]<em>table-name</em></code></p>
<div class="paragraph">
<p>displays the names of all the views that were created for the specified table. if you do not qualify the table name with
catalog and schema names, get uses the catalog and schema of the current session. for the <em>catalog-name</em>, you can specify
only trafodion.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="get_considerations">3.31.2. Considerations for GET</h4>
<div class="admonitionblock important">
<table>
<tr>
<td class="icon">
<i class="fa icon-important" title="Important"></i>
</td>
<td class="content">
The GET COMPONENT PRIVILEGES, GET COMPONENTS, GET ROLES FOR USER, and GET USERS FOR ROLE statements work only when
authentication and authorization are enabled in Trafodion. For more information, see
<a href="http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security" class="bare">http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security</a> [Enable Secure Trafodion].
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>The GET statement displays delimited object names in their internal format. For example, the GET statement returns the delimited
name "my ""table""" as my "table".</p>
</div>
<div class="sect4">
<h5 id="get_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a GET statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC by default.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="get_examples">3.31.3. Examples of GET</h4>
<div class="ulist">
<ul>
<li>
<p>This GET statement displays the names of all the schemas in the catalog of the current session, which happens to be the TRAFODION
catalog:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET SCHEMAS;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of all the schemas in the specified catalog, TRAFODION:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET SCHEMAS IN CATALOG TRAFODION;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of schemas owned by DB ROOT:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET SCHEMAS FOR USER DB ROOT;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of all the tables in the catalog and schema of the current session, which happens to be TRAFODION.SEABASE:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET TABLES;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of all the tables in the specified schema, SEABASE2, in the TRAFODION catalog:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET TABLES IN SCHEMA SEABASE2;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of all the views in the catalog and schema of the current session, which happens to be
TRAFODION.SEABASE:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET VIEWS;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of all the views in the specified schema, SEABASE2, the TRAFODION catalog:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET VIEWS IN SCHEMA SEABASE2;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This GET statement displays the names of all the views that were created for the specified table, T, in the TRAFODION.SEABASE schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET VIEWS ON TABLE T;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of the libraries in the catalog and schema of the current session, which happens to be
TRAFODION.SEABASE:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET LIBRARIES;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of the libraries in the TRAFODION.<em>MD</em> schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET LIBRARIES IN SCHEMA &quot;_MD_&quot;;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of procedures registered in the library, TRAFODION.<em>MD</em>.UDR_LIBRARY:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET PROCEDURES FOR LIBRARY &quot;_MD_&quot;.UDR_LIBRARY;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of procedures in the TRAFODION.<em>MD</em> schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET PROCEDURES IN SCHEMA &quot;_MD_&quot;;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of procedures in the catalog and schema of the current session, which happens to be TRAFODION.SEABASE:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET PROCEDURES;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of user-defined functions (UDFs) in the catalog and schema of the current session, which happens to be
TRAFODION.SEABASE:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET FUNCTIONS;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of UDFs in MYSCHEMA:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET FUNCTIONS IN SCHEMA MYSCHEMA;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This GET statement displays the names of UDFs created in the library, TRAFODION.MYSCHEMA.MYUDFS:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET FUNCTIONS FOR LIBRARY MYSCHEMA.MYUDFS;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays a list of all the existing components:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get components;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the names of the component privileges available for the SQL_OPERATIONS component:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get component privileges on sql_operations;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays the component privileges that have been granted to the DB ROOT user for the SQL_OPERATIONS component:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get component privileges on sql_operations for db root;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays a list of all the existing roles:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get roles;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays all the roles that have been granted to the DB ROOT user:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get roles for user db root;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays a list of all the registered database users:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get users;</code></pre>
</div>
</div>
</li>
<li>
<p>This GET statement displays all the database users who have been granted the DB ROOTROLE role:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get users for role db rootrole;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="get_hbase_objects_statement">3.32. GET HBASE OBJECTS Statement</h3>
<div class="paragraph">
<p>The GET HBASE OBJECTS statement displays a list of HBase objects directly from HBase, not from the Trafodion metadata,
and it can be run in any SQL interface, such as the Trafodion Command Interface (TrafCI). This command is equivalent
to running a list command from an HBase shell, but without having to start and connect to an HBase shell.</p>
</div>
<div class="paragraph">
<p>GET HBASE OBJECTS is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET [ USER | SYSTEM | EXTERNAL | ALL } HBASE OBJECTS</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="get_hbase_objects_syntax">3.32.1. Syntax Description of GET HBASE OBJECTS</h4>
<div class="ulist">
<ul>
<li>
<p><code>USER</code></p>
<div class="paragraph">
<p>displays a list of the Trafodion user objects.</p>
</div>
</li>
<li>
<p><code>SYSTEM</code></p>
<div class="paragraph">
<p>displays a list of the Trafodion system objects, such as metadata, repository, privileges, and Distributed Transaction
Manager (DTM) tables.</p>
</div>
</li>
<li>
<p><code>EXTERNAL</code></p>
<div class="paragraph">
<p>displays a list of non-Trafodion objects.</p>
</div>
</li>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>displays a list of all objects, including user, system, and external objects.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="get_hbase_objects_examples">3.32.2. Examples of GET HBASE OBJECTS</h4>
<div class="ulist">
<ul>
<li>
<p>This GET HBASE OBJECTS statement displays the Trafodion user objects in HBase:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">Trafodion Conversational Interface 1.1.0
(c) Copyright 2015 Apache Software Foundation
&gt;&gt;get user hbase objects;
TRAFODION.SCH.SB_HISTOGRAMS
TRAFODION.SCH.SB_HISTOGRAM_INTERVALS
TRAFODION.SCH.T006T1
TRAFODION.SCH.T006T2
TRAFODION.SCH.T006T3
TRAFODION.SCH.T006T4
TRAFODION.SCH.T006T5
TRAFODION.SCH.T006T6
TRAFODION.SCH.T006T7
TRAFODION.SCH.T006T8
TRAFODION.SCH.X1
TRAFODION.SCH.X2
TRAFODION.SCH.X3
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This GET HBASE OBJECTS statement displays the Trafodion system objects in HBase:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;get system hbase objects;
TRAFODION._DTM_.TLOG0_CONTROL_POINT
...
TRAFODION._DTM_.TLOG1_LOG_f
TRAFODION._MD_.AUTHS
TRAFODION._MD_.COLUMNS
TRAFODION._MD_.DEFAULTS
TRAFODION._MD_.INDEXES
TRAFODION._MD_.KEYS
TRAFODION._MD_.LIBRARIES
TRAFODION._MD_.LIBRARIES_USAGE
TRAFODION._MD_.OBJECTS
TRAFODION._MD_.OBJECTS_UNIQ_IDX
TRAFODION._MD_.REF_CONSTRAINTS
TRAFODION._MD_.ROUTINES
TRAFODION._MD_.SEQ_GEN TRAFODION._MD_.TABLES
TRAFODION._MD_.TABLE_CONSTRAINTS
TRAFODION._MD_.TEXT
TRAFODION._MD_.UNIQUE_REF_CONSTR_USAGE
TRAFODION._MD_.VERSIONS
TRAFODION._MD_.VIEWS
TRAFODION._MD_.VIEWS_USAGE
TRAFODION._REPOS_.METRIC_QUERY_AGGR_TABLE
TRAFODION._REPOS_.METRIC_QUERY_TABLE
TRAFODION._REPOS_.METRIC_SESSION_TABLE
TRAFODION._REPOS_.METRIC_TEXT_TABLE
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>This GET HBASE OBJECTS statement displays the external, non-Trafodion objects in HBase:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;get external hbase objects;
obj1
obj2
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="get_version_of_metadata_statement">3.33. GET VERSION OF METADATA Statement</h3>
<div class="paragraph">
<p>The GET VERSION OF METADATA statement displays the version of the metadata in the Trafodion instance and indicates if
the metadata is current.</p>
</div>
<div class="paragraph">
<p>GET VERSION OF METADATA is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET VERSION OF METADATA</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="get_version_of_metadata_considerations">3.33.1. Considerations for GET VERSION OF METADATA</h4>
<div class="ulist">
<ul>
<li>
<p>If the metadata is compatible with the installed Trafodion software version, the GET VERSION OF METADATA statement
indicates that the metadata is current:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">Current Version 3.0. Expected Version 3.0.
Metadata is current.</code></pre>
</div>
</div>
</li>
<li>
<p>If the metadata is incompatible with the installed Trafodion software version, the GET VERSION OF METADATA statement
indicates that you need to upgrade or reinitialize the metadata:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">Current Version 2.3. Expected Version 3.0.
Metadata need to be upgraded or reinitialized.</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="get_version_of_metadata_examples">3.33.2. Examples of GET VERSION OF METADATA</h4>
<div class="ulist">
<ul>
<li>
<p>This GET VERSION OF METADATA statement displays the metadata version in a Trafodion Release 1.0.0 instance:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt; get version of metadata;
Current Version 3.0. Expected Version 3.0.
Metadata is current.
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This GET VERSION OF METADATA statement displays the metadata version in a Trafodion Release 0.9.0 instance:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt; get version of metadata;
Current Version 2.3. Expected Version 2.3.
Metadata is current.
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>If the metadata is incompatible with the installed Trafodion software version, you will see this output indicating
that you need to upgrade or reinitialize the metadata:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get version of metadata;
Current Version 2.3. Expected Version 3.0.
Metadata need to be upgraded or reinitialized.
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="get_version_of_software_statement">3.34. GET VERSION OF SOFTWARE Statement</h3>
<div class="paragraph">
<p>The GET VERSION OF SOFTWARE statement displays the version of the Trafodion software that is installed on the system and
indicates if it is current.</p>
</div>
<div class="paragraph">
<p>GET VERSION OF SOFTWARE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET VERSION OF SOFTWARE</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="get_version_of_software_considerations">3.34.1. Considerations for GET VERSION OF SOFTWARE</h4>
<div class="ulist">
<ul>
<li>
<p>If the software on the system is current, the GET VERSION OF SOFTWARE statement displays this output:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">System Version 1.0.0. Expected Version 1.0.0.
Software is current.</code></pre>
</div>
</div>
</li>
<li>
<p>In rare circumstances where something went wrong with the Trafodion software installation and mismatched objects were
installed, the GET VERSION OF SOFTWARE statement displays this output:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">System Version 0.9.1. Expected Version 1.0.0.
Version of software being used is not compatible with version of software on the system.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="get_version_of_software_examples">3.34.2. Examples of GET VERSION OF SOFTWARE</h4>
<div class="ulist">
<ul>
<li>
<p>This GET VERSION OF SOFTWARE statement displays the software version for Trafodion Release 1.0.0:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt; get version of software;
System Version 1.0.0. Expected Version 1.0.0.
Software is current.
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>This GET VERSION OF SOFTWARE statement displays the software version for Trafodion Release 0.9.0:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get version of software;
System Version 0.9.0. Expected Version 0.9.0.
Software is current.
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>If something went wrong with the Trafodion software installation and if mismatched objects were installed, you will
see this output indicating that the software being used is incompatible with the software on the system:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">get version of software;
System Version 0.9.1. Expected Version 1.0.0.
Version of software being used is not compatible with version of software on the system.
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="grant_statement">3.35. GRANT Statement</h3>
<div class="paragraph">
<p>The GRANT statement grants access privileges on an SQL object and its columns to specified users or roles.
Privileges can be granted on the object, on one or more columns, or both.</p>
</div>
<div class="admonitionblock important">
<table>
<tr>
<td class="icon">
<i class="fa icon-important" title="Important"></i>
</td>
<td class="content">
This statement works only when authentication and
authorization are enabled in Trafodion. For more information, see
<a href="http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security" class="bare">http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security</a> [Enable Secure Trafodion].
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GRANT {privilege [,privilege]... |ALL [PRIVILEGES]}
ON [object-type] [schema.]object
TO grantee
[WITH GRANT OPTION]
[[GRANTED] BY grantor]
privilege is:
DELETE
| EXECUTE
| INSERT [column-list]
| REFERENCES [column-list]
| SELECT [column-list]
| UPDATE [column-list]
| USAGE
object-type is:
FUNCTION
| PROCEDURE
| LIBRARY
| SEQUENCE
| TABLE
grantee is:
auth-name
grantor is:
role-name
column-list is:
(column [,colummn] ...)</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="_syntax_description_of_grant">3.35.1. syntax description of grant</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>privilege</em> [,<em>privilege</em> ] &#8230; | all [privileges]</code></p>
<div class="paragraph">
<p>Specifies the privileges to grant. You can specify these privileges for an object.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DELETE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Can use the delete statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">EXECUTE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Can execute a stored procedure using a call statement or can execute a user-defined function (UDF).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">INSERT [column-list]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Can use the insert statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">REFERENCES [column-list]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Can create constraints that reference the object.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SELECT [column-list]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Can use the select statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">UPDATE [column-list]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Can use the update statement on table objects.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">USAGE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">For libraries, can create procedures and functions on library objects.
For sequence generators, can use the sequence in a SQL statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">ALL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">All the applicable privileges. When you specify all for a table or view,
this includes the select, delete, insert, references, and update privileges. When the object is a
stored procedure or user-defined function (UDF), only the execute privilege is applied. When the
object is a library, only the update and usage privileges are applied. When the object is a sequence
generator, only the usage privilege is applied.</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p><code>ON [<em>object-type</em>] <em class="_schema_.">object</em></code></p>
<div class="paragraph">
<p>Specifies an object on which to grant privileges. If none is specified, it defaults to TABLE. See <a href="#database_object_names">"Database Object Names</a> for more details. <em>object-type</em> can be:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>FUNCTION <em class="_schema_.">function-name</em></code>, where <em>function-name</em> is the name of a user-defined function (UDF) in the database.</p>
</li>
<li>
<p><code>LIBRARY <em class="_schema_.">library-name</em></code>, where <em>library-name</em> is the name of a library object in the database.</p>
</li>
<li>
<p><code>PROCEDURE <em class="_schema_.">procedure-name</em></code>, where <em>procedure-name</em> is the name of a stored procedure in java (SPJ)
registered in the database.</p>
</li>
<li>
<p><code>SEQUENCE <em class="_schema_.">sequence-name</em></code>, where <em>sequence-name</em> is the name of a sequence object in the database.</p>
</li>
<li>
<p><code>[TABLE] <em class="_schema_.">object</em></code>, where <em>object</em> is a table or view.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>TO {<em>grantee</em> &#8230; }</code></p>
<div class="paragraph">
<p>Specifies the <em>auth-name</em> to which you grant privileges.</p>
</div>
</li>
<li>
<p><code><em>auth-name</em></code></p>
<div class="paragraph">
<p>Specifies the name of an authorization id to which you grant privileges. See <a href="#authorization_ids">authorization ids</a>.
The authorization id must be a registered database username, an existing role name, or public. the name is a regular
or delimited case-insensitive identifier. See <a href="#case_insensitive_delimited_identifiers">case-insensitive delimited identifiers</a>.
If you grant a privilege to public, the privilege remains available to all users, unless it is later revoked from public.</p>
</div>
</li>
<li>
<p><code>WITH GRANT OPTION</code></p>
<div class="paragraph">
<p>Specifies that the <em>auth-name</em> to which a privilege is granted may in turn grant the same privilege to other users or roles.</p>
</div>
</li>
<li>
<p><code>[GRANTED] BY <em>grantor</em></code></p>
<div class="paragraph">
<p>Allows you to grant privileges on behalf of a role. If not specified, the privileges will be granted on your behalf as
the current user/grantor.</p>
</div>
</li>
<li>
<p><code><em>role-name</em></code></p>
<div class="paragraph">
<p>Specifies a role on whose behalf the grant operation is performed. To grant the privileges on behalf of a role, you must
be a member of the role, and the role must have the authority to grant the privileges; that is, the role must have been
granted the privileges with grant option.</p>
</div>
</li>
<li>
<p><code><em>column-list</em></code></p>
<div class="paragraph">
<p>Specifies the list of columns to grant the requested privilege to.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="grant_considerations">3.35.2. Considerations for GRANT</h4>
<div class="sect4">
<h5 id="grant_authorization_and_availability_requirements">Authorization and Availability Requirements</h5>
<div class="paragraph">
<p>To grant a privilege on an object, you must have both that privilege and the right to grant that privilege. Privileges can
be granted directly to you or to one of the roles you have been granted. You can grant a privilege on an object if you are
the owner of the object (by which you are implicitly granted all privileges on the object) or the owner of the schema containing
the object, or if you have been granted both the privilege and the WITH GRANT OPTION for the privilege.</p>
</div>
<div class="paragraph">
<p>If granting privileges on behalf of a role, you must specify the role in the [GRANTED] BY clause. To grant the privileges on
behalf of a role, you must be a member of the role, and the role must have the authority to grant the privileges; that is, the
role must have been granted the privileges WITH GRANT OPTION.</p>
</div>
<div class="paragraph">
<p>If you lack authority to grant one or more of the specified privileges, SQL returns a warning (yet does grant the specified
privileges for which you do have authority to grant). If you lack authority to grant any of the specified privileges, SQL returns
an error.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="grant_examples">3.35.3. Examples of GRANT</h4>
<div class="ulist">
<ul>
<li>
<p>To grant column level SELECT and object level DELETE privileges on a table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GRANT SELECT (part_no, part_name), DELETE ON TABLE invent.partloc
TO &quot;MO.Neill@company.com&quot;;]</code></pre>
</div>
</div>
</li>
<li>
<p>To grant SELECT privileges on a table to a user:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GRANT SELECT ON TABLE invent.partloc TO ajones;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="grant_component_privilege_statement">3.36. GRANT COMPONENT PRIVILEGE Statement</h3>
<div class="paragraph">
<p>The GRANT COMPONENT PRIVILEGE statement grants one or more component privileges to a user or role. See <a href="#privileges">Privileges</a> and <a href="#roles">Roles</a>.</p>
</div>
<div class="paragraph">
<p>GRANT COMPONENT PRIVILEGE is a Trafodion SQL extension.</p>
</div>
<div class="admonitionblock important">
<table>
<tr>
<td class="icon">
<i class="fa icon-important" title="Important"></i>
</td>
<td class="content">
This statement works only when authentication and authorization are enabled in Trafodion. For more information, see
<a href="http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security" class="bare">http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security</a> [Enable Secure Trafodion].
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GRANT COMPONENT PRIVILEGE {privilege-name [, privilege-name]...}
ON component-name
TO grantee
[WITH GRANT OPTION] [[GRANTED] BY grantor]
grantee is:
auth-name
grantor is:
role-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="grant_component_privilege_syntax">3.36.1. Syntax Description of GRANT COMPONENT PRIVILEGE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>privilege-name</em></code></p>
<div class="paragraph">
<p>specifies one or more component privileges to grant. The comma-separated list can include only privileges within the same component.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 60%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Component</th>
<th class="tableblock halign-left valign-top">Component Privilege</th>
<th class="tableblock halign-left valign-top">Description</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SQL_OPERATIONS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ALTER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to alter database objects</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ALTER_SCHEMA</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to alter schemas</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ALTER_SEQUENCE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to alter sequence generators</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ALTER_TABLE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to alter tables</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ALTER_VIEW</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to alter views</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create database objects</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE_INDEX</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create indexes</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE_LIBRARY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create libraries in the database</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE_PROCEDURE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create stored procedures in Java (SPJs)</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE_ROUTINE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create user-defined functions (UDFs),
table-mapping functions, and other routines in the database</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE_SCHEMA</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create schemas in the database</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE_SEQUENCE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create sequence generators in the database</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE_TABLE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create tables in the database</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CREATE_VIEW</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create views in the database</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop database objects</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP_INDEX</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop indexes</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP_LIBRARY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop libraries</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP_PROCEDURE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop stored procedures in Java (SPJs)</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP_ROUTINE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop user-defined functions (UDFs),
table-mapping functions, and other routines from the database</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP_SCHEMA</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop schemas</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP_SEQUENCE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop sequence generators</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP_TABLE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop tables</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DROP_VIEW</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to drop views</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MANAGE_COMPONENT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to perform component commands, such as register, create, and grant privileges</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MANAGE_LIBRARY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to perform library-related commands, such as creating and dropping libraries</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MANAGE_LOAD</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to perform LOAD and UNLOAD commands</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MANAGE_ROLES</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to create, alter, drop, grant, and revoke roles</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MANAGE_STATISTICS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to update and display statistics</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MANAGE_USERS</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to register or unregister users, alter users, and grant or revoke
component privileges.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">QUERY_ACTIVATE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to activate and executing query after it has been suspended</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">QUERY_CANCEL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to cancel an executing query</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">QUERY_SUSPEND</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to suspend an executing query</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SHOW</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Privilege to run EXPLAIN, GET, INVOKE, and SHOW commands. The SHOW privilege
has been granted to PUBLIC by default.</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p><code>ON <em>component-name</em></code></p>
<div class="paragraph">
<p>specifies a component name on which to grant component privileges. Currently, the only valid component name is SQL_OPERATIONS.</p>
</div>
</li>
<li>
<p><code>TO <em>grantee</em></code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>specifies an <em>auth-name</em> to which you grant component privileges.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>auth-name</em></code></p>
<div class="paragraph">
<p>specifies the name of an authorization ID to which you grant privileges. See <a href="#authorization_ids">Authorization IDs</a>.
The authorization ID must be a registered database username, existing role name, or PUBLIC. The name is a regular or
delimited case-insensitive identifier. See <a href="#case_insensitive_delimited_identifiers">Case-Insensitive Delimited Identifiers</a>.
If you grant a privilege to PUBLIC, the privilege remains available to all users, unless it is later revoked from PUBLIC.</p>
</div>
</li>
<li>
<p><code>WITH GRANT OPTION</code></p>
<div class="paragraph">
<p>specifies that the <em>auth-name</em> to which a component privilege is granted may in turn grant the same component privilege
to other users or roles.</p>
</div>
</li>
<li>
<p><code>[GRANTED] BY <em>grantor</em></code></p>
<div class="paragraph">
<p>allows you to grant component privileges on behalf of a role. If not specified, the privileges will be granted on your
behalf as the current user/grantor.</p>
</div>
</li>
<li>
<p><code><em>role-name</em></code></p>
<div class="paragraph">
<p>specifies a role on whose behalf the GRANT COMPONENT PRIVILEGE operation is performed. To grant the privileges on behalf
of a role, you must be a member of the role, and the role must have the authority to grant the privileges; that is, the
role must have been granted the privileges WITH GRANT OPTION.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="grant_component_privilege_considerations">3.36.2. Considerations for GRANT COMPONENT PRIVILEGE</h4>
<div class="ulist">
<ul>
<li>
<p>A user or role granted a component privilege WITH GRANT OPTION can grant the same component privilege to other users or roles.</p>
</li>
<li>
<p>If all of the component privileges have already been granted, SQL returns an error.</p>
</li>
<li>
<p>If one or more component privileges has already been granted, SQL silently ignores the granted privileges and proceeds
with the grant operation.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="grant_component_privilege_syntaxauthorization_and_availability_requirements">Authorization and Availability Requirements</h5>
<div class="paragraph">
<p>To grant a component privilege, you must have one of these privileges:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>User administrative privileges (that is, a user who has been granted the MANAGE_USERS component privilege). Initially,
DB_ROOT is the only database user who has been granted the MANAGE_USERS component privilege.</p>
</li>
<li>
<p>A user other than a user administrator who has the WITH GRANT OPTION for the component privilege.</p>
</li>
<li>
<p>A user who was granted a role that has the WITH GRANT OPTION privilege for the component privilege.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="grant_component_privilege_considerations">3.36.3. Examples of GRANT COMPONENT PRIVILEGE</h4>
<div class="ulist">
<ul>
<li>
<p>Grant a component privilege, CREATE_TABLE, on a component, SQL_OPERATIONS, to SQLUSER1:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GRANT COMPONENT PRIVILEGE CREATE_TABLE ON SQL_OPERATIONS TO sqluser1;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="grant_role_statement">3.37. GRANT ROLE Statement</h3>
<div class="paragraph">
<p>The GRANT ROLE statement grants one or more roles to a user. See <a href="#roles">Roles</a>.</p>
</div>
<div class="admonitionblock important">
<table>
<tr>
<td class="icon">
<i class="fa icon-important" title="Important"></i>
</td>
<td class="content">
This statement works only when authentication and authorization are enabled in Trafodion. For more information,
<a href="http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security" class="bare">http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security</a> [Enable Secure Trafodion].
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GRANT ROLE {role-name [,role-name ]...}
TO grantee
grantee is:
database-username</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="grant_role_syntax">3.37.1. Syntax Description of GRANT ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>`<em>role-name</em> [,<em>role-name</em>] &#8230;</p>
<div class="paragraph">
<p>specifies the existing roles to grant.</p>
</div>
</li>
<li>
<p><code>TO <em>grantee</em></code></p>
<div class="paragraph">
<p>specifies the registered database username to whom to grant the roles.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="grant_role_considerations">3.37.2. Considerations for GRANT ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>To grant roles to other grantees, you must own the roles or have user administrative privileges for the roles. You
have user administrative privileges for roles if you have been granted the MANAGE_ROLES component privilege. Initially,
DB ROOT is the only database user who has been granted the MANAGE_ROLES component privilege.</p>
</li>
<li>
<p>When you grant a role to a user, the additional privileges are automatically propagated to and detected by active
sessions. There is no need for users to disconnect from and reconnect to a session to see the updated set of privileges.</p>
</li>
<li>
<p>If any errors occur in processing a GRANT ROLE statement that names multiple roles, then no grants are done.</p>
</li>
<li>
<p>If you attempt to grant a role but a grant with the same role and grantee already exists, SQL ignores the request and
returns a successful operation.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="grant_role_examples">3.37.3. Examples of GRANT ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>To grant multiple roles to a grantee:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GRANT ROLE clerks, sales TO jsmith;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="insert_statement">3.38. INSERT Statement</h3>
<div class="paragraph">
<p>The INSERT statement is a DML statement that inserts rows in a table or
view.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO table [(target-col-list)] insert-source
target-col-list is:
colname [,colname]...
insert-source is:
query-expr [order-by-clause] [access-clause] | DEFAULT VALUES</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="insert_syntax">3.38.1. Syntax Description of INSERT</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>names the user table or view in which to insert rows. <em>table</em> must be a base table or an updatable view.</p>
</div>
</li>
<li>
<p><code><em>(target-col-list)</em></code></p>
<div class="paragraph">
<p>names the columns in the table or view in which to insert values. The data type of each target column must be
compatible with the data type of its corresponding source value. Within the list, each target column must
have the same position as its associated source value, whose position is determined by the columns in the table
derived from the evaluation of the query expression (<em>query-expr</em>).</p>
</div>
<div class="paragraph">
<p>If you do not specify all of the columns in <em>table</em> in the <em>target-col-list</em>, column default values are inserted
into the columns that do not appear in the list. See <a href="#column_default_settings">Column Default Settings</a>.</p>
</div>
<div class="paragraph">
<p>If you do not specify <em>target-col-list</em>, row values from the source table are inserted into all columns in <em>table</em>.
The order of the column values in the source table must be the same order as that of the columns specified in the
CREATE TABLE for <em>table</em>. (This order is the same as that of the columns listed in the result table of SHOWDDL
<em>table</em>.)</p>
</div>
</li>
<li>
<p><code><em>insert-source</em></code></p>
<div class="paragraph">
<p>specifies the rows of values to be inserted into all columns of <em>table</em> or, optionally, into specified columns of <em>table</em>.</p>
</div>
</li>
<li>
<p><code><em>query-expr</em></code></p>
<div class="paragraph">
<p>For the description of <em>query-expr</em>, <em>order-by-clause</em>, and <em>access-clause</em>, see the <a href="#select_statement">SELECT Statement</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>DEFAULT VALUES</code></p>
<div class="paragraph">
<p>is equivalent to a <em>query-expr</em> of the form VALUES (DEFAULT, &#8230;). The value of each DEFAULT is the default value defined in
the column descriptor of <em>colname</em>, which is contained in the table descriptor of <em>table</em>. Each default value is inserted into
its column to form a new row. If you specify DEFAULT VALUES, you cannot specify a column list. You can use DEFAULT VALUES only
when all columns in <em>table</em> have default values.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="insert_considerations">3.38.2. Considerations for INSERT</h4>
<div class="sect4">
<h5 id="insert_authorization_requirements">Authorization Requirements</h5>
<div class="paragraph">
<p>INSERT requires authority to read and write to the table or view receiving the data and authority to read tables or views
specified in the query expression (or any of its subqueries) in the INSERT statement.</p>
</div>
</div>
<div class="sect4">
<h5 id="insert_transaction_initiation_and_termination">Transaction Initiation and Termination</h5>
<div class="paragraph">
<p>The INSERT statement automatically initiates a transaction if no transaction is active. Alternatively, you can explicitly initiate
a transaction with the BEGIN WORK statement. After a transaction is started, the SQL statements execute within that transaction
until a COMMIT or ROLLBACK is encountered or an error occurs. If AUTOCOMMIT is ON, the transaction terminates at the end of the
INSERT statement.</p>
</div>
</div>
<div class="sect4">
<h5 id="insert_self_referencing_insert_and_begin_work_or_autocommit_off">Self-Referencing INSERT and BEGIN WORK or AUTOCOMMIT OFF</h5>
<div class="paragraph">
<p>A self-referencing INSERT statement is one that references, in the statement&#8217;s <em>insert-source</em>, the same table or view into which
rows will be inserted (see <a href="#examples_of_self_referencing_inserts">Examples of Self-Referencing Inserts</a>). A self-referencing INSERT
statement will not execute correctly and an error is raised if either BEGIN WORK or AUTOCOMMIT OFF is used unless the compiler&#8217;s
plan sorts the rows before they are inserted. If you want to use a self-referencing INSERT statement, you should avoid the use of
BEGIN WORK or AUTOCOMMIT OFF. For information about AUTOCOMMIT, see the <a href="#set_transaction_statement">SET TRANSACTION Statement</a>.</p>
</div>
</div>
<div class="sect4">
<h5 id="insert_isolation-levels-of-transactions-and-access-options-of-statements">Isolation Levels of Transactions and Access Options of Statements</h5>
<div class="paragraph">
<p>The isolation level of an SQL transaction defines the degree to which the operations on data within that transaction are affected by
operations of concurrent transactions. When you specify access options for the DML statements within a transaction, you override the
isolation level of the containing transaction. Each statement then executes with its individual access option.</p>
</div>
</div>
<div class="sect4">
<h5 id="insert_use_of_a_values_clause_for_the_source_query_expression">Use of a VALUES Clause for the Source Query Expression</h5>
<div class="paragraph">
<p>If the query expression consists of the VALUES keyword followed by rows of values, each row consists of a list of value expressions
or a row subquery (a subquery that returns a single row of column values). A value in a row can also be a scalar subquery (a subquery
that returns a single row consisting of a single column value).</p>
</div>
<div class="paragraph">
<p>Within a VALUES clause, the operands of a value expression can be numeric, string, datetime, or interval values; however, an operand
cannot reference a column (except in the case of a scalar or row subquery returning a value or values in its result table).</p>
</div>
</div>
<div class="sect4">
<h5 id="insert_requirements_for_inserted_rows">Requirements for Inserted Rows</h5>
<div class="paragraph">
<p>Each row to be inserted must satisfy the constraints of the table or underlying base table of the view. A table constraint is satisfied if
the check condition is not false—it is either true or has an unknown value.</p>
</div>
</div>
<div class="sect4">
<h5 id="insert_using_compatible_data_types">Using Compatible Data Types</h5>
<div class="paragraph">
<p>To insert a row, you must provide a value for each column in the table that has no default value. The data types of the values in each row to
be inserted must be compatible with the data types of the corresponding target columns.</p>
</div>
<div class="sect5">
<h6 id="_inserting_character_values">Inserting Character Values</h6>
<div class="paragraph">
<p>Any character string data type is compatible with all other character string data types that have the same character set. For fixed length, an
inserted value shorter than the column length is padded on the right with blank characters of the appropriate character set (for example,
ISO88591 blanks (HEX20). If the value is longer than the column length, string truncation of non-blank trailing characters returns an error, and
the truncated string is not inserted.</p>
</div>
<div class="paragraph">
<p>For variable length, a shorter inserted value is not padded. As is the case for fixed length, if the value is longer than the column length,
string truncation of non-blank trailing characters returns an error, and the truncated string is not inserted.</p>
</div>
</div>
<div class="sect5">
<h6 id="_inserting_numeric_values">Inserting Numeric Values</h6>
<div class="paragraph">
<p>Any numeric data type is compatible with all other numeric data types. If you insert a value into a numeric column that
is not large enough, an overflow error occurs. If a value has more digits to the right of the decimal point than
specified by the scale for the column definition, the value is truncated.</p>
</div>
</div>
<div class="sect5">
<h6 id="_inserting_interval_values">Inserting Interval Values</h6>
<div class="paragraph">
<p>A value of interval data type is compatible with another value of interval data type only if the two data types are both
year-month or both day-time intervals.</p>
</div>
</div>
<div class="sect5">
<h6 id="_inserting_date_and_time_values">Inserting Date and Time Values</h6>
<div class="paragraph">
<p>Date, time, and timestamp are the three Trafodion SQL datetime data types. A value with a datetime data type is compatible
with another value with a datetime data type only if the values have the same datetime fields.</p>
</div>
</div>
<div class="sect5">
<h6 id="_inserting_nulls">Inserting Nulls</h6>
<div class="paragraph">
<p>and inserting values with specific data types, you might want to insert nulls. To insert null, use the keyword NULL. NULL
only works with the VALUES clause. Use cast (null as <em>type</em>) for select-list.</p>
</div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="insert_examples">3.38.3. Examples of INSERT</h4>
<div class="ulist">
<ul>
<li>
<p>Insert a row into the CUSTOMER table without using a <em>target-col-list</em>:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO sales.customer
VALUES (4777, 'ZYROTECHNIKS', '11211 40TH ST.', 'BURLINGTON', 'MASS.',
'01803', 'A2');
--- 1 row(s) inserted.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The column name list is not specified for this INSERT statement. This operation works because the number of values listed
in the VALUES clause is equal to the number of columns in the CUSTOMER table, and the listed values appear in the same
order as the columns specified in the CREATE TABLE statement for the CUSTOMER table.</p>
</div>
<div class="paragraph">
<p>By issuing this SELECT statement, this specific order is displayed:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM sales.customer WHERE custnum = 4777;
CUSTNUM CUSTNAME STREET ... POSTCODE CREDIT
------------- -------------- --------------- -------- ------
4777 ZYROTECHNIKS 11211 4OTH ST. ... 01803 A2
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Insert a row into the CUSTOMER table using a <em>target-col-list</em>:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO sales.customer
(custnum, custname, street, city, state, postcode)
VALUES (1120, 'EXPERT MAILERS', '5769 N. 25TH PL',
'PHOENIX', 'ARIZONA', '85016');
--- 1 row(s) inserted.</code></pre>
</div>
</div>
<div class="paragraph">
<p>Unlike the previous example, the insert source of this statement does not contain a value for the CREDIT column, which
has a default value. Asa result, this INSERT must include the column name list.</p>
</div>
<div class="paragraph">
<p>This SELECT statement shows the default value 'C1' for CREDIT:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM sales.customer WHERE custnum = 1120;
CUSTNUM CUSTNAME STREET ... POSTCODE CREDIT
------------- -------------- --------------- -------- ------
1120 EXPERT MAILERS 5769 N. 25TH PL ... 85016 C1
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Insert multiple rows into the JOB table by using only one INSERT statement:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO persnl.job
VALUES (100,'MANAGER'),
(200,'PRODUCTION SUPV'),
(250,'ASSEMBLER'),
(300,'SALESREP'),
(400,'SYSTEM ANALYST'),
(420,'ENGINEER'),
(450,'PROGRAMMER'),
(500,'ACCOUNTANT'),
(600,'ADMINISTRATOR'),
(900,'SECRETARY');
--- 10 row(s) inserted.</code></pre>
</div>
</div>
</li>
<li>
<p>The PROJECT table consists of five columns using the data types numeric, varchar, date, timestamp, and interval.
Insert values by using these types:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO persnl.project
VALUES (1000, 'SALT LAKE CITY', DATE '2007-10-02',
TIMESTAMP '2007-12-21 08:15:00.00', INTERVAL '30' DAY);
--- 1 row(s) inserted.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Suppose that CUSTLIST is a view of all columns of the CUSTOMER table except the credit rating. Insert information
from the SUPPLIER table into the CUSTOMER table through the CUSTLIST view, and then update the credit rating:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO sales.custlist
(SELECT * FROM invent.supplier
WHERE suppnum = 10);
UPDATE sales.customer
SET credit = 'A4'
WHERE custnum = 10;</code></pre>
</div>
</div>
<div class="paragraph">
<p>You could use this sequence in the following situation. Suppose that one of your suppliers has become a customer.
If you use the same number for both the customer and supplier numbers, you can select the information from the SUPPLIER
table for the new customer and insert it into the CUSTOMER table through the CUSTLIST view (as shown in the example).</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>This operation works because the columns of the SUPPLIER table contain values that correspond to the columns of the
CUSTLIST view. Further, the credit rating column in the CUSTOMER table is specified with a default value. If you want
a credit rating that is different from the default, you must update this column in the row of new customer data.</p>
</div>
<div class="sect4">
<h5 id="insert_examples_of_self_referencing_inserts">Examples of Self-Referencing Inserts</h5>
<div class="ulist">
<ul>
<li>
<p>This is an example of a self-referencing insert:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">insert into table1 select pk+?, b, c from table1</code></pre>
</div>
</div>
</li>
<li>
<p>This is an example of a self-referencing insert where the target of the insert, table1, is also used in a subquery of the insert-source:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">insert into table1
select a+16, b, c from table2 where table2.b not in
(select b from table1 where a &gt; 16)</code></pre>
</div>
</div>
<div class="paragraph">
<p>The source table is not affected by the insert.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="invoke_statement">3.39. INVOKE Statement</h3>
<div class="paragraph">
<p>The INVOKE statement generates a record description that corresponds to a row in the specified table, view, or index.
The record description includes a data item for each column in the table, view, or index, including the primary key but
excluding the SYSKEY column. It includes the SYSKEY column of a view only if the view explicitly listed the column in its
definition.</p>
</div>
<div class="paragraph">
<p>INVOKE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INVOKE table-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="invoke_syntax">3.39.1. Syntax Description of INVOKE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>table-name</em></code>
_
specifies the name of a table, view, or index for which to generate a record description.
See <a href="#database_object_names">Database Object Names</a>.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="invoke_considerations">3.39.2. Considerations for INVOKE</h4>
</div>
<div class="sect3">
<h4 id="invoke_required_privileges">3.39.3. Required Privileges</h4>
<div class="paragraph">
<p>To issue an INVOKE statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the table.</p>
</li>
<li>
<p>You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC by default.</p>
</li>
<li>
<p>You have the SELECT privilege on the target table.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="invoke_examples">3.39.4. Examples of INVOKE</h4>
<div class="ulist">
<ul>
<li>
<p>This command generates a record description of the table T:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; invoke trafodion.seabase.t;
-- Definition of Trafodion table TRAFODION.SEABASE.T
-- Definition current Wed Mar 5 10:36:06 2014
(
A INT NO DEFAULT NOT NULL NOT DROPPABLE
)
PRIMARY KEY (A ASC)
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="merge_statement">3.40. MERGE Statement</h3>
<div class="paragraph">
<p>The MERGE statement:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Updates a table if the row exists or inserts into a table if the row does not exist. This is upsert functionality.</p>
</li>
<li>
<p>Updates (merges) matching rows from one table to another.</p>
</li>
</ul>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO table [using-clause]
on-clause
{[when-matched-clause]|[when-not-matched-clause]} ...
using-clause is:
USING (select-query) AS derived-table-name [derived-column-names]
on-clause is:
ON predicate
when-matched-clause is:
WHEN MATCHED THEN UPDATE SET set-clause [WHERE predicate]
WHEN MATCHED THEN DELETE
when-not-matched-clause is:
WHEN NOT MATCHED THEN INSERT insert-values-list
insert-values-list is:
[(column1, ..., columnN )] VALUES (value1, ..., valueN)</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="merge_syntax">3.40.1. Syntax Description of MERGE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>is the ANSI logical name for the table.</p>
</div>
</li>
<li>
<p><code>ON <em>predicate</em></code></p>
<div class="paragraph">
<p>used to determine if a row is or is not present in the table. The ON predicate must be a predicate on the clustering
key of the table if the MERGE has a <em>when-not-matched-clause</em>. The clustering key can be a single or multi-column key.</p>
</div>
<div class="paragraph">
<p>The ON predicate must select a unique row if the MERGE has a <em>when-not-matched-clause</em>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="merge_considerations">3.40.2. Considerations for MERGE</h4>
</div>
<div class="sect3">
<h4 id="merge_upsert_using_single_row">3.40.3. Upsert Using Single Row</h4>
<div class="paragraph">
<p>A MERGE statement allows you to specify a set of column values that should be updated if the row is found, and another
row to be inserted if the row is not found. The ON predicate must select exactly one row that is to be updated if the
MERGE statement has an INSERT clause.</p>
</div>
<div class="paragraph">
<p>In a MERGE statement, at least one of the clauses <em>when-matched</em> or <em>when-not-matched</em> must be specified. Note the following:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>If a <em>when-matched</em> clause is present and the WHERE predicate in the UPDATE is satisfied, the columns in the SET clause are updated.</p>
</li>
<li>
<p>If a <em>when-matched</em> clause is present and the WHERE predicate in the UPDATE is not satisfied, the columns in the SET clause are not updated.</p>
</li>
<li>
<p>If a <em>when-matched</em> clause is present and the UPDATE has no WHERE predicate, the columns in the SET clause are updated.</p>
</li>
<li>
<p>If a <em>when-not-matched</em> clause is present and columns are explicitly specified in the INSERT clause, the specified values for those columns
are inserted. Missing columns are updated using the default values for those columns.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>This example updates column b to 20 if the row with key column a with value 10 is found. A new row (10, 30) is inserted if the row is not
found in table t.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t ON a = 10
WHEN MATCHED THEN UPDATE SET b = 20
WHEN NOT MATCHED THEN INSERT VALUES (10, 30)</code></pre>
</div>
</div>
<div class="paragraph">
<p>This example updates column b to 20 if column a with value 10 is found. If column a with value 10 is not found, nothing is done.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t ON a = 10
WHEN MATCHED THEN UPDATE SET b = 20</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>This example inserts values (10, 30) if column a with value 10 is not found. If column a with value 10 is found, nothing is done.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t ON a = 10
WHEN NOT MATCHED THEN INSERT VALUES (10, 30)</code></pre>
</div>
</div>
<div class="sect4">
<h5 id="merge_conditional_upsert_using_single_row">Conditional Upsert Using Single Row</h5>
<div class="paragraph">
<p>In this example, the MERGE statement uses a single-row conditional upsert that inserts one row (keycol, col, seqnum) value
if a row with that keycol (parameter-specified) value is not yet in table d. Otherwise, the MERGE statement updates that
row&#8217;s col and seqnum columns if that row&#8217;s seqnum is higher than the current (parameter-specified) sequence number. If the
matching row&#8217;s seqnum column value is not higher than the current sequence number, then that matched row is not updated.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO d ON keycol = ?
WHEN MATCHED THEN UPDATE SET (col, seqnum) = (?, ?) WHERE seqnum &lt; ?
WHEN NOT MATCHED THEN INSERT (keycol, col, seqnum) VALUES (?, ?, ?)</code></pre>
</div>
</div>
<div class="paragraph">
<p>The optional WHERE predicate in the <em>when-matched-then-update</em> clause is useful when the update is wanted only if the given
condition is satisfied. Consider this use case. Suppose object</p>
</div>
<div class="paragraph">
<p>X is represented as a row in table T. Also, suppose a stream of updates exists for object X. The updates are marked by a
sequence number at their source. However, the updates flow through a network which does not guarantee first-in, first-out
delivery. In fact, the updates may arrive out-of-order to the database. In this case, the last update (the one with the current
highest sequence number) should always win in the database. The MERGE statement shown above can be used to satisfy this
use case:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>A stream of updates for table d exists that are sequenced by a sequence number seqnum at their source</p>
</li>
<li>
<p>The updates race through the network and may arrive in the database in any order, and</p>
</li>
<li>
<p>You want to guarantee that the last update (the one with the highest seqnum) always wins in the database.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="merge_restrictions">Restrictions</h5>
<div class="ulist">
<ul>
<li>
<p>The MERGE statement does not use ESP parallelism.</p>
</li>
<li>
<p>A merged table cannot be a view.</p>
</li>
<li>
<p>Merge is not allowed if the table has constraints.</p>
</li>
<li>
<p>The <em>on-clause</em> cannot contain a subquery. This statement is not allowed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t ON a = (SELECT a FROM t1) WHEN ...</code></pre>
</div>
</div>
</li>
<li>
<p>The optional WHERE predicate in the when-matched clause cannot contain a subquery or an aggregate function.
These statements are not allowed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t ON a = 10
WHEN MATCHED THEN UPDATE SET b=4 WHERE b=(SELECT b FROM t1)
WHEN NOT MATCHED THEN INSERT VALUES (10,30);
MERGE INTO t ON a=10
WHEN MATCHED THEN UPDATE SET b=4 WHERE b=MAX(b)
WHEN NOT MATCHED THEN INSERT VALUES (10,30);</code></pre>
</div>
</div>
</li>
<li>
<p>The UPDATE SET clause in a MERGE statement cannot contain a subquery.
This statement is not allowed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t ON a = 1 WHEN MATCHED THEN UPDATE SET b = (SELECT a FROM t1)</code></pre>
</div>
</div>
</li>
<li>
<p>The <em>insert-values-list</em> clause in a MERGE statement cannot contain a subquery. This statement is not allowed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t ON a = 1 WHEN NOT MATCHED THEN INSERT VALUES ((SELECT a FROM t1))</code></pre>
</div>
</div>
</li>
<li>
<p>Use of a non-unique <em>on-clause</em> for a MERGE update is allowed only if no INSERT clause exists.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t USING (SELECT a,b FROM t1) x ON t.a=x.a
WHEN MATCHED THEN UPDATE SET b=x.b;</code></pre>
</div>
</div>
<div class="paragraph">
<p>In this example, t.a=x.a is not a fully qualified unique primary key predicate.</p>
</div>
</li>
<li>
<p>Use of a non-unique <em>on-clause</em> for a MERGE delete is allowed only if no INSERT clause exists.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t USING (SELECT a,b FROM t1) x ON t.a=x.a
WHEN MATCHED THEN DELETE;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="merge_merge_from_one_table_into_another">MERGE From One Table Into Another</h5>
<div class="paragraph">
<p>The MERGE statement can be used to upsert all matching rows from the source table into the target table.
Each row from the source table is treated as the source of a single upsert statement. The <em>using-clause</em>
contains the <em>select-query</em> whose output is used as the source to the MERGE statement.</p>
</div>
<div class="paragraph">
<p>The source <em>select-query</em> must be renamed using the AS clause.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t ON
USING (_select-query_) AS Z(X) ON col = Z.X
WHEN MATCHED THEN . . .</code></pre>
</div>
</div>
<div class="paragraph">
<p>For each row selected out of the select-query, the MERGE statement is evaluated. Values selected are used
in the <em>on-clause</em> to join with the column of the merged table. If the value is found, it is updated. If it
is not found, the insert is done. The restrictions are the same as those for &lt;&lt;upsert_using_single_row, Upsert Using Single Row&gt;.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="merge_examples">3.40.4. Examples of MERGE</h4>
<div class="ulist">
<ul>
<li>
<p>This query extracts derived columns a and b from the USING query as derived table z and use each row to join to the
merged table t based on the <em>on-clause</em>. For each matched row, column b in table t is updated using column b in derived
table z. For rows that are not matched, values z.a and z.b are inserted.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MERGE INTO t USING
(SELECT * FROM t1) z(a,b) on a = z.a
WHEN MATCHED THEN UPDATE SET b = z.b
WHEN NOT MATCHED THEN INSERT VALUES (z.a, z.b);</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="prepare_statement">3.41. PREPARE Statement</h3>
<div class="paragraph">
<p>The PREPARE statement compiles an SQL statement for later use with the EXECUTE statement in the same Trafodion Command
Interface (TrafCI) session.</p>
</div>
<div class="paragraph">
<p>You can also use PREPARE to check the syntax of a statement without executing the statement in the same TrafCI session.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">PREPARE statement-name FROM statement</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="prepare_syntax">3.41.1. Syntax Description of PREPARE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>statement-name</em></code></p>
<div class="paragraph">
<p>is an SQL identifier that specifies a name to be used for the prepared statement. See <a href="#identifiers">Identifiers</a>.
The statement name should be a character string and not a numeric value. If you specify the name of an existing
prepared statement, the new statement overwrites the previous one.</p>
</div>
</li>
<li>
<p><code><em>statement</em></code></p>
<div class="paragraph">
<p>specifies the SQL statement to prepare.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="prepare_considerations">3.41.2. Considerations for PREPARE</h4>
<div class="sect4">
<h5 id="prepare_availability_of_a_prepared_statement">Availability of a Prepared Statement</h5>
<div class="paragraph">
<p>If a PREPARE statement fails, any subsequent attempt to run EXECUTE on the named statement fails. Only the TrafCI
session that executes the PREPARE can run EXECUTE on the prepared statement.</p>
</div>
<div class="paragraph">
<p>The prepared statement is available for running EXECUTE until you terminate the TrafCI session.</p>
</div>
<div class="paragraph">
<p>A statement must be compiled by PREPARE before you can run EXECUTE on it. However, after the statement is compiled,
you can run EXECUTE on the statement multiple times without recompiling the statement.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="prepare_examples">3.41.3. Examples of PREPARE</h4>
<div class="ulist">
<ul>
<li>
<p>Prepare a SELECT statement, checking for syntax errors:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;prepare empsal from
+&gt;select salary from employee
+&gt;where jobcode = 100;
*** ERROR[4082] Table, view or stored procedure TRAFODION.INVENT.EMPLOYEE does not exist or is inaccessible.
*** ERROR[8822] The statement was not prepared.
SQL&gt;</code></pre>
</div>
</div>
</li>
<li>
<p>Prepare a SELECT statement with an unnamed parameter (?) and later run EXECUTE on it:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;prepare findsal from
+&gt;select salary from persnl.employee
+&gt;where jobcode = ?;
--- SQL command prepared.
SQL&gt;execute findsal using 450;
SALARY
----------
32000.00
33000.50
40000.00
32000.00
45000.00
--- 5 row(s) selected.
SQL&gt;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Prepare a SELECT statement with a named parameter (?<em>param-name</em>) and later run EXECUTE on it:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;prepare findsal from
+&gt;select salary from persnl.employee
+&gt;where jobcode = ?job;
--- SQL command prepared.
SQL&gt;set param ?job 450
SQL&gt;execute findsal;
SALARY
----------
32000.00
33000.50
40000.00
32000.00
45000.00
--- 5 row(s) selected.
SQL&gt;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>For more information, see the <a href="#execute_statement">EXECUTE Statement</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="register_user_statement">3.42. REGISTER USER Statement</h3>
<div class="paragraph">
<p>The REGISTER USER statement registers a user in the SQL database, associating the user&#8217;s login name with a database username.</p>
</div>
<div class="paragraph">
<p>REGISTER USER is a Trafodion SQL extension.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
The user&#8217;s login name is also the name by which the user is defined in the directory service, so the syntax description
below refers to it as the <em>directory-service username</em>.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REGISTER USER directory-service-username [ AS database-username ]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="register_user_syntax">3.42.1. Syntax Description of REGISTER USER</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>directory-service-username</em></code></p>
<div class="paragraph">
<p>is the name that identifies the user in the directory service. This is also the name the user specifies when logging in to
a Trafodion database. The <em>directory-service-username</em> is a regular or delimited case-insensitive identifier.
See <a href="#case_insensitive_delimited_identifiers">Case-Insensitive Delimited Identifiers</a>.</p>
</div>
</li>
<li>
<p><code><em>database-username</em></code></p>
<div class="paragraph">
<p>is a regular or delimited case-insensitive identifier that denotes the username as defined in the database. The database
username cannot be identical to a registered database username or an existing role name. However, it can be the same as
the directory-service username. If you omit the AS <em>database-username</em> clause, the database username will be the same as
the directory-service username.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="register_user_register_user_considerations">3.42.2. Considerations for REGISTER USER</h4>
<div class="sect4">
<h5 id="register_user_who_can_register_a_user">Who Can Register a User</h5>
<div class="paragraph">
<p>To register a user, you must have user administrative privileges. You have user administrative privileges if you have
been granted the MANAGE_USERS component privilege. Initially, DB ROOT is the only database user who has been granted
the MANAGE_USERS component privilege.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="register_user_add_the_user_to_the_directory_before_registering_the_user">Add the User to the Directory Before Registering the User</h5>
<div class="paragraph">
<p>Add the user to the appropriate directory service before you register the user. Otherwise, REGISTER USER will fail.</p>
</div>
</div>
<div class="sect4">
<h5 id="register_user_as_database_user_clause">AS <em>database-username</em> Clause</h5>
<div class="paragraph">
<p>Use the AS <em>database-username</em> clause to assign a database username that is different than the username defined in
the directory service. In particular, it is often convenient to assign a database username that is shorter and easier
to type than the directory-service username.</p>
</div>
<div class="paragraph">
<p>For example, if the user logs on as <code>John.Allen.Doe.the.Second@mycompany.com</code>, you might want to assign the user a
database username of JDoe.</p>
</div>
<div class="paragraph">
<p>Database user names are authorization IDs. If you specify a name already assigned to another user or to an existing
role, the command will fail. For more information, see <a href="#authorization_ids">Authorization IDs</a>.</p>
</div>
</div>
<div class="sect4">
<h5 id="register_user_reserved_names">Reserved Names</h5>
<div class="paragraph">
<p>PUBLIC, _SYSTEM, NONE, and database user names beginning with DB are reserved. You cannot register users with any
such name.</p>
</div>
</div>
<div class="sect4">
<h5 id="register_user_username_length">Username Length</h5>
<div class="paragraph">
<p>Database user names are limited to 128 characters.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="register_user_examples">3.42.3. Examples of REGISTER USER</h4>
<div class="ulist">
<ul>
<li>
<p>To register a user and assign a database username different than the user&#8217;s login name:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REGISTER USER &quot;jsmith@company.com&quot; AS jsmith;</code></pre>
</div>
</div>
</li>
<li>
<p>To register a user without specifying a database username, so the database username will be the same as the user&#8217;s login name:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REGISTER USER &quot;jsmith@company.com&quot;;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="_revoke_statement">3.43. REVOKE Statement</h3>
<div class="paragraph">
<p>The REVOKE statement revokes access privileges on an SQL object from specified users or roles.
Privileges can be revoked from the object, from one or more columns, or both.</p>
</div>
<div class="admonitionblock important">
<table>
<tr>
<td class="icon">
<i class="fa icon-important" title="Important"></i>
</td>
<td class="content">
This statement works only when authentication and authorization are enabled in Trafodion. For more information,
<a href="http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security" class="bare">http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security</a> [Enable Secure Trafodion].
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REVOKE [GRANT OPTION FOR]
{privilege [,privilege]...| ALL [PRIVILEGES]}
ON [object-type] [schema.]object
FROM {grantee}
[[GRANTED] BY grantor]
privilege is:
DELETE
| EXECUTE
| INSERT [column-list]
| REFERENCES [column-list]
| SELECT [column-list]
| UPDATE [column-list]
| USAGE
object-type is:
FUNCTION
| LIBRARY
| PROCEDURE
| SEQUENCE
| TABLE
grantee is:
auth-name
grantor is:
role-name
column-list is:
(column [,column]...)</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="_syntax_description_of_revoke">3.43.1. Syntax Description of REVOKE</h4>
<div class="ulist">
<ul>
<li>
<p><code>GRANT OPTION FOR</code></p>
<div class="paragraph">
<p>Specifies that the grantee’s authority to grant the specified privileges to other users or roles (that is, WITH GRANT
OPTION) be revoked. This is an optional clause. When this clause is specified, only the ability to grant the privilege
to another user is revoked.</p>
</div>
</li>
<li>
<p><code><em>privilege</em> [, <em>privilege</em> ] &#8230; | ALL [ PRIVILEGES ]</code></p>
<div class="paragraph">
<p>Specifies the privileges to revoke. You can specify these privileges for an object:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 80%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DELETE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes the ability to use the DELETE statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">EXECUTE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes the ability to execute a stored procedure using a CALL statement or revokes the ability</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">INSERT [columm-list]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes the ability to use the INSERT statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">REFERENCES [column-list]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes the ability to create constraints that reference the object.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SELECT [column-list]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes the ability to use the SELECT statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">UPDATE [column-list]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes the ability to use the UPDATE statement.
to execute a user-defined function (UDF).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">USAGE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">For libraries, revokes the ability to access a library using the
CREATE PROCEDURE or CREATE FUNCTION statement.
For sequence generators, revokes the ability to access a sequence in a SQL query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">ALL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Revokes the ability to use all privileges that apply to the object type.
When you specify ALL for a table or view, this includes the SELECT, DELETE, INSERT, REFERENCES, and
UPDATE privileges. When the object is a stored procedure or user-defined function (UDF), this includes
the EXECUTE privilege. When the object is a library, this includes the UPDATE and USAGE privileges.
When the object is a sequence generator, only the usage privilege is applied.</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p><code>ON [<em>object-type</em>] <em class="_schema_.">object</em></code></p>
<div class="paragraph">
<p>Specifies an object on which to grant privileges. If none is specified, it defaults to TABLE. See <a href="#database_object_names">"Database Object Names</a> for more details. <em>object-type</em> can be:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>FUNCTION <em class="_schema_.">function-name</em>, where <em>function-name</em> is the name of a user-defined function in the database.</p>
</li>
<li>
<p>LIBRARY <em class="_schema_.">library-name</em>, where <em>library-name</em> is the name of a library object in the database.</p>
</li>
<li>
<p>PROCEDURE <em class="_schema_.">procedure-name</em>, where <em>procedure-name</em> is the name of a stored procedure in Java (SPJ)
registered in the database.</p>
</li>
<li>
<p>SEQUENCE <em class="_schema_.">sequence-name</em>, where <em>sequence-name</em> is the name of a sequence generator.</p>
</li>
<li>
<p>[TABLE] <em class="_schema_.">object-name</em>, where <em>object-name</em> is the name of a table or view.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>FROM {<em>grantee</em> [,<em>grantee</em>] &#8230; }</code></p>
<div class="paragraph">
<p>Specifies an <em>auth-name</em> from which you revoke privileges.</p>
</div>
</li>
<li>
<p><code><em>auth-name</em></code></p>
<div class="paragraph">
<p>Specifies the name of an authorization ID from which you revoke privileges. See <a href="#authorization_ids">Authorization IDs</a>.
The authorization ID must be a registered database username, existing role name, or PUBLIC. The name is
a regular or delimited case-insensitive identifier. See
<a href="#case_insensitive_delimited_identifiers">Case-Insensitive Delimited Identifiers</a>.</p>
</div>
</li>
<li>
<p><code>[GRANTED] BY <em>grantor</em></code></p>
<div class="paragraph">
<p>Allows you to revoke privileges on behalf of a role. If not specified, the privileges will be revoked
on your behalf as the current user/grantor.</p>
</div>
</li>
<li>
<p><code><em>role-name</em></code></p>
<div class="paragraph">
<p>Specifies a role on whose behalf the GRANT operation was performed. To revoke the privileges on behalf of a role,
you must be a member of the role, and the role must have the authority to revoke the privileges;
that is, the role must have been granted the privileges WITH GRANT OPTION.</p>
</div>
</li>
<li>
<p><code><em>column-list</em></code></p>
<div class="paragraph">
<p>Specifies the list of columns to revoke the requested privilege from.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="revoke_considerations">3.43.2. Considerations for REVOKE</h4>
<div class="sect4">
<h5 id="revoke_authorization_and_availability_requirements">Authorization and Availability Requirements</h5>
<div class="paragraph">
<p>You can revoke privileges for which you are the grantor, either through a direct grant or a grant done on your
behalf. If you are revoking privileges that were granted on behalf of a role, you must be a member of the role,
and you must specify the role in the [GRANTED] BY clause.</p>
</div>
<div class="paragraph">
<p>If one or more privileges have not been granted, SQL returns a warning.</p>
</div>
<div class="paragraph">
<p>When you specify the CASCADE option, all objects that were created based upon the privileges being revoked are removed.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="revoke_examples">3.43.3. Examples of REVOKE</h4>
<div class="ulist">
<ul>
<li>
<p>To revoke GRANT OPTION for column level SELECT and table level DELETE privileges on a table from a user:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REVOKE GRANT OPTION FOR SELECT (part_no, part_name), DELETE ON TABLE invent.partloc FROM jsmith;</code></pre>
</div>
</div>
</li>
<li>
<p>To revoke the privilege to grant SELECT and DELETE privileges on a table from a user and a role:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REVOKE SELECT (part_no, part_name), DELETE ON TABLE invent.partloc FROM jsmith, clerks;</code></pre>
</div>
</div>
</li>
<li>
<p>To revoke a user’s SELECT privileges on a table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">-- User administrator grants the SELECT privilege to JSMITH:
GRANT SELECT ON TABLE invent.partloc TO jsmith WITH GRANT OPTION;
-- JSMITH grants the SELECT privilege to AJONES:
GRANT SELECT ON TABLE invent.partloc TO ajones;
-- If the user administrator attempts to revoke the SELECT
-- privilege from JSMITH, this would fail because
-- of the privilege granted to AJONES based on the
-- privilege granted to JSMITH.
-- To successfully revoke the SELECT privilege from
-- JSMITH, the SELECT privilege granted to AJONES
-- must be revoked first. For this example:
-- 1. JSMITH revokes the SELECT privilege granted to AJONES:
REVOKE SELECT ON TABLE invent.partloc FROM ajones;
-- 2. User administrator revokes the SELECT privilege on the
-- table from JSMITH:
REVOKE SELECT ON TABLE invent.partloc FROM jsmith RESTRICT;
-- The REVOKE operation succeeds.
-- An easier way to make the REVOKE operation successful is
-- to use the CASCADE option:
REVOKE SELECT ON TABLE invent.partloc FROM jsmith CASCADE;
-- The REVOKE operation succeeds because the CASCADE option
-- causes all specified privileges, and all privileges that
-- were granted based upon the specified privileges, to be
-- removed.</code></pre>
</div>
</div>
</li>
<li>
<p>Administration in the shipping department decides that the CLERKS role should no longer be able to grant
privileges on the invent.partloc table. Fred has recently moved to another department, so JSMITH revokes
the SELECT privilege on the invent.partloc table from Fred, who was granted the privilege by CLERKS. Then,
JSMITH revokes the grant option from CLERKS:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REVOKE SELECT on table invent.partloc FROM fred GRANTED BY clerks;
REVOKE GRANT OPTION FOR SELECT ON TABLE invent.partloc FROM clerks;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="revoke_component_privilege_statement">3.44. REVOKE COMPONENT PRIVILEGE Statement</h3>
<div class="paragraph">
<p>The REVOKE COMPONENT PRIVILEGE statement removes one or more component
privileges from a user or role. See <a href="#privileges">Privileges</a> and <a href="#roles">Roles</a>.</p>
</div>
<div class="paragraph">
<p>REVOKE COMPONENT PRIVILEGE is a Trafodion SQL extension.</p>
</div>
<div class="admonitionblock important">
<table>
<tr>
<td class="icon">
<i class="fa icon-important" title="Important"></i>
</td>
<td class="content">
This statement works only when authentication and authorization are enabled in Trafodion. For more information,
<a href="http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security" class="bare">http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security</a> [Enable Secure Trafodion].
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REVOKE [GRANT OPTION FOR]
COMPONENT PRIVILEGE {privilege-name[, privilege-name]...}
ON component-name
FROM grantee
[[GRANTED] BY grantor]
grantee is:
auth-name
grantor is:
role-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="_syntax_description_of_revoke_component_privilege">3.44.1. Syntax Description of REVOKE COMPONENT PRIVILEGE</h4>
<div class="ulist">
<ul>
<li>
<p><code>GRANT OPTION FOR</code></p>
<div class="paragraph">
<p>specifies that the grantee’s authority to grant the specified component privileges to other users or roles (that is,
WITH GRANT OPTION) be revoked. This is an optional clause. When this clause is specified, only the ability to grant
the component privilege to another user is revoked.</p>
</div>
</li>
<li>
<p><code><em>privilege-name</em></code></p>
<div class="paragraph">
<p>specifies one or more component privileges to revoke. The comma-separated list can include only privileges within the
same component.</p>
</div>
</li>
<li>
<p><code>ON <em>component-name</em></code></p>
<div class="paragraph">
<p>specifies a valid component name on which to revoke component privileges. Currently, the only valid component name is
SQL_OPERATIONS.</p>
</div>
</li>
<li>
<p><code>FROM <em>grantee</em></code></p>
<div class="paragraph">
<p>specifies an <em>auth-name</em> from which you revoke the component privileges.</p>
</div>
</li>
<li>
<p><code><em>auth-name</em></code></p>
<div class="paragraph">
<p>specifies the name of an authorization ID from which you revoke privileges. See <a href="#authorization_ids">Authorization IDs</a>.
The authorization ID must be a registered database username, existing role name, or PUBLIC. The name is a regular or
delimited case-insensitive identifier. See
<a href="#case_insensitive_delimited_identifiers">Case-Insensitive Delimited Identifiers</a>.</p>
</div>
</li>
<li>
<p><code>[ GRANTED ] BY <em>grantor</em></code></p>
<div class="paragraph">
<p>allows you to revoke component privileges on behalf of a role. If not specified, the component privileges will be revoked
on your behalf as the current user/grantor.</p>
</div>
</li>
<li>
<p><code><em>role-name</em></code></p>
<div class="paragraph">
<p>specifies a role on whose behalf the GRANT COMPONENT PRIVILEGE operation was performed. To revoke the privileges on behalf
of a role, you must be a member of the role, and the role must have the authority to revoke the privileges; that is, the
role must have been granted the privileges WITH GRANT OPTION.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="revoke_component_privilege_considerations">3.44.2. Considerations for REVOKE COMPONENT PRIVILEGE</h4>
<div class="ulist">
<ul>
<li>
<p>At revoke time, all privileges granted WITH GRANT OPTION are removed. That is, the revoke behavior is CASCADE.</p>
</li>
<li>
<p>If none of the component privileges has been granted, SQL returns an error.</p>
</li>
<li>
<p>If one or more component privileges have not been granted, SQL silently ignores those privileges and proceeds with
the revoke operation.</p>
</li>
<li>
<p>Component privileges must be revoked before a role can be dropped or a user unregistered. If any privileges have been
granted to a role or user, an error is returned when that role is dropped or the user unregistered. For more information,
see the <a href="#drop_role_statement">DROP ROLE Statement</a> and the <a href="#unregister_user_statement">UNREGISTER USER Statement</a>.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="revoke_component_privilege_authorization_and_availability_requirements">Authorization and Availability Requirements</h5>
<div class="paragraph">
<p>You can revoke component privileges for which you are the grantor, either through a direct grant or a grant done on your
behalf. If you are revoking privileges that were granted on behalf of a role, you must be a member of the role, and you
must specify the role in the [GRANTED] BY clause.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="revoke_component_examples">3.44.3. Examples of REVOKE COMPONENT PRIVILEGE</h4>
<div class="ulist">
<ul>
<li>
<p>Revoke a component privilege from SQLUSER1:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REVOKE COMPONENT PRIVILEGE CREATE_TABLE ON SQL_OPERATIONS FROM sqluser1;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="revoke_role_statement">3.45. REVOKE ROLE Statement</h3>
<div class="paragraph">
<p>The REVOKE ROLE statement removes one or more roles from a user. See
<a href="#roles">Roles</a>.</p>
</div>
<div class="admonitionblock important">
<table>
<tr>
<td class="icon">
<i class="fa icon-important" title="Important"></i>
</td>
<td class="content">
This statement works only when authentication and authorization are enabled in Trafodion. For more information,
<a href="http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security" class="bare">http://trafodion.incubator.apache.org/docs/provisioning_guide/index.html#enable-security</a> [Enable Secure Trafodion].
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REVOKE ROLE {role-name [,role-name]...}
FROM grantee
[RESTRICT | CASCADE]
grantee is:
database-username</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="revoke_role_syntax">3.45.1. Syntax Description of REVOKE ROLE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>role-name</em> [, <em>role-name</em> ] &#8230;</code></p>
<div class="paragraph">
<p>specifies the valid roles to revoke.</p>
</div>
</li>
<li>
<p><code>FROM <em>grantee</em></code></p>
<div class="paragraph">
<p>specifies the registered database username from whom you revoke the roles.</p>
</div>
</li>
<li>
<p><code>[ RESTRICT | CASCADE ]</code></p>
<div class="paragraph">
<p>If you specify RESTRICT, the REVOKE ROLE operation fails if any privileges were granted to
the role or any objects were created based upon those privileges.</p>
</div>
<div class="paragraph">
<p>If you specify CASCADE, any dependent privileges are removed as part of the REVOKE ROLE operation.</p>
</div>
<div class="paragraph">
<p>The default value is RESTRICT.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="revoke_role_considerations">3.45.2. Considerations for REVOKE ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>To revoke roles from users, you must own the roles or have user administrative privileges for the roles. You have
user administrative privileges for roles if have been granted the MANAGE_ROLES component privilege. Initially,
DB ROOT is the only database user who has been granted the MANAGE_ROLES component privilege.</p>
</li>
<li>
<p>If RESTRICT (or nothing) is specified and if you want to revoke a role from a user that has created objects based
solely on role privileges, you must drop the objects before revoking the role. However, if you specify CASCADE, the
dependent objects are automatically dropped, and the role is revoked.</p>
</li>
<li>
<p>All of the specified roles must have been granted to the specified user. If any role has not been granted to the user,
the operation returns an error, and no roles are revoked.</p>
</li>
<li>
<p>When you revoke a role from a user, the reduction in privileges is automatically propagated to and detected by
active sessions. There is no need for users to disconnect from and reconnect to a session to see the updated set of privileges.</p>
</li>
<li>
<p>If the REVOKE ROLE names multiple roles and any errors occur in processing, no revokes are performed.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="revoke_role_examples">3.45.3. Examples of REVOKE ROLE</h4>
<div class="ulist">
<ul>
<li>
<p>To revoke multiple roles from a user:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REVOKE ROLE clerks, sales FROM jsmith;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>To revoke a role with dependent objects from a user:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">-- CMILLER grants a role to AJONES:
GRANT ROLE sales TO ajones;
-- CMILLER grants a privilege to the role:
GRANT SELECT ON TABLE invent.partloc TO sales;
-- AJONES creates a view based upon the privilege granted
-- to the role granted to him:
CREATE VIEW invent.partlocview (partnum, loc_code) AS
SELECT partnum, loc_code FROM invent.partloc;
-- If CMILLER attempts to revoke the role from AJONES,
-- this would fail because of the view created based
-- upon the privilege granted to the role granted to
-- AJONES.
-- CMILLER revokes the role from AJONES with the CASCADE option:
REVOKE ROLE sales from AJONES CASCADE;
-- The REVOKE ROLE operation succeeds, and all dependent object privileges are revoked.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="rollback_work_statement">3.46. ROLLBACK WORK Statement</h3>
<div class="paragraph">
<p>The ROLLBACK WORK statement undoes all database modifications to objects made during the current transaction and ends
the transaction. See <a href="#transaction_management">Transaction Management</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROLLBACK [WORK]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="rollback_work_syntax">3.46.1. Syntax Description of ROLLBACK WORK</h4>
<div class="paragraph">
<p>WORK is an optional keyword that has no effect.</p>
</div>
<div class="paragraph">
<p>ROLLBACK WORK issued outside of an active transaction generates error 8609.</p>
</div>
</div>
<div class="sect3">
<h4 id="rollback_work_considerations">3.46.2. Considerations for ROLLBACK WORK</h4>
<div class="sect4">
<h5 id="rollback_work_begin_and_end_a_transaction">Begin and End a Transaction</h5>
<div class="paragraph">
<p>BEGIN WORK starts a transaction. COMMIT WORK or ROLLBACK WORK ends a transaction.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="rollback_work_examples">3.46.3. Example of ROLLBACK WORK</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that you add an order for two parts numbered 4130 to the ORDERS and ODETAIL tables. When you update the PARTLOC
table to decrement the quantity available, you discover no such part number exists in the given location.</p>
<div class="paragraph">
<p>Use ROLLBACK WORK to terminate the transaction without committing the database changes:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">BEGIN WORK;
INSERT INTO sales.orders
VALUES (124, DATE '2007-04-10',
DATE '2007-06-10', 75, 7654);
INSERT INTO sales.odetail VALUES (124, 4130, 25000, 2);
UPDATE invent.partloc
SET qty_on_hand = qty_on_hand - 2
WHERE partnum = 4130 AND loc_code = 'K43';
ROLLBACK WORK;</code></pre>
</div>
</div>
<div class="paragraph">
<p>ROLLBACK WORK cancels the insert and update that occurred during the transaction.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="select_statement">3.47. SELECT Statement</h3>
<div class="paragraph">
<p>The SELECT statement is a DML statement that retrieves values from tables, views, and derived tables determined by the
evaluation of query expressions, or joined tables.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">sql-query is:
query-specification
| query-expr-and-order
query-specification is:
[with-clause]
SELECT [ &quot;[&quot; ANY N &quot;]&quot; | &quot;[&quot; FIRST N &quot;]&quot; ] [ALL | DISTINCT] select-list
FROM table-ref [,table-ref]...
[WHERE search-condition]
[SAMPLE sampling-method]
[TRANSPOSE transpose-set [transpose-set]...
[KEY BY key-colname]]...
[SEQUENCE BY colname [ASC[ENDING] | DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]]...]
[GROUP BY {colname | colnum} [,{colname | colnum}]...]
[HAVING search-condition]
[access-clause]
[mode-clause]
With-clause is:
WITH with_clause_elements
with_clause_elements is:
with_clause_element [,with_clause_element] …
with_clause_element is:
cte-table-name AS (sql-query)
query-expr-and-order is:
query-expr [order-by-clause] [access-clause] [mode-clause]
query-expr is:
query-primary
| query-expr UNION [ALL] query-primary
| query-expr INTERSECT query-primary
| query-expr EXCEPT query-primary
query-primary is:
simple-table | (query-expr)
simple-table is:
VALUES (row-value-const) [,(row-value-const)]...
| TABLE table
| query-specification
row-value-const is:
row-subquery
| {expression | NULL} [,{expression | NULL}]...
order-by-clause is:
[ORDER BY {colname | colnum} [ASC[ENDING] | DESC[ENDING]]
[,{colname | colnum} [ASC[ENDING] | DESC[ENDING]]]...]
[access-clause]
access clause is:
[FOR] access-option ACCESS</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">access-option is:
READ COMMITTED
[LIMIT num]
select-list is:
* | select-sublist [,select-sublist]...
select-sublist is:
corr.* | [corr.]single-col [[AS]name] | col-expr [[AS] name]
table-ref is:
table [[AS] corr [(col-expr-list)]]
| view [[AS] corr [(col-expr-list)]]
| (query-expr) [AS] corr [(col-expr-list)]
| (delete-statement [RETURN select-list])
[AS] corr [(col-expr-list)]
| (update-statement [RETURN select-list])
[AS] corr [(col-expr-list)]
| (insert-statement) [AS] corr [(col-expr-list)]
| joined-table
joined-table is:
table-ref [join-type] JOIN table-ref join-spec
| table-ref NATURAL [join-type] JOIN table-ref
| table-ref CROSS JOIN table-ref
| (joined-table)
join-type is:
INNER | LEFT [OUTER] | RIGHT [OUTER] | FULL [OUTER]
join-spec is:
ON search-condition
sampling-method is:
RANDOM percent-size
| FIRST rows-size
[SORT BY colname [ASC[ENDING] | DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]...]
| PERIODIC rows-size EVERY number-rows ROWS
[SORT BY colname [ASC[ENDING] | DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]...]
percent-size is:
percent-result PERCENT [ROWS]
| BALANCE WHEN condition
THEN percent-result PERCENT [ROWS]
[WHEN condition
THEN percent-result PERCENT [ROWS]]...
[ELSE percent-result PERCENT [ROWS]] END</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">rows-size is:
number-rows ROWS
| BALANCE WHEN condition
THEN number-rows ROWS
[WHEN condition
THEN number-rows ROWS]...
[ELSE number-rows ROWS] END
transpose-set is:
transpose-item-list AS transpose-col-list
transpose-item-list is:
expression-list | (expression-list) [,(expression-list)]...</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="select_syntax">3.47.1. Syntax Description of SELECT</h4>
<div class="ulist">
<ul>
<li>
<p>with-clause</p>
<div class="paragraph">
<p>With-clause, known as Common Table Expressions (CTEs) or subquery factoring clause, was introduced in the SQL-99 standard and has been implemented into Trafodion R2.1.</p>
</div>
<div class="paragraph">
<p>The with-clause assigns an alias to a complex expression. The alias is treated like a temporary table or an inline view that lasts only for the duration of the query and can be referenced multiple times in the same query.</p>
</div>
<div class="paragraph">
<p>By abstracting the complicated parts of the query into simpler, separate and logical blocks, and possibly materializing the results of these parts to avoid recomputing it multiple times, the with-clause has following advantages:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Simplifies complicated queries, increasing readability and reducing repeated references.</p>
</li>
<li>
<p>Builds reusable units and decreases maintenance cost.</p>
</li>
<li>
<p>Shortens response time and enhances performance of the query.</p>
</li>
<li>
<p>Improves compatibility with other systems which support with-clause as well.</p>
</li>
</ul>
</div>
</li>
<li>
<p>cte-table-name</p>
<div class="paragraph">
<p>specifies the unique name of the CTE to be created, which is a valid SQL identifier with a maximum of 128 characters. Duplicate names are not allowed in a single with-clause.</p>
</div>
</li>
<li>
<p><code>"[" ANY <em>N</em> "]" | "[" FIRST <em>N</em> "]"</code></p>
<div class="paragraph">
<p>specifies that <em>N</em> rows are to be returned (assuming the table has at least <em>N</em> rows and that the qualification
criteria specified in the WHERE clause, if any, would select at least <em>N</em> rows) and you do not care which <em>N</em> rows
are chosen (out of the qualified rows) to actually be returned.</p>
</div>
<div class="paragraph">
<p><em>You must enclose ANY N or FIRST N in square brackets ([]).</em> The quotation marks ("") around each square bracket in
the syntax diagram indicate that the bracket is a required character that you must type as shown (for example, [ANY 10]
or [FIRST 5]). Do not include quotation marks in ANY or FIRST clauses.</p>
</div>
<div class="paragraph">
<p>[FIRST <em>N</em>] is different from [ANY <em>N</em>] only if you use ORDER BY on any of the columns in the select list to sort the
result table of the SELECT statement. <em>N</em> is an unsigned numeric literal with no scale. If <em>N</em> is greater than the number
of rows in the table, all rows are returned. [ANY <em>N</em>] and [FIRST <em>N</em>] are disallowed in nested SELECT statements and on
either side of a UNION operation.</p>
</div>
</li>
<li>
<p><code>ALL | DISTINCT</code></p>
<div class="paragraph">
<p>specifies whether to retrieve all rows whose columns are specified by the <em>select-list</em> (ALL) or only rows that are not
duplicates (DISTINCT). Nulls are considered equal for the purpose of removing duplicates. The default is ALL.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>select-list</em></code></p>
<div class="paragraph">
<p>specifies the columns or column expressions to select from the table references in the FROM clause.
See the discussion of limitations in <a href="#considerations_for_select_list">Considerations for Select List</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>*</p>
<div class="paragraph">
<p>specifies all columns in a table, view, joined table, or derived table determined by the evaluation of a query expression,
as specified in the FROM clause.</p>
</div>
</li>
<li>
<p><code><em>corr</em>.*</code></p>
<div class="paragraph">
<p>specifies all columns of specific table references by using the correlation name <em>corr</em> of the table references, as
specified in the FROM clause. See <a href="#correlation_names">Correlation Names</a>.</p>
</div>
</li>
<li>
<p><code><em>corr</em>.<em>single-col</em> [[AS] <em>name</em>]</code></p>
<div class="paragraph">
<p>specifies one column of specific table references by using the correlation name of the table reference, as specified in
the FROM clause. See <a href="#correlation_names">Correlation Names</a>. By using the AS clause, you can associate the column with
a <em>name</em>. <em>name</em> is an SQL identifier. See <a href="#identifiers">Identifiers</a>.</p>
</div>
</li>
<li>
<p><code><em>single-col</em> [[AS] <em>name</em>]</code></p>
<div class="paragraph">
<p>specifies a column. By using the AS clause, you can associate the column with a <em>name</em>. <em>name</em> is an SQL identifier. See
<a href="#identifiers">Identifiers</a>.</p>
</div>
</li>
<li>
<p><code><em>col-expr</em> [[AS] <em>name</em>]</code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of an SQL value expression in the list. By using the AS clause,
you can associate a derived column, <em>col-expr</em>, with a <em>name</em>. <em>name</em> is an SQL identifier. See <a href="#identifiers">Identifiers</a>.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>FROM <em>table-ref</em> [,<em>table-ref</em>]&#8230;</code></p>
<div class="paragraph">
<p>specifies a list of tables, views, derived tables, or joined tables that determine the contents of an intermediate result
table from which Trafodion SQL returns the columns you specify in <em>select-list</em>.</p>
</div>
<div class="paragraph">
<p>If you specify only one <em>table-ref</em>, the intermediate result table consists of rows derived from that table reference. If you specify more
than one <em>table-ref</em>, the intermediate result table is the cross-product of result tables derived from the individual table
references.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>table [[AS] corr [(col-expr-list)]] | view [[AS] corr [(col-expr-list)]] |
(query-expr) [AS] corr [(col-expr-list)] | (delete-statement [RETURN
select-list]) [AS] corr [(col-expr-list)] | (update-statement [RETURN
select-list]) [AS] corr [(col-expr-list)] | (insert-statement) [AS] corr
[(col-expr-list)] | joined-table</code></p>
<div class="paragraph">
<p>specifies a <em>table-ref</em> as a single table, view, derived table determined by the evaluation of a query expression, or a joined table.</p>
</div>
<div class="paragraph">
<p>You can specify this optional clause for a table or view. This clause is required for a derived table:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>[AS] <em>corr</em> [(<em>col-expr-list)</em>]</code></p>
<div class="paragraph">
<p>specifies a correlation name, <em>corr</em>, for the preceding table reference <em>table-ref</em> in the FROM clause.
See <a href="#correlation_names">Correlation Names</a>.</p>
</div>
</li>
<li>
<p><code><em>col-expr</em> [[AS] <em>name</em>] [,<em>col-expr</em> [[AS] <em>name</em>]] &#8230;</code></p>
<div class="paragraph">
<p>specifies the items in <em>col-expr-list</em>, a list of derived columns. By using the AS clause, you can associate a derived column,
<em>col-expr</em>, with a <em>name</em>. <em>name</em> is an SQL identifier. See <a href="#identifiers">Identifiers</a>.</p>
</div>
<div class="paragraph">
<p>For the specification of a query expression, see the syntax diagram for <em>query-expr</em> above.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>(<em>delete-statement</em> [RETURN <em>select-list</em>]) [AS] <em>corr</em> [(<em>col-expr-list</em>)]</code></p>
<div class="paragraph">
<p>enables an application to read and delete rows with a single operation. For the syntax of
<em>delete-statement</em>, see the <a href="#delete_statement">DELETE Statement</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>RETURN <em>select-list</em></code></p>
<div class="paragraph">
<p>specifies the columns or column expressions returned from the deleted row. the items in the <em>select-list</em> can be of these forms:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>[old.]*</code></p>
<div class="paragraph">
<p>specifies the row from the old table exposed by the embedded delete. the old table refers to column values before the delete
operation. new is not allowed. an implicit old.* return list is assumed for a delete operation that does not specify a return list.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>col-expr</em> [[AS] <em>name</em>]</code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of an sql value expression in the list. any column referred to in a value
expression is from the row in the old table exposed by the delete. the old table refers to column values before the delete operation.</p>
</div>
<div class="paragraph">
<p>By using the as clause, you can associate a derived column, <em>col-expr</em>, with a <em>name</em>. <em>name</em> is an SQL identifier. See
<a href="#identifiers">Identifier</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>[AS] <em>corr</em> [(<em>col-expr-list</em>)]</code></p>
<div class="paragraph">
<p>specifies a correlation name, <em>corr</em>, and an optional column list for the preceding items in the select list RETURN <em>select-list</em>.
See <a href="#correlation_names">Correlation Names</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>(<em>update-statement</em> [RETURN <em>select-list</em>]) [AS] <em>corr</em> [(<em>col-expr-list</em>)]</code></p>
<div class="paragraph">
<p>enables an application to read and update rows with a single operation. For the syntax of <em>update-statement</em>, see the
<a href="#update_statement">UPDATE Statement</a>.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>RETURN <em>select-list</em></code></p>
<div class="paragraph">
<p>specifies the columns or column expressions returned from the updated row. The items in the <em>select-list</em> can be of these forms:</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>[OLD.| NEW.]*</code></p>
<div class="paragraph">
<p>specifies the row from the old or new table exposed by the update. The old table refers to column values before the update
operation; the new table refers to column values after the update operation. If a column has not been updated, the new value
is equivalent to the old value.</p>
</div>
<div class="paragraph">
<p>An implicit NEW.* return list is assumed for an update operation that
does not specify a return list.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>col-expr</em> [[AS] <em>name</em>]</code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of an SQL value expression in the list. Any column referred to in
a value expression can be specified as being from the row in the old table exposed by the update or can be specified as being
from the row in the new table exposed by the update.</p>
</div>
<div class="paragraph">
<p>For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RETURN old.empno,old.salary,new.salary, (new.salary - old.salary).</code></pre>
</div>
</div>
<div class="paragraph">
<p>By using the AS clause, you can associate a derived column, <em>col-expr</em>, with a <em>name</em>. <em>name</em> is an SQL identifier.
See <a href="#identifiers">Identifiers</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>[AS] <em>corr</em> [(<em>col-expr-list</em>)]</code></p>
<div class="paragraph">
<p>specifies a correlation name, <em>corr</em>, and an optional column list for the preceding items in the select list RETURN
<em>select-list</em>. See <a href="#correlation_names">Correlation Names</a>. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RETURN old.empno,old.salary,new.salary,
(new.salary - old.salary)
AS emp (empno, oldsalary, newsalary, increase).</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>(<em>insert-statement</em>) [AS] <em>corr</em> [(<em>col-expr-list</em>)]</code></p>
<div class="paragraph">
<p>For the syntax of <em>insert-statement</em>, see the <a href="#insert_statement">INSERT Statement</a>.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>[AS] <em>corr</em> [(<em>col-expr-list</em>)]</code></p>
<div class="paragraph">
<p>specifies a correlation name, <em>corr</em>, and an optional column list. See <a href="#correlation_names">Correlation Names</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>joined-table</em></code></p>
<div class="paragraph">
<p>A <em>joined-table</em> can be specified as:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">_table-ref_ [_join-type_] JOIN _table-ref join-spec_
| _table-ref_ NATURAL [_join-type_] JOIN _table-ref_
| _table-ref_ CROSS JOIN _table-ref_
| (_joined-table_)</code></pre>
</div>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>join-type</em> is: INNER | LEFT [OUTER] | RIGHT [OUTER] | FULL [OUTER]</code></p>
<div class="paragraph">
<p>is a joined table. You specify the <em>join-type</em> by using the CROSS, INNER, OUTER, LEFT, RIGHT, and FULL keywords.
If you omit the optional OUTER keyword and use LEFT, RIGHT, or FULL in a join, Trafodion SQL assumes the join is
an outer join.</p>
</div>
<div class="paragraph">
<p>If you specify a CROSS join as the <em>join-type</em>, you cannot specify a NATURAL join or a</p>
</div>
</li>
<li>
<p><code><em>join-spec</em>.</code></p>
<div class="paragraph">
<p>If you specify an INNER, LEFT, RIGHT, or FULL join as the <em>join-type</em> and you do not specify a NATURAL join, you
must use an ON clause as the <em>join-spec</em>, as follows: subqueries are not allowed in the join predicate of FULL OUTER JOIN.</p>
</div>
</li>
<li>
<p><code>ON <em>search-condition</em></code></p>
<div class="paragraph">
<p>specifies a <em>search-condition</em> for the join. Each column reference in <em>search-condition</em> must be a column that exists
in either of the two result tables derived from the table references to the left and right of the JOIN keyword. A join
of two rows in the result tables occurs if the condition is satisfied for those rows.</p>
</div>
<div class="paragraph">
<p>The type of join and the join specification if used determine which rows are joined from the two table references, as follows:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>table-ref</em> CROSS JOIN <em>table-ref</em></code></p>
<div class="paragraph">
<p>joins each row of the left <em>table-ref</em> with each row of the right <em>table-ref</em>.</p>
</div>
</li>
<li>
<p><code><em>table-ref</em> NATURAL JOIN <em>table-ref</em></code></p>
<div class="paragraph">
<p>joins rows only where the values of all columns that have the same name in both tables match. This option is equivalent
to NATURAL INNER.</p>
</div>
</li>
<li>
<p><code><em>table-ref</em> NATURAL LEFT JOIN <em>table-ref</em></code></p>
<div class="paragraph">
<p>joins rows where the values of all columns that have the same name in both tables match, plus rows from the left <em>table-ref</em>
that do not meet this condition.</p>
</div>
</li>
<li>
<p><code><em>table-ref</em> NATURAL RIGHT JOIN <em>table-ref</em></code></p>
<div class="paragraph">
<p>joins rows where the values of all columns that have the same name in both tables match, plus rows from the right <em>table-ref</em>
that do not meet this condition.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>table-ref</em> NATURAL FULL JOIN <em>table-ref</em></code></p>
<div class="paragraph">
<p>joins rows where the values of all columns that have the same name in both tables match, plus rows from either side that
do not meet this condition, filling in NULLs for missing values.</p>
</div>
</li>
<li>
<p><code><em>table-ref</em> JOIN <em>table-ref join-spec</em></code></p>
<div class="paragraph">
<p>joins only rows that satisfy the condition in the <em>join-spec</em> clause. This option is equivalent to INNER JOIN &#8230; ON.</p>
</div>
</li>
<li>
<p><code><em>table-ref</em> LEFT JOIN <em>table-ref join-spec</em></code></p>
<div class="paragraph">
<p>joins rows that satisfy the condition in the <em>join-spec</em> clause, plus rows from the left <em>table-ref</em> that do not
satisfy the condition.</p>
</div>
</li>
<li>
<p><code><em>table-ref</em> RIGHT JOIN <em>table-ref join-spec</em></code></p>
<div class="paragraph">
<p>joins rows that satisfy the condition in the <em>join-spec</em> clause, plus rows from the right
<em>table-ref</em> that do not satisfy the condition.</p>
</div>
</li>
<li>
<p><code><em>table-ref</em> FULL OUTER JOIN <em>table-ref join-spec</em></code></p>
<div class="paragraph">
<p>combines the results of both left and right outer joins. These joins show records from both tables and fill in NULLs for missing matches on
either side</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>simple-table</em></code></p>
<div class="paragraph">
<p>A <em>simple-table</em> can be specified as:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> VALUES (_row-value-const_) [,(_row-value-const_)]...
| TABLE _table_
| _query-specification_</code></pre>
</div>
</div>
<div class="paragraph">
<p>A <em>simple-table</em> can be a table value constructor. It starts with the VALUES keyword followed by a sequence of row
value constructors, each of which is enclosed in parentheses. A <em>row-value-const</em> is a list of expressions (or NULL)
or a row subquery (a subquery that returns a single row of column values). An operand of an expression cannot reference
a column (except when the operand is a scalar subquery returning a single column value in its result table).</p>
</div>
<div class="paragraph">
<p>The use of NULL as a <em>row-value-const</em> element is a Trafodion SQL extension.</p>
</div>
<div class="paragraph">
<p>A <em>simple-table</em> can be specified by using the TABLE keyword followed by a table name, which is equivalent to the
query specification SELECT * FROM <em>table</em>.</p>
</div>
<div class="paragraph">
<p>A <em>simple-table</em> can be a <em>query-specification</em>—that is, a SELECT statement consisting of SELECT &#8230; FROM &#8230; with
optionally the WHERE, SAMPLE, TRANSPOSE, SEQUENCE BY, GROUP BY, and HAVING clauses.</p>
</div>
</li>
<li>
<p><code>WHERE <em>search-condition</em></code></p>
<div class="paragraph">
<p>specifies a <em>search-condition</em> for selecting rows. See <a href="#search_condition">Search Condition</a>. The WHERE clause
cannot contain an aggregate (set) function.</p>
</div>
<div class="paragraph">
<p>The <em>search-condition</em> is applied to each row of the result table derived from the table reference in the FROM clause
or, in the case of multiple table references, the cross-product of result tables derived from the individual table references.</p>
</div>
<div class="paragraph">
<p>Each column you specify in <em>search-condition</em> is typically a column in this intermediate result table. In the case of nested
subqueries used to provide comparison values, the column can also be an outer reference. See<a href="#subquery">Subquery</a>.</p>
</div>
<div class="paragraph">
<p>To comply with ANSI standards, Trafodion SQL does not move aggregate predicates from the WHERE clause to a HAVING clause and
does not move non-aggregate predicates from the HAVING clause to the WHERE clause.</p>
</div>
</li>
<li>
<p><code>SAMPLE <em>sampling-method</em></code></p>
<div class="paragraph">
<p>specifies the sampling method used to select a subset of the intermediate result table of a SELECT statement. Each of the
methods uses a sampling size. The three sampling methods—random, first, and periodic—are specified as:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>RANDOM <em>percent-size</em></code></p>
<div class="paragraph">
<p>directs Trafodion SQL to choose rows randomly (each row having an unbiased probability of being chosen) without replacement
from the result table. The sampling size is determined by using a percent of the result table.</p>
</div>
</li>
<li>
<p><code>FIRST <em>rows-size</em> [SORT BY <em>colname</em> [,<em>colname</em>]&#8230;]</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to choose the first <em>rows-size</em> rows from the sorted result table. The sampling size is determined
by using the specified number of rows.</p>
</div>
</li>
<li>
<p><code>PERIODIC <em>rows-size</em> EVERY <em>number-rows</em> ROWS [SORT BY <em>colname</em> [,<em>colname</em>] &#8230;]</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to choose the first rows from each block (period) of contiguous sorted rows. The sampling size is
determined by using the specified number of rows chosen from each block.</p>
</div>
</li>
<li>
<p>SAMPLE is a Trafodion SQL extension. See <a href="#sample_clause">SAMPLE Clause</a>.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>TRANSPOSE <em>transpose-set</em>[<em>transpose-set</em>]&#8230; [KEY BY <em>key-colname</em>]</code></p>
<div class="paragraph">
<p>specifies the <em>transpose-sets</em> and an optional key clause within a TRANSPOSE clause. You can use multiple TRANSPOSE
clauses in a SELECT statement.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>transpose-item-list</em> AS <em>transpose-col-list</em></code></p>
<div class="paragraph">
<p>specifies a <em>transpose-set.</em> You can use multiple transpose sets within a TRANSPOSE clause. The TRANSPOSE clause generates,
for each row of the source table derived from the table reference or references in the FROM clause, a row for each item in
each <em>transpose-item-list</em> of all the transpose sets.</p>
</div>
<div class="paragraph">
<p>The result table of a TRANSPOSE clause has all the columns of the source table plus a value column or columns, as specified
in each <em>transpose-col-list</em> of all the transpose sets, and an optional key column <em>key-colname</em>.</p>
</div>
</li>
<li>
<p><code>KEY BY <em>key-colname</em></code></p>
<div class="paragraph">
<p>optionally specifies an optional key column <em>key-colname</em>. It identifies which expression the value in the transpose column
list corresponds to by its position in the <em>transpose-item-list</em>. <em>key-colname</em> is an SQL identifier. The data type is exact
numeric, and the value is NOT NULL.</p>
</div>
</li>
<li>
<p>TRANSPOSE is a Trafodion SQL extension. See <a href="#transpose_clause">TRANSPOSE Clause</a>.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>SEQUENCE BY <em>colname</em> [ASC[ENDING] | DESC[ENDING]] [,<em>colname</em> [ASC[ENDING] | DESC[ENDING]]] &#8230;</code></p>
<div class="paragraph">
<p>specifies the order in which to sort the rows of the intermediate result table for calculating sequence functions. You must
include a SEQUENCE BY clause if you include a sequence function in <em>select-list</em>. Otherwise, Trafodion SQL returns an error.
Further, you cannot include a SEQUENCE BY clause if no sequence function is in <em>select-list</em>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>colname</em></code></p>
<div class="paragraph">
<p>names a column in <em>select-list</em> or a column in a table reference in the FROM clause of the SELECT statement. <em>colname</em> is
optionally qualified by a table, view, or correlation name; for example, CUSTOMER.CITY.</p>
</div>
</li>
<li>
<p><code>ASC | DESC</code></p>
<div class="paragraph">
<p>specifies the sort order. The default is ASC. When Trafodion SQL orders an intermediate result table on a column that can
contain null, nulls are considered equal to one another but greater than all other non-null values.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>GROUP BY [<em>col-expr</em>] {<em>colname</em> | <em>colnum</em>} [,{<em>colname</em> | <em>colnum</em>}]&#8230;]</code></p>
<div class="paragraph">
<p>specifies grouping columns that define a set of groups for the result table of the SELECT statement. The expression in the
GROUP BY clause must be exactly the same as the expression in the select list. These columns must appear in the list of
columns in the table references in the FROM clause of the SELECT statement.</p>
</div>
<div class="paragraph">
<p>If you include a GROUP BY clause, the columns you refer to in the <em>select-list</em> must be grouping columns or arguments of
an aggregate (or set) function.</p>
</div>
<div class="paragraph">
<p>The grouping columns define a set of groups in which each group consists of rows with identical values in the specified
columns. The column names can be qualified by a table or view name or a correlation name; for example, CUSTOMER.CITY.</p>
</div>
<div class="paragraph">
<p>For example, if you specify AGE, the result table contains one group of rows with AGE equal to 40 and one group of rows
with AGE equal to 50. If you specify AGE and then JOB, the result table contains one group for each age and, within each
age group, subgroups for each job code.</p>
</div>
<div class="paragraph">
<p>You can specify GROUP BY using ordinals to refer to the relative position within the SELECT list. For example, GROUP BY 3, 2, 1.</p>
</div>
<div class="paragraph">
<p>For grouping purposes, all nulls are considered equal to one another. The result table of a GROUP BY clause can have only
one null group. See <a href="#considerations_for_group_by">Considerations for GROUP BY</a>.</p>
</div>
</li>
<li>
<p><code>HAVING <em>search-condition</em></code></p>
<div class="paragraph">
<p>specifies a <em>search-condition</em> to apply to each group of the grouped table resulting from the preceding GROUP BY clause
in the SELECT statement.</p>
</div>
<div class="paragraph">
<p>To comply with ANSI standards, Trafodion SQL does not move aggregate predicates from the WHERE clause to a HAVING clause
and does not move non-aggregate predicates from the HAVING clause to the WHERE clause.</p>
</div>
<div class="paragraph">
<p>If no GROUP BY clause exists, the <em>search-condition</em> is applied to the entire table (which consists of one group) resulting
from the WHERE clause (or the FROM clause if no WHERE clause exists).</p>
</div>
<div class="paragraph">
<p>In <em>search-condition</em>, you can specify any column as the argument of an aggregate (or set) function; for example, AVG (SALARY).
An aggregate function is applied to each group in the grouped table.</p>
</div>
<div class="paragraph">
<p>A column that is not an argument of an aggregate function must be a grouping column. When you refer to a grouping column,
you are referring to a single value because each row in the group contains the same value in the grouping column.
See <a href="#search_condition">Search Condition</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>[FOR] <em>access-option</em> ACCESS</code></p>
<div class="paragraph">
<p>specifies the <em>access-option</em> when accessing data specified by the SELECT statement or by a table reference in the FROM
clause derived from the evaluation of a query expression that is a SELECT statement.
See <a href="#data_consistency_and_access_options">Data Consistency and Access Options</a>.</p>
</div>
</li>
<li>
<p><code>READ COMMITTED</code></p>
<div class="paragraph">
<p>specifies that any data accessed must be from committed rows.</p>
</div>
</li>
<li>
<p><code>UNION [ALL] <em>select-stmt</em></code></p>
<div class="paragraph">
<p>specifies a set union operation between the result table of a SELECT statement and the result table of another SELECT statement.</p>
</div>
<div class="paragraph">
<p>The result of the union operation is a table that consists of rows belonging to either of the two contributing tables. If
you specify UNION ALL, the table contains all the rows retrieved by each SELECT statement. Otherwise, duplicate rows are removed.</p>
</div>
<div class="paragraph">
<p>The select lists in the two SELECT statements of a union operation must have the same number of columns, and columns in
corresponding positions within the lists must have compatible data types. The select lists must not be preceded by
[ANY <em>N</em>] or [FIRST N].</p>
</div>
<div class="paragraph">
<p>The number of columns in the result table of the union operation is the same as the number of columns in each select list.
The column names in the result table of the union are the same as the corresponding names in the select list of the left
SELECT statement. A column resulting from the union of expressions or constants has the name (EXPR).
See <a href="#considerations_for_union">Considerations for UNION</a>.</p>
</div>
</li>
<li>
<p><code><em>select-stmt</em> INTERSECT <em>select-stmt</em></code></p>
<div class="paragraph">
<p>specifies a set intersect operation between the result table of a SELECT statement and the result table of another SELECT statement.
The result of the intersect operation is a table that consists of rows appear in both result sets.</p>
</div>
<div class="paragraph">
<p>The result of INTERSECT does not contain any duplicate rows.</p>
</div>
<div class="paragraph">
<p>The select lists in the two SELECT statements of an intersect operation must have the same number of columns, and columns in
corresponding positions within the lists must have compatible data types. The select lists must not be preceded by
[ANY <em>N</em>] or [FIRST N].</p>
</div>
</li>
<li>
<p><code><em>select-stmt</em> EXCEPT <em>select-stmt</em></code></p>
<div class="paragraph">
<p>specifies a set except operation between the result table of a SELECT statement and the result table of another SELECT statement.
The result of the except operation is a table that consists of rows that are in the result of the left SELECT statement but not in
the result of the right one.</p>
</div>
<div class="paragraph">
<p>The result of EXCEPT does not contain any duplicate rows.</p>
</div>
<div class="paragraph">
<p>The select lists in the two SELECT statements of an except operation must have the same number of columns, and columns in
corresponding positions within the lists must have compatible data types. The select lists must not be preceded by
[ANY <em>N</em>] or [FIRST N].</p>
</div>
</li>
<li>
<p><code>ORDER BY {<em>colname</em> | <em>colnum</em>} [ASC[ENDING] | DESC[ENDING]] [,{<em>colname</em> | <em>colnum</em>} [ASC[ENDING] | DESC[ENDING]]]&#8230;</code></p>
<div class="paragraph">
<p>specifies the order in which to sort the rows of the final result table.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>colname</em></code></p>
<div class="paragraph">
<p>names a column in <em>select-list</em> or a column in a table reference in the FROM clause of the SELECT statement.
<em>colname</em> is optionally qualified by a table, view, or correlation name; for example, CUSTOMER.CITY. If a
column has been aliased to another name you must use the alias name.</p>
</div>
</li>
<li>
<p><code><em>colnum</em></code></p>
<div class="paragraph">
<p>specifies a column by its position in <em>select-list</em>. Use <em>colnum</em> to refer to unnamed columns, such as derived columns.</p>
</div>
</li>
<li>
<p><code>ASC | DESC</code></p>
<div class="paragraph">
<p>specifies the sort order. The default is ASC. For ordering a result table on a column that can contain null, nulls are
considered equal to one another but greater than all other non-null values.</p>
</div>
<div class="paragraph">
<p>See <a href="#considerations_for_order_by">Considerations for ORDER BY</a>.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>LIMIT <em>num</em></code></p>
<div class="paragraph">
<p>limits the number of rows returned by the query with no limit applied if <em>num</em> is null or less than zero. The LIMIT
clause is executed after the ORDER BY clause to support TopN queries.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="select_considerations">3.47.2. Considerations for SELECT</h4>
<div class="sect4">
<h5 id="select_authorization_requirements">Authorization Requirements</h5>
<div class="paragraph">
<p>SELECT requires authority to read all views and tables referred to in the statement, including the underlying tables
of views referred to in the statement.</p>
</div>
</div>
<div class="sect4">
<h5 id="select_use_of_views_with_select">Use of Views With SELECT</h5>
<div class="paragraph">
<p>When a view is referenced in a SELECT statement, the specification that defines the view is combined with the statement.
The combination can cause the SELECT statement to be invalid. If you receive an error message that indicates a problem
but the SELECT statement seems to be valid, check the view definition.</p>
</div>
<div class="paragraph">
<p>For example, suppose that the view named AVESAL includes column A defined as AVG (X). The SELECT statement that
contains MAX (A) in its select list is invalid because the select list actually contains MAX (AVG (X)), and an aggregate
function cannot have an argument that includes another aggregate function.</p>
</div>
</div>
<div class="sect4">
<h5 id="select_join_limits">Join Limits</h5>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
We recommend that you limit the number of tables in a join to a maximum of 64, which includes base tables of views
referenced in joins. Queries with joins that involve a larger number of tables are not guaranteed to compile.
</td>
</tr>
</table>
</div>
</div>
<div class="sect4">
<h5 id="select_object_names_in_select">Object Names in SELECT</h5>
<div class="paragraph">
<p>You can use fully qualified names only in the FROM clause of a SELECT statement.</p>
</div>
</div>
<div class="sect4">
<h5 id="select_as_and_order_by_conflicts">AS and ORDER BY Conflicts</h5>
<div class="paragraph">
<p>When you use the AS verb to rename a column in a SELECT statement, and the ORDER BY clause uses the original column name,
the query fails. If a column has been aliased to another name, you must use the alias name. The ANSI standard does not
support this type of query.</p>
</div>
</div>
<div class="sect4">
<h5 id="select_restrictions_on_embedded_inserts">Restrictions on Embedded Inserts</h5>
<div class="ulist">
<ul>
<li>
<p>An embedded INSERT cannot be used in a join.</p>
</li>
<li>
<p>An embedded INSERT cannot appear in a subquery.</p>
</li>
<li>
<p>An embedded INSERT statement cannot have a subquery in the WHERE clause.</p>
</li>
<li>
<p>An INSERT statement cannot contain an embedded INSERT statement.</p>
</li>
<li>
<p>A union between embedded INSERT expressions is not supported.</p>
</li>
<li>
<p>Declaring a cursor on an embedded INSERT statement is not supported.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="select_distinct_aggregate_functions">DISTINCT Aggregate Functions</h5>
<div class="paragraph">
<p>An aggregate function can accept an argument specified as DISTINCT, which eliminates duplicate values before the aggregate
function is applied. For a given grouping, multiple DISTINCT aggregates are allowed and can be used with non distinct aggregates.
A restriction exists that DISTINCT STDDEV and VARIANCE cannot be used with multiple DISTINCT aggregates.</p>
</div>
</div>
<div class="sect4">
<h5 id="select_limitations_of_distinct_aggregates">Limitations of DISTINCT Aggregates</h5>
<div class="ulist">
<ul>
<li>
<p>No limit exists to the number of distinct aggregates.</p>
</li>
<li>
<p>Distinct STDDEV and distinct VARIANCE are not supported with multiple distinct aggregates. For example, this statement will
result in an error.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT sum(distinct a), stddev(distinct b) from T group by d;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="select_examples_of_multiple_distinct_aggregates">Examples of Multiple Distinct Aggregates</h5>
<div class="ulist">
<ul>
<li>
<p>This statement contains distinct aggregates:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT sum(distinct a), count(distinct b), avg(distinct c) from T group by d;</code></pre>
</div>
</div>
</li>
<li>
<p>This statement does not contain multiple distincts. Because each distinct aggregate is on the same column (a), this is
treated as one distinct value.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT sum(distinct a), count(distinct a), avg(distinct a) from T group by d;</code></pre>
</div>
</div>
</li>
<li>
<p>This statement shows that multiple distinct aggregates can be used with non distinct aggregates:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT sum(distinct a), avg(distinct b), sum(c) from T group by d;</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="select_considerations_for_with-clause">Considerations for with-clause</h5>
<div class="ulist">
<ul>
<li>
<p>Materialization of CTEs in temporary tables is not yet enabled by default.</p>
</li>
<li>
<p>Trafodion only supports non-recursive common table expressions, which means with-clause cannot be self-referencing, but it can reference a previously defined CTE within the same with-clause.</p>
</li>
<li>
<p>The with-clause in Trafodion can be specified only once, at the beginning of a SELECT statement. INSERT, UPDATE, DELETE and CREATE VIEW statements are not supported yet.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="select_considerations_for_select_list">Considerations for Select List</h5>
<div class="ulist">
<ul>
<li>
<p>The * and <em>corr</em>.* forms of a <em>select-list</em> specification are convenient. However, such specifications make the order
of columns in the SELECT result table dependent on the order of columns in the current definition of the referenced tables
or views.</p>
</li>
<li>
<p>A <em>col-expr</em> is a single column name or a derived column. A derived column is an SQL value expression; its operands can
be numeric, string, datetime, or interval literals, columns, functions (including aggregate unctions) defined on columns,
scalar subqueries, CASE expressions, or CAST expressions. Any single columns named in <em>col-expr</em> must be from tables or views
specified in the FROM clause. For a list of aggregate functions, see <a href="#aggregate_functions">Aggregate (Set) Functions</a>.</p>
</li>
<li>
<p>If <em>col-expr</em> is a single column name, that column of the SELECT result table is a named column. All other columns are
unnamed columns in the result table (and have the (EXPR) heading) unless you use the AS clause to specify a name for a
derived column.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="select_considerations_for_group_by">Considerations for GROUP BY</h5>
<div class="ulist">
<ul>
<li>
<p>If you include a GROUP BY clause, the columns you refer to in the <em>select-list</em> must be either grouping columns or
arguments of an aggregate (or set) function. For example, if AGE is not a grouping column, you can refer to AGE only
as the argument of a function, such as AVG (AGE).</p>
</li>
<li>
<p>The expression in the GROUP BY clause must be exactly the same as the expression in the select list. An error will
be returned if it is not. It cannot contain aggregate functions or subqueries.</p>
</li>
<li>
<p>If the value of <em>col-expr</em> is a numeric constant, it refers to the position of the select list item and is treated
as the current GROUP BY using the ordinal feature.</p>
</li>
<li>
<p>You can specify GROUP BY using ordinals to refer to the relative position within the SELECT list. For example,
GROUP BY 3, 2, 1.</p>
</li>
<li>
<p>If you do not include a GROUP BY clause but you specify an aggregate function in the <em>select-list</em>, all rows of the
result table form the one and only group. The result of AVG, for example, is a single value for the entire table.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="select_considerations_for_order_by">Considerations for ORDER BY</h5>
<div class="paragraph">
<p>When you specify an ORDER BY clause and its ordering columns, consider:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>ORDER BY is allowed only in the outer level of a query or in the SELECT part of an INSERT/SELECT statement. It is not
allowed inside nested SELECT expressions, such as subqueries.</p>
</li>
<li>
<p>If you specify DISTINCT, the ordering column must be in <em>select-list</em>.</p>
</li>
<li>
<p>If you specify a GROUP BY clause, the ordering column must also be a grouping column.</p>
</li>
<li>
<p>If an ORDER BY clause applies to a union of SELECT statements, the ordering column must be explicitly referenced, and
not within an aggregate function or an expression, in the <em>select-list</em> of the leftmost SELECT statement.</p>
</li>
<li>
<p>SQL does not guarantee a specific or consistent order of rows unless you specify an ORDER BY clause. ORDER BY can
reduce performance, however, so use it only if you require a specific order.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="_considerations_for_union">Considerations for UNION</h5>
<div class="paragraph">
<p>Suppose that the contributing SELECT statements are named SELECT1 and SELECT2, the contributing tables resulting from
the SELECT statements are named TABLE1 and TABLE2, and the table resulting from the UNION operation is named RESULT.</p>
</div>
<div class="sect5">
<h6 id="select_characteristics_of_the_union_columns">Characteristics of the UNION Columns</h6>
<div class="paragraph">
<p>For columns in TABLE1 and TABLE2 that contribute to the RESULT table:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>If both columns contain character strings, the corresponding column in RESULT contains a character string whose length
is equal to the greater of the two contributing columns.</p>
</li>
<li>
<p>If both columns contain variable-length character strings, RESULT contains a variable-length character string whose
length is equal to the greater of the two contributing columns.</p>
</li>
<li>
<p>If both columns are of exact numeric data types, RESULT contains an exact numeric value whose precision and scale are
equal to the greater of the two contributing columns.</p>
</li>
<li>
<p>If both columns are of approximate numeric data types, RESULT contains an approximate numeric value whose precision is
equal to the greater of the two contributing columns.</p>
</li>
<li>
<p>If both columns are of datetime data type (DATE, TIME, or TIMESTAMP), the corresponding column in RESULT has the same data type.</p>
</li>
<li>
<p>If both columns are INTERVAL data type and both columns are year-month or day-time, RESULT contains an INTERVAL value
whose range of fields is the most significant start field to the least significant end field of the INTERVAL fields in the
contributing columns. (The year-month fields are YEAR and MONTH. The day-time fields are DAY, HOUR, MINUTE, and SECOND.)</p>
<div class="paragraph">
<p>For example, suppose that the column in TABLE1 has the data type INTERVAL HOUR TO MINUTE, and the column in TABLE2 has the
data type INTERVAL DAY TO HOUR. The data type of the column resulting from the union operation is INTERVAL DAY TO MINUTE.</p>
</div>
</li>
<li>
<p>If both columns are described with NOT NULL, the corresponding column of RESULT cannot be null. Otherwise, the column can be null.</p>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="select_order_by_clause_and_the_union_operator">ORDER BY Clause and the UNION Operator</h6>
<div class="paragraph">
<p>In a query containing a UNION operator, the ORDER BY clause defines an ordering on the result of the union. In this case,
the SELECT statement cannot have an individual ORDER BY clause.</p>
</div>
<div class="paragraph">
<p>You can specify an ORDER BY clause only as the last clause following the final SELECT statement (SELECT2 in this example).
The ORDER BY clause in RESULT specifies the ordinal position of the sort column either by using an integer or by using the
column name from the select list of SELECT1.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>This SELECT statement shows correct use of the ORDER BY clause:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT A FROM T1 UNION SELECT B FROM T2 ORDER BY A</code></pre>
</div>
</div>
</li>
<li>
<p>This SELECT statement is incorrect because the ORDER BY clause does not follow the final SELECT statement:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT A FROM T1 ORDER BY A UNION SELECT B FROM T2</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This SELECT statement is also incorrect:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT A FROM T1 UNION (SELECT B FROM T2 ORDER BY A)</code></pre>
</div>
</div>
<div class="paragraph">
<p>Because the subquery (SELECT B FROM T2&#8230;) is processed first, the ORDER BY clause does not follow the final SELECT.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="select_group_by_clause_having_clause_and_the_union_operator">GROUP BY Clause, HAVING Clause, and the UNION Operator</h6>
<div class="paragraph">
<p>In a query containing a UNION operator, the GROUP BY or HAVING clause is associated with the SELECT statement it is a
part of (unlike the ORDER BY clause, which can be associated with the result of a union operation). The groups are visible
in the result table of the particular SELECT statement. The GROUP BY and HAVING clauses cannot be used to form groups in
the result of a union operation.</p>
</div>
</div>
<div class="sect5">
<h6 id="select_union_all_and_associativity">UNION ALL and Associativity</h6>
<div class="paragraph">
<p>The UNION ALL operation is left associative, meaning that these two queries return the same result:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(SELECT * FROM TABLE1 UNION ALL
SELECT * FROM TABLE2) UNION ALL SELECT * FROM TABLE3;
SELECT * FROM TABLE1 UNION ALL
(SELECT * FROM TABLE2 UNION ALL SELECT * FROM TABLE3);</code></pre>
</div>
</div>
<div class="paragraph">
<p>If both the UNION ALL and UNION operators are present in the query, the order of evaluation is always from left to right.
A parenthesized union of SELECT statements is evaluated first, from left to right, followed by the remaining union of SELECT statements.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="select_examples">3.47.3. Examples of SELECT</h4>
<div class="ulist">
<ul>
<li>
<p>The following example defines two CTEs, w1 and w2. w2 references w1 which is defined before w2.</p>
</li>
</ul>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;select * from t1
C1 C2
----------
1 1
2 2
3 3
4 4
5 5
--- SQL operation complete.
&gt;&gt;with w1 as (select * from t1),
&gt;&gt;w2 as (select * from w1)
&gt;&gt;select * from w2;
C1 C2
----------
1 1
2 2
3 3
4 4
5 5
--- SQL operation complete.</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p>The following example defines two CTEs, w1 and w2, and then perform a JOIN between them.</p>
</li>
</ul>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;select * from t1
C1 C2
----------
1 1
2 2
3 3
4 4
5 5
--- SQL operation complete.
&gt;&gt;select * from t2
C1 C2
----------
3 3
4 4
5 5
6 6
7 7
--- SQL operation complete.
&gt;&gt;with w1 as (select c1, c2 from t1),
&gt;&gt;w2 as (select c1, c2 from t2)
&gt;&gt;select * from w1, w2 where w1.c1 = w2.c1;
C1 C2 C1 C2
----------
3 3 3 3
4 4 4 4
5 5 5 5
--- SQL operation complete.</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p>Retrieve information from the EMPLOYEE table for employees with a job code greater than 500 and who are in departments
with numbers less than or equal to 3000, displaying the results in ascending order by job code:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT jobcode, deptnum, first_name, last_name, salary
FROM persnl.employee
WHERE jobcode &gt; 500
AND deptnum &lt;= 3000
ORDER BY jobcode;
DEPTNUM FIRST_NAME LAST_NAME SALARY
------- --------------- ----------- ----------
1500 JONATHAN MITCHELL 32000.00
1500 JIMMY SCHNEIDER 26000.00
2500 MIRIAM KING 18000.00
1000 SUE CRAMER 19000.00
. . .</code></pre>
</div>
</div>
</li>
<li>
<p>Display selected rows grouped by job code in ascending order:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT jobcode, AVG(salary)
FROM persnl.employee
WHERE jobcode &gt; 500
AND deptnum &lt;= 3000
GROUP BY jobcode
ORDER BY jobcode;
JOBCODE EXPR
------- ----------------------
600 29000.00
900 25100.00
--- 2 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>This select list contains only grouping columns and aggregate functions. Each row of the output summarizes the
selected data within one group.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Select data from more than one table by specifying the table names in the FROM clause and specifying the
condition for selecting rows of the result in the WHERE clause:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT jobdesc, first_name, last_name, salary
FROM persnl.employee E, persnl.job J
WHERE E.jobcode = J.jobcode
AND E.jobcode IN (900, 300, 420);
JOBDESC FIRST_NAME LAST_NAME SALARY
------------ ------------ --------------- -----------
SALESREP TIM WALKER 32000.00
SALESREP HERBERT KARAJAN 29000.00
...
ENGINEER MARK FOLEY 33000.00
ENGINEER MARIA JOSEF 18000.10
...
SECRETARY BILL WINN 32000.00
SECRETARY DINAH CLARK 37000.00
...
--- 27 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>This type of condition is sometimes called a join predicate. The query first joins the EMPLOYEE and JOB tables by
combining each row of the EMPLOYEE table with each row of the JOB table; the intermediate result is the Cartesian
product of the two tables.</p>
</div>
<div class="paragraph">
<p>This join predicate specifies that any row (in the intermediate result) with equal job codes is included in the
result table. The WHERE condition further specifies that the job code must be 900, 300, or 420. All other rows
are eliminated.</p>
</div>
<div class="paragraph">
<p>The four logical steps that determine the intermediate and final results of the previous query are:</p>
</div>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>Join the tables.</p>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top" colspan="3">EMPLOYEE Table</th>
<th class="tableblock halign-left valign-top" colspan="2">JOB Table</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>EMPNUM &#8230;</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBCODE &#8230;</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>SALARY</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBCODE</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBDESC</strong></p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</li>
<li>
<p>Drop rows with unequal job codes.</p>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top" colspan="3">EMPLOYEE Table</th>
<th class="tableblock halign-left valign-top" colspan="2">JOB Table</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>EMPNUM &#8230;</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBCODE &#8230;</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>SALARY</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBCODE</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBDESC</strong></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">175500</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MANAGER</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">75</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">32000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SALESREP</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">178</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">900</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">28000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">900</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SECRETARY</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">207</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">420</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">33000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">420</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ENGINEER</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">568</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">39500</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SALESREP</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p>Drop rows with job codes not equal to 900, 300, or 420.</p>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top" colspan="3">EMPLOYEE Table</th>
<th class="tableblock halign-left valign-top" colspan="2">JOB Table</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>EMPNUM &#8230;</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBCODE &#8230;</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>SALARY</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBCODE</strong></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><strong>JOBDESC</strong></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">75</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">32000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SALESREP</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">178</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">900</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">28000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">900</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SECRETARY</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">207</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">420</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">33000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">420</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ENGINEER</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">568</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">39500</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SALESREP</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p>Process the select list, leaving only four columns.</p>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">JOBDESC</th>
<th class="tableblock halign-left valign-top">FIRST_NAME</th>
<th class="tableblock halign-left valign-top">LAST_NAME</th>
<th class="tableblock halign-left valign-top">SALARY</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SALESREP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TIM</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">WALKER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">32000</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SECRETARY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">JOHN</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CHOU</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">28000</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">ENGINEER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MARK</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FOLEY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">33000</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SALESREP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">JESSICA</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CRINER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">39500</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>The final result is shown in the output:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">JOBDESC FIRST_NAME LAST_NAME SALARY
------------ ------------ --------------- -----------
SALESREP TIM WALKER 32000.00
...
SECRETARY JOHN CHOU 28000.00
...</code></pre>
</div>
</div>
</li>
</ol>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Select from three tables, group the rows by job code and (within job code) by department number, and order the
groups by the maximum salary of each group:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT E.jobcode, E.deptnum, MIN (salary), MAX (salary)
FROM persnl.employee E, persnl.dept D, persnl.job J
WHERE E.deptnum = D.deptnum
AND E.jobcode = J.jobcode
AND E.jobcode IN (900, 300, 420)
GROUP BY E.jobcode, E.deptnum
ORDER BY 4;
JOBCODE DEPTNUM (EXPR) (EXPR)
------- ------- ----------- -----------
900 1500 17000.00 17000.00
900 2500 18000.00 18000.00
...
300 3000 19000.00 32000.00
900 2000 32000.00 32000.00
...
300 3200 22000.00 33000.10
420 4000 18000.10 36000.00
...
--- 16 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>Only job codes 300, 420, and 900 are selected. The minimum and maximum salary for the same job in each department
are computed, and the rows are ordered by maximum salary.</p>
</div>
</li>
<li>
<p>Select from two tables that have been joined by using an INNER JOIN on matching part numbers:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT OD.*, P.*
FROM sales.odetail OD
INNER JOIN sales.parts P ON OD.partnum = P.partnum;
Order/Num Part/Num Unit/Price Qty/Ord Part/Num Part Description PRICE Qty/Avail
---------- -------- ------------ ---------- -------- ------------------ ------------ -----------
400410 212 2450.00 12 212 PCSILVER, 20 MB 2500.00 3525
500450 212 2500.00 8 212 PCSILVER, 20 MB 2500.00 3525
100210 244 3500.00 3 244 PCGOLD, 30 MB 3000.00 4426
800660 244 3000.00 6 244 PCGOLD, 30 MB 3000.00 4426
... ... ... ... ... ... ... ...
--- 72 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Select from three tables and display them in employee number order. Two tables are joined by using a LEFT JOIN on matching department
numbers, then an additional table is joined on matching job codes:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT empnum, first_name, last_name, deptname, location, jobdesc
FROM employee e
LEFT JOIN dept d ON e.deptnum = d.deptnum
LEFT JOIN job j ON e.jobcode = j.jobcode
ORDER BY empnum;</code></pre>
</div>
</div>
</li>
<li>
<p>Suppose that the JOB_CORPORATE table has been created from the JOB table by using the CREATE LIKE statement.
Form the union of these two tables:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM job UNION SELECT * FROM job_corporate;
JOBCODE JOBDESC
------- ------------------
100 MANAGER
200 PRODUCTION SUPV
250 ASSEMBLER
300 SALESREP
400 SYSTEM ANALYST
420 ENGINEER
450 PROGRAMMER
500 ACCOUNTANT
600 ADMINISTRATOR
900 SECRETARY
100 CORP MANAGER
300 CORP SALESREP
400 CORP SYSTEM ANALYS
500 CORP ACCOUNTANT
600 CORP ADMINISTRATOR
900 CORP SECRETARY
--- 16 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>A FULL OUTER JOIN combines the results of both left and right outer joins. These joins show records from both tables
and fill in NULLs for missing matches on either side:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT *
FROM employee
FULL OUTER JOIN department
ON employee.DepartmentID = department.DepartmentID;
LastName DepartmentID DepartmentName DepartmentID
-------- ------------ -------------- ------------
Smith 34 Clerical 34
Jones 33 Engineering 33
Robinson 34 Clerical 34
Jasper 36 NULL NULL
Steinberg 33 Engineering 33
Rafferty 31 Sales 31
NULL NULL Marketing 35</code></pre>
</div>
</div>
</li>
<li>
<p>Present two ways to select the same data submitted by customers from California. The first way:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT OD.ordernum, SUM (qty_ordered * price)
FROM sales.parts P, sales.odetail OD
WHERE OD.partnum = P.partnum AND OD.ordernum IN
( SELECT O.ordernum
FROM sales.orders O, sales.customer C
WHERE O.custnum = C.custnum AND state = 'CALIFORNIA'
)
GROUP BY OD.ordernum;
ORDERNUM (EXPR)
---------- ---------------------
200490 1030.00
300350 71025.00
300380 28560.00
--- 3 row(s) selected.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>The second way:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT OD.ordernum, SUM (qty_ordered * price)
FROM sales.parts P, sales.odetail OD
WHERE OD.partnum = P.partnum AND OD.ordernum IN
( SELECT O.ordernum
FROM sales.orders O WHERE custnum IN
( SELECT custnum
FROM sales.customer
WHERE state = 'CALIFORNIA'
)
)
GROUP BY OD.ordernum;
ORDERNUM (EXPR)
---------- ---------------------
200490 1030.00
300350 71025.00
300380 28560.00
--- 3 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The price for the total quantity ordered is computed for each order number.</p>
</div>
</li>
<li>
<p>Show employees, their salaries, and the percentage of the total payroll that their salaries represent.
Note the subquery as part of the expression in the select list:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
empnum
, first_name
, last_name
, salary
, CAST(salary * 100 / ( SELECT SUM(salary) FROM persnl.employee) AS NUMERIC(4,2))
FROM persnl.employee ORDER BY salary, empnum;
Employee/Number First Name Last Name salary (EXPR)
--------------- --------------- -------------------- ----------- -------
209 SUSAN CHAPMAN 17000.00 .61
235 MIRIAM KING 18000.00 .65
224 MARIA JOSEF 18000.10 .65
...
23 JERRY HOWARD 137000.10 4.94
32 THOMAS RUDLOFF 138000.40 4.98
1 ROGER GREEN 175500.00 6.33
...
--- 62 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Examples of using expressions in the GROUP BY clause:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT a+1 FROM t GROUP BY a+1;
SELECT cast(a AS int) FROM t GROUP BY cast(a AS int);
SELECT a+1 FROM t GROUP BY 1;</code></pre>
</div>
</div>
</li>
<li>
<p>Examples of unsupported expressions in the GROUP BY clause:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT sum(a) FROM t GROUP BY sum(a);
SELECT (SELECT a FROM t1) FROM t GROUP BY (SELECT a FROM t1);
SELECT a+1 FROM t GROUP BY 1+a;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="set_schema_statement">3.48. SET SCHEMA Statement</h3>
<div class="paragraph">
<p>The SET SCHEMA statement sets the default logical schema for unqualified object names for the current SQL session.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SET SCHEMA default-schema-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="set_schema_syntax">3.48.1. Syntax Description of SET SCHEMA</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>default-schema-name</em></code></p>
<div class="paragraph">
<p>specifies the name of a schema. See <a href="#schemas">Schemas</a>.</p>
</div>
<div class="paragraph">
<p><em>default-schema-name</em> is an SQL identifier. For example, you can use
MYSCHEMA or myschema or a delimited identifier "My_Schema". See <a href="#identifiers">Identifiers</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="set_schema_considerations">3.48.2. Considerations for SET SCHEMA</h4>
<div class="paragraph">
<p>The default schema you specify with SET SCHEMA remains in effect until the end of the session or until you execute
another SET SCHEMA statement. If you do not set a schema name for the session using SET SCHEMA, the default schema
is SEABASE, which exists in the TRAFODION catalog.</p>
</div>
<div class="paragraph">
<p>For information on how to create a schema, see <a href="#creating_and_dropping_schemas">Creating and Dropping Schemas</a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="set_schema_examples">3.48.3. Examples of SET SCHEMA</h4>
<div class="ulist">
<ul>
<li>
<p>Set the default schema name:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SET SCHEMA myschema;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="set_transaction_statement">3.49. SET TRANSACTION Statement</h3>
<div class="paragraph">
<p>The SET TRANSACTION statement sets the autocommit attribute for transactions. It stays in effect until the end of
the session or until the next SET TRANSACTION statement, whichever comes first. Therefore, the SET TRANSACTION statement
can set the autocommit attribute of all subsequent transactions in the session.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SET TRANSACTION autocommit-option
autocommit-option is:
AUTOCOMMIT [ON] | AUTOCOMMIT OFF</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="set_transaction_syntax">3.49.1. Syntax Description of SET TRANSACTION</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>autocommit-option</em></code></p>
<div class="paragraph">
<p>specifies whether Trafodion SQL commits or rolls back automatically at the end of statement execution. This option
applies to any statement for which the system initiates a transaction.</p>
</div>
<div class="paragraph">
<p>If this option is set to ON, Trafodion SQL automatically commits any changes or rolls back any changes made to the
database at the end of statement execution. AUTOCOMMIT is on by default at the start of a session.</p>
</div>
<div class="paragraph">
<p>If this option is set to OFF, the current transaction remains active until the end of the session unless you explicitly
commit or rollback the transaction. AUTOCOMMIT is a Trafodion SQL extension; you cannot use in it with any other option.</p>
</div>
<div class="paragraph">
<p>Using the AUTOCOMMIT option in a SET TRANSACTION statement does not reset other transaction attributes that may have
been specified in a previous SET TRANSACTION statement. Similarly, a SET TRANSACTION statement that does not specify
the AUTOCOMMIT attribute does not reset this attribute.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="set_transaction_consideration">3.49.2. Considerations for SET TRANSACTION</h4>
<div class="sect4">
<h5 id="set_transaction_implicit_transactions">Implicit Transactions</h5>
<div class="paragraph">
<p>Most DML statements are transaction initiating—the system automatically initiates a transaction when the statement
begins executing.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>The exceptions (statements that are not transaction initiating) are:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>COMMIT, FETCH, ROLLBACK, and SET TRANSACTION</p>
</li>
<li>
<p>EXECUTE, which is transaction initiating only if the associated statement is transaction-initiating</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="set_transaction_explicit_transactions">Explicit Transactions</h5>
<div class="paragraph">
<p>You can issue an explicit BEGIN WORK even if the autocommit option is on. The autocommit option is temporarily disabled
until you explicitly issue COMMIT or ROLLBACK.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="set_transaction_examples">3.49.3. Examples of SET TRANSACTION</h4>
<div class="ulist">
<ul>
<li>
<p>The following SET TRANSACTION statement turns off autocommit so that the current transaction remains active until the
end of the session unless you explicitly commit or rollback the transaction. Trafodion SQL does not automatically commit
or roll back any changes made to the database at the end of statement execution. Instead, Trafodion SQL commits all the
changes when you issue the COMMIT WORK statement.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SET TRANSACTION AUTOCOMMIT OFF;
--- SQL operation complete.
BEGIN WORK;
--- SQL operation complete.
DELETE FROM persnl.employee WHERE empnum = 23;
--- 1 row(s) deleted.
INSERT INTO persnl.employee
(empnum, first_name, last_name, deptnum, salary)
VALUES (50, 'JERRY','HOWARD', 1000, 137000.00);
--- 1 row(s) inserted.
UPDATE persnl.dept SET manager = 50
WHERE deptnum = 1000;
--- 1 row(s) updated.
COMMIT WORK;
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="showcontrol_statement">3.50. SHOWCONTROL Statement</h3>
<div class="paragraph">
<p>The SHOWCONTROL statement displays the default attributes in effect.</p>
</div>
<div class="paragraph">
<p>SHOWCONTROL is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWCONTROL {ALL | [QUERY] DEFAULT [attribute-name[, MATCH {FULL | PARTIAL }]]}</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="showcontrol_syntax">3.50.1. Syntax Description of SHOWCONTROL</h4>
<div class="ulist">
<ul>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>displays all the hard-coded default attributes that have been set for the Trafodion instance.</p>
</div>
</li>
<li>
<p><code>[QUERY] DEFAULT</code></p>
<div class="paragraph">
<p>displays the CONTROL QUERY DEFAULT statements in effect for the session. For more information,
see the <a href="#control_query default_statement">Control Query Default Statement</a>.</p>
</div>
</li>
<li>
<p><code><em>attribute-name</em>[, MATCH {FULL | PARTIAL }]</code></p>
<div class="paragraph">
<p>displays only the defaults that match, either fully or partially, the <em>attribute</em> used in CONTROL QUERY DEFAULT
statements. The match is not case-sensitive. For descriptions of these attributes, see the
<a href="http://trafodion.incubator.apache.org/docs/cqd_reference/index.html">Trafodion Control Query Default (CQD) Reference Guide</a>.</p>
</div>
<div class="paragraph">
<p>MATCH FULL specifies that <em>attribute-name</em> must be the same as the attribute name used in a control query default
statement. match partial specifies that <em>attribute-name</em> must be included in the attribute name used in a control
query default statement. the default is match partial.</p>
</div>
<div class="paragraph">
<p>If <em>attribute-name</em> is a reserved word, such as MIN, MAX, or TIME, you must capitalize <em>attribute-name</em> and delimit
it within double quotes ("). The only exceptions to this rule are the reserved words CATALOG and SCHEMA, which you
can either capitalize and delimit within double quotes or specify without quotation marks.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="showcontrol_examples">3.50.2. Examples of SHOWCONTROL</h4>
<div class="ulist">
<ul>
<li>
<p>Issue multiple CONTROL QUERY DEFAULT statements followed by a SHOWCONTROL DEFAULT command:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CONTROL QUERY DEFAULT CACHE_HISTOGRAMS_REFRESH_INTERVAL '7200';
--- SQL operation complete.
CONTROL QUERY DEFAULT HIST_NO_STATS_REFRESH_INTERVAL '7200';
--- SQL operation complete.
SHOWCONTROL DEFAULT;
CONTROL QUERY DEFAULT
CACHE_HISTOGRAMS_REFRESH_INTERVAL 7200
HIST_NO_STATS_REFRESH_INTERVAL 7200
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="showddl_statement">3.51. SHOWDDL Statement</h3>
<div class="paragraph">
<p>The SHOWDDL statement describes the DDL syntax used to create an object as it exists in the metadata, or it returns
a description of a user, role, or component in the form of a GRANT statement.</p>
</div>
<div class="paragraph">
<p>SHOWDDL is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWDDL showddl-spec
showddl-spec
[TABLE | LIBRARY | PROCEDURE] [schema-name.]object-name[, PRIVILEGES ]
| COMPONENT component-name
| USER database-username
| ROLE role-name[, GRANTEES ]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="showddl_syntax">3.51.1. Syntax Description of SHOWDDL</h4>
<div class="ulist">
<ul>
<li>
<p><code><em class="_schema-name_.">object-name</em></code></p>
<div class="paragraph">
<p>specifies the ANSI name of an existing table, view, library, or procedure.
See <a href="#database_object_names">Database Object Names</a>. If <em>object-name</em> is not fully qualified, SHOWDDL
uses the default schema for the session.</p>
</div>
</li>
<li>
<p><code>PRIVILEGES</code></p>
<div class="paragraph">
<p>describes the PRIVILEGES associated with the object. If specified, privileges are displayed for an object
in the form of GRANT statements.</p>
</div>
</li>
<li>
<p><code><em>component-name</em></code></p>
<div class="paragraph">
<p>specifies an existing component. Currently, the only valid component name is SQL_OPERATIONS.</p>
</div>
</li>
<li>
<p><code><em>database-username</em></code></p>
<div class="paragraph">
<p>specifies a registered database username.</p>
</div>
</li>
<li>
<p><code><em>role-name</em></code></p>
<div class="paragraph">
<p>specifies an existing role.</p>
</div>
</li>
<li>
<p><code>GRANTEES</code></p>
<div class="paragraph">
<p>displays all users who have been granted the role in the form of GRANT ROLE statements. This is an optional clause.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="showddl_considerations">3.51.2. Considerations for SHOWDDL</h4>
<div class="ulist">
<ul>
<li>
<p>SHOWDDL can differ from the original DDL used to create an object.</p>
</li>
<li>
<p>SHOWDDL can be used within TrafCI.</p>
</li>
<li>
<p>SHOWDDL [TABLE \| LIBRARY \| PROCEDURE] displays the following information:</p>
<div class="ulist">
<ul>
<li>
<p>A constraint may be disabled.</p>
</li>
<li>
<p>A table may be off line.</p>
</li>
<li>
<p>An active DDL lock may exist on an object.</p>
</li>
</ul>
</div>
</li>
<li>
<p>SHOWDDL USER displays user information as a REGISTER USER statement.</p>
</li>
<li>
<p>SHOWDDL ROLE displays the role information as a CREATE ROLE statement.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="showddl_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a SHOWDDL statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the database object.</p>
</li>
<li>
<p>You have the SHOW component privilege for the SQL_OPERATIONS component.
The SHOW component privilege is granted to PUBLIC by default.</p>
</li>
<li>
<p>You have the SELECT privilege on the target object.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="showddl_differences_between_showddl_output_and_original_ddl">Differences Between SHOWDDL Output and Original DDL</h5>
<div class="ulist">
<ul>
<li>
<p>All column constraints (NOT NULL, PRIMARY KEY, and CHECK) are transformed into table constraints.
All NOT NULL constraints are consolidated into a single check constraint.</p>
</li>
<li>
<p>Check constraints are moved out of the CREATE TABLE statement and encapsulated in a separate ALTER TABLE ADD CONSTRAINT
statement.</p>
</li>
<li>
<p>SHOWDDL generates ALTER TABLE ADD COLUMN statements for each column that was added to the table.</p>
</li>
<li>
<p>All ANSI names in the output are qualified with the schema name.</p>
</li>
<li>
<p>SHOWDDL displays constraint names even though they might not have been specified during the creation of the constraint.</p>
</li>
<li>
<p>SHOWDDL always generates a Java signature for the SPJ.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="showddl_privileges_option">PRIVILEGES Option</h5>
<div class="paragraph">
<p>The PRIVILEGES option includes the GRANT statements as they apply to the option. Each privilege is specified in
separate GRANT statements even if they were granted in a single statement.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="showddl_examples">3.51.3. Examples of SHOWDDL</h4>
<div class="ulist">
<ul>
<li>
<p>This SHOWDDL statement displays the statement that created the specified table in the database and the privileges
granted on that table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;showddl tab41;
CREATE TABLE TRAFODION.SCH41.TAB41 (
A INT DEFAULT NULL
, B INT DEFAULT NULL
)
;
-- GRANT DELETE, INSERT, SELECT, UPDATE, REFERENCES ON TRAFODION.&quot;SCH41&quot;.&quot;TAB41&quot; TO PAULLOW41 WITH GRANT OPTION;
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>This SHOWDDL statement displays the statement that registered the specified user in the database:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;showddl user sqluser_admin;
REGISTER USER &quot;SQLUSER_ADMIN&quot;;
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>This SHOWDDL statement displays the statement that created the specified role in the database and the users who
have been granted this role:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;showddl role db rootrole;
CREATE ROLE &quot;DB ROOTROLE&quot;;
SHOWDDL Statement 161
-- GRANT ROLE &quot;DB ROOTROLE&quot; TO &quot;DB ROOT&quot; WITH ADMIN OPTION;
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="showddl_schema_statement">3.52. SHOWDDL SCHEMA Statement</h3>
<div class="paragraph">
<p>The SHOWDDL SCHEMA statement displays the DDL syntax used to create a schema as it exists in the metadata and shows
the authorization ID that owns the schema.</p>
</div>
<div class="paragraph">
<p>SHOWDDL SCHEMA is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWDDL SCHEMA [catalog-name.]schema-name</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="showddl_schema_syntax">3.52.1. Syntax Description for SHOWDDL SCHEMA</h4>
<div class="ulist">
<ul>
<li>
<p><code><em class="_catalog-name_.">schema-name</em></code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>specifies the ANSI name of an existing catalog and schema. If <em>schema-name</em> is not fully qualified, SHOWDDL uses the default catalog
for the session, TRAFODION. For more information, see <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="showddl_schema_considerations">3.52.2. Considerations for SHOWDDL SCHEMA</h4>
<div class="paragraph">
<p>If not specified, the catalog is the current default catalog, TRAFODION.</p>
</div>
<div class="sect4">
<h5 id="showddl_schema_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a SHOWDDL SCHEMA statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the schema.</p>
</li>
<li>
<p>You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted to PUBLIC
by default.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="showddl_schema_examples">3.52.3. Examples of SHOWDDL SCHEMA</h4>
<div class="ulist">
<ul>
<li>
<p>This SHOWDDL SCHEMA statement displays the DDL syntax used to create the schema, MYSCHEMA, as it exists in the metadata
and shows the authorization ID that owns the schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWDDL SCHEMA MYSCHEMA;
CREATE PRIVATE SCHEMA &quot;TRAFODION&quot;.&quot;MYSCHEMA&quot; AUTHORIZATION &quot;DB ROOT&quot;;
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="_showstats_statement">3.53. SHOWSTATS Statement</h3>
<div class="paragraph">
<p>The SHOWSTATS statement displays the histogram statistics for one or
more groups of columns within a table. These statistics are used to
devise optimized access plans.</p>
</div>
<div class="paragraph">
<p>SHOWSTATS is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWSTATS FOR TABLE table-name ON group-list [DETAIL]
group-list is:
column-list[, column-list]...
| EVERY COLUMN[, column-list]...
| EVERY KEY[, column-list]...
| EXISTING COLUMN[S][, column-list]...
column-list for a single-column group is:
column-name
| (column-name)
| column-name TO column-name
| (column-name) TO (column-name)
| column-name TO (column-name)
| (column-name) TO column-name
column-list for a multicolumn group is:
(column-name, column-name[, column-name]...)</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="showstats_syntax">3.53.1. Syntax Description of SHOWSTATS</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>table-name</em></code></p>
<div class="paragraph">
<p>is the ANSI name of the table for which statistics are to be displayed.</p>
</div>
</li>
<li>
<p><code>ON <em>group-list</em></code></p>
<div class="paragraph">
<p>specifies one or more groups of columns, <em>group-list</em>, for which to display histogram statistics.</p>
</div>
</li>
<li>
<p><code><em>group-list</em> is: <em>column-list</em> [, <em>column-list</em>]&#8230; | EVERY COLUMN [,<em>column-list</em>]&#8230; | EVERY KEY [, <em>column-list</em>]&#8230; | EXISTING
COLUMN[S] [, <em>column-list</em>]&#8230;</code></p>
<div class="paragraph">
<p>specifies the ways in which <em>group-list</em> can be defined. The column list represents both a single-column group and a
multi-column group.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>EVERY COLUMN</code></p>
<div class="paragraph">
<p>indicates that histogram statistics are to be displayed for each individual column of <em>table</em> and any multi columns that
make up the primary key and indexes. For columns that do not have histograms, this option returns
<code>No histogram data for column(s) ---&#93;</code>.</p>
</div>
</li>
<li>
<p><code>EVERY KEY</code></p>
<div class="paragraph">
<p>indicates that histogram statistics are to be displayed for columns that make up the primary key and indexes.</p>
</div>
</li>
<li>
<p><code>EXISTING COLUMN[S]</code></p>
<div class="paragraph">
<p>indicates that histogram statistics are to be displayed only for columns of <em>table</em> that actually have histograms.
This option yields a more concise report because columns with no histogram data are omitted. This option includes
any existing multicolumn histograms.</p>
</div>
</li>
<li>
<p><code>DETAIL</code></p>
<div class="paragraph">
<p>displays statistics for corresponding histogram intervals and other details.</p>
</div>
<div class="paragraph">
<p>If you do not select the DETAIL keyword, the default display lists the basic histogram information, including the
histogram ID, number of intervals, total rows, total UEC, and the column names. The detailed display additionally
includes the low value and high value as well as interval data.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-list</em> for a single-column group is: <em>column-name</em> |
(<em>column-name</em>) | <em>column-name</em> TO <em>column-name</em> | (<em>column-name</em>)
TO (<em>column-name</em>) | <em>column-name</em> TO (<em>column-name</em>) |
(<em>column-name</em>) TO <em>column-name</em></code></p>
<div class="paragraph">
<p>specifies the ways in which the <em>column-name</em> can be defined for single-column groups. A range of columns specified
using the TO keyword causes all columns in that range to be included, defined by their order of declaration in the table.</p>
</div>
</li>
<li>
<p><code><em>column-list</em> for a multicolumn group is: (<em>column-name, column-name</em>[,<em>column-name</em>]&#8230;)</code></p>
<div class="paragraph">
<p>specifies the ways in which the <em>column-name</em> can be defined for multicolumn groups. For example, (abc, def) indicates
the multicolumn histogram consisting of columns abc and def, not two single-column histograms.</p>
</div>
<div class="paragraph">
<p>For more information about the column list syntax and specifying columns, see the
<a href="#update_statistics_statement">UPDATE STATISTICS Statement</a>.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="showstats_considerations">3.53.2. Considerations for SHOWSTATS</h4>
<div class="sect4">
<h5 id="showstats_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a SHOWSTATS statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the database object.</p>
</li>
<li>
<p>You have the SHOW component privilege for the SQL_OPERATIONS component. The SHOW component privilege is granted
to PUBLIC by default.</p>
</li>
<li>
<p>You have the SELECT privilege on the target object.</p>
</li>
<li>
<p>You have the MANAGE_STATISTICS component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="showstats_examples">3.53.3. Examples of SHOWSTATS</h4>
<div class="ulist">
<ul>
<li>
<p>This example displays histogram statistics for table A using the EVERY KEY keyword. In addition, the DETAIL
keyword is selected:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWSTATS FOR TABLE A ON EVERY KEY DETAIL;</code></pre>
</div>
</div>
</li>
<li>
<p>This example displays statistics for table CAT.SCH.A and selects all columns from abc through def:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWSTATS FOR TABLE CAT.SCH.A ON ABC TO DEF;</code></pre>
</div>
</div>
</li>
<li>
<p>This example displays statistics for table A. The list of column names contained within parenthesis refers
to a multicolumn group:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWSTATS FOR TABLE A ON (ABC,DEF);</code></pre>
</div>
</div>
</li>
<li>
<p>This example displays statistics for table A using the EXISTING COLUMNS keyword. In addition, the DETAIL
keyword is selected:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SHOWSTATS FOR TABLE A ON EXISTING COLUMNS DETAIL;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>Default output example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SHOWSTATS FOR TABLE A ON EXISTING COLUMNS;
Histogram data for Table CAT.SCH.A Table ID: 341261536378386
Hist ID # Ints Rowcount UEC Colname(s)
========== ====== =========== ==============================
623327638 1 11 10 ABC, DEF, GHI
623327633 10 11 10 ABC
623327628 9 11 9 DEF
623327623 10 11 10 GHI
--- SQL operation complete.
&gt;&gt;SHOWSTATS FOR TABLE A ON ABC;
Histogram data for Table CAT.SCH.A Table ID: 341261536378386
Hist ID # Ints Rowcount UEC Colname(s)
========== ====== =========== ==============================
623327633 10 11 10 ABC
--- SQL operation complete.
&gt;&gt;SHOWSTATS FOR TABLE A ON DEF DETAIL;
Detailed Histogram data for Table CAT.SCH.A Table ID: 341261536378386
Hist ID: 623327628
Column(s): DEF
Total Rows: 11
Total UEC: 9
Low Value: (1)
High Value: (199)
Intervals: 9
Number Rowcount UEC Boundary
====== =========== ==============================
0 0 0 (1)
1 1 1 (1)
2 3 1 (2)
3 1 1 (4)
4 1 1 (11)
5 1 1 (12)
6 1 1 (14)
7 1 1 (99)
8 1 1 (123)
9 1 1 (199)
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="table_statement">3.54. TABLE Statement</h3>
<div class="paragraph">
<p>The TABLE statement is equivalent to the query specification SELECT *
FROM <em>table</em>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TABLE table</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="table_syntax">3.54.1. Syntax Description of Table Statement</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>names the user table or view.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="_considerations_for_table">3.54.2. Considerations for TABLE</h4>
<div class="sect4">
<h5 id="table_relationship_to_select_statement">Relationship to SELECT Statement</h5>
<div class="paragraph">
<p>The result of the TABLE statement is one form of a simple-table, which refers to the definition of a table reference
within a SELECT statement. See the <a href="#select_statement">SELECT Statement</a>.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="_examples_of_table_statement">3.54.3. Examples of TABLE Statement</h4>
<div class="ulist">
<ul>
<li>
<p>This TABLE statement returns the same result as SELECT * FROM job:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TABLE job;
Job/Code Job Description
-------- --------------------
100 MANAGER
200 PRODUCTION SUPV
250 ASSEMBLER
300 SALESREP
400 SYSTEM ANALYST
420 ENGINEER
450 PROGRAMMER
500 ACCOUNTANT
600 ADMINISTRATOR
900 SECRETARY
--- 10 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="unregister_user_statement">3.55. UNREGISTER USER Statement</h3>
<div class="paragraph">
<p>The UNREGISTER USER statement removes a database username from the SQL
database. The user can no longer log on to the database.</p>
</div>
<div class="paragraph">
<p>UNREGISTER USER is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UNREGISTER USER database-username [RESTRICT | CASCADE]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="unregister_user_syntax">3.55.1. Syntax Description of UNREGISTER USER</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>database-username</em></code></p>
<div class="paragraph">
<p>is the name of a currently registered database user. <em>database-username</em> is a regular or delimited case-insensitive
identifier. See <a href="#case_insensitive_delimited_identifiers">Case-Insensitive Delimited Identifiers</a>.</p>
</div>
</li>
<li>
<p><code>[ RESTRICT | CASCADE ]</code></p>
<div class="paragraph">
<p>If you specify RESTRICT, the UNREGISTER USER operation fails if there
are any objects or schemas in the database owned by the user or any
privileges or roles granted to the user.</p>
</div>
<div class="paragraph">
<p>If you specify CASCADE, all objects and schemas owned by the user are
dropped, and all privileges and roles granted to the user are revoked as
part of the UNREGISTER USER operation.</p>
</div>
<div class="paragraph">
<p>The default value is RESTRICT.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="unregister_user_considerations">3.55.2. Considerations for UNREGISTER USER</h4>
<div class="ulist">
<ul>
<li>
<p>To unregister a user, you must have user administrative privileges.
You have user administrative privileges if you have been granted the
MANAGE_USERS component privilege. Initially,</p>
<div class="paragraph">
<p>DB ROOT is the only database user who has been granted the MANAGE_USERS
component privilege.</p>
</div>
</li>
<li>
<p>You cannot unregister any username beginning with DB . Role names
beginning with DB are reserved by Trafodion.</p>
</li>
<li>
<p>UNREGISTER USER fails if you specify RESTRICT (or nothing) and if the
user owns any objects or schemas or if the user has been granted any
privileges or roles.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="unregister_user_examples">3.55.3. Examples of UNREGISTER USER</h4>
<div class="ulist">
<ul>
<li>
<p>To unregister a user:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UNREGISTER USER &quot;jsmith@company.com&quot;;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="update_statement">3.56. UPDATE Statement</h3>
<div class="paragraph">
<p>The UPDATE statement is a DML statement that updates data in a row or
rows in a table or updatable view. Updating rows in a view updates the
rows in the table on which the view is based.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">Searched UPDATE is:
UPDATE table
{ set-clause-type1 | set-clause-type2 }
set-clause-type1 is:
SET set-clause[, set-clause ]..
set-clause is:
column-name = {expression | NULL}
set-clause-type2 is:
SET (column1, ..., columnN) = {(value1, ..., valueN) | (query-expr)}
[WHERE search-condition]
[[FOR] access-option ACCESS]
access-option is:
READ COMMITTED</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="update_syntax">3.56.1. Syntax Description of UPDATE</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>names the user table or view to update. <em>table</em> must be a base table or
an updatable view. To refer to a table or view, use the ANSI logical
name. See <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code><em>set-clause-type1</em></code></p>
<div class="paragraph">
<p>This type of SET clause associates a value with a specific column in the
table being updated. For each <em>set-clause</em>, the value of the specified
target <em>column-name</em> is replaced by the value of the update source
<em>expression</em> (or NULL). The data type of each target column must be
compatible with the data type of its source value.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-name</em></code></p>
<div class="paragraph">
<p>names a column in <em>table</em> to update. You cannot qualify or repeat a
column name. You cannot update the value of a column that is part of the
primary key.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>is an SQL value expression that specifies a value for the column. The
<em>expression</em> cannot contain an aggregate function defined on a column.
The data type of <em>expression</em> must be compatible with the data type of
<em>column-name</em>.</p>
</div>
<div class="paragraph">
<p>If <em>expression</em> refers to columns being updated, Trafodion SQL uses the
original values to evaluate the expression and determine the new value.
See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code>NULL</code></p>
<div class="paragraph">
<p>can also specify the value of the update source.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code><em>set-clause-type2</em></code></p>
<div class="paragraph">
<p>This type of SET clause allows multiple columns to be specified on the
left side of the assignment operator. These columns are updated using
multiple values specified on the right side of the assignment operator.
The right side of the assignment operator could be simple values or a
subquery.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column1</em>, &#8230;, <em>columnN</em></code></p>
<div class="paragraph">
<p>names columns in <em>table</em> to update. You cannot qualify or repeat a
column name. You cannot update the value of a column that is part of the
primary key.</p>
</div>
</li>
<li>
<p><code><em>value1</em>, &#8230;, <em>valueN</em></code></p>
<div class="paragraph">
<p>are values specified on the right side of the assignment operator for
the columns specified on the left side of the assignment operator. The
data type of each value must be compatible with the data type of the
corresponding column on the left side of the assignment operator.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code><em>query-expr</em></code></p>
<div class="paragraph">
<p>is a SELECT subquery. Only one subquery can be specified on the right
side of a SET clause. The subquery cannot refer to the table being
updated. For the syntax and description of <em>query-expr</em>, see the
<a href="#select_statement">SELECT Statement</a>.</p>
</div>
</li>
<li>
<p><code>WHERE <em>search-condition</em></code></p>
<div class="paragraph">
<p>specifies a <em>search-condition</em> that selects rows to update. Within the
<em>search-condition</em>, columns being compared are also being updated in
the table or view. See <a href="#search_condition">Search Condition</a>.</p>
</div>
<div class="paragraph">
<p>If you do not specify a <em>search-condition</em>, all rows in the table or
view are updated.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>Do not use an UPDATE statement with a WHERE clause that contains a
SELECT for the same table. Reading from and inserting into, updating in,
or deleting from the same table generates an error. Use a positioned
(WHERE CURRENT OF) UPDATE instead. See <a href="#merge_statement">MERGE Statement</a>.</p>
</div>
</li>
<li>
<p><code>[FOR] <em>access-option</em> ACCESS</code></p>
<div class="paragraph">
<p>specifies the <em>access-option</em> required for data used in the evaluation
of a search condition. See <a href="#data_consistency_and_access_options">Data Consistency and Access Options</a>.</p>
</div>
</li>
<li>
<p><code>READ COMMITTED</code></p>
<div class="paragraph">
<p>specifies that any data used in the evaluation of the search condition
must be from committed rows.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="update_considerations">3.56.2. Considerations for UPDATE</h4>
<div class="sect4">
<h5 id="update_performance">Performance</h5>
<div class="paragraph">
<p>An UPDATE of primary key columns could perform poorly when compared to
an UPDATE of non-key columns. This is because the UPDATE operation
involves moving records in disk by deleting all the records in the
before-image and then inserting the records in the after-image back into
the table.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_authorization_requirements">Authorization Requirements</h5>
<div class="paragraph">
<p>UPDATE requires authority to read and write to the table or view being
updated and authority to read any table or view specified in subqueries
used in the search condition. A column of a view can be updated if its
underlying column in the base table can be updated.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_transaction_initiation_and_termination">Transaction Initiation and Termination</h5>
<div class="paragraph">
<p>The UPDATE statement automatically initiates a transaction if no active
transaction exists. Otherwise, you can explicitly initiate a transaction
with the BEGIN WORK statement. When a transaction is started, the SQL
statements execute within that transaction until a COMMIT or ROLLBACK is
encountered or an error occurs.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_isolation_levels_of_transactions_and_access_options_of_statements">Isolation Levels of Transactions and Access Options of Statements</h5>
<div class="paragraph">
<p>The isolation level of a Trafodion SQL transaction defines the degree to
which the operations on data within that transaction are affected by
operations of concurrent transactions. When you specify
access options for the DML statements within a transaction, you override
the isolation level of the containing transaction. Each statement then
executes with its individual access option.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_conflicting_updates_in_concurrent_applications">Conflicting Updates in Concurrent Applications</h5>
<div class="paragraph">
<p>If you are using the READ COMMITTED isolation level within a
transaction, your application can read different committed values for
the same data at different times. Further, two concurrent applications
can update (possibly in error) the same column in the same row.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_requirements_for_data_in_row">Requirements for Data in Row</h5>
<div class="paragraph">
<p>Each row to be updated must satisfy the constraints of the table or
underlying base table of the view. No column updates can occur unless
all of these constraints are satisfied. (A table constraint is satisfied
if the check condition is not false—that is, it is either true or has an
unknown value.)</p>
</div>
<div class="paragraph">
<p>In addition, a candidate row from a view created with the WITH CHECK
OPTION must satisfy the view selection criteria. The selection criteria
are specified in the WHERE clause of the AS <em>query-expr</em> clause in the
CREATE VIEW statement.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_reporting_of_updates">Reporting of Updates</h5>
<div class="paragraph">
<p>When an UPDATE completes successfully, Trafodion SQL reports the number
of times rows were updated during the operation.</p>
</div>
<div class="paragraph">
<p>Under certain conditions, updating a table with indexes can cause
Trafodion SQL to update the same row more than once, causing the number
of reported updates to be higher than the actual number of changed rows.
However, both the data in the table and the number of reported updates
are correct. This behavior occurs when all of these conditions are true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The optimizer chooses an alternate index as the access path.</p>
</li>
<li>
<p>The index columns specified in WHERE <em>search-condition</em> are not changed by the update.</p>
</li>
<li>
<p>Another column within the same index is updated to a higher value (if
that column is stored in ascending order), or a lower value (if that
column is stored in descending order).</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>When these conditions occur, the order of the index entries ensures that
Trafodion SQL will encounter the same row (satisfying the same
<em>search-condition)</em> at a later time during the processing of the table.
The row is then updated again by using the same value or values.</p>
</div>
<div class="paragraph">
<p>For example, suppose that the index of MYTABLE consists of columns A and
B, and the UPDATE statement is specified:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE MYTABLE SET B = 20 WHERE A &gt; 10;</code></pre>
</div>
</div>
<div class="paragraph">
<p>If the contents of columns A and B are 1 and 12 respectively before the
UPDATE, after the UPDATE Trafodion SQL will encounter the same row
indexed by the values 1 and 20.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_updating_character_values">Updating Character Values</h5>
<div class="paragraph">
<p>For a fixed-length character column, an update value shorter than the
column length is padded with single-byte ASCII blanks (HEX20) to fill
the column. If the update value is longer than the column length, string
truncation of non blank trailing characters returns an error, and the
column is not updated.</p>
</div>
<div class="paragraph">
<p>For a variable-length character column, an update value is not padded;
its length is the length of the value specified. As is the case for
fixed length, if the update value is longer than the column length,
string truncation of non blank trailing characters returns an error, and
the column is not updated.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_set_clause_restrictions_and_error_cases">SET Clause Restrictions and Error Cases</h5>
<div class="paragraph">
<p>The SET clause has the following restrictions:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The number of columns on the left side of each assignment operator
should match the number of values or SELECT list elements on the right
side. The following examples are not allowed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE t SET (a,b)=(10,20,30)
UPDATE t set (b,c)=(SELECT r,t,s FROM x)</code></pre>
</div>
</div>
</li>
<li>
<p>If multi-column update syntax is specified and the right side contains
a subquery, only one element, the subquery, is not allowed.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE t SET (a,b)=(10, (SELECT a FROM t1))</code></pre>
</div>
</div>
</li>
<li>
<p>More than one subquery is not allowed if multiple-column syntax is
used.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE t SET (a,b)=(SELECT x,y FROM z), (c,d)=(SELECT x,y FROM a))</code></pre>
</div>
</div>
</li>
<li>
<p>If a subquery is used, it must return at most one row.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="update_examples">3.56.3. Examples of UPDATE</h4>
<div class="ulist">
<ul>
<li>
<p>Update a single row of the ORDERS table that contains information
about order number 200300 and change the delivery date:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE sales.orders
SET deliv_date = DATE '2008-05-02'
WHERE ordernum = 200300;</code></pre>
</div>
</div>
</li>
<li>
<p>Update several rows of the CUSTOMER table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE sales.customer SET credit = 'A1'
WHERE custnum IN (21, 3333, 324);</code></pre>
</div>
</div>
</li>
<li>
<p>Update all rows of the CUSTOMER table to the default credit 'C1':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE sales.customer SET credit = 'C1';</code></pre>
</div>
</div>
</li>
<li>
<p>Update the salary of each employee working for all departments located
in Chicago:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE persnl.employee
SET salary = salary * 1.1
WHERE deptnum IN
(SELECT deptnum FROM persnl.dept
WHERE location = 'CHICAGO');</code></pre>
</div>
</div>
<div class="paragraph">
<p>The subquery is evaluated for each row of the DEPT table and returns
department numbers for departments located in Chicago.</p>
</div>
</li>
<li>
<p>This is an example of a self-referencing UPDATE statement, where the
table being updated is scanned in a subquery:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE table3 SET b = b + 2000 WHERE a, b =
(SELECT a, b FROM table3 WHERE b &gt; 200);</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="upsert_statement">3.57. UPSERT Statement</h3>
<div class="paragraph">
<p>The UPSERT statement either updates a table if the row exists or inserts
into a table if the row does not exist.</p>
</div>
<div class="paragraph">
<p>UPSERT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPSERT [USING LOAD] INTO table [(target-col-list)] {query-expr | values-clause}
target-col-list is:
column-name[, column-name]...
values-clause is:
VALUES ( expression[, expression]... )</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="upsert_syntax">3.57.1. Syntax Description of UPSERT</h4>
<div class="ulist">
<ul>
<li>
<p><code>USING LOAD</code></p>
<div class="paragraph">
<p>allows the UPSERT to occur without a transaction. Use this clause when
inserting data into an empty table. If you do not specify this clause,
the UPSERT occurs within a transaction.</p>
</div>
</li>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>names the user table in which to insert or update rows. <em>table</em> must be
a base table. (<em>target-col-list</em>)</p>
</div>
<div class="paragraph">
<p>names the columns in the table in which to insert or update values. The
data type of each target</p>
</div>
<div class="paragraph">
<p>column must be compatible with the data type of its corresponding source
value. Within the list, each target column must have the same position
as its associated source value, whose position is determined by the
columns in the table derived from the evaluation of the query expression
(<em>query-expr</em>).</p>
</div>
<div class="paragraph">
<p>If you do not specify all of the columns in the target <em>table</em> in the
<em>target-col-list</em>, column default values are inserted into or updated
in the columns that do not appear in the list. See
<a href="#column_default_settings">Column Default Settings</a>.</p>
</div>
<div class="paragraph">
<p>If you do not specify <em>target-col-list</em>, row values from the source
table are inserted into or updated in all columns in table. The order of
the column values in the source table must be the same order as that of
the columns specified in the CREATE TABLE for <em>table</em>. (This order is
the same as that of the columns listed in the result table of SHOWDDL
<em>table</em>.)</p>
</div>
</li>
<li>
<p><code><em>column-name</em></code></p>
<div class="paragraph">
<p>names a column in the target <em>table</em> in which to either insert or update
data. You cannot qualify or repeat a column name.</p>
</div>
</li>
<li>
<p><code><em>query-expr</em></code></p>
<div class="paragraph">
<p>is a SELECT subquery that returns data to be inserted into or updated in
the target <em>table</em>. The subquery cannot refer to the table being
operated on. For the syntax and description of <em>query-expr</em>, see the
<a href="#select_statement">SELECT Statement</a>.</p>
</div>
</li>
<li>
<p><code>VALUES ( <em>expression</em>[, <em>expression</em>]&#8230; )</code></p>
<div class="paragraph">
<p>specifies an SQL value expression or a set of expressions that specify
values to be inserted into or updated in the target <em>table</em>. The data
type of <em>expression</em> must be compatible with the data type of the
corresponding column in the target <em>table</em>. See
<a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="upsert_examples">3.57.2. Examples of UPSERT</h4>
<div class="ulist">
<ul>
<li>
<p>This UPSERT statement either inserts or updates the part number and
price in the PARTS table using the part number and unit price from the
ODETAIL table where the part number is 244:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPSERT INTO sales.parts (partnum, price)
SELECT partnum, unit_price FROM sales.odetail WHERE partnum = 244;</code></pre>
</div>
</div>
</li>
<li>
<p>This UPSERT statement either inserts or updates rows in the EMPLOYEE
table using the results of querying the EMPLOYEE_EUROPE table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPSERT INTO persnl.employee SELECT * FROM persnl.employee_europe;</code></pre>
</div>
</div>
</li>
<li>
<p>This UPSERT statement either inserts or updates a row in the DEPT
table using the specified values:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPSERT INTO persnl.dept
VALUES (3500,'CHINA SALES',111,3000,'HONG KONG');</code></pre>
</div>
</div>
</li>
<li>
<p>This UPSERT statement either inserts or updates a row in the DEPT
table using the specified values:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPSERT INTO persnl.dept (deptnum, deptname, manager)
VALUES (3600,‘JAPAN SALES’, 996);</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="values_statement">3.58. VALUES Statement</h3>
<div class="paragraph">
<p>The VALUES statements starts with the VALUES keyword followed by a
sequence of row value constructors, each of which is enclosed in
parenthesis. It displays the results of the evaluation of the
expressions and the results of row subqueries within the row value
constructors.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">VALUES (row-value-const) [, (row-value-const)]...
row-value-const is:
row-subquery
| {expression | NULL} [,{expression | NULL}...</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="values_syntax">3.58.1. Syntax Description of VALUES</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>row-value-const</em></code></p>
<div class="paragraph">
<p>specifies a list of expressions (or NULL) or a row subquery (a subquery
that returns a single row of column values). An operand of an expression
cannot reference a column (except when the operand is a scalar subquery
returning a single column value in its result table).</p>
</div>
<div class="paragraph">
<p>The results of the evaluation of the expressions and the results of the
row subqueries in the row value constructors must have compatible data
types.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="values_considerations">3.58.2. Considerations for VALUES</h4>
<div class="sect4">
<h5 id="values_relationship_to_select_statement">Relationship to SELECT Statement</h5>
<div class="paragraph">
<p>The result of the VALUES statement is one form of a <em>simple-table</em>,
which is part of the definition of a table reference within a SELECT
statement. See the <a href="#select statement">SELECT Statement</a>.</p>
</div>
</div>
<div class="sect4">
<h5 id="values_relationship_to_insert_statement">Relationship to INSERT Statement</h5>
<div class="paragraph">
<p>For a VALUES clause that is the direct source of an INSERT statement,
Trafodion SQL also allows the keyword DEFAULT in a VALUES clause, just
like NULL is allowed. For more information, see the
<a href="#insert statement">INSERT Statement</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="values_examples">3.58.3. Examples of VALUES</h4>
<div class="ulist">
<ul>
<li>
<p>This VALUES statement displays two rows with simple constants:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">VALUES (1,2,3), (4,5,6);
(EXPR) (EXPR) (EXPR)
------ ------ -----
1 2 3
4 5 6
--- 2 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>This VALUES statement displays the results of the expressions and the
row subquery in the lists:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">VALUES (1+2, 3+4), (5, (select count (*) from t));
(EXPR) (EXPR)
------ ----------------- ------
3 7
5 2
--- 2 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="sql_utilities">4. SQL Utilities</h2>
<div class="sectionbody">
<div class="paragraph">
<p>A utility is a tool that runs within Trafodion SQL and performs tasks.
This section describes the Trafodion SQL utilities:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#cleanup_statement">CLEANUP Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Cleans up objects whose information is inconsistent in the metadata.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#load_statement">LOAD Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Uses the Trafodion Bulk Loader to load data from a source table, either
a Trafodion table or a Hive table, into a target Trafodion table.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#populate_index_utility">POPULATE INDEX Utility</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Loads indexes.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#purgedata_utility">PURGEDATA Utility</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Purges data from tables and indexes.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#unload_statement">UNLOAD Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unloads data from Trafodion tables into an HDFS location that you
specify.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#update_statistics_statement">UPDATE STATISTICS Statement</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Updates the histogram statistics for one or more groups of columns
within a table. These statistics are used to devise optimized access plans.</p></td>
</tr>
</tbody>
</table>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
Trafodion SQL utilities are entered interactively or from script
files using a client-based tool, such as the Trafodion Command Interface
(TrafCI). To install and configure a client application that enables you
to connect to and issue SQL utilities, see the
<a href="http://trafodion.incubator.apache.org/docs/client_installation/index.html"><em>Trafodion Client Installation Guide</em></a>.
</td>
</tr>
</table>
</div>
<div style="page-break-after: always;"></div>
<div class="sect2">
<h3 id="cleanup_statement">4.1. CLEANUP Statement</h3>
<div class="paragraph">
<p>The CLEANUP Statement cleans up objects whose information is inconsistent in the metadata. This command can be used to clean up individual objects or all objects in a schema. This command can also be used to locate all inconsistent objects in the Trafodion metadata and then clean them up.</p>
</div>
<div class="paragraph">
<p>Inconsistent objects can be cleaned up and removed from the metadata and HBase by using one of the following options.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CLEANUP object-type object-name [ ,UID {object-uid} ]
CLEANUP [ PRIVATE | SHARED ] SCHEMA {schema-name}
CLEANUP UID {object-uid}
CLEANUP METADATA [ , CHECK ] [ , RETURN DETAILS ]</code></pre>
</div>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">object-type is: TABLE | INDEX | SEQUENCE | OBJECT
object-name is: Name of the object that needs to be cleaned up
object-uid is: UID (Unique ID) of the object that is stored in metadata
schema-name is: Name of the schema whose contents need to be cleaned up</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="cleanup_syntax">4.1.1. Syntax Description of CLEANUP Statement</h4>
<div class="ulist">
<ul>
<li>
<p><code>CLEANUP object-type object-name [ , UID {object-uid} ]</code></p>
<div class="paragraph">
<p>This command will clean up the specified object from all Trafodion metadata tables
and HBase. If an object cannot be found in the metadata but exists in HBase,
then it will be removed from HBase. All dependent objects, such as indexes,
views, LOBs, internal sequences, and constraints, are also removed from the
metadata and HBase.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>object-type</code></p>
<div class="ulist">
<ul>
<li>
<p>If an object type is specified as TABLE, INDEX, or SEQUENCE and that object exists
in the metadata, then a check will be done to make sure that the specified <code>object-name</code> is of the specified type. An error is returned if they are not the same.</p>
</li>
<li>
<p>If an object type is specified as OBJECT, then any object that matches the
specified name is removed from the metadata and HBase.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>object-name</code></p>
<div class="paragraph">
<p>Specifies the name of the object to be removed.</p>
</div>
</li>
<li>
<p><code>object-uid</code></p>
<div class="paragraph">
<p>If an object exists in the OBJECTS metadata table, then the stored object UID is compared with the specified object UID. If they do not match, then cleanup is not done. If an object does not exist in the OBJECTS metadata table, then all entries matching the specified object UID are removed from the metadata tables.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>CLEANUP [ PRIVATE | SHARED ] SCHEMA {schema-name}</code></p>
<div class="paragraph">
<p>This command will clean up all objects that are created in the specified schema.</p>
</div>
</li>
<li>
<p><code>CLEANUP UID {object-uid}</code></p>
<div class="paragraph">
<p>This command will remove all entries from all metadata tables that match the specified object UID. If the specified object UID exists in the OBJECTS metadata table and the object name associated with that UID can be retrieved, then that object is also removed from HBase.</p>
</div>
</li>
<li>
<p><code>CLEANUP METADATA [ , CHECK ] [ , RETURN DETAILS ]</code></p>
<div class="paragraph">
<p>This command will look for inconsistent entries in the metadata, return information about them, and clean them up. Multiple checks are done to validate metadata consistency.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>CHECK</code></p>
<div class="paragraph">
<p>One can check for inconsistent metadata entries without actually cleaning them up.
This can be done by specifying the <code>CHECK</code> option. If <code>CHECK</code> is specified, the following checks will be performed simultaneously, and a summary of inconsistent objects belonging to the categories listed below will be returned.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Orphan Metadata Objects</p>
<div class="paragraph">
<p>This check is done to validate that objects that exist in metadata also exist in HBase. If the object does not exist in HBase, then it is marked as an orphan metadata object.</p>
</div>
</li>
<li>
<p>Orphan HBase Objects</p>
<div class="paragraph">
<p>This check is done to validate that objects that exist in HBase also exist in metadata. If the object does not exist in metadata, then it is marked as an orphan HBase object.</p>
</div>
</li>
<li>
<p>Inconsistent Object Entries</p>
<div class="paragraph">
<p>This check is done to make sure that all entries in the OBJECTS table also exist in
the OBJECTS unique index (OBJECTS_UNIQ_IDX) and that all entries in OBJECTS_UNIQ_IDX also exist in the OBJECTS table. It also checks to make sure that all entries in the COLUMNS table have a corresponding entry in the OBJECTS table. If any of the previous checks fail, then that entry is marked as inconsistent.</p>
</div>
</li>
<li>
<p>Inconsistent View Entries</p>
<div class="paragraph">
<p>This check is done to make sure that all view entries are consistent among the views and the OBJECTS table.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>RETURN DETAILS</code></p>
<div class="paragraph">
<p>If <code>RETURN DETAILS</code> is specified, then details on which objects are inconsistent is also returned.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="cleanup_considerations">4.1.2. Considerations for CLEANUP Statement</h4>
<div class="sect4">
<h5 id="security_and_privileges">Security and Privileges</h5>
<div class="paragraph">
<p>To clean up an object, one needs to have DROP privileges. If object privileges cannot be retrieved from the metadata or if metadata cleanup is being done, then one needs to be DB_ROOT to perform the cleanup.</p>
</div>
</div>
<div class="sect4">
<h5 id="consistency_checks_during_access">Consistency Checks During Access</h5>
<div class="paragraph">
<p>If an object exists in the metadata but does not exist in HBase, then error 4254 will be returned if that object is accessed during any DML or DDL operation.</p>
</div>
<div class="paragraph">
<p>An object is also marked as inconsistent during any complex DDL operation. For example, if a CREATE TABLE also creates implicit indexes or constraints, then the object will be marked as inconsistent until the complex DDL operation is completed. If an abnormal error happens (such as a process crash or a node failure), then that object remains inconsistent. Any attempt to access that object will return error 4254.</p>
</div>
<div class="paragraph">
<p>An inconsistent object will need to be cleaned up before it can be accessed.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="cleanup_examples">4.1.3. Examples of CLEANUP Statement</h4>
<div class="ulist">
<ul>
<li>
<p>Accessing Inconsistent Objects</p>
<div class="paragraph">
<p>Table T026T1 has been marked as inconsistent from a previous session. Any operation on it will return error 4254. For this test case, a metadata update was done, and the table was marked as invalid in the OBJECTS table.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;invoke t026t1;
*** ERROR[4254] Object TRAFODION.SCH026.T026T1 has invalid state and cannot be accessed. Use cleanup command to drop it.
*** ERROR[4082] Object TRAFODION.SCH026.T026T1 does not exist or is inaccessible.
--- SQL operation failed with errors.
&gt;&gt;drop table t026t1;
*** ERROR[4254] Object TRAFODION.SCH026.T026T1 has invalid state and cannot be accessed. Use cleanup command to drop it.
--- SQL operation failed with errors.
&gt;&gt;select * from t026t1;
*** ERROR[4254] Object TRAFODION.SCH026.T026T1 has invalid state and cannot be accessed. Use cleanup command to drop it.
*** ERROR[4082] Object TRAFODION.SCH026.T026T1 does not exist or is inaccessible.
*** ERROR[8822] The statement was not prepared.
&gt;&gt;</code></pre>
</div>
</div>
</li>
<li>
<p>Accessing Incorrect Objects</p>
<div class="paragraph">
<p>If an object type is specified, then the object stored in the metadata must match it. In this example, object ‘TI’ is an index that cannot be cleaned up as a table.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;create index ti on t(b);
--- SQL operation complete.
&gt;&gt;cleanup table ti;
*** ERROR[1389] Object TI does not exist in Trafodion.
*** ERROR[4256] Object type specified for this object does not match the object type stored in metadata.
--- SQL operation failed with errors.
&gt;&gt;</code></pre>
</div>
</div>
</li>
<li>
<p>Cleaning Up an Inconsistent Object</p>
<div class="paragraph">
<p>A CLEANUP command will need to be used to clean up an object in invalid state.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;drop table t026t1;
*** ERROR[4254] Object TRAFODION.SCH026.T026T1 has invalid state and cannot be accessed. Use cleanup command to drop it.
--- SQL operation failed with errors.
&gt;&gt;cleanup table t026t1;
--- SQL operation complete.
&gt;&gt;invoke t026t1;
*** ERROR[4082] Object TRAFODION.SCH026.T026T1 does not exist or is inaccessible.
--- SQL operation failed with errors.
&gt;&gt;</code></pre>
</div>
</div>
<div class="paragraph">
<p>DROP TABLE, CREATE TABLE, DROP INDEX, and CREATE INDEX failures will call cleanup.</p>
</div>
</li>
<li>
<p>Cleaning Up an Object by Specifying its UID</p>
<div class="paragraph">
<p>Specify object T by its object UID and clean it up.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;select object_uid from &quot;_MD_&quot;.objects where schema_name = 'SCH026' and object_name = 'T';
OBJECT_UID
--------------------
127287511636506969
--- 1 row(s) selected.
&gt;&gt;cleanup uid 127287511636506969;
--- SQL operation complete.
&gt;&gt;invoke t;
*** ERROR[4082] Object TRAFODION.SCH026.T does not exist or is inaccessible.
--- SQL operation failed with errors.
&gt;&gt;</code></pre>
</div>
</div>
</li>
<li>
<p>Metadata Cleanup</p>
<div class="paragraph">
<p>This example shows that the metadata is consistent and that there are no issues with it.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;cleanup metadata, check, return details;
Metadata Cleanup: started, check only
Start: Cleanup Orphan Objects Entries
End: Cleanup Orphan Objects Entries (0 entries found)
Start: Cleanup Orphan Hbase Entries
End: Cleanup Orphan Hbase Entries (0 entries found)
Start: Cleanup Inconsistent Objects Entries
End: Cleanup Inconsistent Objects Entries (0 entries found)
Start: Cleanup Inconsistent Views Entries
End: Cleanup Inconsistent Views Entries (0 entries found)
Metadata Cleanup: done
--- SQL operation complete.
&gt;&gt;</code></pre>
</div>
</div>
<div class="paragraph">
<p>This example shows inconsistencies in the metadata:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;cleanup metadata, check, return details;
Metadata Cleanup: started, check only
Start: Cleanup Orphan Objects Entries
Entry #1(OBJECT): TRAFODION.SCH026.T026T10
End: Cleanup Orphan Objects Entries (1 entry found)
Start: Cleanup Orphan Hbase Entries
Entry #1(OBJECT): TRAFODION.SCH026.T026T11
End: Cleanup Orphan Hbase Entries (1 entry found)
Start: Cleanup Inconsistent Objects Entries
Entry #1(OBJECT): TRAFODION.SCH026.T026T12
Entry #2(UID): 29899934458095403
End: Cleanup Inconsistent Objects Entries (2 entries found)
Start: Cleanup Inconsistent Views Entries
End: Cleanup Inconsistent Views Entries (0 entries found)
Metadata Cleanup: done
--- SQL operation complete.
&gt;&gt;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Running the CLEANUP METADATA command cleans up the inconsistent metadata:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;cleanup metadata, return details;
Metadata Cleanup: started
Start: Cleanup Orphan Objects Entries
Entry #1(OBJECT): TRAFODION.SCH026.T026T10
End: Cleanup Orphan Objects Entries (1 entry cleaned up)
Start: Cleanup Orphan Hbase Entries
Entry #1(OBJECT): TRAFODION.SCH026.T026T11
End: Cleanup Orphan Hbase Entries (1 entry cleaned up)
Start: Cleanup Inconsistent Objects Entries
Entry #1(OBJECT): TRAFODION.SCH026.T026T12
Entry #2(UID): 29899934458095403
End: Cleanup Inconsistent Objects Entries (2 entries cleaned up)
Start: Cleanup Inconsistent Views Entries
End: Cleanup Inconsistent Views Entries (0 entries cleaned up)
Metadata Cleanup: done
--- SQL operation complete.
&gt;&gt;
&gt;&gt;cleanup metadata, check, return details;
Metadata Cleanup: started, check only
Start: Cleanup Orphan Objects Entries
End: Cleanup Orphan Objects Entries (0 entries found)
Start: Cleanup Orphan Hbase Entries
End: Cleanup Orphan Hbase Entries (0 entries found)
Start: Cleanup Inconsistent Objects Entries
End: Cleanup Inconsistent Objects Entries (0 entries found)
Start: Cleanup Inconsistent Views Entries
End: Cleanup Inconsistent Views Entries (0 entries found)
Metadata Cleanup: done
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="load_statement">4.2. LOAD Statement</h3>
<div class="paragraph">
<p>The LOAD statement uses the Trafodion Bulk Loader to load data from a
source table, either a Trafodion table or a Hive table, into a target
Trafodion table. The Trafodion Bulk Loader prepares and loads HFiles
directly in the region servers and bypasses the write path and the cost
associated with it. The write path begins at a client, moves to a region
server, and ends when data eventually is written to an HBase data file
called an HFile.</p>
</div>
<div class="paragraph">
<p>The Trafodion bulk load process takes place in the following phases:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><strong>Disable Indexes</strong> (if incremental index build not used)</p>
</li>
<li>
<p><strong>Prepare</strong> (takes most time, heart of the bulk load operation)</p>
<div class="ulist">
<ul>
<li>
<p>Read source files (Trafodion Table, Hive table, or Hive external table)</p>
</li>
<li>
<p>Data encoded in Trafodion encoding</p>
</li>
<li>
<p>Data repartitioned and sorted to match regions of target table</p>
</li>
<li>
<p>Data written to HFiles</p>
</li>
<li>
<p>Data repartitioned and written to index HFiles (if incremental index build IS used)</p>
</li>
</ul>
</div>
</li>
<li>
<p><strong>Complete</strong> (with or without Snapshot recovery)</p>
<div class="ulist">
<ul>
<li>
<p>Take a snapshot of the table</p>
</li>
<li>
<p>Merge HFiles into HBase table (very fast – move, not a copy)</p>
</li>
<li>
<p>Delete snapshot or restore from snapshot if merge fails</p>
</li>
</ul>
</div>
</li>
<li>
<p><strong>Populate Indexes</strong> (if incremental index build is NOT used)</p>
</li>
<li>
<p><strong>Cleanup</strong></p>
<div class="ulist">
<ul>
<li>
<p>HFiles temporary space cleanup</p>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>LOAD is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LOAD [WITH option[[,] option]...] INTO target-table SELECT ... FROM source-table
option is:
TRUNCATE TABLE
| NO RECOVERY
| NO POPULATE INDEXES
| NO DUPLICATE CHECK
| NO OUTPUT
| INDEX TABLE ONLY
| UPSERT USING LOAD</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="load_syntax">4.2.1. Syntax Description of LOAD</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>target-table</em></code></p>
<div class="paragraph">
<p>is the name of the target Trafodion table where the data will be loaded.
See <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code><em>source-table</em></code></p>
<div class="paragraph">
<p>is the name of either a Trafodion table or a Hive table that has the
source data. Hive tables can be accessed in Trafodion using the
HIVE.HIVE schema (for example, hive.hive.orders). The Hive table needs
to already exist in Hive before Trafodion can access it. If you want to
load data that is already in an HDFS folder, then you need to create an
external Hive table with the right fields and pointing to the HDFS
folder containing the data. You can also specify a WHERE clause on the
source data as a filter.</p>
</div>
</li>
<li>
<p><code>[WITH <em>option</em>[[,] <em>option</em>]&#8230;]</code></p>
<div class="paragraph">
<p>is a set of options that you can specify for the load operation. You can
specify one or more of these options:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>TRUNCATE TABLE</code></p>
<div class="paragraph">
<p>causes the Bulk Loader to truncate the target table before starting the
load operation. By default, the Bulk Loader does not truncate the target
table before loading data.</p>
</div>
</li>
<li>
<p><code>NO RECOVERY</code></p>
<div class="paragraph">
<p>specifies that the Bulk Loader not use HBase snapshots for recovery. By
default, the Bulk Loader handles recovery using the HBase snapshots
mechanism.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>NO POPULATE INDEXES</code></p>
<div class="paragraph">
<p>specifies that the Bulk Loader not handle index maintenance or populate
the indexes. By default, the Bulk Loader handles index maintenance,
disabling indexes before starting the load operation and populating them
after the load operation is complete.</p>
</div>
</li>
<li>
<p><code>NO DUPLICATE CHECK</code></p>
<div class="paragraph">
<p>causes the Bulk Loader to ignore duplicates in the source data. By
default, the Bulk Loader checks if there are duplicates in the source
data and generates an error when it detects duplicates.</p>
</div>
</li>
<li>
<p><code>NO OUTPUT</code></p>
<div class="paragraph">
<p>prevents the LOAD statement from displaying status messages. By default,
the LOAD statement prints status messages listing the steps that the
Bulk Loader is executing.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>INDEX TABLE ONLY</code></p>
<div class="paragraph">
<p>specifies that the target table, which is an index, be populated with
data from the parent table.</p>
</div>
</li>
<li>
<p><code>UPSERT USING LOAD</code></p>
<div class="paragraph">
<p>specifies that the data be inserted into the target table using row set
inserts without a transaction.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="load_considerations">4.2.2. Considerations for LOAD</h4>
<div class="sect4">
<h5 id="load_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue a LOAD statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the target table.</p>
</li>
<li>
<p>You have these privileges:</p>
<div class="ulist">
<ul>
<li>
<p>SELECT and INSERT privileges on the target table</p>
</li>
<li>
<p>DELETE privilege on the target table if TRUNCATE TABLE is specified</p>
</li>
</ul>
</div>
</li>
<li>
<p>You have the MANAGE_LOAD component privilege for the SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="load_configuration_before_running_load">Configuration Before Running LOAD</h5>
<div class="paragraph">
<p>Before running the LOAD statement, make sure that you have configured
the staging folder, source table, and HBase according to these
guidelines.</p>
</div>
</div>
<div class="sect4">
<h5 id="_staging_folder_for_hfiles">Staging Folder for HFiles</h5>
<div class="paragraph">
<p>The Bulk Loader uses an HDFS folder as a staging area for the HFiles
before calling HBase APIs to merge them into the Trafodion table.</p>
</div>
<div class="paragraph">
<p>By default, Trafodion uses /bulkload as the staging folder. This folder
must be owned by the same user as the one under which Trafodion runs. Trafodion
also must have full permissions on this folder. The HBase user (that is,
the user under which HBase runs) must have read/write access to this
folder.</p>
</div>
<div class="paragraph">
<p>Example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">drwxr-xr-x - trafodion trafodion 0 2014-07-07 09:49 /bulkload.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="_improving_throughput">Improving Throughput</h5>
<div class="paragraph">
<p>The following CQD (Control Query Default) settings help improve the Bulk Loader
throughput:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>TRAF_LOAD_MAX_HFILE_SIZE</code></p>
<div class="paragraph">
<p>Specifies the HFile size limit beyond which the current file is closed and a
new file is created for the same partition. Adjust this setting to minimize
HBase splitting/merging.</p>
</div>
<div class="paragraph">
<p><strong>Default</strong>: 10GB</p>
</div>
</li>
<li>
<p><code>TRAF_LOAD_PREP_TMP_LOCATION</code></p>
<div class="paragraph">
<p>Specifies the HDFS directory where HFiles are created during load.</p>
</div>
<div class="paragraph">
<p><strong>Default</strong>: <code>/bulkload</code></p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Also, consider using <code>NO DUPLICATE CHECK</code> to improve througput if your
source data is clean.</p>
</div>
</div>
<div class="sect4">
<h5 id="_hive_source_table">Hive Source Table</h5>
<div class="paragraph">
<p>To load data stored in HDFS, you need to create a Hive table with
the right fields and types pointing to the HDFS folder containing the
data before you start the load.</p>
</div>
</div>
<div class="sect4">
<h5 id="_hbase_snapshots">HBase Snapshots</h5>
<div class="paragraph">
<p>If you do not specify the NO RECOVERY OPTION in the LOAD statement, the
Bulk Loader uses HBase snapshots as a mechanism for recovery. Snapshots
are a lightweight operation where some metadata is copied. (Data is not
copied.)</p>
</div>
<div class="paragraph">
<p>A snapshot is taken before the load starts and is removed after
the load completes successfully. If something goes wrong and it is
possible to recover, the snapshot is used to restore the table to its
initial state before the load started. To use this recovery mechanism,
HBase needs to be configured to allow snapshots.</p>
</div>
</div>
<div class="sect4">
<h5 id="_incremental_loads">Incremental Loads</h5>
<div class="paragraph">
<p>The Bulk Loader allows for incremental loads by default. Snapshots are
taken before second phase starts and deleted once the bulk load completes.</p>
</div>
<div class="paragraph">
<p>If something goes wrong with the load, then the snapshot is restored to
go to the previous state.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="_non_incremental_loads">Non-Incremental Loads</h5>
<div class="paragraph">
<p>These following bulk load options can be used to do non-incremental load:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>NO RECOVERY</code>: Do not take a snapshot of the table.</p>
</li>
<li>
<p><code>TRUNCATE TABLE</code>: Truncates the table before starting the load.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="_space_usage">Space Usage</h5>
<div class="paragraph">
<p>The target table values for SYSKEY, SALT, identity, divisioning columns
are created automatically the during transformation step. The size of the
HBase files is determined based on encoding, compression, HDFS replication
factor, and row format. Target table can be pre-split into regions using
salting, a Java Program, by seeding the table with data.</p>
</div>
</div>
<div class="sect4">
<h5 id="_performance">Performance</h5>
<div class="paragraph">
<p>The overall throughput is influenced by row format, row length, number of
columns, skew in data, etc. LOAD sas upsert semantics (duplicate constraint
not checked with existing data). LOAD has lower CPU abd disk activity than
similar trickle load (INSERT, UPSERT, or UPSERT USING LOAD), Also, LOAD has
lower compaction activity after completion than Trickle Load.</p>
</div>
</div>
<div class="sect4">
<h5 id="_hive_scans">Hive Scans</h5>
<div class="paragraph">
<p>Direct access for Hive table data supports:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Only text input format and sequence files.</p>
</li>
<li>
<p>Only structured data types.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Tables must be created/dropped/altered through Hive itself.</p>
</div>
<div class="paragraph">
<p>Trafodion:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Reads Hive metadata to determine information about table.</p>
</li>
<li>
<p>UPDATE STATISTICS can be performed on Hive tables - improves performance!</p>
</li>
<li>
<p>Can write to Hive tables in both Text and Sequence formats (used by UNLOAD).</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="load_examples">4.2.3. Examples of LOAD</h4>
<div class="ulist">
<ul>
<li>
<p>For customer demographics data residing in
<code>/hive/tpcds/customer_demographics</code>, create an external Hive table using
the following Hive SQL:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create external table customer_demographics
(
cd_demo_sk int
, cd_gender string
, cd_marital_status string
, cd_education_status string
, cd_purchase_estimate int
, cd_credit_rating string
, cd_dep_count int
, cd_dep_employed_count int
, cd_dep_college_count int
)
row format delimited fields terminated by '|' location
'/hive/tpcds/customer_demographics';</code></pre>
</div>
</div>
</li>
<li>
<p>The Trafodion table where you want to load the data is defined using
this DDL:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">create table customer_demographics_salt
(
cd_demo_sk int not null
, cd_gender char(1)
, cd_marital_status char(1)
, cd_education_status char(20)
, cd_purchase_estimate int
, cd_credit_rating char(10)
, cd_dep_count int
, cd_dep_employed_count int
, cd_dep_college_count int
, primary key (cd_demo_sk)
)
salt using 4 partitions on (cd_demo_sk);</code></pre>
</div>
</div>
</li>
<li>
<p>This example shows how the LOAD statement loads the
customer_demographics_salt table from the Hive table,
<code>hive.hive.customer_demographics</code>:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;load into customer_demographics_salt
+&gt;select * from hive.hive.customer_demographics where cd_demo_sk &lt;= 5000;
Task: LOAD Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT
Task: DISABLE INDEX Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT
Task: DISABLE INDEX Status: Ended Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT
Task: PREPARATION Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT
Rows Processed: 5000
Task: PREPARATION Status: Ended ET: 00:00:03.199
Task: COMPLETION Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT
Task: COMPLETION Status: Ended ET: 00:00:00.331
Task: POPULATE INDEX Status: Started Object: TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS_SALT
Task: POPULATE INDEX Status: Ended ET: 00:00:05.262</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="populate_index_utility">4.3. POPULATE INDEX Utility</h3>
<div class="paragraph">
<p>The POPULATE INDEX utility performs a fast INSERT of data into an index
from the parent table. You can execute this utility in a client-based
tool like TrafCI.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">POPULATE INDEX index ON table [index-option]
index-option is:
ONLINE | OFFLINE</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="populate_index_syntax">4.3.1. Syntax Description of POPULATE INDEX</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>index</em></code></p>
<div class="paragraph">
<p>is an SQL identifier that specifies the simple name for the index. You
cannot qualify <em>index</em> with its schema name. Indexes have their own
name space within a schema, so an index name might be the same as a table
or constraint name. However, no two indexes in a schema can have the
same name.</p>
</div>
</li>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>is the name of the table for which to populate the index. See
<a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code>ONLINE</code></p>
<div class="paragraph">
<p>specifies that the populate operation should be done on-line. That is,
ONLINE allows read and write DML access on the base table while the
populate operation occurs. Additionally, ONLINE reads the audit trail to
replay updates to the base table during the populate phase. If a lot of
audit is generated and you perform many CREATE INDEX operations, we
recommend that you avoid ONLINE operations because they can add more
contention to the audit trail. The default is ONLINE.</p>
</div>
</li>
<li>
<p><code>OFFLINE</code></p>
<div class="paragraph">
<p>specifies that the populate should be done off-line. OFFLINE allows only
read DML access to the base table. The base table is unavailable for
write operations at this time. OFFLINE must be specified explicitly.
SELECT is allowed.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="populate_index_considerations">4.3.2. Considerations for POPULATE INDEX</h4>
<div class="paragraph">
<p>When POPULATE INDEX is executed, the following steps occur:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The POPULATE INDEX operation runs in many transactions.</p>
</li>
<li>
<p>The actual data load operation is run outside of a transaction.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>If a failure occurs, the rollback is faster because it does not have to
process a lot of audit. Also, if a failure occurs, the index remains
empty, unaudited, and not attached to the base table (off-line).</p>
</div>
<div class="ulist">
<ul>
<li>
<p>When an off-line POPULATE INDEX is being executed, the base table is
accessible for read DML operations. When an on-line POPULATE INDEX is
being executed, the base table is accessible for read and write DML
operations during that time period, except during the commit phase at
the very end.</p>
</li>
<li>
<p>If the POPULATE INDEX operation fails unexpectedly, you may need to
drop the index again and re-create and repopulate.</p>
</li>
<li>
<p>On-line POPULATE INDEX reads the audit trail to replay updates by
allowing read/write access. If you plan to create many indexes in
parallel or if you have a high level of activity on the audit trail, you
should consider using the OFFLINE option.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Errors can occur if the source base table or target index cannot be
accessed, or if the load fails due to some resource problem or problem
in the file system.</p>
</div>
<div class="sect4">
<h5 id="populate_index_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To perform a POPULATE INDEX operation, one of the following must be
true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the table.</p>
</li>
<li>
<p>You have the SELECT and INSERT (or ALL) privileges on the associated table.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="populate_index_examples">4.3.3. Examples of POPULATE INDEX</h4>
<div class="ulist">
<ul>
<li>
<p>This example loads the specified index from the specified table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">POPULATE INDEX myindex ON myschema.mytable;</code></pre>
</div>
</div>
</li>
<li>
<p>This example loads the specified index from the specified table, which
uses the default schema:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">POPULATE INDEX index2 ON table2;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="purgedata_utility">4.4. PURGEDATA Utility</h3>
<div class="paragraph">
<p>The PURGEDATA utility performs a fast DELETE of data from a table and
its related indexes. You can execute this utility in a client-based tool
like TrafCI.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">PURGEDATA object</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="purgedata_syntax">4.4.1. Syntax Description of PURGEDATA</h4>
<div class="paragraph">
<p><em>object</em></p>
</div>
<div class="paragraph">
<p>is the name of the table from which to purge the data. See
<a href="#database object names">Database Object Names</a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="purgedata_considerations">4.4.2. Considerations for PURGEDATA</h4>
<div class="ulist">
<ul>
<li>
<p>The <em>object</em> can be a table name.</p>
</li>
<li>
<p>Errors are returned if <em>table</em> cannot be accessed or if a resource or
file-system problem causes the delete to fail.</p>
</li>
<li>
<p>PURGEDATA is not supported for volatile tables.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="purgedata_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To perform a PURGEDATA operation, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the table.</p>
</li>
<li>
<p>You have the SELECT and DELETE (or ALL) privileges on the associated
table.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="purgedata_availability">Availability</h5>
<div class="paragraph">
<p>PURGEDATA marks the table OFFLINE and sets the corrupt bit while
processing. If PURGEDATA fails before it completes, the table and its
dependent indexes will be unavailable, and you must run PURGEDATA again
to complete the operation and remove the data. Error 8551 with an
accompanying file system error 59 or error 1071 is returned in this
case.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="purgedata_examples">4.4.3. Examples of PURGEDATA</h4>
<div class="ulist">
<ul>
<li>
<p>This example purges the data in the specified table. If the table has
indexes, their data is also purged.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">PURGEDATA myschema.mytable;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="unload_statement">4.5. UNLOAD Statement</h3>
<div class="paragraph">
<p>The UNLOAD statement unloads data from Trafodion tables into an HDFS
location that you specify. Extracted data can be either compressed or
uncompressed based on what you choose.</p>
</div>
<div class="paragraph">
<p>UNLOAD is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UNLOAD [WITH option[ option]...] INTO 'target-location' SELECT ... FROM source-table ...
option is:
DELIMITER { 'delimiter-string' | delimiter-ascii-value }
| RECORD_SEPARATOR { 'separator-literal' | separator-ascii-value }
| NULL_STRING 'string-literal'
| PURGEDATA FROM TARGET
| COMPRESSION GZIP
| MERGE FILE merged_file-path [OVERWRITE]
| NO OUTPUT
| { NEW | EXISTING } SNAPSHOT HAVING SUFFIX 'string'</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="unload_syntax">4.5.1. Syntax Description of UNLOAD</h4>
<div class="ulist">
<ul>
<li>
<p><code>'<em>target-location</em>'</code></p>
<div class="paragraph">
<p>is the full pathname of the target HDFS folder where the extracted data
will be written. Enclose the name of folder in single quotes. Specify
the folder name as a full pathname and not as a relative path. You must
have write permissions on the target HDFS folder. If you run UNLOAD in
parallel, multiple files will be produced under the <em>target-location</em>.
The number of files created will equal the number of ESPs.</p>
</div>
</li>
<li>
<p><code>SELECT &#8230; FROM <em>source-table</em> &#8230;</code></p>
<div class="paragraph">
<p>is either a simple query or a complex one that contains GROUP BY, JOIN,
or UNION clauses. <em>source-table</em> is the name of a Trafodion table that
has the source data. See <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code>[WITH <em>option</em>[ <em>option</em>]&#8230;]</code></p>
<div class="paragraph">
<p>is a set of options that you can specify for the unload operation. If
you specify an option more than once, Trafodion returns an error with
SQLCODE -4489. You can specify one or more of these options:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>DELIMITER { '<em>delimiter-string</em>' | <em>delimiter-ascii-value</em> }</code></p>
<div class="paragraph">
<p>specifies the delimiter as either a delimiter string or an ASCII value.
If you do not specify this option, Trafodion uses the character "|" as
the delimiter.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><em>delimiter-string</em> can be any ASCII or Unicode string. You can also
specify the delimiter as an ASCII value. Valid values range from 1 to 255.
Specify the value in decimal notation; hexadecimal or octal
notation are currently not supported. If you are using an ASCII value,
the delimiter can be only one character wide. Do not use quotes when
specifying an ASCII value for the delimiter.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>RECORD_SEPARATOR { '<em>separator-literal</em>' | <em>separator-ascii-value</em> }</code></p>
<div class="paragraph">
<p>specifies the character that will be used to separate consecutive
records or rows in the output file. You can specify either a literal
or an ASCII value for the separator. The default value is a newline character.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><em>separator-literal</em> can be any ASCII or Unicode character. You can also
specify the separator as an ASCII value. Valid values range from 1 to 255.
Specify the value in decimal notation; hexadecimal or octal
notation are currently not supported. If you are using an ASCII value,
the separator can be only one character wide. Do not use quotes when
specifying an ASCII value for the separator.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code>NULL_STRING '<em>string-literal</em>'</code></p>
<div class="paragraph">
<p>specifies the string that will be used to indicate a NULL value. The
default value is the empty string ''.</p>
</div>
</li>
<li>
<p><code>PURGEDATA FROM TARGET</code></p>
<div class="paragraph">
<p>causes files in the target HDFS folder to be deleted before the unload
operation.</p>
</div>
</li>
<li>
<p><code>COMPRESSION GZIP</code></p>
<div class="paragraph">
<p>uses gzip compression in the extract node, writing the data to disk in
this compressed format. GZIP is currently the only supported type of
compression. If you do not specify this option, the extracted data will
be uncompressed.</p>
</div>
</li>
<li>
<p><code>MERGE FILE <em>merged_file-path</em> [OVERWRITE]</code></p>
<div class="paragraph">
<p>merges the unloaded files into one single file in the specified
<em>merged-file-path</em>. If you specify compression, the unloaded data will
be in compressed format, and the merged file will also be in compressed
format. If you specify the optional OVERWRITE keyword, the file is
overwritten if it already exists; otherwise, Trafodion raises an error
if the file already exists.</p>
</div>
</li>
<li>
<p><code>NO OUTPUT</code></p>
<div class="paragraph">
<p>prevents the UNLOAD statement from displaying status messages. By
default, the UNLOAD statement prints status messages listing the steps
that the Bulk Unloader is executing.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>{ NEW | EXISTING } SNAPSHOT HAVING SUFFIX '<em>string</em>'</code></p>
<div class="paragraph">
<p>initiates an HBase snapshot scan during the unload operation. During a
snapshot scan, the Bulk Unloader will get a list of the Trafodion tables
from the query explain plan and will create and verify snapshots for the
tables. Specify a suffix string, '<em>string</em>', which will be appended to
each table name.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="unload_considerations">4.5.2. Considerations for UNLOAD</h4>
<div class="ulist">
<ul>
<li>
<p>You must have write permissions on the target HDFS folder.</p>
</li>
<li>
<p>If a WITH option is specified more than once, Trafodion returns an
error with SQLCODE -4489.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="unload_required_privileges">Required Privileges</h5>
<div class="paragraph">
<p>To issue an UNLOAD statement, one of the following must be true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the target table.</p>
</li>
<li>
<p>You have the SELECT privilege on the target table.</p>
</li>
<li>
<p>You have the MANAGE_LOAD component privilege for the SQL_OPERATIONS
component.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="unload_examples">4.5.3. Examples of UNLOAD</h4>
<div class="ulist">
<ul>
<li>
<p>This example shows how the UNLOAD statement extracts data from a
Trafodion table, <code>TRAFODION.HBASE.CUSTOMER_DEMOGRAPHICS</code>, into an HDFS
folder, <code>/bulkload/customer_demographics</code>:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;UNLOAD
+&gt;WITH PURGEDATA FROM TARGET
+&gt;MERGE FILE 'merged_customer_demogs.gz' OVERWRITE
+&gt;COMPRESSION GZIP
+&gt;INTO '/bulkload/customer_demographics'
+&gt;select * from trafodion.hbase.customer_demographics
+&gt;&lt;&lt;+ cardinality 10e10 ,+ cardinality 10e10 &gt;&gt;;
Task: UNLOAD Status: Started
Task: EMPTY TARGET Status: Started
Task: EMPTY TARGET Status: Ended ET: 00:00:00.014
Task: EXTRACT Status: Started
Rows Processed: 200000
Task: EXTRACT Status: Ended ET: 00:00:04.743 Task: MERGE FILES Status: Started
Task: MERGE FILES Status: Ended ET: 00:00:00.063
--- 200000 row(s) unloaded.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="update_statistics_statement">4.6. UPDATE STATISTICS Statement</h3>
<div class="paragraph">
<p>The UPDATE STATISTICS statement updates the histogram statistics for one
or more groups of columns within a table. These statistics are used to
devise optimized access plans.</p>
</div>
<div class="paragraph">
<p>UPDATE STATISTICS is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE STATISTICS FOR TABLE table [CLEAR | on-clause | sample-table-clause ]
on-clause is:
ON column-group-list CLEAR
| ON column-group-list [histogram-option]...
| ON column-group-list INCREMENTAL WHERE predicate
column-group-list is:
column-list [,column-list]...
| EVERY COLUMN [,column-list]...
| EVERY KEY [,column-list]...
| EXISTING COLUMN[S] [,column-list]...
| NECESSARY COLUMN[S] [,column-list]...
column-list for a single-column group is:
column-name
| (column-name)
| column-name TO column-name
| (column-name) TO (column-name)
| column-name TO (column-name)
| (column-name) TO column-name
column-list for a multicolumn group is:
(column-name, column-name [,column-name]...)
histogram-option is:
GENERATE n INTERVALS
| SAMPLE [sample-option]
sample-option is:
[r ROWS]
| RANDOM percent PERCENT [PERSISTENT]
| PERIODIC size ROWS EVERY period ROWS
sample-table-clause is:
CREATE SAMPLE RANDOM percent PERCENT
| REMOVE SAMPLE</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="update_statistics_syntax">4.6.1. Syntax Description of UPDATE STATISTICS</h4>
<div class="ulist">
<ul>
<li>
<p><code><em>table</em></code></p>
<div class="paragraph">
<p>names the table for which statistics are to be updated. To refer to a
table, use the ANSI logical name.
See <a href="#database_object_names">Database Object Names</a>.</p>
</div>
</li>
<li>
<p><code>CLEAR</code></p>
<div class="paragraph">
<p>deletes some or all histograms for the table <em>table</em>. Use this option
when new applications no longer use certain histogram statistics.</p>
</div>
<div class="paragraph">
<p>If you do not specify <em>column-group-list</em>, all histograms for <em>table</em>
are deleted. If you specify <em>column-group-list</em>, only columns in the
group list are deleted.</p>
</div>
</li>
<li>
<p><code>ON <em>column-group-list</em></code></p>
<div class="paragraph">
<p>specifies one or more groups of columns for which to generate histogram
statistics with the option of clearing the histogram statistics. You
must use the ON clause to generate statistics stored in histogram
tables.</p>
</div>
</li>
<li>
<p><code><em>column-list</em></code></p>
<div class="paragraph">
<p>specifies how <em>column-group-list</em> can be defined. The column list
represents both a single-column group and a multi-column group.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Single-column group:</p>
<div class="ulist">
<ul>
<li>
<p><code><em>column-name</em> | (<em>column-name</em>) | <em>column-name</em> TO <em>column-name</em> |
(<em>column-name</em>) TO (<em>column-name</em>)</code></p>
<div class="paragraph">
<p>specifies how you can specify individual columns or a group of
individual columns.</p>
</div>
<div class="paragraph">
<p>To generate statistics for individual columns, list each column. You can
list each single column name within or without parentheses.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p>Multicolumn group:</p>
<div class="ulist">
<ul>
<li>
<p><code>(<em>column-name</em>, <em>column-name</em> [,<em>column-name</em>]&#8230;)</code></p>
<div class="paragraph">
<p>specifies a multi-column group.</p>
</div>
<div class="paragraph">
<p>To generate multi-column statistics, group a set of columns within
parentheses, as shown. You cannot specify the name of a column more than
once in the same group of columns.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>One histogram is generated for each unique column group. Duplicate
groups, meaning any permutation of the same group of columns, are
ignored and processing continues. When you run UPDATE STATISTICS again
for the same user table, the new data for that table replaces the data
previously generated and stored in the table’s histogram tables.
Histograms of column groups not specified in the ON clause remain
unchanged in histogram tables.</p>
</div>
<div class="paragraph">
<p>For more information about specifying columns, see
<a href="#generating_and_clearing_statistics_for_columns">Generating and Clearing Statistics for Columns</a>.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>EVERY COLUMN</code></p>
<div class="paragraph">
<p>The EVERY COLUMN keyword indicates that histogram statistics are to be
generated for each individual column of <em>table</em> and any multi-columns
that make up the primary key and indexes. For example, <em>table</em> has
columns A, B, C, D defined, where A, B, C compose the primary key. In
this case, the ON EVERY COLUMN option generates a single column
histogram for columns A, B, C, D, and two multi-column histograms of (A,
B, C) and (A, B).</p>
</div>
<div class="paragraph">
<p>The EVERY COLUMN option does what EVERY KEY does, with additional
statistics on the individual columns.</p>
</div>
</li>
<li>
<p><code>EVERY KEY</code></p>
<div class="paragraph">
<p>The EVERY KEY keyword indicates that histogram statistics are to be
generated for columns that make up the primary key and indexes. For
example, <em>table</em> has columns A, B, C, D defined. If the primary key
comprises columns A, B, statistics are generated for (A, B), A and B. If
the primary key comprises columns A, B, C, statistics are generated for
(A,B,C), (A,B), A, B, C. If the primary key comprises columns A, B, C,
D, statistics are generated for (A, B, C, D), (A, B, C), (A, B), and A,
B, C, D.</p>
</div>
</li>
<li>
<p><code>EXISTING COLUMN[S]</code></p>
<div class="paragraph">
<p>The EXISTING COLUMN keyword indicates that all existing histograms of
the table are to be updated. Statistics must be previously captured to
establish existing columns.</p>
</div>
</li>
<li>
<p><code>NECESSARY COLUMN[S]</code></p>
<div class="paragraph">
<p>The NECESSARY COLUMN[S] keyword generates statistics for histograms that
the optimizer has requested but do not exist. Update statistics
automation must be enabled for NECESSARY COLUMN[S] to generate
statistics. To enable automation, see <a href="#update_statistics_automating_update_statistics">Automating Update Statistics</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>histogram-option</em></code></p>
<div class="ulist">
<ul>
<li>
<p><code>GENERATE <em>n</em> INTERVALS</code></p>
<div class="paragraph">
<p>The GENERATE <em>n</em> INTERVALS option for UPDATE STATISTICS accepts values
between 1 and 10,000. Keep in mind that increasing the number of
intervals per histograms may have a negative impact on compile time.</p>
</div>
<div class="paragraph">
<p>Increasing the number of intervals can be used for columns with small
set of possible values and large variance of the frequency of these
values. For example, consider a column ‘CITY’ in table SALES, which
stores the city code where the item was sold, where number of cities in
the sales data is 1538. Setting the number of intervals to a number
greater or equal to the number of cities (that is, setting the number of
intervals to 1600) guarantees that the generated histogram captures the
number of rows for each city. If the specified value n exceeds the
number of unique values in the column, the system generates only as many
intervals as the number of unique values.</p>
</div>
</li>
<li>
<p><code>SAMPLE [<em>sample-option</em>]</code></p>
<div class="paragraph">
<p>is a clause that specifies that sampling is to be used to gather a
subset of the data from the table. UPDATE STATISTICS stores the sample
results and generates histograms.</p>
</div>
<div class="paragraph">
<p>If you specify the SAMPLE clause without additional options, the result
depends on the number of rows in the table. If the table contains no
more than 10,000 rows, the entire table will be read (no sampling). If
the number of rows is greater than 10,000 but less than 1 million,
10,000 rows are randomly sampled from the table. If there are more than
1 million rows in the table, a random row sample is used to read 1
percent of the rows in the table, with a maximum of 1 million rows
sampled.</p>
</div>
<div class="admonitionblock tip">
<table>
<tr>
<td class="icon">
<i class="fa icon-tip" title="Tip"></i>
</td>
<td class="content">
As a guideline, the default sample of 1 percent of the rows in the
table, with a maximum of 1 million rows, provides good statistics for
the optimizer to generate good plans.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>If you do not specify the SAMPLE clause, if the table has fewer rows
than specified, or if the sample size is greater than the system limit,
Trafodion SQL reads all rows from <em>table</em>. See <a href="#sample_clause">SAMPLE Clause</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>sample-option</em></code></p>
<div class="ulist">
<ul>
<li>
<p><code>r_ rows</code></p>
<div class="paragraph">
<p>A row sample is used to read <em>r</em> rows from the table. The value <em>r</em> must
be an integer that is greater than zero</p>
</div>
</li>
<li>
<p><code>RANDOM <em>percent</em> PERCENT</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to choose rows randomly from the table. The value
percent must be a value between zero and 100 (0 &lt; percent &#60;= 100). In
addition, only the first four digits to the right of the decimal point
are significant. For example, value 0.00001 is considered to be 0.0000,
Value 1.23456 is considered to be 1.2345.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>PERSISTENT</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to create a persistent sample table and store the
random sample in it. This table can then be used later for updating statistics
incrementally.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>PERIODIC <em>size</em> ROWS EVERY <em>period</em> ROW</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to choose the first <em>size</em> number of rows from
each <em>period</em> of rows. The value <em>size</em> must be an integer that is
greater than zero and less than or equal to the value <em>period</em>. (0 &lt;
<em>size</em> &#60;= <em>period</em>). The size of the <em>period</em> is defined by the number
of rows specified for <em>period</em>. The value <em>period</em> must be an integer
that is greater than zero (<em>period</em> &gt; 0).</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>INCREMENTAL WHERE <em>predicate</em></code></p>
<div class="paragraph">
<p>directs Trafodion SQL to update statistics incrementally. That is, instead
of taking a fresh sample of the entire table, Trafodion SQL will use a previously
created persistent sample table. Trafodion SQL will update the persistent sample
by replacing any rows satisfying the <em>predicate</em> with a fresh sample of rows from
the original table satisfying the <em>predicate</em>. The sampling rate used is the
<em>percent</em> specified when the persistent sample table was created. Statistics
are then generated from this updated sample. See also
<a href="#update_statistics_incremental_update_statistics">Incremental Update Statistics</a>.</p>
</div>
</li>
<li>
<p><code>CREATE SAMPLE RANDOM <em>percent</em> PERCENT</code></p>
<div class="paragraph">
<p>Creates a persistent sample table associated with this table. The sample is
created using a random sample of <em>percent</em> percent of the rows. The table
can then be used for later incremental statistics update.</p>
</div>
</li>
<li>
<p><code>REMOVE SAMPLE</code></p>
<div class="paragraph">
<p>Drops the persistent sample table associated with this table.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="update_statistics_considerations">4.6.2. Considerations for UPDATE STATISTICS</h4>
<div class="sect4">
<h5 id="update_statistics_using_statistics">Using Statistics</h5>
<div class="paragraph">
<p>Use UPDATE STATISTICS to collect and save statistics on columns. The SQL
compiler uses histogram statistics to determine the selectivity of
predicates, indexes, and tables. Because selectivity directly influences
the cost of access plans, regular collection of statistics increases the
likelihood that Trafodion SQL chooses efficient access plans.</p>
</div>
<div class="paragraph">
<p>While UPDATE STATISTICS is running on a table, the table is active and
available for query access.</p>
</div>
<div class="paragraph">
<p>When a user table is changed, either by changing its data significantly
or its definition, re-execute the UPDATE STATISTICS statement for the
table.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="update_statistics_histogram_statistics">Histogram Statistics</h5>
<div class="paragraph">
<p>Histogram statistics are used by the compiler to produce the best plan
for a given SQL query. When histograms are not available, default
assumptions are made by the compiler and the resultant plan might not
perform well. Histograms that reflect the latest data in a table are
optimal.</p>
</div>
<div class="paragraph">
<p>The compiler does not need histogram statistics for every column of a
table. For example, if a column is only in the select list, its
histogram statistics will be irrelevant. A histogram statistic is useful
when a column appears in:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>A predicate</p>
</li>
<li>
<p>A GROUP BY column</p>
</li>
<li>
<p>An ORDER BY clause</p>
</li>
<li>
<p>A HAVING clause</p>
</li>
<li>
<p>Or similar clause</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>In addition to single-column histogram statistics, the compiler needs
multi-column histogram statistics, such as when group by column-5,
column-3, column-19 appears in a query. Then, histogram statistics for
the combination (column-5, column-3, column-19) are needed.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_statistics_required-privileges">Required Privileges</h5>
<div class="paragraph">
<p>To perform an UPDATE STATISTICS operation, one of the following must be
true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>You are DB ROOT.</p>
</li>
<li>
<p>You are the owner of the target table.</p>
</li>
<li>
<p>You have the MANAGE_STATISTICS component privilege for the
SQL_OPERATIONS component.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="update_statistics_locking">Locking</h5>
<div class="paragraph">
<p>UPDATE STATISTICS momentarily locks the definition of the user table
during the operation but not the user table itself. The UPDATE
STATISTICS statement uses READ UNCOMMITTED isolation level for the user
table.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="update_statistics_transactions">Transactions</h5>
<div class="paragraph">
<p>Do not start a transaction before executing UPDATE STATISTICS. UPDATE
STATISTICS runs multiple transactions of its own, as needed. Starting
your own transaction in which UPDATE STATISTICS runs could cause the
transaction auto abort time to be exceeded during processing.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_statistics_generating_and_clearing_statistics_for_columns">Generating and Clearing Statistics for Columns</h5>
<div class="paragraph">
<p>To generate statistics for particular columns, name each column, or name
the first and last columns of a sequence of columns in the table. For
example, suppose that a table has consecutive columns CITY, STATE, ZIP.
This list gives a few examples of possible options you can specify:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25.2525%;">
<col style="width: 37.3737%;">
<col style="width: 37.3738%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Single-Column Group</th>
<th class="tableblock halign-left valign-top">Single-Column Group Within Parentheses</th>
<th class="tableblock halign-left valign-top">Multicolumn Group</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON CITY, STATE, ZIP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON (CITY),(STATE),(ZIP)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON (CITY, STATE) or ON (CITY,STATE,ZIP)</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON CITY TO ZIP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON (CITY) TO (ZIP)</p></td>
<td class="tableblock halign-left valign-top"></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON ZIP TO CITY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON (ZIP) TO (CITY)</p></td>
<td class="tableblock halign-left valign-top"></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON CITY, STATE TO ZIP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON (CITY), (STATE) TO (ZIP)</p></td>
<td class="tableblock halign-left valign-top"></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON CITY TO STATE, ZIP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ON (CITY) TO (STATE), (ZIP)</p></td>
<td class="tableblock halign-left valign-top"></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>The TO specification is useful when a table has many columns, and you
want histograms on a subset of columns. Do not confuse (CITY) TO (ZIP)
with (CITY, STATE, ZIP), which refers to a multi-column histogram.</p>
</div>
<div class="paragraph">
<p>You can clear statistics in any combination of columns you specify, not
necessarily with the <em>column-group-list</em> you used to create statistics.
However, those statistics will remain until you clear them.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="update_statistics_column_lists_and_access_plans">Column Lists and Access Plans</h5>
<div class="paragraph">
<p>Generate statistics for columns most often used in data access plans for
a table—that is, the primary key, indexes defined on the table, and any
other columns frequently referenced in predicates in WHERE or GROUP BY
clauses of queries issued on the table. Use the EVERY COLUMN option to
generate histograms for every individual column or multi columns that
make up the primary key and indexes.</p>
</div>
<div class="paragraph">
<p>The EVERY KEY option generates histograms that make up the primary key
and indexes.</p>
</div>
<div class="paragraph">
<p>If you often perform a GROUP BY over specific columns in a table, use
multi-column lists in the UPDATE STATISTICS statement (consisting of the
columns in the GROUP BY clause) to generate histogram statistics that
enable the optimizer to choose a better plan. Similarly, when a query
joins two tables by two or more columns, multi-column lists (consisting
of the columns being joined) help the optimizer choose a better plan.</p>
</div>
</div>
<div class="sect4">
<h5 id="update_statistics_automating_update_statistics">Automating Update Statistics</h5>
<div class="paragraph">
<p>To enable update statistics automation, set the Control Query Default
(CQD) attribute, USTAT_AUTOMATION_INTERVAL, in a session where you will
run update statistics operations. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">control query default USTAT_AUTOMATION_INTERVAL '1440';</code></pre>
</div>
</div>
<div class="paragraph">
<p>The value of USTAT_AUTOMATION_INTERVAL is intended to be an automation
interval (in minutes), but, in Trafodion Release 1.0, this value does
not act as a timing interval. Instead, any value greater than zero
enables update statistics automation.</p>
</div>
<div class="paragraph">
<p>After enabling update statistics automation, prepare each of the queries
that you want to optimize. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">prepare s from select...;</code></pre>
</div>
</div>
<div class="paragraph">
<p>The PREPARE statement causes the Trafodion SQL compiler to compile and
optimize a query without executing it. When preparing queries with
update statistic automation enabled, any histograms needed by the
optimizer that are not present will cause those columns to be marked as
needing histograms.</p>
</div>
<div class="paragraph">
<p>Next, run this UPDATE STATISTICS statement against each table, using ON
NECESSARY COLUMN[S] to generate the needed histograms:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">update statistics for table _table-name_ on necessary columns sample;</code></pre>
</div>
</div>
</div>
<div class="sect4">
<h5 id="update_statistics_incremental_update_statistics">Incremental Update Statistics</h5>
<div class="paragraph">
<p>UPDATE STATISTICS processing time can be lengthy for very large tables.
One strategy for reducing the time is to create histograms only for
columns that actually need them (for example, using the ON NECESSARY COLUMNS
column group). Another strategy is to update statistics incrementally. These
strategies can be used together if desired.</p>
</div>
<div class="paragraph">
<p>To use the incremental update statistics feature, you must first create
statistics for the table and create a persistent sample table. One way to
do this is to perform a normal update statistics command, adding the
PERSISTENT keyword to the <em>sample-option</em>. Another way to do this if you
already have reasonably up-to-date statistics for the table, is to create
a persistent sample table separately using the CREATE SAMPLE option.</p>
</div>
<div class="paragraph">
<p>You can then perform update statistics incrementally by using the INCREMENTAL
WHERE <em>predicate</em> syntax in the on-clause. The <em>predicate</em> should be chosen
to describe the set of rows that have changed since the last statistics update
was performed. For example, if your table contains a column with a timestamp
giving the date and time of last update, this is a particularly useful column
to use in the <em>predicate</em>.</p>
</div>
<div class="paragraph">
<p>If you decide later that you wish to change the <em>percent</em> sampling rate used
for the persistent sample table, you can do so by dropping the persistent
sample table (using REMOVE SAMPLE) and creating a new one (by using the
CREATE SAMPLE option). Using a higher <em>percent</em> results in more accurate
histograms, but at the price of a longer-running operation.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="update_statistics_examples">4.6.3. Examples of UPDATE STATISTICS</h4>
<div class="ulist">
<ul>
<li>
<p>This example generates four histograms for the columns jobcode,
empnum, deptnum, and (empnum, deptnum) for the table EMPLOYEE. Depending
on the table’s size and data distribution, each histogram should contain
ten intervals.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE STATISTICS FOR TABLE employee
ON (jobcode),(empnum, deptnum) GENERATE 10 INTERVALS;
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>This example generates histogram statistics using the ON EVERY COLUMN
option for the table DEPT. This statement performs a full scan, and
Trafodion SQL determines the default number of intervals.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE STATISTICS FOR TABLE dept ON EVERY COLUMN;
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
<li>
<p>Suppose that a construction company has an ADDRESS table of potential
sites and a DEMOLITION_SITES table that contains some of the columns of
the ADDRESS table. The primary key is ZIP. Join these two tables on two
of the columns in common:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT COUNT(AD.number), AD.street,
AD.city, AD.zip, AD.state
FROM address AD, demolition_sites DS
WHERE AD.zip = DS.zip AND AD.type = DS.type
GROUP BY AD.street, AD.city, AD.zip, AD.state;</code></pre>
</div>
</div>
<div class="paragraph">
<p>To generate statistics specific to this query, enter these statements:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE STATISTICS FOR TABLE address
ON (street), (city), (state), (zip, type);
UPDATE STATISTICS FOR TABLE demolition_sites ON (zip, type);</code></pre>
</div>
</div>
</li>
<li>
<p>This example removes all histograms for table DEMOLITION_SITES:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE STATISTICS FOR TABLE demolition_sites CLEAR;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This example selectively removes the histogram for column STREET in
table ADDRESS:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE STATISTICS FOR TABLE address ON street CLEAR;</code></pre>
</div>
</div>
</li>
<li>
<p>This example generates statistics but also creates a persistent
sample table for use when updating statistics incrementally:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE STATISTICS FOR TABLE address
ON (street), (city), (state), (zip, type)
SAMPLE RANDOM 5 PERCENT PERSISTENT;</code></pre>
</div>
</div>
</li>
<li>
<p>This example updates statistics incrementally. It assumes that
a persistent sample table has already been created. The predicate
in the WHERE clause describes the set of rows that have changed
since statistics were last updated. Here we assume that rows
with a state of California are the only rows that have changed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE STATISTICS FOR TABLE address
ON EXISTING COLUMNS
INCREMENTAL WHERE state = 'CA';</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="sql_language_elements">5. SQL Language Elements</h2>
<div class="sectionbody">
<div class="paragraph">
<p>Trafodion SQL language elements, which include data types, expressions, functions, identifiers, literals, and
predicates, occur within the syntax of SQL statements. The statement and command topics support the syntactical
and semantic descriptions of the language elements in this section.</p>
</div>
<div class="sect2">
<h3 id="_authorization_ids">5.1. Authorization IDs</h3>
<div class="paragraph">
<p>An authorization ID is used for an authorization operation. Authorization is the process of validating that a
database user has permission to perform a specified SQL operation. Externally, the authorization ID is a regular
or delimited case-insensitive identifier that can have a maximum of 128 characters. See
<a href="#case_insensitive_delimited_identifiers">Case-Insensitive Delimited Identifiers</a>.
Internally, the authorization ID is associated with a 32-bit number that the database generates and uses for
efficient access and storage.</p>
</div>
<div class="paragraph">
<p>All authorization IDs share the same name space. An authorization ID can be a database user name or a role name.
Therefore, a database user and a role cannot share the same name.</p>
</div>
<div class="paragraph">
<p>An authorization ID can be the PUBLIC authorization ID, which represents all present and future authorization IDs.
An authorization ID cannot be SYSTEM, which is the implicit grantor of privileges to the creator of objects.</p>
</div>
</div>
<div class="sect2">
<h3 id="character_sets">5.2. Character Sets</h3>
<div class="paragraph">
<p>You can specify ISO88591 or UTF8 for a character column definition. The use of UTF8 permits you to store characters
from many different languages.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="columns">5.3. Columns</h3>
<div class="paragraph">
<p>A column is a vertical component of a table and is the relational representation of a field in a record. A column
contains one data value for each row of the table.</p>
</div>
<div class="paragraph">
<p>A column value is the smallest unit of data that can be selected from or updated in a table. Each column has a name
that is an SQL identifier and is unique within the table or view that contains the column.</p>
</div>
<div class="sect3">
<h4 id="column_references">5.3.1. Column References</h4>
<div class="paragraph">
<p>A qualified column name, or column reference, is a column name qualified by the name of the table or view to which
the column belongs, or by a correlation name.</p>
</div>
<div class="paragraph">
<p>If a query refers to columns that have the same name but belong to different tables, you must use a qualified column
name to refer to the columns within the query. You must also refer to a column by a qualified column name if you join
a table with itself within a query to compare one row of the table with other rows in the same table.</p>
</div>
<div class="paragraph">
<p>The syntax of a column reference or qualified column name is:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">{table-name | view-name | correlation-name}.column-name</code></pre>
</div>
</div>
<div class="paragraph">
<p>If you define a correlation name for a table in the FROM clause of a statement, you must use that correlation name if
you need to qualify the column name within the statement.</p>
</div>
<div class="paragraph">
<p>If you do not define an explicit correlation name in the FROM clause, you can qualify the column name with the name of
the table or view that contains the column. See <a href="#correlation_names">Correlation Names</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="derived_column_names">5.3.2. Derived Column Names</h4>
<div class="paragraph">
<p>A derived column is an SQL value expression that appears as an item in the select list of a SELECT statement. An explicit
name for a derived column is an SQL identifier associated with the derived column. The syntax of a derived column name is:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">column-expression [[AS] column-name]</code></pre>
</div>
</div>
<div class="paragraph">
<p>The column expression can simply be a column reference. The expression is optionally followed by the AS keyword and the
name of the derived column.</p>
</div>
<div class="paragraph">
<p>If you do not assign a name to derived columns, the headings for unnamed columns in query result tables appear as (EXPR).
Use the AS clause to assign names that are meaningful to you, which is important if you have more than one derived column
in your select list.</p>
</div>
<div class="sect4">
<h5 id="examples_of_derived_column_names">Examples of Derived Column Names</h5>
<div class="paragraph">
<p>These two examples show how to use names for derived columns.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The first example shows (EXPR) as the column heading of the SELECT result table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG (salary) FROM persnl.employee; (EXPR)
----------------
49441.52
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>The second example shows AVERAGE SALARY as the column heading:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG (salary) AS &quot;AVERAGE SALARY&quot;
FROM persnl.employee; &quot;AVERAGE SALARY&quot;
----------------
49441.52
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="column_default_settings">5.3.3. Column Default Settings</h4>
<div class="paragraph">
<p>You can define specific default settings for columns when the table is created. The CREATE TABLE statement defines the
default settings for columns within tables. The default setting for a column is the value inserted in a row when an INSERT
statement omits a value for a particular column.</p>
</div>
</div>
</div>
<div class="sect2">
<h3 id="constraints">5.4. Constraints</h3>
<div class="paragraph">
<p>An SQL constraint is an object that protects the integrity of data in a table by specifying a condition that all the
values in a particular column or set of columns of the table must satisfy.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL enforces these constraints on SQL tables:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 80%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CHECK</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Column or table constraint specifying a condition must be satisfied for each row in the table.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">FOREIGN KEY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Column or table constraint that specifies a referential constraint for the table, declaring that a
column or set of columns (called a foreign key) in a table can contain only values that match those in a column or
set of columns in the table specified in the REFERENCES clause.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">NOT NULL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Column constraint specifying the column cannot contain nulls.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">PRIMARY KEY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Column or table constraint specifying the column or set of columns as the primary key for the table.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">UNIQUE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Column or table constraint that specifies that the column or set of columns cannot contain more than
one occurrence of the same value or set of values.</p></td>
</tr>
</tbody>
</table>
<div class="sect3">
<h4 id="creating_or_adding_constraints_on_sql_tables">5.4.1. Creating or Adding Constraints on SQL Tables</h4>
<div class="paragraph">
<p>To create constraints on an SQL table when you create the table, use the NOT NULL, UNIQUE, CHECK, FOREIGN KEY, or
PRIMARY KEY clause of the CREATE TABLE statement.</p>
</div>
<div class="paragraph">
<p>For more information on Trafodion SQL commands, see <a href="#create_table_statement">CREATE TABLE Statement</a> and
<a href="#alter_table_statement">ALTER TABLE Statement</a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="constraint_names">5.4.2. Constraint Names</h4>
<div class="paragraph">
<p>When you create a constraint, you can specify a name for it or allow a name to be generated by Trafodion SQL.
You can optionally specify both column and table constraint names. Constraint names are ANSI logical names.
See <a href="#database_object_names">Database Object Names</a>. Constraint names are in the same name space as tables and
views, so a constraint name cannot have the same name s a table or view.</p>
</div>
<div class="paragraph">
<p>The name you specify can be fully qualified or not. If you specify the schema parts of the name, they must match
those parts of the affected table and must be unique among table, view, and constraint names in that schema. If you
omit the schema portion of the name you specify, Trafodion SQL expands the name by using the schema for the table.</p>
</div>
<div class="paragraph">
<p>If you do not specify a constraint name, Trafodion SQL constructs an SQL identifier as the name for the constraint
and qualifies it with the schema of the table. The identifier consists of the table name concatenated with a
system-generated unique identifier.</p>
</div>
</div>
</div>
<div class="sect2">
<h3 id="correlation_names">5.5. Correlation Names</h3>
<div class="paragraph">
<p>A correlation name is a name you can associate with a table reference that is a table, view, or subquery in a SELECT
statement to:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Distinguish a table or view from another table or view referred to in a statement</p>
</li>
<li>
<p>Distinguish different uses of the same table</p>
</li>
<li>
<p>Make the query shorter</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>A correlation name can be explicit or implicit.</p>
</div>
<div class="sect3">
<h4 id="explicit_correlation_names">5.5.1. Explicit Correlation Names</h4>
<div class="paragraph">
<p>An explicit correlation name for a table reference is an SQL identifier associated with the table reference in the FROM
clause of a SELECT statement. See <a href="#identifiers">Identifiers</a>. The correlation name must be unique within the FROM clause.
For more information about the FROM clause, table references, and correlation names, see <a href="#select_statement">SELECT Statement</a>.</p>
</div>
<div class="paragraph">
<p>The syntax of a correlation name for the different forms of a table reference within a FROM clause is the same:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">{table | view | (query-expression)} [AS]correlation-name</code></pre>
</div>
</div>
<div class="paragraph">
<p>A table or view is optionally followed by the AS keyword and the correlation name. A derived table, resulting from the
evaluation of a query expression, must be followed by the AS keyword and the correlation name. An explicit correlation
name is known only to the statement in which you define it. You can use the same identifier as a correlation name in
another statement.</p>
</div>
</div>
<div class="sect3">
<h4 id="implicit_correlation_names">5.5.2. Implicit Correlation Names</h4>
<div class="paragraph">
<p>A table or view reference that has no explicit correlation name has an implicit correlation name. The implicit correlation
name is the table or view name qualified with the schema names.</p>
</div>
<div class="paragraph">
<p>You cannot use an implicit correlation name for a reference that has an explicit correlation name within the statement.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_correlation_names">5.5.3. Examples of Correlation Names</h4>
<div class="paragraph">
<p>This query refers to two tables, ORDERS and CUSTOMER, that contain columns named CUSTNUM. In the WHERE clause, one column
reference is qualified by an implicit correlation name (ORDERS) and the other by an explicit correlation name &#169;:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ordernum, custname FROM orders, customer c
WHERE orders.custnum = c.custnum AND orders.custnum = 543;</code></pre>
</div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="database_objects">5.6. Database Objects</h3>
<div class="paragraph">
<p>A database object is an SQL entity that exists in a name space. SQL statements can access Trafodion SQL database objects.
The subsections listed below describe these Trafodion SQL database objects.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#constraints">Constraints</a></p>
</li>
<li>
<p><a href="#indexes">Indexes</a></p>
</li>
<li>
<p><a href="#tables">Tables</a></p>
</li>
<li>
<p><a href="#views">Views</a></p>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="ownership">5.6.1. Ownership</h4>
<div class="paragraph">
<p>In Trafodion SQL, the creator of an object owns the object defined in the schema and has all privileges on the object.
In addition, you can use the GRANT and REVOKE statements to grant access privileges for a table or view to specified users.</p>
</div>
<div class="paragraph">
<p>For more information, see the <a href="#grant_statement">GRANT Statement</a> and <a href="#revoke_statement">REVOKE Statement</a>. For
information on privileges on tables and views, see <a href="#create_table_statement">CREATE TABLE Statement</a> and
<a href="#create_view_statement">CREATE VIEW Statement</a>.</p>
</div>
</div>
</div>
<div class="sect2">
<h3 id="database_object_names">5.7. Database Object Names</h3>
<div class="paragraph">
<p>DML statements can refer to Trafodion SQL database objects. To refer to a database object in a statement, use an appropriate
database object name. For information on the types of database objects see <a href="#database_objects">Database Objects</a>.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="logical_names_for_sql_objects">5.7.1. Logical Names for SQL Objects</h4>
<div class="paragraph">
<p>You may refer to an SQL table, view, constraint, library, function, or procedure by using a one-part, two-part, or three-part
logical name, also called an ANSI name:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">catalog-name.schema-name.object-name</code></pre>
</div>
</div>
<div class="paragraph">
<p>In this three-part name, <em>catalog-name</em> is the name of the catalog, which is TRAFODION for Trafodion SQL objects that map to
HBase tables. <em>schema-name</em> is the name of the schema, and <em>object-name</em> is the simple name of the table, view, constraint,
library, function, or procedure. Each of the parts is an SQL identifier. See <a href="#identifiers">Identifiers</a>.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL automatically qualifies an object name with a schema name unless you explicitly specify schema names with the
object name. If you do not set a schema name for the session using a SET SCHEMA statement, the default schema is SEABASE,
which exists in the TRAFODION catalog. See <a href="#set_schema_statement">SET SCHEMA Statement</a>. A one-part name <em>object-name</em> is
qualified implicitly with the default schema.</p>
</div>
<div class="paragraph">
<p>You can qualify a column name in a Trafodion SQL statement by using a three-part, two-part, or one-part object name, or a
correlation name.</p>
</div>
</div>
<div class="sect3">
<h4 id="sql_object_namespaces">5.7.2. SQL Object Namespaces</h4>
<div class="paragraph">
<p>Trafodion SQL objects are organized in a hierarchical manner. Database objects exist in schemas, which are themselves
contained in a catalog called TRAFODION. A catalog is a collection of schemas. Schema names must be unique within the catalog.</p>
</div>
<div class="paragraph">
<p>Multiple objects with the same name can exist provided that each belongs to a different name space. Trafodion SQL supports these
namespaces:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Index</p>
</li>
<li>
<p>Functions and procedures</p>
</li>
<li>
<p>Library</p>
</li>
<li>
<p>Schema label</p>
</li>
<li>
<p>Table value object (table, view, constraint)</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Objects in one schema can refer to objects in a different schema. Objects of a given name space are required to have
unique names within a given schema.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="data_types">5.8. Data Types</h3>
<div class="paragraph">
<p>Trafodion SQL data types are character, datetime, interval, or numeric (exact or approximate):</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#character_string_data_types">Character String Data Types</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Fixed-length and variable-length character data types.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#datetime_data_types">Datetime Data Types</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DATE, TIME, and TIMESTAMP data types.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#interval_data_types">Interval Data Types</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Year-month intervals (years and months) and day-time intervals (days,
hours, minutes, seconds, and fractions of a second).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#numeric_data_types_">Numeric Data Types</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Exact and approximate numeric data types.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>Each column in a table is associated with a data type. You can use the CAST expression to convert data to the data type that you specify. For
more information, see <a href="#cast_expression">CAST Expression</a>.</p>
</div>
<div class="paragraph">
<p>The following table summarizes the Trafodion SQL data types:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 13%;">
<col style="width: 28.9999%;">
<col style="width: 28.9999%;">
<col style="width: 29.0002%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Type</th>
<th class="tableblock halign-left valign-top">SQL Designation</th>
<th class="tableblock halign-left valign-top">Description</th>
<th class="tableblock halign-left valign-top">Size or Range<sup>1</sup></th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Fixed-length character</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CHAR[ACTER]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Fixed-length character data</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 32707 characters<sup>2</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NCHAR</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Fixed-length character data in predefined national character set</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 32707 bytes<sup>3</sup> <sup>7</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NATIONAL CHAR[ACTER]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Fixed-length character data in predefined national character set</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 32707 bytes<sup>3</sup> <sup>7</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Variable-length character</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">VARCHAR</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Variable-length ASCII character string</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 32703 characters<sup>4</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CHAR[ACTER] VARYING</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Variable-length ASCII character string</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 32703 characters<sup>4</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NCHAR VARYING</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Variable-length ASCII character string</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 32703 bytes<sup>4</sup> <sup>8</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NATIONAL CHAR[ACTER] VARYING</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Variable-length ASCII character string</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 32703 characters<sup>4</sup> <sup>8</sup></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Numeric</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NUMERIC (1,<em>scale</em>) to<br>
NUMERIC (128,<em>scale</em>)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Binary number with optional scale; signed or unsigned for 1 to 9 digits</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 128 digits; stored:<br>
1 to 4 digits in 2 bytes<br>
<br>
5 to 9 digits in 4 bytes<br>
<br>
10 to 128 digits in 8-64 bytes, depending on precision</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SMALLINT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Binary integer; signed or unsigned</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">0 to 65535 unsigned, -32768 to +32767 signed; stored in 2 bytes</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">INTEGER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Binary integer; signed or unsigned</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">0 to 4294967295 unsigned, -2147483648 to +2147483647 signed; stored in 4 bytes</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">LARGEINT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Binary integer; signed only</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">-2<strong>63 to +(2</strong>63)-1; stored in 8 bytes</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Numeric (extended numeric precision)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NUMERIC (precision 19 to 128)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Binary integer; signed or unsigned</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Stored as multiple chunks of 16-bit integers, with a minimum storage
length of 8 bytes.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Floating point number</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FLOAT[(<em>precision</em>)]</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Floating point number; precision designates from 1 through 52 bits of precision</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">+/- 2.2250738585072014e-308 through +/-1.7976931348623157e+308; stored in 8 bytes</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">REAL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Floating point number (32 bits)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">+/- 1.17549435e-38 through +/ 3.40282347e+38; stored in 4 bytes</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DOUBLE PRECISION</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Floating-point numbers (64 bits) with 1 through 52 bits of precision (52 bits of binary precision and 1 bits of exponent)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">+/- 2.2250738585072014e-308 through +/-1.7976931348623157e+308; stored in 8 byte</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Decimal number</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DECIMAL (1,<em>scale</em>) to DECIMAL (18,<em>scale</em>)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Decimal number with optional scale; stored as ASCII characters; signed or unsigned for 1 to 9 digits; signed required for 10 or more digits</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1 to 18 digits. Byte length equals the number of digits. Sign is stored as the first bit of the leftmost byte.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date-Time</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Point in time, using the Gregorian calendar and a 24 hour clock system. The five supported designations are listed below.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">YEAR 0001-9999<br>
MONTH 1-12<br>
DAY 1-31<br>
<br>
DAY constrained by MONTH and YEAR<br>
<br>
HOUR 0-23<br>
MINUTE 0-59<br>
SECOND 0-59<br>
FRACTION(n) 0-999999<br>
<br>
in which n is the number of significant digits, from 1 to 6
(default is 6; minimum is 1; maximum is 6). Actual database storage is
incremental, as follows:
<br>
YEAR in 2 bytes<br>
MONTH in 1 byte<br>
DAY in 1 byte<br>
HOUR in 1 byte<br>
MINUTE in 1
byte SECOND in 1 byte<br>
FRACTION in 4 bytes<br></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DATE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Format as YYYY-MM-DD; actual database storage size is 4 bytes</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TIME</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time of day, 24 hour clock, no time precision. Format as HH:MM:SS; actual database storage size is 3 bytes</p></td>
<td class="tableblock halign-left valign-top"></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">TIME (with time precision)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time of day, 24 hour clock, with time precision</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Format as HH:MM:SS.FFFFFF; actual database storage size is 7 bytes</p></td>
<td class="tableblock halign-left valign-top"></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">TIMESTAMP</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Point in time, no time precision</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Format as YYYY-MM-DD HH:MM:SS; actual database storage size is 7 bytes</p></td>
<td class="tableblock halign-left valign-top"></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">TIMESTAMP (with time precision) Point in time, with time precision</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Format as YYYY-MM-DD HH:MM:SS.FFFFFF; actual database storage size is 1 byte</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">INTERVAL</p></td>
</tr>
</tbody>
</table>
<div class="ulist">
<ul>
<li>
<p><em>scale</em> is the number of digits to the right of the decimal.</p>
</li>
<li>
<p><em>precision</em> specifies the allowed number of decimal digits.</p>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>The size of a column that allows null values is 2 bytes larger than the size for the defined data type.</p>
</li>
<li>
<p>The maximum row size is 32708 bytes, but the actual row size is less than that because of bytes used by
null indicators, varchar column length indicators, and actual data encoding.</p>
</li>
<li>
<p>Storage size is the same as that required by CHAR data type but store only half as many characters depending
on character set selection.</p>
</li>
<li>
<p>Storage size is reduced by 4 bytes for storage of the varying character length.</p>
</li>
<li>
<p>The maximum number of digits in an INTERVAL value is 18, including the digits in all INTERVAL fields of the value.
Any INTERVAL field that is a starting field can have up to 18 digits minus the number of other digits in the INTERVAL value.</p>
</li>
<li>
<p>The maximum is 32707 if the national character set was specified at installation time to be ISO88591.
The maximum is 16353 if the national character set was specified at installation time as UTF8.</p>
</li>
<li>
<p>The maximum is 32703 if the national character set was specified at installation time to be ISO88591.
The maximum is 16351 if the national character set was specified at installation time as UTF8.</p>
</li>
</ol>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="comparable_and_compatible_data_types">5.8.1. Comparable and Compatible Data Types</h4>
<div class="paragraph">
<p>Two data types are comparable if a value of one data type can be compared to a value of the other data type.</p>
</div>
<div class="paragraph">
<p>Two data types are compatible if a value of one data type can be assigned to a column of the other data type, and if
columns of the two data types can be combined using arithmetic operations. Compatible data types are also comparable.</p>
</div>
<div class="paragraph">
<p>Assignment and comparison are the basic operations of Trafodion SQL. Assignment operations are performed during the
execution of INSERT and UPDATE statements. Comparison operations are performed during the execution of statements that
include predicates, aggregate (or set) functions, and GROUP BY, HAVING, and ORDER BY clauses.</p>
</div>
<div class="paragraph">
<p>The basic rule for both assignment and comparison is that the operands have compatible data types. Data types with
different character sets cannot be compared without converting one character set to the other. However, the SQL compiler
will usually generate the necessary code to do this conversion automatically.</p>
</div>
<div class="sect4">
<h5 id="character_data_types">Character Data Types</h5>
<div class="paragraph">
<p>Values of fixed and variable length character data types of the same character set are all character strings and are
all mutually comparable and mutually assignable.</p>
</div>
<div class="paragraph">
<p>When two strings are compared, the comparison is made with a temporary copy of the shorter string that has been padded
on the right with blanks to have the same length as the longer string.</p>
</div>
</div>
<div class="sect4">
<h5 id="datetime_data_types">Datetime Data Types</h5>
<div class="paragraph">
<p>Values of type datetime are mutually comparable and mutually assignable only if the types have the same datetime fields.
A DATE, TIME, or TIMESTAMP value can be compared with another value only if the other value has the same data type.</p>
</div>
<div class="paragraph">
<p>All comparisons are chronological. For example, this predicate is true:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMP '2008-09-28 00:00:00' &gt; TIMESTAMP '2008-06-26 00:00:00'</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="interval_data_types">Interval Data Types</h5>
<div class="paragraph">
<p>Values of type INTERVAL are mutually comparable and mutually assignable only if the types are either both year-month
intervals or both day-time intervals.</p>
</div>
<div class="paragraph">
<p>For example, this predicate is true:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INTERVAL '02-01' YEAR TO MONTH &gt; INTERVAL '00-01' YEAR TO MONTH</code></pre>
</div>
</div>
<div class="paragraph">
<p>The field components of the INTERVAL do not have to be the same. For example, this predicate is also true:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INTERVAL '02-01' YEAR TO MONTH &gt; INTERVAL '01' YEAR</code></pre>
</div>
</div>
</div>
<div class="sect4">
<h5 id="numeric_data_types">Numeric Data Types</h5>
<div class="paragraph">
<p>Values of the approximate data types FLOAT, REAL, and DOUBLE PRECISION, and values of the exact data types NUMERIC,
DECIMAL, INTEGER, SMALLINT, and LARGEINT, are all numbers and are all mutually comparable and mutually assignable.</p>
</div>
<div class="paragraph">
<p>When an approximate data type value is assigned to a column with exact data type, rounding might occur, and the
fractional part might be truncated. When an exact data type value is assigned to a column with approximate data type,
the result might not be identical to the original number.</p>
</div>
<div class="paragraph">
<p>When two numbers are compared, the comparison is made with a temporary copy of one of the numbers, according to defined
rules of conversion. For example, if one number is INTEGER and the other is DECIMAL, the comparison is made with a
temporary copy of the integer converted to a decimal.</p>
</div>
<div class="sect5">
<h6 id="extended_numeric_precision">Extended Numeric Precision</h6>
<div class="paragraph">
<p>Trafodion SQL provides support for extended numeric precision data type. Extended numeric precision is an extension to
the NUMERIC(x,y) data type where no theoretical limit exists on precision. It is a software data type, which means that
the underlying hardware does not support it and all computations are performed by software. Computations using this data
type may not match the performance of other hardware supported data types.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect5">
<h6 id="considerations_for_extended_numeric_precision_data_type">Considerations for Extended NUMERIC Precision Data Type</h6>
<div class="paragraph">
<p>Consider these points and limitations for extended NUMERIC precision data type:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>May cost more than other data type options.</p>
</li>
<li>
<p>Is a software data type.</p>
</li>
<li>
<p>Cannot be compared to data types that are supported by hardware.</p>
</li>
<li>
<p>If your application requires extended NUMERIC precision arithmetic
expressions, specify the required precision in the table DDL or as
explicit extended precision type casts of your select list items. The
default system behavior is to treat user-specified extended precision
expressions as extended precision values. Conversely, non-user-specified
(that is, temporary, intermediate) extended precision expressions may
lose precision. In the following example, the precision appears to lose
one digit because the system treats the sum of two NUMERIC(18,4) type
columns as NUMERIC(18,4). NUMERIC(18) is the longest non-extended
precision numeric type. NUMERIC(19) is the shortest extended precision
numeric type. The system actually computes the sum of 2 NUMERIC(18,4)
columns as an extended precision NUMERIC(19,4) sum. But because no
user-specified extended precision columns exist, the system casts the
sum back to the user-specified type of NUMERIC(18,4).</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE T(a NUMERIC(18,4), B NUMERIC(18,4));
INSERT INTO T VALUES (1.1234, 2.1234);
&gt;&gt; SELECT A+B FROM T;
(EXPR)
--------------
3.246</code></pre>
</div>
</div>
<div class="paragraph">
<p>If this behavior is not acceptable, you can use one of these options:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Specify the column type as NUMERIC(19,4). For example, CREATE TABLE T(A NUMERIC(19,4), B NUMERIC(19,4)); or</p>
</li>
<li>
<p>Cast the sum as NUMERIC(19,4). For example, SELECT CAST(A+B AS NUMERIC(19,4)) FROM T; or</p>
</li>
<li>
<p>Use an extended precision literal in the expression. For example, SELECT A+B*1.00000000000000000000 FROM T;.</p>
<div class="paragraph">
<p>Note the result for the previous example when changing to NUMERIC(19,4):</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CAST(A+B AS NUMERIC(19,4)) FROM T;
(EXPR)
------------
3.2468</code></pre>
</div>
</div>
<div class="paragraph">
<p>When displaying output results in the command interface of a
client-based tool, casting a select list item to an extended precision
numeric type is acceptable. However, when retrieving an extended
precision select list item into an application program&#8217;s host variable,
you must first convert the extended precision numeric type into a string
data type. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CAST(CAST(A+B AS NUMERIC(19,4)) AS CHAR(24)) FROM T;
(EXPR)
------------
3.2468</code></pre>
</div>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
An application program can convert an externalized extended
precision value in string form into a numeric value it can handle. But,
an application program cannot correctly interpret an extended precision
value in internal form.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="rules_for_extended_numeric_precision_data_type">Rules for Extended NUMERIC Precision Data Type</h6>
<div class="paragraph">
<p>These rules apply:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>No limit on maximum precision.</p>
</li>
<li>
<p>Supported in all DDL and DML statements where regular NUMERIC data type is supported.</p>
</li>
<li>
<p>Allowed as part of key columns for hash partitioned tables only.</p>
</li>
<li>
<p>NUMERIC type with precision 10 through 18.</p>
<div class="ulist">
<ul>
<li>
<p>UNSIGNED is supported as extended NUMERIC precision data type</p>
</li>
<li>
<p>SIGNED is supported as 64-bit integer</p>
</li>
</ul>
</div>
</li>
<li>
<p>CAST function allows conversion between regular NUMERIC and extended NUMERIC precision data type.</p>
</li>
<li>
<p>Parameters in SQL queries support extended NUMERIC precision data type.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect5">
<h6 id="example_of_extended_numeric_precision_data_type">Example of Extended NUMERIC Precision Data Type</h6>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;CREATE TABLE t( n NUMERIC(128,30));
--- SQL operation complete.
&gt;&gt;SHOWDDL TABLE t;
CREATE TABLE SCH.T
(
N NUMERIC(128, 30) DEFAULT NULL
)
;
--- SQL operation complete.
&gt;&gt;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="character_string_data_types">5.8.2. Character String Data Types</h4>
<div class="paragraph">
<p>Trafodion SQL includes both fixed-length character data and variable-length character data. You cannot compare character data to
numeric, datetime, or interval data.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-type</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CHAR[ACTER] [(_length_ [CHARACTERS])] [_char-set_] [UPSHIFT] [[NOT]CASESPECIFIC]
| CHAR[ACTER] VARYING(_length_) [CHARACTERS][_char-set_] [UPSHIFT] [[NOT]CASESPECIFIC]
| VARCHAR(_length_) [CHARACTERS] [_char-set_] [UPSHIFT] [[NOT]CASESPECIFIC]
| NCHAR [(_length_)] [CHARACTERS] [UPSHIFT] [[NOT]CASESPECIFIC]
| NCHAR VARYING (_length_) [CHARACTERS] [UPSHIFT] [[NOT]CASESPECIFIC]
| NATIONAL CHAR[ACTER] [(_length_)] [CHARACTERS] [UPSHIFT] [[NOT]CASESPECIFIC]
| NATIONAL CHAR[ACTER] VARYING (_length_) [CHARACTERS] [UPSHIFT] [[NOT]CASESPECIFIC]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>char-set</em></code> is</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CHARACTER SET char-set-name</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>CHAR, NCHAR, and NATIONAL CHAR are fixed-length character types. CHAR
VARYING, VARCHAR, NCHAR VARYING and NATIONAL CHAR VARYING are
varying-length character types.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>length</em></code></p>
<div class="paragraph">
<p>is a positive integer that specifies the number of characters allowed in
the column. You must specify a value for <em>length</em>.</p>
</div>
</li>
<li>
<p><code><em>char-set-name</em></code></p>
<div class="paragraph">
<p>is the character set name, which can be ISO88591 or UTF8.</p>
</div>
</li>
<li>
<p><code>CHAR[ACTER] [(<em>length</em> [CHARACTERS])] [<em>char-set</em>] [UPSHIFT] [[NOT]CASESPECIFIC]</code></p>
<div class="paragraph">
<p>specifies a column with fixed-length character data.</p>
</div>
</li>
<li>
<p><code>CHAR[ACTER] VARYING (<em>length</em>) [CHARACTERS] [<em>char-set</em>] [UPSHIFT] [[NOT]CASESPECIFIC]</code></p>
<div class="paragraph">
<p>specifies a column with varying-length character data. VARYING specifies
that the number of characters stored in the column can be fewer than the
<em>length</em>.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>Values in a column declared as VARYING can be logically and physically
shorter than the maximum length, but the maximum internal size of a
VARYING column is actually four bytes larger than the size required for
an equivalent column that is not VARYING.</p>
</div>
</li>
<li>
<p><code>VARCHAR (<em>length</em>) [<em>char-set</em>] [UPSHIFT] [[NOT]CASESPECIFIC]</code></p>
<div class="paragraph">
<p>specifies a column with varying-length character data. VARCHAR is
equivalent to data type CHAR[ACTER] VARYING.</p>
</div>
</li>
<li>
<p><code>NCHAR [(<em>length</em>)] [UPSHIFT] [[NOT]CASESPECIFIC], NATIONAL CHAR[ACTER] [(<em>length</em>)] [UPSHIFT] [[NOT]CASESPECIFIC]</code></p>
<div class="paragraph">
<p>specifies a column with data in the predefined national character set.</p>
</div>
</li>
<li>
<p><code>NCHAR VARYING [(<em>length</em>)] [UPSHIFT] [[NOT]CASESPECIFIC], NATIONAL CHAR[ACTER] VARYING (<em>length</em>) [UPSHIFT] [[NOT]CASESPECIFIC]</code></p>
<div class="paragraph">
<p>specifies a column with varying-length data in the predefined national character set.</p>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="considerations_for_character_string_data_types">Considerations for Character String Data Types</h5>
<div class="sect5">
<h6 id="difference_between_char_and_varchar">Difference Between CHAR and VARCHAR</h6>
<div class="paragraph">
<p>You can specify a fixed-length character column as CHAR(<em>n</em>), where
<em>n</em> is the number of characters you want to store. However, if you store
five characters into a column specified as CHAR(10), ten characters are
stored where the rightmost five characters are blank.</p>
</div>
<div class="paragraph">
<p>If you do not want to have blanks added to your character string, you
can specify a variable-length character column as VARCHAR(<em>n</em>), where
<em>n</em> is the maximum number of characters you want to store. If you store
five characters in a column specified as VARCHAR(10), only the five
characters are stored logically—without blank padding.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect5">
<h6 id="nchar_columns_in_sql_tables">NCHAR Columns in SQL Tables</h6>
<div class="paragraph">
<p>In Trafodion SQL, the NCHAR type specification is equivalent to:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>NATIONAL CHARACTER</p>
</li>
<li>
<p>NATIONAL CHAR</p>
</li>
<li>
<p>CHAR &#8230; CHARACTER SET &#8230;, where the character set is the character set for NCHAR</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Similarly, you can use NCHAR VARYING, NATIONAL CHARACTER VARYING, NATIONAL CHAR
VARYING, and VARCHAR &#8230; CHARACTER SET &#8230; , where the character set is
the character set for NCHAR. The character set for NCHAR is determined
when Trafodion SQL is installed.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="datetime_data_types">5.8.3. Datetime Data Types</h4>
<div class="paragraph">
<p>A value of datetime data type represents a point in time according to
the Gregorian calendar and a 24-hour clock in local civil time (LCT). A
datetime item can represent a date, a time, or a date and time.</p>
</div>
<div class="paragraph">
<p>When a numeric value is added to or subtracted from a date type, the
numeric value is automatically casted to an INTERVAL DAY value. When a
numeric value is added to or subtracted from a time type or a timestamp
type, the numeric value is automatically casted to an INTERVAL SECOND
value. For information on CAST, see <a href="#cast
expression">CAST
Expression</a>.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL accepts dates, such as October 5 to 14, 1582, that were
omitted from the Gregorian calendar. This functionality is a Trafodion
SQL extension.</p>
</div>
<div class="paragraph">
<p>The range of times that a datetime value can represent is:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">January 1, 1 A.D., 00:00:00.000000 (low value) December 31, 9999, 23:59:59.999999 (high value)</code></pre>
</div>
</div>
<div class="paragraph">
<p>Trafodion SQL has three datetime data types:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-type</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> DATE
| TIME [(_time-precision_)]
| TIMESTAMP [(_timestamp-precision_)]</code></pre>
</div>
</div>
</li>
<li>
<p><code>DATE</code></p>
<div class="paragraph">
<p>specifies a datetime column that contains a date in the external form
yyyy-mm-dd and stored in four bytes.</p>
</div>
</li>
<li>
<p><code>TIME [(<em>time-precision</em>)]</code></p>
<div class="paragraph">
<p>specifies a datetime column that, without the optional time-precision,
contains a time in the external form hh:mm:ss and is stored in three
bytes. <em>time-precision</em> is an unsigned integer that specifies the number
of digits in the fractional seconds and is stored in four bytes. The
default for <em>time-precision</em> is 0, and the maximum is 6.</p>
</div>
</li>
<li>
<p><code>TIMESTAMP [(<em>timestamp-precision</em>)]</code></p>
<div class="paragraph">
<p>specifies a datetime column that, without the optional
<em>timestamp-precision</em>, contains a timestamp in the external form
yyyy-mm-dd hh:mm:ss and is stored in seven bytes. <em>timestamp-precision</em>
is an unsigned integer that specifies the number of digits in the
fractional seconds and is stored in four bytes. The default for
<em>timestamp-precision</em> is 6, and the maximum is 6.</p>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="considerations_for_datetime_data_types">Considerations for Datetime Data Types</h5>
<div class="sect5">
<h6 id="datetime_ranges">Datetime Ranges</h6>
<div class="paragraph">
<p>The range of values for the individual fields in a DATE, TIME, or
TIMESTAMP column is specified as:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>yyyy</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Year, from 0001 to 9999</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>mm</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Month, from 01 to 12</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>dd</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Day, from 01 to 31</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>hh</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Hour, from 00 to 23</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>mm</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Minute, from 00 to 59</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>ss</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Second, from 00 to 59</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>msssss</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Microsecond, from 000000 to 999999</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>When you specify <em>datetime_value</em> (FORMAT ‘string’) in the DML statement
and the specified format is ‘mm/dd/yyyy’,’MM/DD/YYYY’, or ‘yyyy/mm/dd’
or ‘yyyy-mm-dd’, the datetime type is automatically cast.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="interval_data_types">5.8.4. Interval Data Types</h4>
<div class="paragraph">
<p>Values of interval data type represent durations of time in year-month
units (years and months) or in day-time units (days, hours, minutes,
seconds, and fractions of a second).</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>interval-type</em> is:</code></p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INTERVAL[-] { start-field TO end-field | single-field }</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>start-field</em> is:</code></p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">{YEAR | MONTH | DAY | HOUR | MINUTE} [(_leading-precision_)]</code></pre>
</div>
</div>
</li>
<li>
<p>`<em>end-field</em> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [(_fractional-precision_)]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>single-field</em> is:</code></p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">_start-field_ | SECOND [(_leading-precision_, _fractional-precision_)]</code></pre>
</div>
</div>
</li>
<li>
<p><code>INTERVAL[-] { <em>start-field</em> TO <em>end-field</em> | <em>single-field</em> }</code></p>
<div class="paragraph">
<p>specifies a column that represents a duration of time as a year-month or
day-time range or a single-field. The optional sign indicates if this is
a positive or negative integer. If you omit the sign, it defaults to
positive.</p>
</div>
<div class="paragraph">
<p>If the interval is specified as a range, the <em>start-field</em> and
<em>end-field</em> must be in one of these categories:</p>
</div>
</li>
<li>
<p><code>{YEAR | MONTH | DAY | HOUR | MINUTE} [(<em>leading-precision</em>)]</code></p>
<div class="paragraph">
<p>specifies the <em>start-field</em>. A <em>start-field</em> can have a
<em>leading-precision</em> up to 18 digits (the maximum depends on the number
of fields in the interval). The <em>leading-precision</em> is the number of digits allowed in the
<em>start-field</em>. The default for <em>leading-precision</em> is 2.</p>
</div>
</li>
<li>
<p><code>YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [(<em>fractional-precision</em>)]</code></p>
<div class="paragraph">
<p>specifies the <em>end-field</em>. If the <em>end-field</em> is SECOND, it can have a
<em>fractional-precision</em> up to 6 digits. The <em>fractional-precision</em> is the
number of digits of precision after the decimal point. The default for
<em>fractional-precision</em> is 6.</p>
</div>
</li>
<li>
<p><code>start-field | SECOND [(<em>leading-precision</em>, <em>fractional-precision</em>)]</code></p>
<div class="paragraph">
<p>specifies the <em>single-field</em>. If the <em>single-field</em> is SECOND, the
<em>leading-precision</em> is the number of digits of precision before the
decimal point, and
the <em>fractional-precision</em> is the number of digits of precision after
the decimal point. The default for <em>leading-precision</em> is 2, and the
default for <em>fractional-precision</em>
is 6. The maximum for <em>leading-precision</em> is 18, and the maximum for
<em>fractional-precision</em> is 6.</p>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="considerations_for_interval_data_types">Considerations for Interval Data Types</h5>
<div class="sect5">
<h6 id="adding_or_subtracting_imprecise_interval_values">Adding or Subtracting Imprecise Interval Values</h6>
<div class="paragraph">
<p>Adding or subtracting an interval that is any multiple of a MONTH, a
YEAR, or a combination of these may result in a runtime error. For
example, adding 1 MONTH to January 31, 2009 will result in an error
because February 31 does not exist and it is not clear whether the user
would want rounding back to February 28, 2009, rounding up to March 1,
2009 or perhaps treating the interval 1 MONTH as if it were 30 days
resulting in an answer of March 2, 2009. Similarly, subtracting 1 YEAR
from February 29, 2008 will result in an error. See the descriptions for
the <a href="#add_months_function">ADD_MONTHS Function</a>,
<a href="#date_add_function">DATE_ADD Function</a>,
<a href="#date_sub_function">DATE_SUB Function</a> , and <a href="#dateadd_function">DATEADD Function</a> for ways
to add or subtract such intervals without getting errors at runtime.</p>
</div>
</div>
<div class="sect5">
<h6 id="interval_leading_precision">Interval Leading Precision</h6>
<div class="paragraph">
<p>The maximum for the <em>leading-precision</em> depends on the number of fields
in the interval and on the <em>fractional-precision</em>. The maximum is
computed as:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[[18 - _fractional-precision_ - 2 * (_n_ - 1)]]
_max-leading-precision_ = 18 - _fractional-precision_ - 2 * (_N_ - 1)</code></pre>
</div>
</div>
<div class="paragraph">
<p>where <em>N</em> is the number of fields in the interval.</p>
</div>
<div class="paragraph">
<p>For example, the maximum number of digits for the <em>leading-precision</em> in
a column with data type INTERVAL YEAR TO MONTH is computed as: 18 – 0 –
2 * (2 – 1) = 16</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect5">
<h6 id="interval_ranges">Interval Ranges</h6>
<div class="paragraph">
<p>Within the definition of an interval range (other than a single field),
the <em>start-field</em> and
<em>end-field</em> can be any of the specified fields with these restrictions:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>An interval range is either year-month or day-time—that is, if the
<em>start-field</em> is YEAR, the <em>end-field</em> is MONTH; if the <em>start-field</em> is
DAY, HOUR, or MINUTE, the <em>end-field</em> is also a time field.</p>
</li>
<li>
<p>The <em>start-field</em> must precede the <em>end-field</em> within the hierarchy:
YEAR, MONTH, DAY, HOUR, MINUTE, and SECOND.</p>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="signed_intervals">Signed Intervals</h6>
<div class="paragraph">
<p>To include a quoted string in a signed interval data type, the sign must
be outside the quoted string. It can be before the entire literal or
immediately before the duration enclosed in quotes.</p>
</div>
<div class="paragraph">
<p>For example, for the interval “minus (5 years 5 months) these formats
are valid:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INTERVAL - '05-05'YEAR TO MONTH
- INTERVAL '05-05' YEAR TO MONTH</code></pre>
</div>
</div>
</div>
<div class="sect5">
<h6 id="overflow_conditions">Overflow Conditions</h6>
<div class="paragraph">
<p>When you insert a fractional value into an INTERVAL data type field, if
the fractional value is 0 (zero) it does not cause an overflow.
Inserting value INTERVAL '1.000000' SECOND(6) into a field SECOND(0)
does not cause a loss of value. Provided that the value fits in the
target column without a loss of precision, Trafodion SQL does not return
an overflow error.</p>
</div>
<div class="paragraph">
<p>However, if the fractional value is &gt; 0, an overflow occurs. Inserting
value INTERVAL '1.000001' SECOND(6) causes a loss of value.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="numeric_data_types">5.8.5. Numeric Data Types</h4>
<div class="paragraph">
<p>Numeric data types are either exact or approximate. A numeric data type
is compatible with any other numeric data type, but not with character,
datetime, or interval data types.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>exact-numeric-type</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> NUMERIC [(_precision_ [,_scale_])] [SIGNED|UNSIGNED]
| SMALLINT [SIGNED|UNSIGNED]
| INT[EGER] [SIGNED|UNSIGNED]
| LARGEINT
| DEC[IMAL] [(_precision_ [,_scale_])] [SIGNED|UNSIGNED]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>approximate-numeric-type</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> FLOAT [(_precision_)]
| REAL
| DOUBLE PRECISION</code></pre>
</div>
</div>
<div class="paragraph">
<p>Exact numeric data types are types that can represent a value exactly:
NUMERIC, SMALLINT, INTEGER, LARGEINT, and DECIMAL.</p>
</div>
<div class="paragraph">
<p>Approximate numeric data types are types that do not necessarily
represent a value exactly: FLOAT, REAL, and DOUBLE PRECISION.</p>
</div>
<div class="paragraph">
<p>A column in a Trafodion SQL table declared with a floating-point data
type is stored in IEEE floating-point format and all computations on it
are done assuming that. Trafodion SQL tables can contain only IEEE
floating-point data.</p>
</div>
</li>
<li>
<p><code>NUMERIC [(<em>precision</em> [,<em>scale</em>])] [SIGNED|UNSIGNED]</code></p>
<div class="paragraph">
<p>specifies an exact numeric column—a two-byte binary number, SIGNED or
UNSIGNED. <em>precision</em> specifies the total number of digits and cannot
exceed 128. If <em>precision</em> is between 10 and 18, you must use a signed
value to obtain the supported hardware data type. If precision is over
18, you will receive the supported software data type. You will also
receive the supported software data type if the precision type is
between 10 and 18, and you specify UNSIGNED. <em>scale</em> specifies the
number of digits to the right of the decimal point.</p>
</div>
<div class="paragraph">
<p>The default is NUMERIC (9,0) SIGNED.</p>
</div>
</li>
<li>
<p><code>SMALLINT [SIGNED|UNSIGNED]</code></p>
<div class="paragraph">
<p>specifies an exact numeric column—a two-byte binary integer, SIGNED or
UNSIGNED. The
column stores integers in the range unsigned 0 to 65535 or signed -32768
to +32767. The default is SIGNED.</p>
</div>
</li>
<li>
<p><code>INT[EGER] [SIGNED|UNSIGNED]</code></p>
<div class="paragraph">
<p>specifies an exact numeric column—a 4-byte binary integer, SIGNED or
UNSIGNED. The column stores integers in the range unsigned 0 to
4294967295 or signed -2147483648 to +2147483647.</p>
</div>
<div class="paragraph">
<p>The default is SIGNED.</p>
</div>
</li>
<li>
<p><code>LARGEINT</code></p>
<div class="paragraph">
<p>specifies an exact numeric column—an 8-byte signed binary integer. The
column stores integers
in the range -2<sup>63</sup> to +2<sup>63</sup> -1 (approximately 9.223 times 10 to the
eighteenth power).</p>
</div>
</li>
<li>
<p><code>DEC[IMAL] [(<em>precision</em> [,<em>scale</em>])] [SIGNED|UNSIGNED]</code></p>
<div class="paragraph">
<p>specifies an exact numeric column—a decimal number, SIGNED or
UNSIGNED,stored as ASCII characters. <em>precision</em> specifies the total
number of digits and cannot exceed 18. If <em>precision</em> is 10 or more, the
value must be SIGNED. The sign is stored as the first bit of the
leftmost byte. <em>scale</em> specifies the number of digits to the right of
the decimal point.</p>
</div>
<div class="paragraph">
<p>The default is DECIMAL (9,0) SIGNED.</p>
</div>
</li>
<li>
<p><code>FLOAT [( precision )]</code></p>
<div class="paragraph">
<p>specifies an approximate numeric column. The column stores
floating-point numbers and
designates from 1 through 54 bits of <em>precision</em>.
The range is from +/- 2.2250738585072014e-308 through +/-1.7976931348623157e+308 stored in 8 bytes.</p>
</div>
<div class="paragraph">
<p>An IEEE FLOAT <em>precision</em> data type is stored as an IEEE DOUBLE, that is, in 8 bytes, with the specified precision.</p>
</div>
<div class="paragraph">
<p>The default <em>precision</em> is 54.</p>
</div>
</li>
<li>
<p><code>REAL</code></p>
<div class="paragraph">
<p>specifies a 4-byte approximate numeric column. The column stores 32-bit
floating-point numbers with 23 bits of binary precision and 8 bits of
exponent.</p>
</div>
<div class="paragraph">
<p>The minimum and maximum range is from +/- 1.17549435e-38 through +/ 3.40282347e+38.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>DOUBLE PRECISION</code></p>
<div class="paragraph">
<p>specifies an 8-byte approximate numeric column.</p>
</div>
<div class="paragraph">
<p>The column stores 64-bit floating-point numbers and designates from 1
through 52 bits of <em>precision</em>.</p>
</div>
<div class="paragraph">
<p>An IEEE DOUBLE PRECISION data type is stored in 8 bytes with 52 bits of
binary precision and 1 bits of exponent. The minimum and maximum range
is from +/- 2.2250738585072014e-308 through +/-1.7976931348623157e+308.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="expressions">5.9. Expressions</h3>
<div class="paragraph">
<p>An SQL value expression, called an expression, evaluates to a value.
Trafodion SQL supports these types of expressions:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 30%;">
<col style="width: 70%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#character_value_expressions">Character Value Expressions</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Operands can be combined with the concatenation operator (&#124;&#124;).<br>
<br>
Example: <code>'HOUSTON,' || ' TEXAS'</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#datetime_value_expressions">Datetime Value Expressions</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Operands can be combined in specific ways with arithmetic operators.<br>
<br>
Example: <code>CURRENT_DATE + INTERVAL '1' DAY</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#interval_value_expressions">Interval Value Expressions</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Operands can be combined in specific ways with addition and subtraction operators.<br>
<br>
Example: <code>INTERVAL '2' YEAR - INTERVAL '3' MONTH</code></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#numeric_value_expressions">Numeric Value Expressions</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Operands can be combined in specific ways with arithmetic operators.<br>
<br>
Example: <code>SALARY * 1.10</code></p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>The data type of an expression is the data type of the value of the
expression.</p>
</div>
<div class="paragraph">
<p>A value expression can be a character string literal, a numeric literal,
a dynamic parameter, or a column name that specifies the value of the
column in a row of a table. A value expression can also include
functions and scalar subqueries.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="character_value_expressions">5.9.1. Character Value Expressions</h4>
<div class="paragraph">
<p>The operands of a character value expression—called character
primaries—can be combined with the concatenation operator (||). The data
type of a character primary is character string.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> character-primary
| character-expression || character-primary</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>character-primary</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> character-string-literal
| column-reference
| character-type-host-variable
| dynamic parameter
| character-value-function
| aggregate-function
| sequence-function
| scalar-subquery
| CASE-expression
| CAST-expression
| (character-expression)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Character (or string) value expressions are built from operands that can be:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Character string literals</p>
</li>
<li>
<p>Character string functions</p>
</li>
<li>
<p>Column references with character values</p>
</li>
<li>
<p>Dynamic parameters</p>
</li>
<li>
<p>Aggregate functions, sequence functions, scalar subqueries, CASE expressions, or CAST expressions that return character values</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="examples_of_character_value_expressions">Examples of Character Value Expressions</h5>
<div class="paragraph">
<p>These are examples of character value expressions:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 40%;">
<col style="width: 60%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Expression</th>
<th class="tableblock halign-left valign-top">Description</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">'ABILENE'</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Character string literal.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">'ABILENE ' ||' TEXAS'</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The concatenation of two string literals.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">'ABILENE ' ||' TEXAS ' || x’55 53 41'</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The concatenation of three string literals to form the literal: 'ABILENE TEXAS USA'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">'Customer ' || custname</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The concatenation of a string literal with the value in column CUSTNAME.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CAST (order_date AS CHAR(10))</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">CAST function applied to a DATE value.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="datetime_value_expressions">5.9.2. Datetime Value Expressions</h4>
<div class="paragraph">
<p>The operands of a datetime value expression can be combined in specific
ways with arithmetic operators.</p>
</div>
<div class="paragraph">
<p>In this syntax diagram, the data type of a datetime primary is DATE,
TIME, or TIMESTAMP. The data type of an interval term is INTERVAL.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> datetime-primary
| interval-expression + datetime-primary
| datetime-expression + interval-term
| datetime-expression - interval-term</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>datetime-primary</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> datetime-literal
| column-reference
| datetime-type-host-variable
| dynamic parameter
| datetime-value-function
| aggregate-function
| sequence-function
| scalar-subquery
| CASE-expression
| CAST-expression
| (datetime-expression)</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>interval-term</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> interval-factor
| numeric-term * interval-factor</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>interval-factor</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[+|-] interval-primary</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>interval-primary</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> interval-literal
| column-reference
| interval-type-host-variable
| dynamic parameter
| aggregate-function
| sequence-function
| scalar-subquery
| CASE-expression
| CAST-expression
| (interval-expression)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Datetime value expressions are built from operands that can be:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Interval value expressions</p>
</li>
<li>
<p>Datetime or interval literals</p>
</li>
<li>
<p>Dynamic parameters</p>
</li>
<li>
<p>Column references with datetime or interval values</p>
</li>
<li>
<p>Dynamic parameters</p>
</li>
<li>
<p>Datetime or interval value functions</p>
</li>
<li>
<p>Any aggregate functions, sequence functions, scalar subqueries, CASE
expressions, or CAST expressions that return datetime or interval values</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="considerations_for_datetime_value_expressions">Considerations for Datetime Value Expressions</h5>
<div class="sect5">
<h6 id="data_type_of_result">Data Type of Result</h6>
<div class="paragraph">
<p>In general, the data type of the result is the data type of the
<em>datetime-primary</em> part of the datetime expression. For example,
datetime value expressions include:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 33.3333%;">
<col style="width: 33.3333%;">
<col style="width: 33.3334%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Datetime Expression</th>
<th class="tableblock halign-left valign-top">Description</th>
<th class="tableblock halign-left valign-top">Result Data Type</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_DATE + INTERVAL '1' DAY</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The sum of the current date and an interval value of one day.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DATE</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_DATE + est_complete</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The sum of the current date and the interval value in column EST_COMPLETE.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">DATE</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>( SELECT ship_timestamp FROM project WHERE projcode=1000) + INTERVAL '07:04' DAY TO HOUR</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The sum of the ship timestamp for the specified project and an interval value of seven days, four hours.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TIMESTAMP</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>The datetime primary in the first expression is CURRENT_DATE, a function
that returns a value with DATE data type. Therefore, the data type of
the result is DATE.</p>
</div>
<div class="paragraph">
<p>In the last expression, the datetime primary is this scalar subquery:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">( SELECT ship_timestamp FROM project WHERE projcode=1000 )</code></pre>
</div>
</div>
<div class="paragraph">
<p>The preceding subquery returns a value with TIMESTAMP data type.
Therefore, the data type of the result is TIMESTAMP.</p>
</div>
</div>
<div class="sect5">
<h6 id="restrictions_on_operations_with_datetime_or_interval_operands">Restrictions on Operations With Datetime or Interval Operands</h6>
<div class="paragraph">
<p>You can use datetime and interval operands with arithmetic operators in
a datetime value expression only in these combinations:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Operand 1</th>
<th class="tableblock halign-left valign-top">Operator</th>
<th class="tableblock halign-left valign-top">Operand 2</th>
<th class="tableblock halign-left valign-top">Result Type</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Datetime</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>+ or –</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Datetime</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>+</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Datetime</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Datetime</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>When a numeric value is added to or subtracted from a DATE type, the
numeric value is automatically casted to an INTERVAL DAY value. When a
numeric value is added to or subtracted from a time type or a timestamp
type, the numeric value is automatically casted to an INTERVAL SECOND
value. For information on CAST, see <a href="#cast expression">CAST Expression</a>.
For more information on INTERVALS, see
<a href="#interval_value_expressions">Interval Value Expressions</a></p>
</div>
<div class="paragraph">
<p>When using these operations, note:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Adding or subtracting an interval of months to a DATE value results in
a value of the same day plus or minus the specified number of months.
Because different months have different lengths, this is an approximate
result.</p>
</li>
<li>
<p>Datetime and interval arithmetic can yield unexpected results,
depending on how the fields are used. For example, execution of this
expression (evaluated left to right) returns an error:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE '2007-01-30' + INTERVAL '1' MONTH + INTERVAL '7' DAY</code></pre>
</div>
</div>
<div class="paragraph">
<p>In contrast, this expression (which adds the same values as the previous
expression, but in a different order) correctly generates the value
2007-03-06:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE '2007-01-30' + INTERVAL '7' DAY + INTERVAL '1' MONTH</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>You can avoid these unexpected results by using the <a href="#add_months_function">ADD_MONTHS Function</a>.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_datetime_value_expressions">Examples of Datetime Value Expressions</h5>
<div class="paragraph">
<p>The PROJECT table consists of five columns that use the data types
NUMERIC, VARCHAR, DATE, TIMESTAMP, and INTERVAL DAY. Suppose that you
have inserted values into the PROJECT table. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO persnl.project
VALUES (1000,'SALT LAKE CITY',DATE '2007-04-10',
TIMESTAMP '2007-04-21:08:15:00.00',INTERVAL '15' DAY);</code></pre>
</div>
</div>
<div class="paragraph">
<p>The next examples use these values in the PROJECT table:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">PROJCODE</th>
<th class="tableblock halign-left valign-top">START_DATE</th>
<th class="tableblock halign-left valign-top">SHIP_TIMESTAMP</th>
<th class="tableblock halign-left valign-top">EST_COMPLETE</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-04-10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-04-21 08:15:00.00</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">15</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">945</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-10-20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-12-21 08:15:00.00</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">30</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">920</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-02-21</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-03-12 09:45:00.00</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">134</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-1 -20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2008-01-01 00:00:00.00</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">30</p></td>
</tr>
</tbody>
</table>
<div class="ulist">
<ul>
<li>
<p>Add an interval value qualified by YEAR to a datetime value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date + INTERVAL '1' YEAR FROM persnl.project
WHERE projcode = 1000;
(EXPR)
----------
2008-04-10
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Subtract an interval value qualified by MONTH from a datetime value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ship_timestamp - INTERVAL '1' MONTH FROM persnl.project
WHERE projcode = 134;
(EXPR)
--------------------------
2007-12-01 00:00:00.000000
--- 1 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result is 2007-12-01 00:00:00.00. The YEAR value is decremented by 1
because subtracting a month from January 1 causes the date to be in the
previous year.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Add a column whose value is an interval qualified by DAY to a datetime
value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date + est_complete FROM persnl.project
WHERE projcode = 920;
(EXPR)
----------
2007-03-12
--- 1 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result of adding 20 days to 2008-02-21 is 2008-03-12. Trafodion SQL
correctly handles 2008 as a leap year.</p>
</div>
</li>
<li>
<p>Subtract an interval value qualified by HOUR TO MINUTE from a datetime
value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ship_timestamp - INTERVAL '15:30' HOUR TO MINUTE
FROM persnl.project WHERE projcode = 1000;
(EXPR)
--------------------------
2008-04-20 16:45:00.000000</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result of subtracting 15 hours and 30 minutes from 2007-04-21
08:15:00.00 is 2007-04-20 16:45:00.00.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="interval_value_expressions">5.9.3. Interval Value Expressions</h4>
<div class="paragraph">
<p>The operands of an interval value expression can be combined in specific
ways with addition and subtraction operators. In this syntax diagram,
the data type of a datetime expression is DATE, TIME, or TIMESTAMP; the
data type of an interval term or expression is INTERVAL.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>interval-expression</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> interval-term
| interval-expression + interval-term
| interval-expression - interval-term
| (datetime-expression - datetime-primary)
[interval-qualifier]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>interval-term</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> interval-factor
| interval-term * numeric-factor
| interval-term / numeric-factor
| numeric-term * interval-factor</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>interval-factor</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[+|-] interval-primary</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>interval-primary</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">interval-literal
| column-reference
| interval-type-host-variable
| dynamic-parameter
| aggregate-function
| sequence-function
| scalar-subquery
| CASE-expression
| CAST-expression
| (interval-expression)</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>numeric-factor</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> [+|-] numeric-primary
| [+|-] numeric-primary ** numeric-factor</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Interval value expressions are built from operands that can be:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Integers</p>
</li>
<li>
<p>Datetime value expressions</p>
</li>
<li>
<p>Interval literals</p>
</li>
<li>
<p>Column references with datetime or interval values</p>
</li>
<li>
<p>Dynamic parameters</p>
</li>
<li>
<p>Datetime or interval value functions</p>
</li>
<li>
<p>Aggregate functions, sequence functions, scalar subqueries, CASE expressions, or CAST expressions that return interval values</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For <em>interval-term</em>, <em>datetime-expression</em>, and <em>datetime-primary</em>, see <a href="#datetime_value_[expressions">Datetime Value Expressions</a>.</p>
</div>
<div class="paragraph">
<p>If the interval expression is the difference of two datetime expressions, by default, the result is expressed in the least
significant unit of measure for that interval. For date differences, the interval is expressed in days. For timestamp differences, the interval
is expressed in fractional seconds.</p>
</div>
<div class="paragraph">
<p>If the interval expression is the difference or sum of interval
operands, the interval qualifiers of the operands are either year-month
or day-time. If you are updating or inserting a value that is the result
of adding or subtracting two interval qualifiers, the interval qualifier
of the result depends on the interval qualifier of the target column.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="considerations_for_interval_value_expressions">Considerations for Interval Value Expressions</h5>
<div class="sect5">
<h6 id="start_and_end_fields">Start and End Fields</h6>
<div class="paragraph">
<p>Within the definition of an interval range, the <em>start-field</em> and
<em>end-field</em> can be any of the specified fields with these restrictions:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>An interval is either year-month or day-time. If the <em>start-field</em> is
YEAR, the <em>end-field</em> is MONTH; if the <em>start-field</em> is DAY, HOUR, or
MINUTE, the <em>end-field</em> is also a time field.</p>
</li>
<li>
<p>The <em>start-field</em> must precede the <em>end-field</em> within the hierarchy
YEAR, MONTH, DAY, HOUR, MINUTE, and SECOND.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Within the definition of an interval expression, the <em>start-field</em> and
<em>end-field</em> of all operands in the expression must be either year-month
or day-time.</p>
</div>
</div>
<div class="sect5">
<h6 id="interval_qualifier">Interval Qualifier</h6>
<div class="paragraph">
<p>The rules for determining the interval qualifier of the result
expression vary. For example, interval value expressions include:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 40%;">
<col style="width: 40%;">
<col style="width: 20%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Datetime Expression</th>
<th class="tableblock halign-left valign-top">Description</th>
<th class="tableblock halign-left valign-top">Result Data Type</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_DATE - start_date</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">By default, the interval difference between the current date and the value in column START_DATE is expressed
in days. You are not required to specify the interval qualifier.</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL DAY (12)</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '3' DAY - INTERVAL '2' DAY</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The difference of two interval literals. The result is 1 day.</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL DAY (3)</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '3' DAY + INTERVAL '2' DAY</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The sum of two interval literals. The result is 5 days.</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL DAY (3)</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '2' YEAR - INTERVAL '3' MONTH</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The difference of two interval literals. The result is 1 year, 9 months.</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL YEAR (3) TO MONTH</pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect5">
<h6 id="restrictions_on_operations">Restrictions on Operations</h6>
<div class="paragraph">
<p>You can use datetime and interval operands with arithmetic operators in
an interval value expression only in these combinations:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Operand 1</th>
<th class="tableblock halign-left valign-top">Operator</th>
<th class="tableblock halign-left valign-top">Operand 2</th>
<th class="tableblock halign-left valign-top">Result Type</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Datetime</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">-</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Datetime</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">+ or –</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">* or /</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Numeric</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Numeric</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">*</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>This table lists valid combinations of datetime and interval arithmetic operators, and the data type of the result:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Operands</th>
<th class="tableblock halign-left valign-top">Result type</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date + Interval or Interval + Date</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date + Numeric or Numeric + Date</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date - Numeric</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date – Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Date – Date</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time + Interval or Interval + Time</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time + Numeric or Numeric + Time</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time - Number</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time – Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp + Interval or Interval + Timestamp</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp + Numeric or Numeric + Timestamp</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp - Numeric</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp – Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">year-month Interval + year-month Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">year-month Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">day-time Interval + day-time Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">day-time Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">year-month Interval – year-month Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">year-month Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">day-time Interval – day-time Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">day-time Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time – Time</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp – Timestamp</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval * Number or Number * Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval / Number</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval – Interval or Interval + Interval</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>When using these operations, note:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>If you subtract a datetime value from another datetime value, both
values must have the same data type. To get this result, use the CAST
expression. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CAST (ship_timestamp AS DATE) - start_date</code></pre>
</div>
</div>
</li>
<li>
<p>If you subtract a datetime value from another datetime value, and you
specify the interval qualifier, you must allow for the maximum number of
digits in the result for the precision. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(CURRENT_TIMESTAMP - ship_timestamp) DAY(4) TO SECOND(6)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>If you are updating a value that is the result of adding or
subtracting two interval values, an SQL error occurs if the source value
does not fit into the target column&#8217;s range of interval fields. For
example, this expression cannot replace an INTERVAL DAY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INTERVAL '1' MONTH + INTERVAL '7' DAY</code></pre>
</div>
</div>
</li>
<li>
<p>If you multiply or divide an interval value by a numeric value
expression, Trafodion SQL converts the interval value to its least
significant subfield and then multiplies or divides it by the numeric
value expression. The result has the same fields as the interval that
was multiplied or divided. For example, this expression returns the
value 5-02:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INTERVAL '2-7' YEAR TO MONTH * 2</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_interval_value_expressions">Examples of Interval Value Expressions</h5>
<div class="paragraph">
<p>The PROJECT table consists of five columns using the data types NUMERIC,
VARCHAR, DATE, TIMESTAMP, and INTERVAL DAY. Suppose that you have
inserted values into the PROJECT table. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO persnl.project
VALUES (1000,'SALT LAKE CITY',DATE '2007-04-10',
TIMESTAMP '2007-04-21:08:15:00.00',INTERVAL '15' DAY);</code></pre>
</div>
</div>
<div class="paragraph">
<p>The next example uses these values in the PROJECT table:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">PROJCODE</th>
<th class="tableblock halign-left valign-top">START_DATE</th>
<th class="tableblock halign-left valign-top">SHIP_TIMESTAMP</th>
<th class="tableblock halign-left valign-top">EST_COMPLETE</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-04-10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-04-21:08:15:00.0000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">15</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-06-10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-07-21:08:30:00.0000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">30</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2500</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-10-10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-12-21:09:00:00.0000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">60</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-08-21</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-10-21:08:10:00.0000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">60</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">4000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-09-21</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-10-21:10:15:00.0000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">30</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">5000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-09-28</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2007-10-28:09:25:01.1 1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">30</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Suppose that the CURRENT_TIMESTAMP is 2000-01-06 1 :14:41.748703. Find
the number of days, hours, minutes, seconds, and fractional seconds in
the difference of the current timestamp and the SHIP_TIMESTAMP in the
PROJECT table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT projcode,
(CURRENT_TIMESTAMP - ship_timestamp) DAY(4) TO SECOND(6)
FROM samdbcat.persnl.project;
Project/Code (EXPR)
------------ ---------------------
1000 1355 02:58:57.087086
2000 1264 02:43:57.087086
2500 1111 02:13:57.087086
3000 1172 03:03:57.087086
4000 1172 00:58:57.087086
5000 1165 01:48:55.975986
--- 6 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="numeric_value_expressions">5.9.4. Numeric Value Expressions</h4>
<div class="paragraph">
<p>The operands of a numeric value expression can be combined in specific
ways with arithmetic operators. In this syntax diagram, the data type of
a term, factor, or numeric primary is numeric.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">numeric-expression` is:
numeric-term
| numeric-expression + numeric-term
| numeric-expression - numeric-term
numeric-term is:
numeric-factor
| numeric-term * numeric-factor
| numeric-term / numeric-factor
numeric-factor is:
[+|-] numeric-primary
| [+|-] numeric-primary ** numeric-factor
numeric-primary is:
unsigned-numeric-literal
| column-reference
| numeric-type-host-variable
| dynamic parameter
| numeric-value-function
| aggregate-function
| sequence-function
| scalar-subquery
| CASE-expression
| CAST-expression
| (numeric-expression)</code></pre>
</div>
</div>
<div class="paragraph">
<p>As shown in the preceding syntax diagram, numeric value expressions are
built from operands that can be:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Numeric literals</p>
</li>
<li>
<p>Column references with numeric values</p>
</li>
<li>
<p>Dynamic parameters</p>
</li>
<li>
<p>Numeric value functions</p>
</li>
<li>
<p>Aggregate functions, sequence functions, scalar subqueries, CASE expressions, or CAST expressions that return numeric values</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="considerations_for_numeric_value_expressions">Considerations for Numeric Value Expressions</h5>
<div class="sect5">
<h6 id="order_of_evaluation">Order of Evaluation</h6>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>Expressions within parentheses</p>
</li>
<li>
<p>Unary operators</p>
</li>
<li>
<p>Exponentiation</p>
</li>
<li>
<p>Multiplication and division</p>
</li>
<li>
<p>Addition and subtraction</p>
</li>
</ol>
</div>
<div class="paragraph">
<p>Operators at the same level are evaluated from left to right for all
operators except exponentiation. Exponentiation operators at the same
level are evaluated from right to left. For example,
<code>X + Y + Z</code> is evaluated as <code>(X + Y) + Z</code>, whereas <code>X ** Y &#42;&#42; Z</code> is evaluated as <code>X &#42;&#42; (Y &#42;&#42; Z)</code>.</p>
</div>
</div>
<div class="sect5">
<h6 id="additional_rules_for_arithmetic_operations">Additional Rules for Arithmetic Operations</h6>
<div class="paragraph">
<p>Numeric expressions are evaluated according to these additional rules:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>An expression with a numeric operator evaluates to null if any of the operands is null.</p>
</li>
<li>
<p>Dividing by 0 causes an error.</p>
</li>
<li>
<p>Exponentiation is allowed only with numeric data types. If the first
operand is 0 (zero), the second operand must be greater than 0, and the
result is 0. If the second operand is 0, the
first operand cannot be 0, and the result is 1. If the first operand is
negative, the second operand must be a value with an exact numeric data
type and a scale of zero.</p>
</li>
<li>
<p>Exponentiation is subject to rounding error. In general, results of
exponentiation should be considered approximate.</p>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="precision_magnitude">Precision, Magnitude, and Scale of Arithmetic Results</h6>
<div class="paragraph">
<p>The precision, magnitude, and scale are computed during the evaluation
of an arithmetic expression. Precision is the maximum number of digits
in the expression. Magnitude is the number of digits to the left of the
decimal point. Scale is the number of digits to the right of the decimal point.</p>
</div>
<div class="paragraph">
<p>For example, a column declared as NUMERIC (18, 5) has a precision of 18,
a magnitude of 13, and a scale of 5. As another example, the literal
12345.6789 has a precision of 9, a magnitude of 5, and a scale of 4.</p>
</div>
<div class="paragraph">
<p>The maximum precision for exact numeric data types is 128 digits. The
maximum precision for the REAL data type is approximately 7 decimal
digits, and the maximum precision for the DOUBLE PRECISION data type is
approximately 16 digits.</p>
</div>
<div class="paragraph">
<p>When Trafodion SQL encounters an arithmetic operator in an expression,
it applies these rules (with the restriction that if the precision
becomes greater than 18, the resulting precision is set to 18 and the
resulting scale is the maximum of 0 and (18- (<em>resulted precision</em> -
<em>resulted scale</em>)).</p>
</div>
<div class="ulist">
<ul>
<li>
<p>If the operator is + or -, the resulting scale is the maximum of the
scales of the operands. The resulting precision is the maximum of the
magnitudes of the operands, plus the scale of the result, plus 1.</p>
</li>
<li>
<p>If the operator is *, the resulting scale is the sum of the scales of
the operands. The resulting precision is the sum of the magnitudes of
the operands and the scale of the result.</p>
</li>
<li>
<p>If the operator is /, the resulting scale is the sum of the scale of
the numerator and the magnitude of the denominator. The resulting
magnitude is the sum of the magnitude of the numerator and the scale of
the denominator.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For example, if the numerator is NUMERIC (7, 3) and the denominator is
NUMERIC (7, 5), the resulting scale is 3 plus 2 (or 5), and the
resulting magnitude is 4 plus 5 (or 9). The expression result is NUMERIC
(14, 5).</p>
</div>
</div>
<div class="sect5">
<h6 id="conversion_of_numeric_types_for_arithmetic_operations">Conversion of Numeric Types for Arithmetic Operations</h6>
<div class="paragraph">
<p>Trafodion SQL automatically converts between floating-point numeric
types (REAL and DOUBLE PRECISION) and other numeric types. All numeric
values in the expression are first converted to binary, with the maximum
precision needed anywhere in the evaluation.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_numeric_value_expressions">Examples of Numeric Value Expressions</h5>
<div class="paragraph">
<p>These are examples of numeric value expressions:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 40%;">
<col style="width: 60%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>-57</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Numeric literal.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>salary * 1.10</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The product of the values in the SALARY column and a numeric literal.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>unit_price * qty_ordered</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The product of the values in the UNIT_PRICE and QTY_ORDERED columns.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>12 * (7 - 4)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">An expression whose operands are numeric literals.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>COUNT (DISTINCT city)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Function applied to the values in a column.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="identifiers">5.10. Identifiers</h3>
<div class="paragraph">
<p>SQL identifiers are names used to identify tables, views, columns, and
other SQL entities. The two types of identifiers are regular and
delimited. A delimited identifier is enclosed in double quotes (").
Case-insensitive delimited identifiers are used only for user names and
role names. Either regular, delimited, or case-sensitive delimited
identifiers can contain up to 128 characters.</p>
</div>
<div class="sect3">
<h4 id="regular_identifiers">5.10.1. Regular Identifiers</h4>
<div class="paragraph">
<p>Regular identifiers begin with a letter (A through Z and a through z),
but can also contain digits (0 through 9) or underscore characters (_).
Regular identifiers are not case-sensitive. You cannot use a reserved
word as a regular identifier.</p>
</div>
</div>
<div class="sect3">
<h4 id="delimited_identifiers">5.10.2. Delimited Identifiers</h4>
<div class="paragraph">
<p>Delimited identifiers are character strings that appear within double
quote characters (") and consist of alphanumeric characters, including
the underscore character (_) or a dash (-). Unlike regular identifiers,
delimited identifiers are case-sensitive. Trafodion SQL does not support
spaces or special characters in delimited identifiers given the
constraints of the underlying HBase file system. You can use reserved
words as delimited identifiers.</p>
</div>
</div>
<div class="sect3">
<h4 id="case_insensitive_delimited_identifiers">5.10.3. Case-Insensitive Delimited Identifiers</h4>
<div class="paragraph">
<p>Case-insensitive delimited identifiers, which are used for user names and
roles, are character strings that appear within double quote characters
(") and consist of alphanumeric characters
(A through Z and a through z), digits (0 through 9), underscores (_), dashes (-), periods (.), at
symbols (@), and forward slashes (/), except for the leading at sign (@)
or leading forward slash (/) character.</p>
</div>
<div class="paragraph">
<p>Unlike other delimited identifiers, case-insensitive-delimited
identifiers are case-insensitive. Identifiers are up-shifted before
being inserted into the SQL metadata. Thus, whether you specify a user&#8217;s
name as <code>"<a href="mailto:Penelope.Quan@company.com">Penelope.Quan@company.com</a>"</code>, <code>"<a href="mailto:PENELOPE.QUAN@company.com">PENELOPE.QUAN@company.com</a>"</code>, or
<code>"<a href="mailto:penelope.quan@company.com">penelope.quan@company.com</a>"</code>, the value stored in the metadata will be the
same: <code>PENELOPE.QUAN@COMPANY.COM</code>.</p>
</div>
<div class="paragraph">
<p>You can use reserved words as case-insensitive delimited identifiers.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="examples_of_identifiers">5.10.4. Examples of Identifiers</h4>
<div class="ulist">
<ul>
<li>
<p>These are regular identifiers:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">mytable SALES2006
Employee_Benefits_Selections
CUSTOMER_BILLING_INFORMATION</code></pre>
</div>
</div>
<div class="paragraph">
<p>Because regular identifiers are case insensitive, SQL treats all these
identifiers as alternative representations of mytable:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">mytable MYTABLE MyTable mYtAbLe</code></pre>
</div>
</div>
</li>
<li>
<p>These are delimited identifiers:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&quot;mytable&quot;
&quot;table&quot;
&quot;CUSTOMER-BILLING-INFORMATION&quot;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Because delimited identifiers are case-sensitive, SQL treats the
identifier "mytable" as different from the identifiers "MYTABLE" or
"MyTable".</p>
</div>
<div class="paragraph">
<p>You can use reserved words as delimited identifiers. For example, table
is not allowed as a regular identifier, but "table" is allowed as a
delimited identifier.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="identity_column">5.11. Identity Column</h3>
<div class="paragraph">
<p>A identity column is an auto-increment column, which is defined to a column of a table with identity attribute and used to automatically generate increasing or decreasing sequential numeric value for a column with each row insertion into the table.</p>
</div>
<div class="paragraph">
<p>Identity column, unlike a sequence which works independently of table column, is bound to a table column and can be accessed only by the table column. For more information, see <a href="#create_sequence_statement">CREATE SEQUENCE Statement</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GENERATED [ALWAYS | BY DEFAULT] AS IDENTITY
[START WITH integer]
[INCREMENT BY integer]
[MAXVALUE integer | NOMAXVALUE]
[MINVALUE integer]
[CYCLE | NO CYCLE]
[CACHE integer | NO CACHE]
[DATA TYPE]</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="syntax_description_of_identity_column">5.11.1. Syntax Description of Identity Column</h4>
<div class="ulist">
<ul>
<li>
<p><code>ALWAYS</code></p>
<div class="paragraph">
<p>Indicates that when a row is inserted to a table, a value will always be generated for the column.</p>
</div>
</li>
<li>
<p><code>BY DEFAULT</code></p>
<div class="paragraph">
<p>Indicates that when a row is inserted to a table, if the value of the column is not specified, then a default value will be assigned for the column. The value can be unique if you place a unique index on the column.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The options above serve the same purposes as they serve when you create a sequence. For more information, see <a href="#create_sequence_statement">CREATE SEQUENCE Statement</a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_identity_column">5.11.2. Examples of Identity Column</h4>
<div class="ulist">
<ul>
<li>
<p>Example of <code>ALWAYS</code></p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE identity_employee (
id LARGEINT GENERATED ALWAYS AS IDENTITY,
description VARCHAR(40)
);
SQL&gt;INSERT INTO identity_employee (description) VALUES ('Just DESCRIPTION');
--- 1 row(s) inserted.
SQL&gt;INSERT INTO identity_employee (id, description) VALUES(NULL, 'ID=NULL and DESCRIPTION');
*** ERROR[4122] NULL cannot be assigned to NOT NULL column TRAFODION.SEBASE.IDENTITY_EMPLOYEE.ID.
SQL&gt;INSERT INTO identity_employee (id, description) VALUES(999, 'ID=999 and DESCRIPTION');
*** ERROR[3428] IDENTITY column ID defined as GENERATED ALWAYS cannot accept values specified by the user.</code></pre>
</div>
</div>
</li>
<li>
<p>Example of <code>BY DEFAULT</code></p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE identity_employee (
id LARGEINT GENERATED BY DEFAULT AS IDENTITY,
description VARCHAR(40)
);
SQL&gt;INSERT INTO identity_employee (description) VALUES ('Just DESCRIPTION');
--- 1 row(s) inserted.
SQL&gt;INSERT INTO identity_employee (id, description) VALUES(NULL, 'ID=NULL and DESCRIPTION');
*** ERROR[4122] NULL cannot be assigned to NOT NULL column TRAFODION.SEBASE.IDENTITY_EMPLOYEE.ID.
SQL&gt;INSERT INTO identity_employee (id, description) VALUES(999, 'ID=999 and DESCRIPTION');
--- 1 row(s) inserted.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="indexes">5.12. Indexes</h3>
<div class="paragraph">
<p>An index is an ordered set of pointers to rows of a table. Each index is
based on the values in one or more columns. Indexes are transparent to
DML syntax.</p>
</div>
<div class="paragraph">
<p>A one-to-one correspondence always exists between index rows and base
table rows.</p>
</div>
<div class="sect3">
<h4 id="sql_indexes">5.12.1. SQL Indexes</h4>
<div class="paragraph">
<p>Each row in a Trafodion SQL index contains:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The columns specified in the CREATE INDEX statement</p>
</li>
<li>
<p>The clustering key of the underlying table (the user-defined
clustering key)</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>An index name is an SQL identifier. Indexes have their own name space
within a schema, so an index name might be the same as a table or
constraint name. However, no two indexes in a schema can have the same
name.</p>
</div>
<div class="paragraph">
<p>See <a href="#create_index_statement">CREATE INDEX Statement</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="keys">5.13. Keys</h3>
<div class="sect3">
<h4 id="clustering_keys">5.13.1. Clustering Keys</h4>
<div class="paragraph">
<p>Every table has a clustering key, which is the set of columns that
determine the order of the rows on disk. Trafodion SQL organizes records
of a table or index by using a b-tree based on this clustering key.
Therefore, the values of the clustering key act as logical row-ids.</p>
</div>
</div>
<div class="sect3">
<h4 id="syskey">5.13.2. SYSKEY</h4>
<div class="paragraph">
<p>When the STORE BY clause is specified with the <em>key-column-list</em> clause,
an additional column is appended to the <em>key-column-list</em> called the
SYSKEY.</p>
</div>
<div class="paragraph">
<p>A SYSKEY (or system-defined clustering key) is a clustering key column
which is defined by Trafodion SQL rather than by the user. Its type is
LARGEINT SIGNED. When you insert a record in a table, Trafodion SQL
automatically generates a value for the SYSKEY column. You cannot supply
the value.</p>
</div>
<div class="paragraph">
<p>You cannot specify a SYSKEY at insert time and you cannot update it
after it has been generated. To see the value of the generated SYSKEY,
include the SYSKEY column in the select list:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT *, SYSKEY FROM t4;</code></pre>
</div>
</div>
</div>
<div class="sect3">
<h4 id="index_keys">5.13.3. Index Keys</h4>
<div class="paragraph">
<p>A one-to-one correspondence always exists between index rows and base
table rows. Each row in a Trafodion SQL index contains:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The columns specified in the CREATE INDEX statement</p>
</li>
<li>
<p>The clustering (primary) key of the underlying table (the user-defined clustering key)</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For a non-unique index, the clustering key of the index is composed of
both items. The clustering key cannot exceed 2048 bytes. Because the
clustering key includes all the columns in the table, each row is also
limited to 2048 bytes.</p>
</div>
<div class="paragraph">
<p>For varying-length character columns, the length referred to in these
byte limits is the defined column length, not the stored length. (The
stored length is the expanded length, which includes two extra bytes for
storing the data length of the item.)</p>
</div>
<div class="paragraph">
<p>See <a href="#create_index_statement">CREATE INDEX Statement</a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="primary_keys">5.13.4. Primary Keys</h4>
<div class="paragraph">
<p>A primary key is the column or set of columns that define the uniqueness
constraint for a table. The columns cannot contain nulls, and only one
primary key constraint can exist on a table.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="literals">5.14. Literals</h3>
<div class="paragraph">
<p>A literal is a constant you can use in an expression, in a statement, or
as a parameter value. An SQL literal can be one of these data types:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#character_string_literals">Character String Literals</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">A series of characters enclosed in single quotes.<br>
<br>
Example: 'Planning'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#datetime_literals">Datetime Literals</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Begins with keyword DATE, TIME, or TIMESTAMP and followed by a character string.<br>
<br>
Example: DATE '1990-01-22'</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#interval_literals">Interval Literals</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Begins with keyword INTERVAL and followed by a character string and an interval qualifier.<br>
<br>
Example: INTERVAL '2-7' YEAR TO MONTH</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#numeric_literals">Numeric Literals</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">A simple numeric literal (one without an exponent) or a numeric literal in scientific notation.<br>
<br>
Example: 99E-2</p></td>
</tr>
</tbody>
</table>
<div class="sect3">
<h4 id="character_string_literals">5.14.1. Character String Literals</h4>
<div class="paragraph">
<p>A character string literal is a series of characters enclosed in single
quotes.</p>
</div>
<div class="paragraph">
<p>You can specify either a string of characters or a set of hexadecimal
code values representing the characters in the string.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em class="_character-set_ | N">'string'</em>
| [<em>character-set</em> | N] X'<em>hex-code-value</em>. . . '
| [<em>character-set</em> | N]
X'<em class="_space_. . .">hex-code-value</em>[<em class="_space_. . .">hex-code-value</em>. . .][<em>space</em>. . .]'
_ character-set_</code></p>
<div class="paragraph">
<p>specifies the character set ISO88591 or UTF8. The <em>character-set</em>
specification of the string literal should correspond with the character
set of the column definition, which is either ISO88591 or UTF8. If you
omit the _character-set specification, Trafodion SQL initially assumes
the ISO88591 character set if the string literal consists entirely of
7-bit ASCII characters and UTF8 otherwise. (However, the initial
assumption will later be changed if the string literal is used in a
context that requires a character set different from the initial
assumption.)</p>
</div>
</li>
<li>
<p><code>N</code></p>
<div class="paragraph">
<p>associates the string literal with the character set of the NATIONAL
CHARACTER (NCHAR) data type. The character set for NCHAR is determined
during the installation of Trafodion SQL. This value can be either UTF8
(the default) or ISO88591.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>'<em>string</em>'</code></p>
<div class="paragraph">
<p>is a series of any input characters enclosed in single quotes. A single
quote within a string is represented by two single quotes (''). A string
can have a length of zero if you specify two single quotes ('') without
a space in between.</p>
</div>
</li>
<li>
<p><code>X</code></p>
<div class="paragraph">
<p>indicates the hexadecimal string.</p>
</div>
</li>
<li>
<p><code>'<em>hex-code-value</em>'</code></p>
<div class="paragraph">
<p>represents the code value of a character in hexadecimal form enclosed in
single quotes. It must contain an even number of hexadecimal digits. For
ISO88591, each value must be two digits long. For UTF8, each value can
be 2, 4, 6, or 8 hexadecimal digits long. If <em>hex-code-value</em> is
improperly formatted (for example, it contains an invalid hexadecimal
digit or an odd number of hexadecimal digits), an error is returned.</p>
</div>
</li>
<li>
<p><code><em>space</em></code></p>
<div class="paragraph">
<p>is space sequences that can be added before or after <em>hex-code-value</em>
for readability. The encoding for <em>space</em> must be the TERMINAL_CHARSET
for an interactive interface and the SQL module character set for the
programmatic interface.</p>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="considerations_for_character_string_literals">Considerations for Character String Literals</h5>
<div class="sect5">
<h6 id="using_string_literals">Using String Literals</h6>
<div class="paragraph">
<p>A string literal can be as long as a character column. See
<a href="#character_string_data_types">Character String Data Types</a>.</p>
</div>
<div class="paragraph">
<p>You can also use string literals in string value expressions—for
example, in expressions that use the concatenation operator (||) or in
expressions that use functions returning string values.</p>
</div>
<div class="paragraph">
<p>When specifying string literals:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Do not put a space between the character set qualifier and the
character string literal. If you use this character string literal in a
statement, Trafodion SQL returns an error.</p>
</li>
<li>
<p>To specify a single quotation mark within a string literal, use two
consecutive single quotation marks.</p>
</li>
<li>
<p>To specify a string literal whose length is more than one line,
separate the literal into several smaller string literals, and use the
concatenation operator (||) to concatenate them.</p>
</li>
<li>
<p>Case is significant in string literals. Lowercase letters are not
equivalent to the corresponding uppercase letters.</p>
</li>
<li>
<p>Leading and trailing spaces within a string literal are significant.</p>
</li>
<li>
<p>Alternately, a string whose length is more than one line can be
written as a literal followed by a space, CR, or tab character, followed
by another string literal.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_character_string_literals">Examples of Character String Literals</h5>
<div class="ulist">
<ul>
<li>
<p>These data type column specifications are shown with examples of
literals that can be stored in the columns.</p>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Character String Data Type</th>
<th class="tableblock halign-left valign-top">Character String Literal Example</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHAR (12) UPSHIFT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>'PLANNING'</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VARCHAR (18)</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>'NEW YORK'</pre></div></td>
</tr>
</tbody>
</table>
</li>
<li>
<p>These are string literals:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">'This is a string literal.'
'abc^&amp;*'
'1234.56'
'This literal contains '' a single quotation mark.'</code></pre>
</div>
</div>
</li>
<li>
<p>This is a string literal concatenated over three lines:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">'This literal is' || '
in three parts,' ||
'specified over three lines.'</code></pre>
</div>
</div>
</li>
<li>
<p>This is a hexadecimal string literal representing the VARCHAR pattern
of the ISO88591 string 'Strauß':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">_ISO88591 X'53 74 72 61 75 DF'</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="datetime_literals">5.14.2. Datetime Literals</h4>
<div class="paragraph">
<p>A datetime literal is a DATE, TIME, or TIMESTAMP constant you can use in
an expression, in a statement, or as a parameter value. Datetime
literals have the same range of valid values as the corresponding
datetime data types. You cannot use leading or trailing spaces within a
datetime string (within the single quotes).</p>
</div>
<div class="paragraph">
<p>A datetime literal begins with the DATE, TIME, or TIMESTAMP keyword and
can appear in default, USA, or European format.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE 'date' | TIME 'time' | TIMESTAMP 'timestamp'
date is:
yyyy-mm-dd Default
| mm/dd/yyyy USA
| dd.mm.yyyy European
time is:
hh:mm:ss.msssss Default
| hh:mm:ss.msssss [am | pm] USA
| hh.mm.ss.msssss European
timestamp is:
yyyy-mm-dd hh:mm:ss.msssss Default
| mm/dd/yyyy hh:mm:ss.msssss [am | pm] USA
| dd.mm.yyyy hh.mm.ss.msssss European</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>date,time,timestamp</em></code></p>
<div class="paragraph">
<p>specify the datetime literal strings whose component fields are:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 30%;">
<col style="width: 70%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>yyyy</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Year, from 0001 to 9999</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>mm</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Month, from 01 to 12</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>dd</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Day, from 01 to 31</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>hh</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Hour, from 00 to 23</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>mm</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Minute, from 00 to 59</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ss</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Second, from 00 to 59</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>msssss</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Microsecond, from 000000 to 999999</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>am</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">AM or am, indicating time from midnight to before noon</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>pm</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">PM or pm, indicating time from noon to before midnight</p></td>
</tr>
</tbody>
</table>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="examples_of_datetime_literals">Examples of Datetime Literals</h5>
<div class="ulist">
<ul>
<li>
<p>These are DATE literals in default, USA, and European formats, respectively:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE '2008-01-22' DATE '01/22/2008' DATE '22.01.2008'</code></pre>
</div>
</div>
</li>
<li>
<p>These are TIME literals in default, USA, and European formats, respectively:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIME '13:40:05'
TIME '01:40:05 PM'
TIME '13.40.05'</code></pre>
</div>
</div>
</li>
<li>
<p>These are TIMESTAMP literals in default, USA, and European formats, respectively:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMP '2008-01-22 13:40:05'
TIMESTAMP '01/22/2008 01:40:05 PM'
TIMESTAMP '22.01.2008 13.40.05'</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="interval_literals">5.14.3. Interval Literals</h4>
<div class="paragraph">
<p>An interval literal is a constant of data type INTERVAL that represents
a positive or negative duration of time as a year-month or day-time
interval; it begins with the keyword INTERVAL optionally preceded or
followed by a minus sign (for negative duration). You cannot include
leading or trailing spaces within an interval string (within single
quotes).</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[-]INTERVAL [-]{'year-month' | 'day:time'} interval-qualifier
year-month is:
years [-months] | months
day:time is:
days [[:]hours [:minutes [:seconds [.fraction]]]]
| hours [:minutes [:seconds [.fraction]]]
| minutes [:seconds [.fraction]]
| seconds [.fraction]
interval-qualifier is:
start-field TO end-field | single-field
start-field is:
{YEAR | MONTH | DAY | HOUR | MINUTE} [(leading-precision)]
end-field is:
YEAR | MONTH | DAY | HOUR | MINUTE | SECOND [(fractional-precision)]
single-field is:
start-field | SECOND [(leading-precision,fractional-precision)]</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>start-field</em> TO <em>end-field</em></code></p>
<div class="paragraph">
<p>must be year-month or day-time.The <em>start-field</em> you specify must
precede the <em>end-field</em> you specify in the list of field names.</p>
</div>
</li>
<li>
<p><code>{YEAR &#124; MONTH &#124; DAY &#124; HOUR &#124; MINUTE} [(<em>leading-precision</em>)]</code></p>
<div class="paragraph">
<p>specifies the <em>start-field</em>. A <em>start-field</em> can have a
<em>leading-precision</em> up to 18 digits (the maximum depends on the number
of fields in the interval). The
<em>leading-precision</em> is the number of digits allowed in the
<em>start-field</em>. The default for <em>leading-precision</em> is 2.</p>
</div>
</li>
<li>
<p><code>YEAR &#124; MONTH &#124; DAY &#124; HOUR &#124; MINUTE &#124; SECOND [(<em>fractional-precision</em>)]</code></p>
<div class="paragraph">
<p>specifies the <em>end-field</em>. If the <em>end-field</em> is SECOND, it can have a
<em>fractional-precision</em> up to 6 digits. The <em>fractional-precision</em> is the
number
of digits of precision after the decimal point. The default for
<em>fractional-precision</em> is 6.</p>
</div>
</li>
<li>
<p><code><em>start-field</em> &#124; SECOND [(<em>leading-precision</em>, <em>fractional-precision</em>)]</code></p>
<div class="paragraph">
<p>specifies the <em>single-field</em>. If the <em>single-field</em> is SECOND, the
<em>leading-precision</em> is the number of digits of precision before the
decimal point, and the <em>fractional-precision</em> is the number of digits of
precision after the decimal point.</p>
</div>
<div class="paragraph">
<p>The default for <em>leading-precision</em> is 2, and the default for
<em>fractional-precision</em> is 1. The maximum for <em>leading-precision</em> is 18,
and the maximum for <em>fractional-precision</em> is 6.</p>
</div>
<div class="paragraph">
<p>See <a href="#interval_data_types">Interval Data Types</a> and
<a href="#interval_value_expressions">Interval Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code>'<em>year-month</em>' &#124; '<em>day:time</em>'</code></p>
<div class="paragraph">
<p>specifies the date and time components of an interval literal. The day
and hour fields can be separated by a space or a colon. The interval
literal strings are:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 15%;">
<col style="width: 85%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>years</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unsigned integer that specifies a number of years. <em>years</em> can be up to 18 digits, or 16 digits if <em>months</em>
is the end-field. The maximum for the <em>leading-precision</em> is specified within the interval qualifier by either YEAR(18)
or YEAR(16) TO MONTH.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>months</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unsigned integer that specifies a number of months. Used as a starting field, <em>months</em> can have up to 18
digits. The maximum for the <em>leading-precision</em> is specified by MONTH(18). Used as an ending field, the value of <em>months</em>
must be in the range 0 to 1 .</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>days</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unsigned integer that specifies number of days. <em>days</em> can have up to 18 digits if no end-field exists; 16 digits
if <em>hours</em> is the end-field; 14 digits if <em>minutes</em> is the end-field; and 13-<em>f</em> digits if <em>seconds</em> is the end-field, where
f is the <em>fraction</em> less than or equal to 6. These maximums are specified by DAY(18), DAY(16) TO HOUR, DAY(14) TO
MINUTE, and DAY(13-<em>f</em>) TO SECOND(<em>f</em>).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>hours</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unsigned integer that specifies a number of hours. Used as a starting field, <em>hours</em> can have up to 18 digits if
no end-field exists; 16 digits if <em>minutes</em> is the end-field; and 14-<em>f</em> digits if <em>seconds</em> is the end-field, where f is
the <em>fraction</em> less than or equal to 6. These maximums are specified by HOUR(18), HOUR(16) TO MINUTE, and HOUR(14-f) TO
SECOND(<em>f</em>). Used as an ending field, the value of <em>hours</em> must be in the range 0 to 23.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>minutes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unsigned integer that specifies a number of minutes. Used as a starting field, <em>minutes</em> can have up to 18 digits
if no end-field exists; and 16-f digits if <em>seconds</em> is the end-field, where <em>f</em> is the <em>fraction</em> less than or equal to 6.
These maximums are specified by MINUTE(18), and MINUTE(16-<em>f</em>) TO SECOND(<em>f</em>). Used as an ending field, the value of <em>minutes</em>
must be in the range 0 to 59.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>seconds</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unsigned integer that specifies a number of seconds. Used as a starting field, <em>seconds</em> can have up to 18 digits,
minus the number of digits f in the <em>fraction</em> less than or equal to 6. This maximum is specified by SECOND(18-<em>f</em>, <em>f</em>). The
value of <em>seconds</em> must be in the range 0 to 59.9(<em>n</em>), where <em>n</em> is the number of digits specified for seconds precision.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>fraction</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unsigned integer that specifies a fraction of a second. When <em>seconds</em> is used as an ending field, <em>fraction</em> is
limited to the number of digits specified by the <em>fractional-precision</em> field following the SECOND keyword.</p></td>
</tr>
</tbody>
</table>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="considerations_for_interval_literals">Considerations for Interval Literals</h5>
<div class="sect5">
<h6 id="length_of_year_month_and_day_time_strings">Length of Year-Month and Day-Time Strings</h6>
<div class="paragraph">
<p>An interval literal can contain a maximum of 18 digits, in the string
following the INTERVAL keyword, plus a hyphen (-) that separates the
year-month fields, and colons (:) that separate the day-time fields. You
can also separate day and hour with a space.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_interval_literals">Examples of Interval Literals</h5>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '1' MONTH</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval of 1 month</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '7' DAY</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval of 7 days</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '2-7' YEAR TO MONTH</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval of 2 years, 7 months</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '5:2:15:36.33' DAY TO SECOND(2)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval of 5 days, 2 hours, 15 minutes, and 36.33 seconds</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL - '5' DAY</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval that subtracts 5 days</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '100' DAY(3)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval of 100 days. This example requires an explicit leading
precision of 3 because the default is 2.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL '364 23' DAY(3) TO HOUR</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Interval of 364 days, 23 hours. The separator for the day and hour
fields can be a space or a colon.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="numeric_literals">5.14.4. Numeric Literals</h4>
<div class="paragraph">
<p>A numeric literal represents a numeric value. Numeric literals can be
represented as an exact numeric literal (without an exponent) or as an
approximate numeric literal by using scientific notation (with an
exponent).</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">exact-numeric-literal is:
[+|-]unsigned-integer[.[unsigned-integer]]
| [+|-].unsigned-integer
approximate-numeric-literal is:
mantissa{E|e}exponent
mantissa is:
exact-numeric-literal
exponent is:
[+|-]unsigned-integer
unsigned-integer is:
digit. . .</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>exact-numeric-literal</em></code></p>
<div class="paragraph">
<p>is an exact numeric value that includes an optional plus sign (+) or
minus sign (-), up to 128 digits (0 through 9), and an optional period
(.) that indicates a decimal point. Leading zeros do not count toward
the 128-digit limit; trailing zeros do.</p>
</div>
<div class="paragraph">
<p>A numeric literal without a sign is a positive number. An exact numeric
literal that does not include a decimal point is an integer. Every exact
numeric literal has the data type NUMERIC and the minimum precision
required to represent its value.</p>
</div>
</li>
<li>
<p><code><em>approximate-numeric-literal</em></code></p>
<div class="paragraph">
<p>is an exact numeric literal followed by an exponent expressed as an
uppercase E or lowercase e followed by an optionally signed integer.</p>
</div>
<div class="paragraph">
<p>Numeric values expressed in scientific notation are treated as data type
REAL if they include no more than seven digits before the exponent, but
treated as type DOUBLE PRECISION if they include eight or more digits.
Because of this factor, trailing zeros after a decimal can sometimes
increase the precision of a numeric literal used as a DOUBLE PRECISION
value.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>+For example, if XYZ is a table that consists of one DOUBLE PRECISION
column, the inserted value:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO XYZ VALUES (1.00000000E-10)</code></pre>
</div>
</div>
<div class="paragraph">
<p>has more precision than:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO XYZ VALUES (1.0E-10)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="examples_of_numeric_literals">Examples of Numeric Literals</h5>
<div class="paragraph">
<p>These are all numeric literals, along with their display format:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Literal</th>
<th class="tableblock halign-left valign-top">Display Format</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>477</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>477</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>580.45</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>580.45</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>+005</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>5</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>-.3175</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>-.3175</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>1300000000</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>1300000000</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>99.</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>99</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>-0.123456789012345678</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>-.123456789012345678</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>99E-2</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>9.9000000E-001</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>12.3e+5</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>1.2299999E+006</pre></div></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="null">5.15. Null</h3>
<div class="paragraph">
<p>Null is a special symbol, independent of data type, that represents an
unknown. The Trafodion SQL keyword NULL represents null. Null indicates
that an item has no value. For sorting purposes, null is greater than
all other values. You cannot store null in a column by using INSERT or
UPDATE, unless the column allows null.</p>
</div>
<div class="paragraph">
<p>A column that allows null can be null at any row position. A nullable
column has extra bytes associated with it in each row. A special value
stored in these bytes indicates that the column has null for that row.</p>
</div>
<div class="sect3">
<h4 id="using_null_versus_default_values">5.15.1. Using Null Versus Default Values</h4>
<div class="paragraph">
<p>Various scenarios exist in which a row in a table might contain no value
for a specific column. For example:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>A database of telemarketing contacts might have null AGE fields if
contacts did not provide their age.</p>
</li>
<li>
<p>An order record might have a DATE_SHIPPED column empty until the order
is actually shipped.</p>
</li>
<li>
<p>An employee record for an international employee might not have a
social security number.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>You allow null in a column when you want to convey that a value in the
column is unknown (such as the age of a telemarketing contact) or not
applicable (such as the social security number of an international
employee).</p>
</div>
<div class="paragraph">
<p>In deciding whether to allow nulls or use defaults, also note:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Nulls are not the same as blanks. Two blanks can be compared and found
equal, while the result of a comparison of two nulls is indeterminate.</p>
</li>
<li>
<p>Nulls are not the same as zeros. Zeros can participate in arithmetic
operations, while nulls are excluded from any arithmetic operation.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="defining_columns_that_allow_or_prohibit_null">5.15.2. Defining Columns That Allow or Prohibit Null</h4>
<div class="paragraph">
<p>The CREATE TABLE and ALTER TABLE statements define the attributes for
columns within tables. A column allows nulls unless the column
definition includes the NOT NULL clause or the column is part of the
primary key of the table.</p>
</div>
<div class="paragraph">
<p>Null is the default for a column (other than NOT NULL) unless the column
definition includes a DEFAULT clause (other than DEFAULT NULL) or the NO
DEFAULT clause. The default value for a column is the value Trafodion
SQL inserts in a row when an INSERT statement omits a value for a
particular column.</p>
</div>
<div class="sect4">
<h5 id="null_in_distinct_group_by_and_order_by_clauses">Null in DISTINCT, GROUP BY, and ORDER BY Clauses</h5>
<div class="paragraph">
<p>In evaluating the DISTINCT, GROUP BY, and ORDER BY clauses, Trafodion
SQL considers all nulls to be equal. Additional considerations for these
clauses are:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 15%;">
<col style="width: 85%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DISTINCT</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Nulls are considered duplicates; therefore, a result has at most one null.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GROUP BY</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result has at most one null group.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ORDER BY</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Nulls are considered greater than non-null values.</p></td>
</tr>
</tbody>
</table>
</div>
<div class="sect4">
<h5 id="null-and-expression-evaluation-comparison">Null and Expression Evaluation Comparison</h5>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 33.3333%;">
<col style="width: 33.3333%;">
<col style="width: 33.3334%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Expression Type</th>
<th class="tableblock halign-left valign-top">Condition</th>
<th class="tableblock halign-left valign-top">Result</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Boolean operators (AND, OR, NOT)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Either operand is null.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">For AND, the result is null. For OR, the result is true if the other
operand is true, or null if the other operand is null or false. For NOT, the result is null.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Arithmetic operators</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Either or both operands are null.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result is null.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">NULL predicate</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The operand is null.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result is true.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Aggregate (or set) functions (except COUNT)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Some rows have null columns. The function is evaluated after eliminating nulls.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result is null if set is empty.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">COUNT(*)</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The function does not eliminate nulls.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result is the number of rows in the table whether or not the rows are null.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">COUNT COUNT DISTINCT</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The function is evaluated after eliminating nulls.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result is zero if set is empty.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Comparison: =, &lt;&gt;, &lt;, &gt;, &lt;&#61;, &gt;&#61;, LIKE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Either operand is null.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result is null.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">IN predicate</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Some expressions in the IN value list are null.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result is null if all of the expressions are null.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Subquery</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">No rows are returned.</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The result is null.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="predicates">5.16. Predicates</h3>
<div class="paragraph">
<p>A predicate determines an answer to a question about a value or group of
values. A predicate returns true, false, or, if the question cannot be
answered, unknown. Use predicates within search conditions to choose
rows from tables or views.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 30%;">
<col style="width: 70%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#between_predicate">BETWEEN Predicate</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Determines whether a sequence of values is within a range of sequences of values.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#comparison_predicates">Comparison Predicates</a><br>
( =, &lt;&gt;, &lt;, &gt;, &lt;&#61;, &gt;&#61; )</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Compares the values of sequences of expressions, or compares the values
of sequences of row values that are the result of row subqueries.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#exists_predicate">EXISTS Predicate</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Determines whether any rows are selected by a subquery. If the subquery
finds at least one row that satisfies its search condition, the
predicate evaluates to true. Otherwise, if the result table of the
subquery is empty, the predicate is false.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#in_predicate">IN Predicate</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Determines if a sequence of values is equal to any of the sequences of
values in a list of sequences.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#like_predicate">LIKE Predicate</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Searches for character strings that match a pattern.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#regexp_predicate">REGEXP Predicate</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Searches for character strings that match an extended regular expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#null_predicate">NULL Predicate</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Determines whether all the values in a sequence of values are null.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#quantified_comparison_predicates">Quantified Comparison Predicates</a><br>
(ALL, ANY, SOME )</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Compares the values of sequences of expressions to the values in each
row selected by a table subquery. The comparison is quantified by ALL,
ANY, or .</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>See the individual entry for a predicate or predicate group.</p>
</div>
<div class="sect3">
<h4 id="between_predicate">5.16.1. BETWEEN Predicate</h4>
<div class="paragraph">
<p>The BETWEEN predicate determines whether a sequence of values is within
a range of sequences of values.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">row-value-constructor [NOT] BETWEEN
row-value-constructor AND row-value-constructor
row-value-constructor is:
(expression [,expression ]...)
| row-subquery</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>row-value-constructor</em></code></p>
<div class="paragraph">
<p>specifies an operand of the BETWEEN predicate. The three operands can be
either of:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>(<em>expression</em> [,<em>expression</em> ]&#8230;)</p>
<div class="paragraph">
<p>is a sequence of SQL value expressions, separated by commas and enclosed
in parentheses.
<em>expression</em> cannot include an aggregate function unless <em>expression</em> is
in a HAVING clause. <em>expression</em> can be a scalar subquery (a subquery
that returns a single row consisting of a single column). See
<a href="#expressions">Expressions</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</li>
<li>
<p><code><em>row-subquery</em></code></p>
<div class="paragraph">
<p>is a subquery that returns a single row (consisting of a sequence of
values). See <a href="#subquery">Subquery</a> .</p>
</div>
<div class="paragraph">
<p>The three <em>row-value-constructors</em> specified in a BETWEEN predicate must
contain the same number of elements. That is, the number of value
expressions in each list, or the number of values returned by a row
subquery, must be the same.</p>
</div>
<div class="paragraph">
<p>The data types of the respective values of the three
<em>row-value-constructors</em> must be comparable. Respective values are
values with the same ordinal position in the two lists. See
<a href="#comparable_and_compatible_data_types">Comparable and Compatible Data Types</a>.</p>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="considerations_for_between">Considerations for BETWEEN</h5>
<div class="sect5">
<h6 id="logical_equivalents_using_and_and_or">Logical Equivalents Using AND and OR</h6>
<div class="paragraph">
<p>The predicate <em>expr1</em> BETWEEN <em>expr2</em> AND <em>expr3</em> is true if and only if
this condition is true:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">expr2 &lt;= expr1 AND expr1 &lt;= expr3</code></pre>
</div>
</div>
<div class="paragraph">
<p>The predicate <em>expr1</em> NOT BETWEEN <em>expr2</em> AND <em>expr3</em> is true if and
only if this condition is true:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">expr2 &gt; expr1 OR expr1 &gt; expr3</code></pre>
</div>
</div>
</div>
<div class="sect5">
<h6 id="descending_columns_in_keys">Descending Columns in Keys</h6>
<div class="paragraph">
<p>If a clause specifies a column in a key BETWEEN <em>expr2</em> and <em>expr3</em>,
<em>expr3</em> must be greater than <em>expr2</em> even if the column is specified as DESCENDING within its table
definition.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_between">Examples of BETWEEN</h5>
<div class="ulist">
<ul>
<li>
<p>This predicate is true if the total price of the units in inventory is
in the range from $1,000 to $10,000:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">qty_on_hand * price
BETWEEN 1000.00 AND 10000.00</code></pre>
</div>
</div>
</li>
<li>
<p>This predicate is true if the part cost is less than $5 or more than $800:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">partcost NOT BETWEEN 5.00 AND 800.00</code></pre>
</div>
</div>
</li>
<li>
<p>This BETWEEN predicate selects the part number 6400:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM partsupp
WHERE partnum BETWEEN 6400 AND 6700
AND partcost &gt; 300.00;
Part/Num Supp/Num Part/Cost Qty/Rec
-------- -------- ------------ ----------
6400 1 390.00 50
6401 2 500.00 20
6401 3 480.00 38
--- 3 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Find names between Jody Selby and Gene Wright:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(last_name, first_name) BETWEEN
('SELBY', 'JODY') AND ('WRIGHT', 'GENE')</code></pre>
</div>
</div>
<div class="paragraph">
<p>The name Barbara Swift would meet the criteria; the name Mike Wright would not.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT empnum, first_name, last_name
FROM persnl.employee
WHERE (last_name, first_name) BETWEEN
('SELBY', 'JODY') AND ('WRIGHT', 'GENE');
EMPNUM FIRST_NAME LAST_NAME
------ --------------- --------------------
43 PAUL WINTER
72 GLENN THOMAS
74 JOHN WALKER
...
--- 15 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="comparison_predicates">5.16.2. Comparison Predicates</h4>
<div class="paragraph">
<p>A comparison predicate compares the values of sequences of expressions,
or the values of sequences of row values that are the result of row
subqueries.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">row-value-constructor comparison-op row-value-constructor</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>comparison-op</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> = Equal
| &lt;&gt; Not equal
| &lt; Less than
| &gt; Greater than
| &lt;= Less than or equal to
| &gt;= Greater than or equal to</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>row-value-constructor</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> (expression [,expression]...)
| row-subquery</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>row-value-constructor</em></code></p>
<div class="paragraph">
<p>specifies an operand of a comparison predicate. The two operands can be
either of these:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>(<em>expression</em> [,<em>expression</em> ]&#8230;)</code></p>
<div class="paragraph">
<p>is a sequence of SQL value expressions, separated by commas and enclosed
in parentheses.</p>
</div>
<div class="paragraph">
<p><em>expression</em> cannot include an aggregate function unless expression is
in a HAVING clause. <em>expression</em> can be a scalar subquery (a subquery
that returns a single row consisting of a single column). See
<a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>row-subquery</em></code></p>
<div class="paragraph">
<p>is a subquery that returns a single row (consisting of a sequence of
values). See <a href="#subquery">Subquery</a> .</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p>The two <em>row-value-constructors</em> must contain the same number of
elements. That is, the number of value expressions in each list, or the
number of values returned by a row subquery, must be the same.</p>
<div class="paragraph">
<p>The data types of the respective values of the two
<em>row-value-constructors</em> must be comparable. (Respective values are
values with the same ordinal position in the two lists.) See
<a href="#comparable_and_compatible_data_types">Comparable and Compatible Data Types</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="considerations_for_comparison_predicates">Considerations for Comparison Predicates</h5>
<div class="sect5">
<h6 id="when_a_comparison_predicate_is_true">When a Comparison Predicate Is True</h6>
<div class="paragraph">
<p>Trafodion SQL determines whether a relationship is true or false by
comparing values in corresponding positions in sequence, until it finds
the first non-equal pair.</p>
</div>
<div class="paragraph">
<p>You cannot use a comparison predicate in a WHERE or HAVING clause to
compare row value constructors when the value expressions in one row
value constructor are equal to null. Use the IS NULL predicate instead.</p>
</div>
<div class="paragraph">
<p>Suppose that two rows with multiple components exist, X and Y:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">X=(X1,X2,...,Xn), Y=(Y1,Y2,...,Yn).</code></pre>
</div>
</div>
<div class="paragraph">
<p>Predicate X=Y is true if for all i=1,&#8230;,n: Xi=Yi. For this predicate,
Trafodion SQL must look through all values. Predicate X = Y is false if
for some i Xi&lt;&gt;Yi. When SQL finds non-equal components, it stops and does
not look at remaining components.</p>
</div>
<div class="paragraph">
<p>Predicate X&lt;&gt;Y is true if X=Y is false. If X1&lt;&gt;Y1, Trafodion SQL does
not look at all components. It stops and returns a value of false for
the X=Y predicate and a value of true for the X&lt;&gt;Y predicate. Predicate
X&lt;&gt;Y is false if X=Y is true, or for all i=1,&#8230;,n: Xi=Yi. In this
situation, Trafodion SQL must look through all components.</p>
</div>
<div class="paragraph">
<p>Predicate X&gt;Y is true if for some index m Xm&gt;Ym and for all i=1,&#8230;,m-1:
Xi=Yi. Trafodion SQL does not look through all components. It stops when
it finds the first nonequal components, Xm&lt;&gt;Ym. If Xm&gt;Ym, the predicate
is true. Otherwise the predicate is false. The predicate is also false
if all components are equal, or X=Y.</p>
</div>
<div class="paragraph">
<p>Predicate X&gt;&#61;Y is true if X&gt;Y is true or X=Y is true. In this scenario,
Trafodion SQL might look through all components and return true if they
are all equal. It stops at the first nonequal components, Xm&lt;&gt;Ym. If
Xm&gt;Ym, the predicate is true. Otherwise, it is false.</p>
</div>
<div class="paragraph">
<p>Predicate X&lt;Y is true if for some index m Xm&lt;Ym, and for all i=1,&#8230;,m-1:
Xi=Yi. Trafodion SQL does not look through all components. It stops when
it finds the first nonequal components Xm&lt;&gt;Ym. If Xm&lt;Ym, the predicate
is true. Otherwise, the predicate is false. The predicate is also false
if all components are equal, or X=Y.</p>
</div>
<div class="paragraph">
<p>Predicate X&lt;&#61;Y is true if X&lt;Y is true or X=Y is true. In this scenario,
Trafodion SQL might need to look through all components and return true
if they are all equal. It stops at the first non-equal components,
Xm&lt;&gt;Ym. If Xm&lt;Ym, the predicate is true. Otherwise, it is false.</p>
</div>
</div>
<div class="sect5">
<h6 id="comparing_character_data">Comparing Character Data</h6>
<div class="paragraph">
<p>For comparisons between character strings of different lengths, the
shorter string is padded on the right with spaces (HEX 20) until it is
the length of the longer string. Both fixed-length and
variable-length strings are padded in this way.</p>
</div>
<div class="paragraph">
<p>For example, Trafodion SQL considers the string ‘JOE’ equal to a value
JOE stored in a column of data type CHAR or VARCHAR of width three or
more. Similarly, Trafodion SQL considers a value JOE stored in any
column of the CHAR data type equal to the value JOE stored in any column
of the VARCHAR data type.</p>
</div>
<div class="paragraph">
<p>Two strings are equal if all characters in the same ordinal position are
equal. Lowercase and uppercase letters are not considered equivalent.</p>
</div>
</div>
<div class="sect5">
<h6 id="comparing_numeric_data">Comparing Numeric Data</h6>
<div class="paragraph">
<p>Before evaluation, all numeric values in an expression are first
converted to the maximum precision needed anywhere in the expression.</p>
</div>
</div>
<div class="sect5">
<h6 id="comparing_interval_data">Comparing Interval Data</h6>
<div class="paragraph">
<p>For comparisons of INTERVAL values, Trafodion SQL first converts the
intervals to a common unit.</p>
</div>
<div class="paragraph">
<p>If no common unit exists, Trafodion SQL reports an error. Two INTERVAL
values must be both year-month intervals or both day-time intervals.</p>
</div>
</div>
<div class="sect5">
<h6 id="comparing_multiple_values">Comparing Multiple Values</h6>
<div class="paragraph">
<p>Use multi-value predicates whenever possible; they are generally more
efficient than equivalent conditions without multi-value predicates.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_comparison_predicates">Examples of Comparison Predicates</h5>
<div class="ulist">
<ul>
<li>
<p>This predicate is true if the customer number is equal to 3210:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">custnum = 3210</code></pre>
</div>
</div>
</li>
<li>
<p>This predicate is true if the salary is greater than the average
salary of all employees:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">salary &gt; (SELECT AVG (salary) FROM persnl.employee);</code></pre>
</div>
</div>
</li>
<li>
<p>This predicate is true if the customer name is BACIGALUPI:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">custname = 'BACIGALUPI'</code></pre>
</div>
</div>
</li>
<li>
<p>This predicate evaluates to unknown for any rows in either CUSTOMER or
ORDERS that contain null in the CUSTNUM column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">customer.custnum &gt; orders.custnum</code></pre>
</div>
</div>
</li>
<li>
<p>This predicate returns information about anyone whose name follows
MOSS, DUNCAN in a list arranged alphabetically by last name and, for the
same last name, alphabetically by first name:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(last_name, first_name) &gt; ('MOSS', 'DUNCAN')</code></pre>
</div>
</div>
<div class="paragraph">
<p>REEVES, ANNE meets this criteria, but MOSS, ANNE does not.</p>
</div>
<div class="paragraph">
<p>This multi-value predicate is equivalent to this condition with three
comparison predicates:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(last_name &gt; 'MOSS') OR
(last_name = 'MOSS' AND first_name &gt; 'DUNCAN')</code></pre>
</div>
</div>
</li>
<li>
<p>Compare two datetime values START_DATE and the result of the
CURRENT_DATE function:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">START_DATE &lt; CURRENT_DATE</code></pre>
</div>
</div>
</li>
<li>
<p>Compare two datetime values START_DATE and SHIP_TIMESTAMP:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CAST (start_date AS TIMESTAMP) &lt; ship_timestamp</code></pre>
</div>
</div>
</li>
<li>
<p>Compare two INTERVAL values:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">JOB1_TIME &lt; JOB2_TIME</code></pre>
</div>
</div>
<div class="paragraph">
<p>Suppose that JOB1_TIME, defined as INTERVAL DAY TO MINUTE, is 2 days 3
hours, and JOB2_TIME, defined as INTERVAL DAY TO HOUR, is 3 days.</p>
</div>
<div class="paragraph">
<p>To evaluate the predicate, Trafodion SQL converts the two INTERVAL
values to MINUTE. The comparison predicate is true.</p>
</div>
</li>
<li>
<p>The next examples contain a subquery in a comparison predicate. Each
subquery operates on a separate logical copy of the EMPLOYEE table.</p>
<div class="paragraph">
<p>The processing sequence is outer to inner. A row selected by an outer
query allows an inner query to be evaluated, and a single value is
returned. The next inner query is evaluated when it receives a value
from its outer query.</p>
</div>
<div class="paragraph">
<p>Find all employees whose salary is greater than the maximum salary of
employees in department 1500:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
first_name, last_name, deptnum, salary
FROM persnl.employee
WHERE salary &gt;
(SELECT MAX (salary) FROM persnl.employee WHERE deptnum = 1500);
FIRST_NAME LAST_NAME DEPTNUM SALARY
--------------- -------------------- ------- -----------
ROGER GREEN 9000 175500.00
KATHRYN HALL 4000 96000.00
RACHEL MCKAY 4000 118000.00
THOMAS RUDLOFF 2000 138000.40
JANE RAYMOND 3000 136000.00
JERRY HOWARD 1000 137000.10
--- 6 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>Find all employees from other departments whose salary is less than the
minimum salary of employees (not in department 1500) that have a salary
greater than the average salary for department 1500:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT first_name, last_name, deptnum, salary
FROM persnl.employee
WHERE deptnum &lt;&gt; 1500
AND salary &lt; (SELECT MIN (salary)
FROM persnl.employee WHERE deptnum &lt;&gt; 1500
AND salary &gt; (SELECT AVG (salary) FROM persnl.employee WHERE deptnum = 1500));
FIRST_NAME LAST_NAME DEPTNUM SALARY
--------------- -------------------- ------- -----------
JESSICA CRINER 3500 39500.00
ALAN TERRY 3000 39500.00
DINAH CLARK 9000 37000.00
BILL WINN 2000 32000.00
MIRIAM KING 2500 18000.00
...
--- 35 row(s) selected.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>The first subquery of this query determines the minimum salary of
employees from other departments whose salary is greater than the
average salary for department 1500. The main query then finds the names
of employees who are not in department 1500 and whose salary is less
than the minimum salary determined by the first subquery.</p>
</div>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="exists_predicate">5.16.3. EXISTS Predicate</h4>
<div class="paragraph">
<p>The EXISTS predicate determines whether any rows are selected by a
subquery. If the subquery finds at least one row that satisfies its
search condition, the predicate evaluates to true. Otherwise, if the
result table of the subquery is empty, the predicate is false.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[NOT] EXISTS subquery</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>subquery</em></code></p>
<div class="paragraph">
<p>specifies the operand of the predicate. A <em>subquery</em> is a query
expression enclosed in parentheses. An EXISTS <em>subquery</em> is typically
correlated with an outer query. See <a href="#subquery">Subquery</a> .</p>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="examples_of_exists">Examples of EXISTS</h5>
<div class="ulist">
<ul>
<li>
<p>Find locations of employees with job code 300:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT deptnum, location FROM persnl.dept D WHERE EXISTS
(SELECT jobcode FROM persnl.employee E
WHERE D.deptnum = E.deptnum AND jobcode = 300);
DEPTNUM LOCATION
------- -------------
3000 NEW YORK
3100 TORONTO
3200 FRANKFURT
3300 LONDON
3500 HONG KONG
--- 5 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>In the preceding example, the EXISTS predicate contains a subquery that
determines which locations have employees with job code 300. The
subquery depends on the value of D.DEPTNUM from the outer query and must
be evaluated for each row of the result table where D.DEPTNUM equals
E.DEPTNUM. The column D.DEPTNUM is an example of an outer reference.</p>
</div>
</li>
<li>
<p>Search for departments that have no employees with job code 420:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT deptname FROM persnl.dept D WHERE NOT EXISTS
(SELECT jobcode FROM persnl.employee E
WHERE D.deptnum = E.deptnum AND jobcode = 420);
DEPTNAME
------------
FINANCE
PERSONNEL
INVENTORY
...
--- 11 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Search for parts with less than 20 units in the inventory:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT partnum, suppnum FROM invent.partsupp PS WHERE EXISTS
(SELECT partnum FROM invent.partloc PL
WHERE PS.partnum = PL.partnum AND qty_on_hand &lt; 20);
PARTNUM SUPPNUM
------- -------
212 1
212 3
2001 1
2003 2
...
--- 18 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="in_predicate">5.16.4. IN Predicate</h4>
<div class="paragraph">
<p>The IN predicate determines if a sequence of values is equal to any of
the sequences of values in a list of sequences. The NOT operator
reverses its truth value. For example, if IN is true, NOT IN is false.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">row-value-constructor
[NOT] IN {table-subquery | in-value-list}
row-value-constructor is:
(expression [,expression]...)
| row-subquery</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>in-value-list</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(expression [,expression_]...)</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>row-value-constructor</em></code></p>
<div class="paragraph">
<p>specifies the first operand of the IN predicate. The first operand can
be either of:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(expression [,expression ]...)</code></pre>
</div>
</div>
<div class="paragraph">
<p>is a sequence of SQL value expressions, separated by commas and enclosed
in parentheses.</p>
</div>
<div class="paragraph">
<p><em>expression</em> cannot include an aggregate function unless expression is
in a HAVING clause. <em>expression</em> can be a scalar subquery (a subquery
that returns a single row consisting of a single column). See
<a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>row-subquery</em></code></p>
<div class="paragraph">
<p>is a subquery that returns a single row (consisting of a sequence of
values). See <a href="#subquery">Subquery</a> .</p>
</div>
</li>
<li>
<p><code><em>table-subquery</em></code></p>
<div class="paragraph">
<p>is a subquery that returns a table (consisting of rows of columns). The
table specifies rows of values to be compared with the row of values
specified by the <em>row-value-constructor</em>. The number of values of the
<em>row-value-constructor</em> must be equal to the number of columns in the
result table of the <em>table-subquery</em>, and the data types of the values
must be comparable.</p>
</div>
</li>
<li>
<p><code><em>in-value-list</em></code></p>
<div class="paragraph">
<p>is a sequence of SQL value expressions, separated by commas and enclosed
in parentheses. <em>expression</em> cannot include an aggregate function
defined on a column. <em>expression</em> can be a scalar subquery (a subquery
that returns a single row consisting of a single column). In this case,
the result of the <em>row-value-constructor</em> is a single value. The data
types of the values must be comparable. The number of expressions in the
<em>in-value-list</em> can have at least 5000 expressions.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="considerations_for_in">Considerations for IN</h5>
<div class="sect5">
<h6 id="logical_equivalent_using_any_or_some">Logical Equivalent Using ANY (or SOME)</h6>
<div class="paragraph">
<p>The predicate <em>expr</em> IN (<em>expr1</em>, <em>expr2</em>, &#8230; ) is true if and only
if the following predicate is true:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">expr = ANY (expr1, expr2, ... )</code></pre>
</div>
</div>
</div>
<div class="sect5">
<h6 id="in_predicate_results">IN Predicate Results</h6>
<div class="paragraph">
<p>The IN predicate is true if and only if either of these is true:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The result of the <em>row-value-constructor</em> (a row or sequence of
values) is equal to any row of column values specified by
<em>table-subquery</em>.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>A table subquery is a query expression and can be specified as a form of
a simple table; for example, as the VALUES keyword followed by a list of
row values. See <a href="#select_statement">SELECT Statement</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The result of the <em>row-value-constructor</em> (a single value) is equal to
any of the values specified by the list of expressions
<em>in-value-list</em>.</p>
<div class="paragraph">
<p>In this case, it is helpful to think of the list of expressions as a
one-column table—a special case of a table subquery. The degree of the
row value constructor and the degree of the list of expressions are both
one.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="comparing_character_data">Comparing Character Data</h6>
<div class="paragraph">
<p>Two strings are equal if all characters in the same ordinal position are
equal. Lowercase and uppercase letters are not considered equivalent.
For comparisons between character strings of different lengths, the
shorter string is padded on the right with spaces (HEX 20) until it is
the length of the longer string. Both fixed-length and varying-length
strings are padded in this way.</p>
</div>
<div class="paragraph">
<p>For example, Trafodion SQL considers the string ‘JOE’ equal to a value
JOE stored in a column of data type CHAR or VARCHAR of width three or
more. Similarly, Trafodion SQL considers a value JOE stored in any
column of the CHAR data type equal to the value JOE stored in any column
of the VARCHAR data type.</p>
</div>
</div>
<div class="sect5">
<h6 id="comparing_numeric_data">Comparing Numeric Data</h6>
<div class="paragraph">
<p>Before evaluation, all numeric values in an expression are first
converted to the maximum precision needed anywhere in the expression.</p>
</div>
</div>
<div class="sect5">
<h6 id="comparing_interval_data">Comparing Interval Data</h6>
<div class="paragraph">
<p>For comparisons of INTERVAL values, Trafodion SQL first converts the
intervals to a common unit.</p>
</div>
<div class="paragraph">
<p>If no common unit exists, Trafodion SQL reports an error. Two INTERVAL
values must be both year-month intervals or both day-time intervals.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_in">Examples of IN</h5>
<div class="ulist">
<ul>
<li>
<p>Find those employees whose EMPNUM is 39, 337, or 452:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT last_name, first_name, empnum
FROM persnl.employee
WHERE empnum IN (39, 337, 452);
LAST_NAME FIRST_NAME EMPNUM
-------------------- --------------- ------
CLARK DINAH 337
SAFFERT KLAUS 39
--- 2 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Find those items in PARTS whose part number is not in the PARTLOC table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT partnum, partdesc FROM sales.parts
WHERE partnum NOT IN (SELECT partnum
FROM invent.partloc);
PARTNUM PARTDESC
------- ------------------
186 186 MegaByte Disk
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Find those items (and their suppliers) in PARTS that have a supplier
in the PARTSUPP table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT P.partnum, P.partdesc, S.suppnum, S.suppname
FROM sales.parts P, invent.supplier S
WHERE P.partnum, S.suppnum IN
(SELECT partnum, suppnum FROM invent.partsupp);</code></pre>
</div>
</div>
</li>
<li>
<p>Find those employees in EMPLOYEE whose last name and job code match
the list of last names and job codes:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT empnum, last_name, first_name
FROM persnl.employee
WHERE (last_name, jobcode)
IN (VALUES ('CLARK', 500), ('GREEN', 200));</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="like_predicate">5.16.5. LIKE Predicate</h4>
<div class="paragraph">
<p>The LIKE predicate searches for character strings that match a pattern.</p>
</div>
<div class="sect4">
<h5 id="like_syntax">Syntax</h5>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">match-value [NOT] LIKE pattern [ESCAPE esc-char-expression]</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>match-value</em></code></p>
<div class="paragraph">
<p>is a character value expression that specifies a set of strings to
search for that match the <em>pattern</em>.</p>
</div>
</li>
<li>
<p><code><em>pattern</em></code></p>
<div class="paragraph">
<p>is a character value expression that specifies the pattern string for
the search.</p>
</div>
</li>
<li>
<p><code><em>esc-char-expression</em></code></p>
<div class="paragraph">
<p>is a character value expression that must evaluate to a single
character. The escape character value is used to turn off the special
meaning of percent (%) and underscore (_). See <a href="#wild_card_characters">Wild-Card Characters</a>.
<a href="#escape_characters">[escape_characters]</a>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</div>
<div class="sect4">
<h5 id="like_considerations">Considerations</h5>
<div class="sect5">
<h6 id="comparing_the_value_to_the_pattern">Comparing the Value to the Pattern</h6>
<div class="paragraph">
<p>The values that you compare must be character strings. Lowercase and
uppercase letters are not equivalent. To make lowercase letters match
uppercase letters, use the UPSHIFT function. A blank is compared in the
same way as any other character.</p>
</div>
</div>
<div class="sect5">
<h6 id="when_a_like_predicate_is_true">When a LIKE Predicate Is True</h6>
<div class="paragraph">
<p>When you refer to a column, the LIKE predicate is true if the <em>pattern</em>
matches the column value. If the value of the column reference is null,
the LIKE predicate evaluates to unknown for that row.</p>
</div>
<div class="paragraph">
<p>If the values that you compare are both empty strings (that is, strings
of zero length), the LIKE predicate is true.</p>
</div>
</div>
<div class="sect5">
<h6 id="using_not">Using NOT</h6>
<div class="paragraph">
<p>If you specify NOT, the predicate is true if the <em>pattern</em> does not
match any string in the <em>match-value</em> or is not the same length as any string in the
<em>match-value</em>. For example, NAME NOT LIKE '_Z' is true if the string
is not two characters long or the last character is not Z. In a search
condition, the predicate NAME NOT LIKE '_Z' is equivalent to NOT (NAME
LIKE '_Z').</p>
</div>
</div>
<div class="sect5">
<h6 id="wild_card_characters">Wild-Card Characters</h6>
<div class="paragraph">
<p>You can look for similar values by specifying only part of the
characters of <em>pattern</em> combined with these wild-card characters:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>Percent Sign (%)</code></p>
<div class="paragraph">
<p>Use a percent sign to indicate zero or more characters of any type. For
example, '%ART%' matches 'SMART', 'ARTIFICIAL', and 'PARTICULAR', but not 'smart'.</p>
</div>
</li>
<li>
<p><code>Underscore (_)</code></p>
<div class="paragraph">
<p>Use an underscore to indicate any single character. For example, 'BOO_'
matches 'BOOK' and 'BOOT' but not 'BOO', 'BOOKLET', or 'book'.</p>
</div>
</li>
<li>
<p><code>Escape Characters</code></p>
<div class="paragraph">
<p>To search for a string containing a percent sign (%) or an underscore
(<em>), define an escape character, using ESCAPE _esc-char-expression</em>,
to turn off the special meaning of the percent sign and underscore.</p>
</div>
<div class="paragraph">
<p>To include a percent sign or an underscore in a comparison string, type
the escape character immediately preceding the percent sign or
underscore. For example, to locate the value 'A_B', type:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">NAME LIKE 'A\_B' ESCAPE '\'</code></pre>
</div>
</div>
<div class="paragraph">
<p>To include the escape character itself in the comparison string, type
two escape characters. For example, to locate 'A_B\C%', type:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">NAME LIKE 'A\_B\\C\%' ESCAPE '\'</code></pre>
</div>
</div>
<div class="paragraph">
<p>The escape character must precede only the percent sign, underscore, or
escape character itself. For example, the pattern RA\BS is an invalid
LIKE pattern if the escape character is defined to be '\'. Error 8410
will be returned if this kind of pattern is used in an SQL query.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect5">
<h6 id="comparing_the_pattern_to_char_columns">Comparing the Pattern to CHAR Columns</h6>
<div class="paragraph">
<p>Columns of data type CHAR are fixed length. When a value is inserted
into a CHAR column, Trafodion SQL pads the value in the column with
blanks if necessary. The value 'JOE' inserted into a CHAR(4) column
becomes 'JOE ' (three characters plus one blank). The LIKE predicate is
true only if the column value and the comparison value are the same
length. The column value 'JOE ' does not match 'JOE' but does match
'JOE%'.</p>
</div>
</div>
<div class="sect5">
<h6 id="comparing_the_pattern_to_varchar_columns">Comparing the Pattern to VARCHAR Columns</h6>
<div class="paragraph">
<p>Columns of variable-length character data types do not include trailing
blanks unless blanks are specified when data is entered. For example,
the value 'JOE' inserted in a VARCHAR(4) column is 'JOE' with no
trailing blanks. The value matches both 'JOE' and 'JOE%'.</p>
</div>
<div class="paragraph">
<p>If you cannot locate a value in a variable-length character column, it
might be because trailing blanks were specified when the value was
inserted into the table. For example, a value of '5MB ' (with one
trailing blank) will not be located by LIKE '%MB' but will be located by
LIKE '%MB%'.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="like_examples">Examples</h5>
<div class="ulist">
<ul>
<li>
<p>Find all employee last names beginning with ZE:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">last_name LIKE 'ZE%'</code></pre>
</div>
</div>
</li>
<li>
<p>Find all part descriptions that are not 'FLOPPY_DISK':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">partdesc NOT LIKE 'FLOPPY\_DISK' ESCAPE '\'</code></pre>
</div>
</div>
<div class="paragraph">
<p>The escape character indicates that the underscore in 'FLOPPY_DISK' is
part of the string to search for, not a wild-card character.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="regexp_predicate">5.16.6. REGEXP Predicate</h4>
<div class="paragraph">
<p>Performs a pattern match of a string expression against a pattern .
The pattern can be an extended regular expression.
Returns 1 if expression matches pattern; otherwise it returns 0.
If either expression or pattern is NULL, the result is NULL.</p>
</div>
<div class="sect4">
<h5 id="regexp_syntax">Syntax</h5>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">match-value [NOT] REGEXP regular-expression</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>match-value</em></code></p>
<div class="paragraph">
<p>is a character value expression that specifies a set of strings to
search for that match the <em>regular-expression</em>.</p>
</div>
</li>
<li>
<p><code><em>regular-expression</em></code></p>
<div class="paragraph">
<p>is a character value expression that specifies a regular expression.
Trafodion regular expressions follow POSIX regular expression rules.</p>
</div>
</li>
</ul>
</div>
<div class="sect5">
<h6 id="using_not">Using NOT</h6>
<div class="paragraph">
<p>If you specify NOT, the predicate is true if the <em>regular-expression</em> does not
match any string in the <em>match-value</em>.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="regexp_examples">Examples</h5>
<div class="ulist">
<ul>
<li>
<p>Find valid numbers</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">col REGEXP '^[0-9]*\s*$'</code></pre>
</div>
</div>
</li>
<li>
<p>Find valid words, no numbers</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">col REGEXP '^.[A-Za-z]+\s*$'</code></pre>
</div>
</div>
</li>
<li>
<p>Find valid email address</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">col REGEXP '\w+([-+.]\w+)*@\w+([-.]\w+)*\.\w+([-.]\w+)*\s*'</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="null_predicate">5.16.7. NULL Predicate</h4>
<div class="paragraph">
<p>The NULL predicate determines whether all the expressions in a sequence
are null. See <a href="#null">Null</a> .</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">row-value-constructor IS [NOT] NULL
row-value-constructor is:
(expression [,expression]...)
| row-subquery</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>row-value-constructor</em></code></p>
<div class="paragraph">
<p>specifies the operand of the NULL predicate. The operand can be either
of these:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(expression [,expression ]...)</code></pre>
</div>
</div>
<div class="paragraph">
<p>is a sequence of SQL value expressions, separated by commas and enclosed
in parentheses.</p>
</div>
<div class="paragraph">
<p><em>expression</em> cannot include an aggregate function unless expression is
in a HAVING clause. <em>expression</em> can be a scalar subquery (a subquery
that returns a single row consisting of a single column). See
<a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>row-subquery</em></code></p>
<div class="paragraph">
<p>is a subquery that returns a single row (consisting of a sequence of
values). See <a href="#subquery">Subquery</a> .</p>
</div>
<div class="paragraph">
<p>If all of the expressions in the <em>row-value-constructor</em> are null, the
IS NULL predicate is true. Otherwise, it is false. If none of the
expressions in the <em>row-value-constructor</em> are null, the IS NOT NULL
predicate is true. Otherwise, it is false.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect4">
<h5 id="considerations-for-null">Considerations for NULL</h5>
<div class="sect5">
<h6 id="summary_of_null_results">Summary of NULL Results</h6>
<div class="paragraph">
<p>Let rvc be the value of the <em>row-value-constructor</em>. This table
summarizes the results of NULL predicates. The degree of a <em>rvc</em> is the
number of values in the <em>rvc</em>.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Expressions</th>
<th class="tableblock halign-left valign-top"><em>rvc</em> IS NULL</th>
<th class="tableblock halign-left valign-top"><em>rvc</em> IS NOT NULL</th>
<th class="tableblock halign-left valign-top">NOT <em>rvc</em> IS NULL</th>
<th class="tableblock halign-left valign-top">NOT <em>rvc</em> IS NOT NULL</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">degree 1: null</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">degree 1: not null</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">degree&gt;1: all null</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">degree&gt;1: some null</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">degree&gt;1: none null</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TRUE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">FALSE</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>The <em>rvc</em> IS NOT NULL predicate is not equivalent to NOT <em>rvc</em> IS NULL.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="examples-of-null">Examples of NULL</h5>
<div class="ulist">
<ul>
<li>
<p>Find all rows with null in the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">salary IS NULL</code></pre>
</div>
</div>
</li>
<li>
<p>This predicate evaluates to true if the expression (PRICE + TAX)
evaluates to null:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(price + tax) IS NULL</code></pre>
</div>
</div>
</li>
<li>
<p>Find all rows where both FIRST_NAME and SALARY are null:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(first_name, salary) IS NULL</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="quantified_comparison_predicates">5.16.8. Quantified Comparison Predicates</h4>
<div class="paragraph">
<p>A quantified comparison predicate compares the values of sequences of
expressions to the values in each row selected by a table subquery. The
comparison operation is quantified by the logical quantifiers ALL, ANY,
or SOME.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">row-value-constructor comparison-op quantifier table-subquery
row-value-constructor is:
(expression [,expression]...)
| row-subquery
comparison-op is:
= Equal
| &lt;&gt; Not equal
| != Not equal
| &lt; Less than
| &gt; Greater than
| &lt;= Less than or equal to
| &gt;= Greater than or equal to
quantifier is:
ALL | ANY | SOME</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>row-value-constructor</em></code></p>
<div class="paragraph">
<p>specifies the first operand of a quantified comparison predicate. The
first operand can be either of:</p>
</div>
</li>
<li>
<p><code>(<em>expression</em> [,<em>expression</em> ]&#8230;)</code></p>
<div class="paragraph">
<p>is a sequence of SQL value expressions, separated by commas and enclosed
in parentheses. <em>expression</em> cannot include an aggregate function
unless <em>expression</em> is in a HAVING clause. <em>expression</em> can be a scalar
subquery (a subquery that returns a single row consisting of a single
column). See <a href="#expressions">Expressions</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>row-subquery</code></p>
<div class="paragraph">
<p>is a subquery that returns a single row (consisting of a sequence of
values). See <a href="#subquery">Subquery</a> .</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>specifies that the predicate is true if the comparison is true for every
row selected by</p>
</div>
<div class="paragraph">
<p><em>table-subquery</em> (or if <em>table-subquery</em> selects no rows), and specifies
that the predicate is false if the comparison is false for at least one
row selected.</p>
</div>
</li>
<li>
<p><code>ANY | SOME</code></p>
<div class="paragraph">
<p>specifies that the predicate is true if the comparison is true for at
least one row selected by the <em>table-subquery</em> and specifies that the
predicate is false if the comparison is false for every row selected (or
if <em>table-subquery</em> selects no rows).</p>
</div>
</li>
<li>
<p><code>table-subquery</code></p>
<div class="paragraph">
<p>provides the values for the comparison. The number of values returned by
the <em>row-value-constructor</em> must be equal to the number of values specified
by the <em>table-subquery</em>, and the data types of values returned by the
<em>row-value-constructor</em> must be comparable to the data types of values
returned by the <em>table-subquery</em>. See “Subquery” .</p>
</div>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="considerations_for_all_any_some">Considerations for ALL, ANY, SOME</h5>
<div class="paragraph">
<p>Let <em>R</em> be the result of the <em>row-value-constructor</em>, <em>T</em> the result
of the <em>table-subquery</em>, and <em>RT</em> a row in <em>T</em>.</p>
</div>
<div class="sect5">
<h6 id="_result_of_em_rcomparison_op_em_all_em_t_em">Result of <em>Rcomparison-op</em> ALL <em>T</em></h6>
<div class="paragraph">
<p>If <em>T</em> is empty or if <em>R comparison-op RT</em> is true for every row <em>RT</em> in
<em>T</em>, the <em>comparison-op</em> ALL predicate is true.</p>
</div>
<div class="paragraph">
<p>If <em>R comparison-op RT</em> is false for at least one row <em>RT</em> in <em>T</em>, the
<em>comparison-op</em> ALL predicate is false.</p>
</div>
</div>
<div class="sect5">
<h6 id="_result_of_em_rcomparison_op_em_any_em_t_em_or_em_rcomparison_op_em_some_em_t_em">Result of <em>Rcomparison-op</em> ANY <em>T</em> or <em>Rcomparison-op</em> SOME <em>T</em></h6>
<div class="paragraph">
<p>If <em>T</em> is empty or if <em>R comparison-op RT</em> is false for every row <em>RT</em>
in <em>T</em>, the <em>comparison-op</em> ANY predicate is false.</p>
</div>
<div class="paragraph">
<p>If <em>R comparison-op RT</em> is true for at least one row <em>RT</em> in <em>T</em>, the
<em>comparison-op</em> ANY predicate is true.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_all_any_some">Examples of ALL, ANY, SOME</h5>
<div class="ulist">
<ul>
<li>
<p>This predicate is true if the salary is greater than the salaries of
all the employees who have a jobcode of 420:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">salary &gt; ALL (SELECT salary
FROM persnl.employee
WHERE jobcode = 420)</code></pre>
</div>
</div>
<div class="paragraph">
<p>Consider this SELECT statement using the preceding predicate:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT empnum, first_name, last_name, salary FROM persnl.employee
WHERE salary &gt; ALL (SELECT salary
FROM persnl.employee WHERE jobcode = 420);</code></pre>
</div>
</div>
<div class="paragraph">
<p>The inner query providing the comparison values yields these results:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT salary
FROM persnl.employee WHERE jobcode = 420;
SALARY
-----------
33000.00
36000.00
18000.10
--- 3 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The SELECT statement using this inner query yields these results. The
salaries listed are greater than the salary of every employees with
jobcode equal to 420—that is, greater than
$33,000.00, $36,000.00, and $18,000.10:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT empnum, first_name, last_name, salary FROM persnl.employee
WHERE salary &gt; ALL (SELECT salary
FROM persnl.employee WHERE jobcode = 420);
FIRST_NAME LAST_NAME SALARY
--------------- -------------------- -----------
ROGER GREEN 175500.00
JERRY HOWARD 137000.10
JANE RAYMOND 136000.00
...
ALAN TERRY 39500.00
BEN HENDERSON 65000.00
JESSICA CRINER 39500.00
--- 23 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>This predicate is true if the part number is equal to any part number
with more than five units in stock:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">partnum = ANY (SELECT partnum
FROM sales.odetail
WHERE qty_ordered &gt; 5)</code></pre>
</div>
</div>
<div class="paragraph">
<p>Consider this SELECT statement using the preceding predicate:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ordernum, partnum, qty_ordered FROM sales.odetail
WHERE partnum = ANY (SELECT partnum
FROM sales.odetail WHERE qty_ordered &gt; 5);</code></pre>
</div>
</div>
<div class="paragraph">
<p>The inner query providing the comparison values yields these results:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT partnum FROM sales.odetail
WHERE qty_ordered &gt; 5;
Part/Num
--------
2403
5100
5103
6301
6500
....
--- 60 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The SELECT statement using this inner query yields these results. All of
the order numbers listed have part number equal to any part number with
more than five total units in stock—that is, equal to 2403, 5100, 5103,
6301, 6500, and so on:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ordernum, partnum, qty_ordered FROM sales.odetail
WHERE partnum = ANY (SELECT partnum
FROM sales.odetail WHERE qty_ordered &gt; 5);
Order/Num Part/Num Qty/Ord
---------- -------- ----------
100210 244 3
100210 2001 3
100210 2403 6
100210 5100 10
100250 244 4
100250 5103 10
100250 6301 15
100250 6500 10
...... .... ..
--- 71 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="privileges">5.17. Privileges</h3>
<div class="paragraph">
<p>A privilege provides authorization to perform a specific operation for a
specific object. A privilege can be granted to or revoked from a user or
role in many ways:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Implicit privileges are granted to an owner of an object when the
object is created. The owner retains implicit privileges for the
lifespan of the object.</p>
</li>
<li>
<p>Explicit privileges can be granted to or revoked from a user or role.
Explicit privileges can be granted or revoked by a database user
administrator, an object owner, or a user who has been granted the
privilege with the WITH GRANT OPTION option.</p>
</li>
<li>
<p>The privileges granted to a user can come from various sources.
Privileges can be directly granted to a user or they can be inherited
through a role. For example, a user gets the SELECT privilege on table
T1 from two different roles. If one of the roles is revoked from the
user, the user will still be able to select from T1 via the SELECT
privilege granted to the remaining role.</p>
</li>
<li>
<p>A user who is granted a role is thereby conferred all privileges of
the role. The only way to revoke any such privilege is to revoke the
role from the user. For more information, see
<a href="#roles">Roles</a> .</p>
</li>
<li>
<p>Privileges granted on an object can be for all the columns of the object or just a subset of the columns.
Only the following subset of privileges is applicable at the column-level: INSERT, REFERENCES, SELECT, and UPDATE.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>You can manage privileges by using the GRANT and REVOKE statements.</p>
</div>
<div class="paragraph">
<p>For more information on GRANT, see:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#grant_statement">GRANT Statement</a></p>
</li>
<li>
<p><a href="#grant_component_privilege_statement">GRANT COMPONENT PRIVILEGE Statement</a></p>
</li>
<li>
<p><a href="#grant_role_statement">GRANT ROLE Statement</a></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For more information on REVOKE, see:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#revoke_statement">REVOKE Statement</a></p>
</li>
<li>
<p><a href="#revoke_component_privilege_statement">REVOKE COMPONENT PRIVILEGE Statement</a></p>
</li>
<li>
<p><a href="#revoke_role_statement">REVOKE ROLE Statement</a></p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="roles">5.18. Roles</h3>
<div class="paragraph">
<p>A role offers the flexibility of implicitly assigning a set of
privileges to users, instead of assigning privileges individually. A
user can be granted one or more roles. A role can be granted to one or
more users. A role can be granted by or revoked by a database user
administrator, a role owner, or a member of the role.</p>
</div>
<div class="paragraph">
<p>Privileges are granted to a role. When a role is granted to a user, the
privileges granted to the role become available to the user. If new
privileges are granted to the role, those privileges become available to
all users who have been granted the role. When a role is revoked from a
user, the privileges granted to the role are no longer available to the
user. The change in privileges is automatically propagated to and detected by
active sessions, so there is no need for users to disconnect from and
reconnect to a session to see the updated set of privileges. For more
information about privileges, see <a href="#privileges">Privileges</a>.</p>
</div>
<div class="paragraph">
<p>A role name is an authorization ID. A role name cannot be identical to a
registered database user name. For more information, see
<a href="#authorization_ids">Authorization IDs</a>.</p>
</div>
<div class="paragraph">
<p>To manage roles, see these SQL statements:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#create_role_statement">CREATE ROLE Statement</a></p>
</li>
<li>
<p><a href="#drop_role_statement">DROP ROLE Statement</a></p>
</li>
<li>
<p><a href="#grant_role_statement">GRANT ROLE Statement</a></p>
</li>
<li>
<p><a href="#revoke_role_statement">REVOKE ROLE Statement</a></p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="schemas">5.19. Schemas</h3>
<div class="paragraph">
<p>The ANSI SQL:1999 schema name is an SQL identifier that is unique for a
given ANSI catalog name. Trafodion SQL automatically qualifies the
schema name with the current default catalog name, TRAFODION.</p>
</div>
<div class="paragraph">
<p>The logical name of the form <em>schema.object</em> is an ANSI name. The part
<em>schema</em> denotes the ANSI-defined schema.</p>
</div>
<div class="paragraph">
<p>To be compliant with ANSI SQL:1999, Trafodion SQL provides support for
ANSI object names.</p>
</div>
<div class="paragraph">
<p>By using these names, you can develop ANSI-compliant applications that
access all SQL objects. You can access Trafodion SQL objects with the
name of the actual object. See <a href="#set_schema_statement">SET SCHEMA Statement</a>.</p>
</div>
<div class="sect3">
<h4 id="creating_and_dropping_schemas">5.19.1. Creating and Dropping Schemas</h4>
<div class="paragraph">
<p>You create a schema using the CREATE SCHEMA command and drop a schema using the
DROP SCHEMA statement. For more information, see the
<a href="#create_schema_statement">CREATE SCHEMA Statement</a> and the
<a href="#drop_schema_statement">DROP SCHEMA Statement</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="search_condition">5.20. Search Condition</h3>
<div class="paragraph">
<p>A search condition is used to choose rows from tables or views,
depending on the result of applying the condition to rows. The condition
is a Boolean expression consisting of predicates combined together with
OR, AND, and NOT operators.</p>
</div>
<div class="paragraph">
<p>You can use a search condition in the WHERE clause of a SELECT, DELETE,
or UPDATE statement, the HAVING clause of a SELECT statement, the
searched form of a CASE expression, the ON clause of a SELECT statement
that involves a join, a CHECK constraint, or a ROWS SINCE sequence
function.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">search-condition is:
boolean-term | search-condition OR boolean-term
boolean-term is:
boolean-factor | boolean-term AND boolean-factor
boolean-factor is:
[NOT] boolean-primary
boolean-primary is:
predicate | (search-condition)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>OR</code></p>
<div class="paragraph">
<p>specifies the resulting search condition is true if and only if either
of the surrounding predicates or search conditions is true.</p>
</div>
</li>
<li>
<p><code>AND</code></p>
<div class="paragraph">
<p>specifies the resulting search condition is true if and only if both the
surrounding predicates or search conditions are true.</p>
</div>
</li>
<li>
<p><code>NOT</code></p>
<div class="paragraph">
<p>reverses the truth value of its operand—the following predicate or
search condition. predicate is a BETWEEN, comparison, EXISTS, IN, LIKE, NULL, or quantified
comparison predicate. A predicate specifies conditions that must be satisfied for a row to be
chosen. See <a href="#predicates">Predicates</a> and individual entries.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="considerations_for_search_condition">5.20.1. Considerations for Search Condition</h4>
<div class="sect4">
<h5 id="order_of_evaluation">Order of Evaluation</h5>
<div class="paragraph">
<p>SQL evaluates search conditions in this order:</p>
</div>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>Predicates within parentheses</p>
</li>
<li>
<p>NOT</p>
</li>
<li>
<p>AND</p>
</li>
<li>
<p>OR</p>
</li>
</ol>
</div>
</div>
<div class="sect4">
<h5 id="column-references">Column References</h5>
<div class="paragraph">
<p>Within a search condition, a reference to a column refers to the value
of that column in the row currently being evaluated by the search
condition.</p>
</div>
</div>
<div class="sect4">
<h5 id="subqueries">Subqueries</h5>
<div class="paragraph">
<p>If a search condition includes a subquery and the subquery returns no
values, the predicate evaluates to null. See
<a href="#subquery">Subquery</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_search_condition">5.20.2. Examples of Search Condition</h4>
<div class="ulist">
<ul>
<li>
<p>Select rows by using a search condition composed of three comparison
predicates joined by AND operators:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT O.ordernum, O.deliv_date, OD.qty_ordered
FROM sales.orders O, sales.odetail OD
WHERE qty_ordered &lt; 9
AND deliv_date &lt;= DATE '2008-11-01'
AND O.ordernum = OD.ordernum;
ORDERNUM DELIV_DATE QTY_ORDERED
---------- ---------- -----------
100210 2008-04-10 3
100210 2008-04-10 3
100210 2008-04-10 6
100250 2008-06-15 4
101220 2008-12-15 3
...
--- 28 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Select rows by using a search condition composed of three comparison
predicates, two of which are joined by an OR operator (within
parentheses), and where the result of the OR and the first comparison
predicate are joined by an AND operator:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT partnum, S.suppnum, suppname
FROM invent.supplier S, invent.partsupp PS
WHERE S.suppnum = PS.suppnum
AND (partnum &lt; 3000 OR partnum = 7102);
SUPPNAME
------------------
NEW COMPUTERS INC
NEW COMPUTERS INC
NEW COMPUTERS INC
...
LEVERAGE INC
--- 18 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="subquery">5.21. Subquery</h3>
<div class="paragraph">
<p>A subquery is a query expression enclosed in parentheses. Its syntactic
form is specified in the syntax of a SELECT statement. For further
information about query expressions, see <a href="#select_statement">SELECT Statement</a>.</p>
</div>
<div class="paragraph">
<p>A subquery is used to provide values for a BETWEEN, comparison, EXISTS,
IN, or quantified comparison predicate in a search condition. It is also
used to specify a derived table in the FROM clause of a SELECT
statement.</p>
</div>
<div class="paragraph">
<p>A subquery can be a table, row, or scalar subquery. Therefore, its
result table can be a table consisting of multiple rows and columns, a
single row of column values, or a single row consisting of only one
column value.</p>
</div>
<div class="sect3">
<h4 id="select_form_of_a_subquery">5.21.1. SELECT Form of a Subquery</h4>
<div class="paragraph">
<p>A subquery is typically specified as a special form of a SELECT
statement enclosed in parentheses that queries (or selects) to provide
values in a search condition or to specify a derived table as a table
reference.</p>
</div>
<div class="paragraph">
<p>The form of a subquery specified as a SELECT statement is <em>query-expr</em>.</p>
</div>
<div class="paragraph">
<p>Neither the ORDER BY clause nor [FIRST N] / [ANY N] clause is allowed in
a subquery.</p>
</div>
</div>
<div class="sect3">
<h4 id="using_subqueries_to_provide_comparison_values">5.21.2. Using Subqueries to Provide Comparison Values</h4>
<div class="paragraph">
<p>When a subquery is used to provide comparison values, the SELECT
statement that contains the subquery is called an outer query. The
subquery within the SELECT is called an <em>inner query</em>.</p>
</div>
<div class="paragraph">
<p>In this case, the differences between the SELECT statement and the
SELECT form of a subquery are:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>A subquery is always enclosed in parentheses.</p>
</li>
<li>
<p>A subquery cannot contain an ORDER BY clause.</p>
</li>
<li>
<p>If a subquery is not part of an EXISTS, IN, or quantified comparison
predicate, and the subquery evaluates to more than one row, a run-time
error occurs.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="nested_subqueries_when_providing_comparison_values">5.21.3. Nested Subqueries When Providing Comparison Values</h4>
<div class="paragraph">
<p>An outer query (a main SELECT statement) can have nested subqueries.
Subqueries within the same WHERE or HAVING clause are at the same level.
For example, this query has one level of nesting:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM table1
WHERE A = (SELECT P FROM table2 WHERE q = 1)
AND b = (SELECT x FROM table3 WHERE y = 2);</code></pre>
</div>
</div>
<div class="paragraph">
<p>A subquery within the WHERE clause of another subquery is at a different
level, however, so this query has two levels of nesting:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM table1
WHERE a = (SELECT p FROM table2
WHERE q = (SELECT x FROM table3
WHERE y = 2))</code></pre>
</div>
</div>
<div class="paragraph">
<p>The maximum level of nested subqueries might depend on:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The complexity of the subqueries.</p>
</li>
<li>
<p>Whether the subquery is correlated and if so, whether it can be un-nested.</p>
</li>
<li>
<p>Amount of available memory.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>Other factors may affect the maximum level of subqueries.</p>
</div>
</div>
<div class="sect3">
<h4 id="correlated_subqueries_when_providing_comparison_values">5.21.4. Correlated Subqueries When Providing Comparison Values</h4>
<div class="paragraph">
<p>In a subquery, when you refer to columns of any table or view defined in
an outer query, the reference is called an outer reference. A subquery
containing an outer reference is called a correlated subquery.</p>
</div>
<div class="paragraph">
<p>If you refer to a column name that occurs in more than one outer query,
you must qualify the column name with the correlation name of the table
or view to which it belongs. Similarly, if you refer to</p>
</div>
<div class="paragraph">
<p>a column name that occurs in the subquery and in one or more outer
queries, you must qualify the column name with the correlation name of
the table or view to which it belongs. The correlation name is known to
other subqueries at the same level, or to inner queries but not to outer
queries.</p>
</div>
<div class="paragraph">
<p>If you use the same correlation name at different levels of nesting, an
inner query uses the one from the nearest outer level.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="tables">5.22. Tables</h3>
<div class="paragraph">
<p>A table is a logical representation of data in which a set of records is
represented as a sequence of rows, and the set of fields common to all
rows is represented by columns. A column is a set of values of the same
data type with the same definition. The intersection of a row and column
represents the data value of a particular field in a particular record.</p>
</div>
<div class="paragraph">
<p>Every table must have one or more columns, but the number of rows can be
zero. No inherent order of rows exists within a table.</p>
</div>
<div class="paragraph">
<p>You create a Trafodion SQL user table by using the CREATE TABLE
statement. See the <a href="#create_table_statement">CREATE TABLE Statement</a>.
The definition of a user table within the statement includes this information:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Name of the table</p>
</li>
<li>
<p>Name of each column of the table</p>
</li>
<li>
<p>Type of data you can store in each column of the table</p>
</li>
<li>
<p>Other information about the table, including the physical
characteristics of the file that stores the table (for example, the
storage order of rows within the table)</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>A Trafodion SQL table is described in an SQL schema and stored as an
HBase table. Trafodion SQL tables have regular ANSI names in the catalog
TRAFODION. A Trafodion SQL table name can be a fully qualified ANSI name
of the form TRAFODION.<em>schema-name.object-name</em>. A Trafodion SQL
table’s metadata is stored in the schema TRAFODION."<em>MD</em>".</p>
</div>
<div class="paragraph">
<p>Because Trafodion defines the encodings for column values in Trafodion
SQL tables, those tables support various Trafodion SQL statements. See
<a href="#supported_sql_statements_with_hbase_tables">Supported SQL Statements With HBase Tables</a>.</p>
</div>
<div class="paragraph">
<p>Internally, Trafodion SQL tables use a single HBase column family and
shortened column names to conserve space. Their encoding allows keys
consisting of multiple columns and preserves the order of key values as
defined by SQL. The underlying HBase column model makes it very easy to
add and remove columns from Trafodion SQL tables. HBase columns that are
not recorded in the Trafodion metadata are ignored, and missing columns
are considered NULL values.</p>
</div>
<div class="sect3">
<h4 id="base_tables_and_views">5.22.1. Base Tables and Views</h4>
<div class="paragraph">
<p>In some descriptions of SQL, tables created with a CREATE TABLE
statement are called base tables to distinguish them from views, which
are called logical tables.</p>
</div>
<div class="paragraph">
<p>A view is a named logical table defined by a query specification that
uses one or more base tables or other views. See <a href="#views">Views</a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="example_of_a_base_table">5.22.2. Example of a Base Table</h4>
<div class="paragraph">
<p>For example, this EMPLOYEE table is a base table in a sample database:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 16.6666%;">
<col style="width: 16.6666%;">
<col style="width: 16.6666%;">
<col style="width: 16.6666%;">
<col style="width: 16.6666%;">
<col style="width: 16.667%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">EMPNUM</th>
<th class="tableblock halign-left valign-top">FIRST_NAME</th>
<th class="tableblock halign-left valign-top">LAST_NAME</th>
<th class="tableblock halign-left valign-top">DEPTNUM</th>
<th class="tableblock halign-left valign-top">JOBCODE</th>
<th class="tableblock halign-left valign-top">SALARY</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ROGER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">GREEN</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">9000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">175500.00</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">23</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">JERRY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">HOWARD</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">137000.00</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">75</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TIM</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">WALKER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">32000.00</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>In this sample table, the columns are EMPNUM, FIRST_NAME, LAST_NAME,
DEPTNUM, JOBCODE, and SALARY. The values in each column have the same
data type.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="views">5.23. Views</h3>
<div class="paragraph">
<p>A view provides an alternate way of looking at data in one or more
tables. A view is a named specification of a result table, which is a
set of rows selected or generated from one or more base tables or other
views. The specification is a SELECT statement that is executed whenever
the view is referenced.</p>
</div>
<div class="paragraph">
<p>A view is a logical table created with the CREATE VIEW statement and
derived by projecting a subset of columns, restricting a subset of rows,
or both, from one or more base tables or other views.</p>
</div>
<div class="sect3">
<h4 id="sql_views">5.23.1. SQL Views</h4>
<div class="paragraph">
<p>A view’s name must be unique among table and view names within the
schema that contains it. Single table views can be updatable. Multi-table
views are not updatable.</p>
</div>
<div class="paragraph">
<p>For information about SQL views, see <a href="#create_view_statement">CREATE VIEW Statement</a>
and <a href="#drop_view_statement">DROP VIEW Statement</a>.</p>
</div>
</div>
<div class="sect3">
<h4 id="example_of_a_view">5.23.2. Example of a View</h4>
<div class="paragraph">
<p>You can define a view to show only part of the data in a table. For
example, this EMPLIST view is defined as part of the EMPLOYEE table:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">EMPNUM</th>
<th class="tableblock halign-left valign-top">FIRST_NAME</th>
<th class="tableblock halign-left valign-top">LAST_NAME</th>
<th class="tableblock halign-left valign-top">DEPTNUM</th>
<th class="tableblock halign-left valign-top">JOBCODE</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">ROGER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">GREEN</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">9000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">23</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">JERRY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">HOWARD</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">75</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TIM</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">WALKER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3000</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">. . .</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>In this sample view, the columns are EMPNUM, FIRST_NAME, LAST_NAME,
DEPTNUM, and JOBCODE. The SALARY column in the EMPLOYEE table is not
part of the EMPLIST view.</p>
</div>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="sql_clauses">6. SQL Clauses</h2>
<div class="sectionbody">
<div class="paragraph">
<p>Clauses are used by Trafodion SQL statements to specify default values,
ways to sample or sort data, how to store physical data, and other
details.</p>
</div>
<div class="paragraph">
<p>This section describes:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><a href="#default_clause">DEFAULT Clause</a> specifies a default value for a column being created.</p>
</li>
<li>
<p><a href="#format_clause">FORMAT Clause</a> specifies the format to use.</p>
</li>
<li>
<p><a href="#sample_clause">SAMPLE Clause</a> specifies the sampling method used to select a subset of the intermediate result table of a SELECT statement.</p>
</li>
<li>
<p><a href="#sequence_by_clause">SEQUENCE BY Clause</a> specifies the order in which to sort rows of the intermediate result table for calculating sequence functions.</p>
</li>
<li>
<p><a href="#transpose_clause">TRANSPOSE Clause</a> generates, for each row of the SELECT source table, a row for each item in the transpose item list.</p>
</li>
</ul>
</div>
<div class="sect2">
<h3 id="default_clause">6.1. DEFAULT Clause</h3>
<div class="paragraph">
<p>The DEFAULT option of the CREATE TABLE or ALTER TABLE <em>table-name</em> ADD
COLUMN statement specifies a default value for a column being created.</p>
</div>
<div class="paragraph">
<p>The default value is used when a row is inserted in the table without a value for the column.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DEFAULT default | NO DEFAULT
default is:
literal
| NULL
| CURRENTDATE
| CURRENTTIME
| CURRENTTIMESTAMP</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>NO DEFAULT</code></p>
<div class="paragraph">
<p>specifies the column has no default value. You cannot specify NO DEFAULT
in an ALTER TABLE statement. See <a href="#alter_table_statement">ALTER TABLE Statement</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="syntax_for_default_clause">6.1.1. Syntax for Default Clause</h4>
<div class="ulist">
<ul>
<li>
<p><code>DEFAULT <em>literal</em></code></p>
<div class="paragraph">
<p>is a literal of a data type compatible with the data type of the
associated column.</p>
</div>
<div class="paragraph">
<p>For a character column, <em>literal</em> must be a string literal of no more
than 240 characters or the length of the column, whichever is less. The
maximum length of a default value for a character column is 240 bytes
(minus control characters) or the length of the column, whichever is
less. Control characters consist of character set prefixes and single
quote delimiter found in the text itself.</p>
</div>
<div class="paragraph">
<p>For a numeric column, <em>literal</em> must be a numeric literal that does not
exceed the defined length of the column. The number of digits to the
right of the decimal point must not exceed the scale of the column, and
the number of digits to the left of the decimal point must not exceed
the number in the length (or length minus scale, if you specified scale
for the column).</p>
</div>
<div class="paragraph">
<p>For a datetime column, <em>literal</em> must be a datetime literal with a
precision that matches the precision of the column.</p>
</div>
<div class="paragraph">
<p>For an INTERVAL column, <em>literal</em> must be an INTERVAL literal that has
the range of INTERVAL fields defined for the column.</p>
</div>
</li>
<li>
<p><code>DEFAULT NULL</code></p>
<div class="paragraph">
<p>specifies NULL as the default. This default can occur only with a column
that allows null.</p>
</div>
</li>
<li>
<p><code>DEFAULT CURRENT_DATE</code></p>
<div class="paragraph">
<p>specifies the default value for the column as the value returned by the
CURRENT_DATE function at the time of the operation that assigns a value
to the column. This default can occur only with a column whose data type
is DATE.</p>
</div>
</li>
<li>
<p><code>DEFAULT CURRENT_TIME</code></p>
<div class="paragraph">
<p>specifies the default value for the column as the value returned by the
CURRENT_TIME function at the time of the operation that assigns a value
to the column. This default can occur only with a column whose data type
is TIME.</p>
</div>
</li>
<li>
<p><code>DEFAULT CURRENT_TIMESTAMP</code></p>
<div class="paragraph">
<p>specifies the default value for the column as the value returned by the
CURRENT_TIMESTAMP function at the time of the operation that assigns a
value to the column. This default can occur only with a column whose
data type is TIMESTAMP.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_default">6.1.2. Examples of DEFAULT</h4>
<div class="ulist">
<ul>
<li>
<p>This example uses DEFAULT clauses on CREATE TABLE to specify default column values:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE items
( item_id CHAR(12) NO DEFAULT
, description CHAR(50) DEFAULT NULL
, num_on_hand INTEGER DEFAULT 0 NOT NULL
) ;</code></pre>
</div>
</div>
</li>
<li>
<p>This example uses DEFAULT clauses on CREATE TABLE to specify default column values:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE persnl.project
( projcode NUMERIC (4) UNSIGNED NO DEFAULT NOT NULL
, empnum NUMERIC (4) UNSIGNED NO DEFAULT NOT NULL
, projdesc VARCHAR (18) DEFAULT NULL
, start_date DATE DEFAULT CURRENT_DATE
, ship_timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP
, est_complete INTERVAL DAY DEFAULT INTERVAL '30' DAY
, PRIMARY KEY (projcode)
) ;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="format_clause">6.2. FORMAT Clause</h3>
<div class="paragraph">
<p>The FORMAT clause specifies the output format for DATE values. It can
also be used to specify the length of character output or to specify
separating the digits of integer output with colons.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Date Formats:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(FORMAT 'format-string') |
(DATE, FORMAT 'format-string')
format-string for Date Formats is:
YYYY-MM-DD
MM/DD/YYYY
YY/MM/DD
YYYY/MM/DD
YYYYMMDD
DD.MM.YYYY
DD-MM-YYYY
DD-MMM-YYYY</code></pre>
</div>
</div>
</li>
<li>
<p>Other Formats:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">(FORMAT 'format-string')
format-string for other formats is:
XXX
99:99:99:99
-99:99:99:99</code></pre>
</div>
</div>
</li>
<li>
<p><code>YYYY-MM-DD</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is <em>year-month-day</em>.</p>
</div>
</li>
<li>
<p><code>MM/DD/YYYY</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is <em>month/day/year</em></p>
</div>
</li>
<li>
<p><code>YY/MM/DD</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is <em>year/month/day</em>.</p>
</div>
</li>
<li>
<p><code>YYYY/MM/DD</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is <em>year/month/day</em>.</p>
</div>
</li>
<li>
<p><code>YYYYMMDD</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is <em>yearmonthday</em>.</p>
</div>
</li>
<li>
<p><code>DD.MM.YYYY</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is <em>day.month.year</em>.</p>
</div>
</li>
<li>
<p><code>DD-MM-YYYY</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is <em>day-month-year</em>.</p>
</div>
</li>
<li>
<p><code>DD-MMM-YYYY</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is <em>day-month-year</em>.</p>
</div>
</li>
<li>
<p><code>XXX</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is a string format. The
input must be a numeric or string value.</p>
</div>
</li>
<li>
<p><code>99:99:99:99</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is a timestamp. The input
must be a numeric value.</p>
</div>
</li>
<li>
<p><code>-99:99:99:99</code></p>
<div class="paragraph">
<p>specifies that the FORMAT clause output format is a timestamp. The input
must be a numeric value.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_date_formats">6.2.1. Considerations for Date Formats</h4>
<div class="paragraph">
<p>The expression preceding the (FORMAT ”<em>format-string</em>') clause must be
a DATE value.</p>
</div>
<div class="paragraph">
<p>The expression preceding the (DATE, FORMAT <em>'format-string</em>') clause
must be a quoted string in the USA, EUROPEAN, or DEFAULT date format.</p>
</div>
<div class="sect4">
<h5 id="considerations_for_other_formats">Considerations for Other Formats</h5>
<div class="paragraph">
<p>For XXX, the expression preceding the (FORMAT <em>'format-string</em>')
clause must be a numeric value or a string value.</p>
</div>
<div class="paragraph">
<p>For 99:99:99:99 and -99:99:99:99, the expression preceding the (FORMAT
<em>'format-string</em>') clause must be a numeric value.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_format">6.2.2. Examples of FORMAT</h4>
<div class="ulist">
<ul>
<li>
<p>The format string 'XXX' in this example will yield a sample result of abc:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT 'abcde' (FORMAT 'XXX') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string 'YYYY-MM_DD' in this example will yield a sample result of 2008-07-17.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CAST('2008-07-17' AS DATE) (FORMAT 'YYYY-MM-DD') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string 'MM/DD/YYYY' in this example will yield a sample result of 07/17/2008.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT '2008-07-17' (DATE, FORMAT 'MM/DD/YYYY') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string 'YY/MM/DD' in this example will yield a sample result of 08/07/17.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT '2008-07-17'(DATE, FORMAT 'YY/MM/DD') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string 'YYYY/MM/DD' in this example will yield a sample result of 2008/07/17.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT '2008-07-17' (DATE, FORMAT 'YYYY/MM/DD') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string 'YYYYMMDD' in this example will yield a sample result`of 20080717.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT '2008-07-17' (DATE, FORMAT 'YYYYMMDD') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string 'DD.MM.YYYY' in this example will yield a sample result of 17.07.2008.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT '2008-07-17' (DATE, FORMAT 'DD.MM.YYYY') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string 'DD-MMM-YYYY' in this example will yield a sample result of 17–JUL-2008.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT '2008-07-17' (DATE, FORMAT 'DD-MMM-YYYY') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string '99:99:99:99' in this example will yield a sample result of 12:34:56:78.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT 12345678 (FORMAT '99:99:99:99') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
<li>
<p>The format string '-99:99:99:99' in this example will yield a sample result of -12:34:56:78.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT (-12345678) (FORMAT '-99:99:99:99') FROM (VALUES(1)) t;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sample_clause">6.3. SAMPLE Clause</h3>
<div class="paragraph">
<p>The SAMPLE clause of the SELECT statement specifies the sampling method
used to select a subset of the intermediate result table of a SELECT
statement. The intermediate result table consists of the rows returned
by a WHERE clause or, if no WHERE clause exists, the FROM clause. See
<a href="#select_statement">SELECT Statement</a>.</p>
</div>
<div class="paragraph">
<p>SAMPLE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SAMPLE sampling-methodis:
RANDOM percent-size
| FIRST rows-size
[SORT BY colname [ASC[ENDING]|DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]]...]
| PERIODIC rows-size EVERY number-rows ROWS
[SORT BY colname [ASC[ENDING] | DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]]...]
percent-size is:
percent-result PERCENT [ROWS]
| BALANCE WHEN condition
THEN percent-result PERCENT [ROWS]
[WHEN condition THEN percent-result PERCENT [ROWS]]...
[ELSE percent-result PERCENT [ROWS]] END
rows-size is:
number-rows ROWS
| BALANCE WHEN condition THEN number-rows ROWS
[WHEN condition THEN number-rows ROWS]...
[ELSE number-rows ROWS] END</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>RANDOM <em>percent-size</em></code></p>
<div class="paragraph">
<p>directs Trafodion SQL to choose rows randomly (each row having an
unbiased probability of being chosen) without replacement from the
result table. The sampling size is determined by the <em>percent-size</em>,
defined as:</p>
</div>
</li>
<li>
<p><code><em>percent-result</em> PERCENT [ROWS] | BALANCE WHEN <em>condition</em> THEN
<em>percent-result</em> PERCENT [ROWS] [WHEN <em>condition</em> THEN <em>percent-result</em>
PERCENT [ROWS]]&#8230; [ELSE <em>percent-result</em> PERCENT [ROWS]] END</code></p>
<div class="paragraph">
<p>specifies the value of the size for RANDOM sampling by using a percent
of the result table. The value <em>percent-result</em> must be a numeric
literal.</p>
</div>
<div class="paragraph">
<p>You can determine the actual size of the sample. Suppose that <em>N</em> rows
exist in the intermediate result table. Each row is picked with a
probability of <em>r</em>%, where <em>r</em> is the sample size in PERCENT.
Therefore, the actual size of the resulting sample is approximately <em>r</em>% of <em>N</em>.
The number of rows picked follows a binomial distribution with
mean equal to <em>r</em> *c_N_/100.</p>
</div>
<div class="paragraph">
<p>If you specify a sample size greater than 100 PERCENT, Trafodion SQL
returns all the rows in the result table plus duplicate rows. The
duplicate rows are picked from the result table according to the
specified sampling method. This technique is called oversampling.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ROWS</code></p>
<div class="paragraph">
<p>specifies row sampling. Row sampling is the default.</p>
</div>
</li>
<li>
<p><code>BALANCE</code></p>
<div class="paragraph">
<p>If you specify a BALANCE expression, Trafodion SQL performs stratified
sampling. The intermediate result table is divided into disjoint strata
based on the WHEN conditions.</p>
</div>
<div class="paragraph">
<p>Each stratum is sampled independently by using the sampling size. For a
given row, the stratum to which it belongs is determined by the first
WHEN condition that is true for that row—if a true condition exists. If
no true condition exists, the row belongs to the ELSE stratum.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>FIRST <em>rows-size</em> [SORT BY <em>colname</em> [ASC[ENDING] | DESC[ENDING]]
[,<em>colname</em> [ASC[ENDING] | DESC[ENDING]]]&#8230;]</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to choose the first rows from the result table.
You can specify the order of the rows to sample. Otherwise, Trafodion
SQL chooses an arbitrary order. The sampling size is determined by the
<em>rows-size</em>, defined as:</p>
</div>
</li>
<li>
<p><code><em>number-rows</em> ROWS | BALANCE WHEN <em>condition</em> THEN <em>number-rows</em> ROWS
[WHEN <em>condition</em> THEN <em>number-rows</em> ROWS]&#8230; [ELSE <em>number-rows</em> ROWS] END</code></p>
<div class="paragraph">
<p>specifies the value of the size for FIRST sampling by using the number
of rows intended in the sample. The value <em>number-rows</em> must be an
integer literal.</p>
</div>
<div class="paragraph">
<p>You can determine the actual size of the sample. Suppose that <em>N</em> rows
exist in the intermediate result table. If the size <em>s</em> of the sample is
specified as a number of rows, the actual size of the resulting sample
is the minimum of <em>s</em> and <em>N</em>.</p>
</div>
</li>
<li>
<p><code>PERIODIC <em>rows-size</em> EVERY <em>number-rows</em> ROWS [SORT BY <em>colname</em>
[ASC[ENDING] | DESC[ENDING]] [,<em>colname</em> [ASC[ENDING] |
DESC[ENDING]]]&#8230;]</code></p>
<div class="paragraph">
<p>directs Trafodion SQL to choose the first rows from each block (or
period) of contiguous rows. This sampling method is equivalent to a
separate FIRST sampling for each period, and the <em>rows-size</em> is defined
as in FIRST sampling.</p>
</div>
<div class="paragraph">
<p>The size of the period is specified as a number of rows. You can specify
the order of the rows to sample. Otherwise, Trafodion SQL chooses an
arbitrary order.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="paragraph">
<p>You can determine the actual size of the sample. Suppose that <em>N</em> rows
exist in the intermediate result table. If the size <em>s</em> of the sample is
specified as a number of rows and the size <em>p</em> of the period is
specified as a number of rows, the actual size of the resulting sample
is calculated as:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">FLOOR (N/p) * s + _minimum_ (MOD (N, p), s)</code></pre>
</div>
</div>
<div class="paragraph">
<p><em>minimum</em> in this expression is used simply as the mathematical
minimum of two values.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_sample">6.3.1. Considerations for SAMPLE</h4>
<div class="sect4">
<h5 id="sample_rows">Sample Rows</h5>
<div class="paragraph">
<p>In general, when you use the SAMPLE clause, the same query returns
different sets of rows for each execution. The same set of rows is
returned only when you use the FIRST and PERIODIC sampling methods with
the SORT BY option, where no duplicates exist in the specified column
combination for the sort.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_sample">6.3.2. Examples of SAMPLE</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that the data-mining tables SALESPER, SALES, and DEPT have been
created as:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE trafodion.mining.salesper
( empid NUMERIC (4) UNSIGNED NOT NULL
, dnum NUMERIC (4) UNSIGNED NOT NULL
, salary NUMERIC (8,2) UNSIGNED
, age INTEGER
, sex CHAR (6)
, PRIMARY KEY (empid) );
CREATE TABLE trafodion.mining.sales
( empid NUMERIC (4) UNSIGNED NOT NULL
, product VARCHAR (20)
, region CHAR (4)
, amount NUMERIC (9,2) UNSIGNED
, PRIMARY KEY (empid) );
CREATE TABLE trafodion.mining.dept
( dnum NUMERIC (4) UNSIGNED NOT NULL
, name VARCHAR (20)
, PRIMARY KEY (dnum) );</code></pre>
</div>
</div>
<div class="paragraph">
<p>Suppose, too, that sample data is inserted into this database.</p>
</div>
</li>
<li>
<p>Return the SALARY of the youngest 50 sales people:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT salary
FROM salesperson
SAMPLE FIRST 50 ROWS
SORT BY age;
SALARY
-----------
90000.00
90000.00
28000.00
27000.12
136000.00
37000.40
...
--- 50 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Return the SALARY of 50 sales people. In this case, the table is
clustered on EMPID. If the optimizer chooses a plan to access rows using
the primary access path, the result consists of salaries of the 50 sales
people with the smallest employee identifiers.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT salary
FROM salesperson
SAMPLE FIRST 50 ROWS;
SALARY
-----------
175500.00
137000.10
136000.00
138000.40
75000.00
90000.00
...
--- 50 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Return the SALARY of the youngest five sales people, skip the next 15
rows, and repeat this process until no more rows exist in the
intermediate result table. You cannot specify periodic sampling with the
sample size larger than the period.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT salary
FROM salesperson
SAMPLE PERIODIC 5 ROWS
EVERY 20 ROWS
SORT BY age;
SALARY
-----------
90000.00
90000.00
28000.00
27000.12
136000.00
36000.00
...
--- 17 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>In this example, 62 rows exist in the SALESPERSON table. For each set of
20 rows, the first five rows are selected. The last set consists of two
rows, both of which are selected.</p>
</div>
</li>
<li>
<p>Compute the average salary of a random 10 percent of the sales people.
You will get a different result each time you run this query because it
is based on a random sample.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG(salary)
FROM salesperson
SAMPLE RANDOM 10 PERCENT;
(EXPR)
--------------------
61928.57
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This query illustrates sampling after execution of the WHERE clause
has chosen the qualifying rows. The query computes the average salary of
a random 10 percent of the sales people over 35 years of age. You will
get a different result each time you run this query because it
is based on a random sample.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG(salary)
FROM salesperson
WHERE age &gt; 35
SAMPLE RANDOM 10 PERCENT;
(EXPR)
--------------------
58000.00
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Compute the average salary of a random 10 percent of sales people
belonging to the CORPORATE department. The sample is taken from the join
of the SALESPERSON and DEPARTMENT tables. You will get a different
result each time you run this query because it is based on a random
sample.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG(salary)
FROM salesperson S, department D
WHERE S.DNUM = D.DNUM AND D.NAME = 'CORPORATE'
SAMPLE RANDOM 10 PERCENT;
(EXPR)
---------------------
106250.000
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>In this example, the SALESPERSON table is first sampled and then
joined with the DEPARTMENT table. This query computes the average salary
of all the sales people belonging to the CORPORATE department in a
random sample of 10 percent of the sales employees.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG(salary)
FROM
( SELECT salary, dnum FROM salesperson SAMPLE RANDOM 10 PERCENT ) AS S
, department D
WHERE S.DNUM = D.DNUM
AND D.NAME = 'CORPORATE';
(EXPR)
--------------------
37000.000
--- 1 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The results of this query and some of the results of previous queries
might return null:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG(salary)
FROM
( SELECT salary, dnum FROM salesperson SAMPLE RANDOM 10 PERCENT ) AS S
, department D
WHERE S.DNUM = D.DNUM AND D.NAME = 'CORPORATE';
(EXPR)
--------------------
?
--- 1 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>For this query execution, the number of rows returned by the embedded
query is limited by the total number of rows in the SALESPERSON table.
Therefore, it is possible that no rows satisfy the search condition in
the WHERE clause.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>In this example, both the tables are sampled first and then joined.
This query computes the average salary and the average sale amount
generated from a random 10 percent of all the sales people and 20
percent of all the sales transactions.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG(salary), AVG(amount)
FROM ( SELECT salary, empid
FROM salesperson
SAMPLE RANDOM 10 PERCENT ) AS S,
( SELECT amount, empid FROM sales
SAMPLE RANDOM 20 PERCENT ) AS T
WHERE S.empid = T.empid;
(EXPR) (EXPR)
--------- ---------
45000.00 31000.00
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>This example illustrates oversampling. This query retrieves 150
percent of the sales transactions where the amount exceeds $1000. The
result contains every row at least once, and 50 percent of the rows,
picked randomly, occur twice.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT *
FROM sales
WHERE amount &gt; 1000
SAMPLE RANDOM 150 PERCENT;
EMPID PRODUCT REGION AMOUNT
----- -------------------- ------ -----------
1 PCGOLD, 30MB E 30000.00
23 PCDIAMOND, 60MB W 40000.00
23 PCDIAMOND, 60MB W 40000.00
29 GRAPHICPRINTER, M1 N 11000.00
32 GRAPHICPRINTER, M2 S 15000.00
32 GRAPHICPRINTER, M2 S 15000.00
... ... ... ...
--- 88 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>The BALANCE option enables stratified sampling. Retrieve the age and
salary of 1000 sales people such that 50 percent of the result are male
and 50 percent female.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT age, sex, salary
FROM salesperson
SAMPLE FIRST
BALANCE
WHEN sex = 'male' THEN 15 ROWS
WHEN sex = 'female' THEN 15 ROWS
END
ORDER BY age;
AGE SEX SALARY
----------- ------ -----------
22 male 28000.00
22 male 90000.00
22 female 136000.00
22 male 37000.40
... ... ...
--- 30 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Retrieve all sales records with the amount exceeding $10000 and a
random sample of 10 percent of the remaining records:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT *
FROM sales SAMPLE RANDOM
BALANCE
WHEN amount &gt; 10000
THEN 100 PERCENT
ELSE 10 PERCENT
END;
PRODUCT REGION AMOUNT
-------------------- ------ -----------
PCGOLD, 30MB E 30000.00
PCDIAMOND, 60MB W 40000.00
GRAPHICPRINTER, M1 N 11000.00
GRAPHICPRINTER, M2 S 15000.00
... ... ...
MONITORCOLOR, M2 N 10500.00
... ... ...
--- 32 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This query shows an example of stratified sampling where the
conditions are not mutually exclusive:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT *
FROM sales SAMPLE RANDOM
BALANCE
WHEN amount &gt; 10000 THEN 100 PERCENT
WHEN product = 'PCGOLD, 30MB' THEN 25 PERCENT
WHEN region = 'W' THEN 40 PERCENT
ELSE 10 PERCENT END;
PRODUCT REGION AMOUNT
-------------------- ------ -----------
PCGOLD, 30MB E 30000.00
PCDIAMOND, 60MB W 40000.00
GRAPHICPRINTER, M1 N 11000.00
GRAPHICPRINTER, M2 S 15000.00
GRAPHICPRINTER, M3 S 20000.00
LASERPRINTER, X1 W 42000.00
... ... ...
--- 30 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sequence_by_clause">6.4. SEQUENCE BY Clause</h3>
<div class="paragraph">
<p>The SEQUENCE BY clause of the SELECT statement specifies the order in
which to sort the rows</p>
</div>
<div class="paragraph">
<p>of the intermediate result table for calculating sequence functions.
This option is used for processing time-sequenced rows in data mining
applications. See <a href="#select_statement">SELECT Statement</a>.</p>
</div>
<div class="paragraph">
<p>Sequence by is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SEQUENCE BY colname[ASC[ENDING]|DESC[ENDING]]
[,colname [ASC[ENDING] | DESC[ENDING]]]...</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>colname</em></code>
_
names a column in <em>select-list</em> or a column in a table reference in the
FROM clause of the SELECT statement. <em>colname</em> is optionally qualified
by a table, view, or correlation name; for example, CUSTOMER.CITY.</p>
</li>
<li>
<p><code>ASC | DESC</code></p>
<div class="paragraph">
<p>specifies the sort order. ASC is the default. For ordering an
intermediate result table on a column that can contain null, nulls are
considered equal to one another but greater than all other non-null
values.</p>
</div>
<div class="paragraph">
<p>You must include a SEQUENCE BY clause if you include a sequence function
in the select list of the SELECT statement. Otherwise, Trafodion SQL
returns an error. Further, you cannot include a SEQUENCE BY clause if no
sequence function exists in the select list. See
<a href="#sequence_functions">Sequence Functions</a> .</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_sequence_by">6.4.1. Considerations for SEQUENCE BY</h4>
<div class="ulist">
<ul>
<li>
<p>Sequence functions behave differently from set (or aggregate)
functions and mathematical (or scalar) functions.</p>
</li>
<li>
<p>If you include both SEQUENCE BY and GROUP BY clauses in the same
SELECT statement, the values of the sequence functions must be evaluated
first and then become input for aggregate functions in the statement.</p>
<div class="ulist">
<ul>
<li>
<p>For a SELECT statement that contains both SEQUENCE BY and GROUP BY
clauses, you can nest the sequence function in the aggregate function:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
ordernum
, MAX(MOVINGSUM(qty_ordered, 3)) AS maxmovsum_qty
, AVG(unit_price) AS avg_price
FROM odetail
SEQUENCE BY partnum
GROUP BY ordernum;</code></pre>
</div>
</div>
</li>
</ul>
</div>
</li>
<li>
<p>To use a sequence function as a grouping column, you must use a
derived table for the SEQUENCE BY query and use the derived column in
the GROUP BY clause:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
ordernum
, movsum_qty
, AVG(unit_price)
FROM
( SELECT ordernum, MOVINGSUM(qty_ordered, 3), unit_price
FROM odetail SEQUENCE BY partnum )
AS tab2 (ordernum, movsum_qty, unit_price)
GROUP BY ordernum, movsum_qty;</code></pre>
</div>
</div>
</li>
<li>
<p>To use an aggregate function as the argument to a sequence function,
you must also use a derived table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MOVINGSUM(avg_price,2)
FROM
( SELECT ordernum, AVG(unit_price) FROM odetail
GROUP BY ordernum)
AS tab2 (ordernum, avg_price)
SEQUENCE BY ordernum;</code></pre>
</div>
</div>
</li>
<li>
<p>Like aggregate functions, sequence functions generate an intermediate
result. If the query has a WHERE clause, its search condition is applied
during the generation of the intermediate result. Therefore, you cannot
use sequence functions in the WHERE clause of a SELECT statement.</p>
<div class="ulist">
<ul>
<li>
<p>This query returns an error:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ordernum, partnum, RUNNINGAVG(unit_price)
FROM odetail
WHERE ordernum &gt; 800000 AND RUNNINGAVG(unit_price) &gt; 350
SEQUENCE BY qty_ordered;</code></pre>
</div>
</div>
</li>
<li>
<p>Apply a search condition to the result of a sequence function, use a
derived table for the SEQUENCE BY query, and use the derived column in
the WHERE clause:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ordernum, partnum, runavg_price
FROM
( SELECT ordernum, partnum, RUNNINGAVG(unit_price)
FROM odetail SEQUENCE BY qty_ordered)
AS tab2 (ordernum, partnum, runavg_price)
WHERE ordernum &gt; 800000 AND
runavg_price &gt; 350;</code></pre>
</div>
</div>
</li>
</ul>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_sequence_by">6.4.2. Examples of SEQUENCE BY</h4>
<div class="ulist">
<ul>
<li>
<p>Sequentially number each row for the entire result and also number the
rows for each part number:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
RUNNINGCOUNT(*) AS RCOUNT
, MOVINGCOUNT(*,ROWS SINCE (d.partnum&lt;&gt;THIS(d.partnum))) AS MCOUNT
, d.partnum
FROM orders o, odetail d
WHERE o.ordernum=d.ordernum
SEQUENCE BY d.partnum, o.order_date, o.ordernum
ORDER BY d.partnum, o.order_date, o.ordernum;
RCOUNT MCOUNT Part/Num
-------------------- --------------------- --------
1 1 212
2 2 212
3 1 244
4 2 244
5 3 244
... ... ...
67 1 7301
68 2 7301
69 3 7301
70 4 7301
--- 70 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Show the orders for each date, the amount for each order item and the
moving total for each order, and the running total of all the orders.
The query sequences orders by date, order number, and part number. (The
CAST function is used for readability only.)</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
o.ordernum
, CAST (MOVINGCOUNT(*,ROWS SINCE(THIS(o.ordernum) &lt;&gt; o.ordernum)) AS INT) AS MCOUNT
, d.partnum
, o.order_date
, (d.unit_price * d.qty_ordered) AS AMOUNT
, MOVINGSUM (d.unit_price * d.qty_ordered, SEQUENCE BY Clause 269 ROWS SINCE(THIS(o.ordernum)&lt;&gt;o.ordernum) ) AS ORDER_TOTAL
, RUNNINGSUM (d.unit_price * d.qty_ordered) AS TOTAL_SALES
FROM orders o, odetail d
WHERE o.ordernum=d.ordernum
SEQUENCE BY o.order_date, o.ordernum, d.partnum
ORDER BY o.order_date, o.ordernum, d.partnum;
Order/Num MCOUNT Part/Num Order/Date AMOUNT ORDER_TOTAL TOTAL_SALES
---------- ----------- -------- ---------- ---------- -------------- --------------
100250 1 244 2008-01-23 14000.00 14000.00 14000.00
100250 2 5103 2008-01-23 4000.00 18000.00 18000.00
100250 3 6500 2008-01-23 950.00 18950.00 18950.00
200300 1 244 2008-02-06 28000.00 28000.00 46950.00
200300 2 2001 2008-02-06 10000.00 38000.00 56950.00
200300 3 2002 2008-02-06 14000.00 52000.00 70950.00
... ... ... ... ... ... ...
800660 18 7102 2008-10-09 1650.00 187360.00 113295.00
800660 19 7301 2008-10-09 5100.00 192460.00 1118395.00
--- 69 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>For example, for order number 200300, the ORDER_TOTAL is a moving sum
within the order date 2008-02-06, and the TOTAL_SALES is a running sum
for all orders. The current window for the moving sum is defined as ROWS
SINCE (THIS(o.ordernum)&lt;&gt;o.ordernum), which restricts the ORDER_TOTAL to
the current order number.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Show the amount of time between orders by calculating the interval between two dates:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT RUNNINGCOUNT(*),o.order_date,DIFF1(o.order_date)
FROM orders o
SEQUENCE BY o.order_date, o.ordernum
ORDER BY o.order_date, o.ordernum ;
(EXPR) Order/Date (EXPR)
-------------------- ---------- -------------
1 2008-01-23 ?
2 2008-02-06 14
3 2008-02-17 11
4 2008-03-03 14
5 2008-03-19 16
6 2008-03-19 0
7 2008-03-27 8
8 2008-04-10 14
9 2008-04-20 10
10 2008-05-12 22
11 2008-06-01 20
12 2008-07-21 50
13 2008-10-09 80
--- 13 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="transpose_clause">6.5. TRANSPOSE Clause</h3>
<div class="paragraph">
<p>The TRANSPOSE clause of the SELECT statement generates for each row of
the SELECT source table a row for each item in the transpose item list.
The result table of the TRANSPOSE clause has all the columns of the
source table plus, for each transpose item list, a value column or
columns and an optional key column.</p>
</div>
<div class="paragraph">
<p>TRANSPOSE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TRANSPOSE transpose-set [transpose-set]...
[KEY BY key-colname]
transpose-set is:
transpose-item-list AS transpose-col-list
transpose-item-list is:
expression-list
| (expression-list) [,(expression-list)]...
expression-list is:
expression [,expression]...
transpose-col-list is:
colname | (colname-list)
colname-list is:
colname [,colname]...</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>transpose-item-list</em> AS <em>transpose-col-list</em></code></p>
<div class="paragraph">
<p>specifies a <em>transpose-set</em>, which correlates a <em>transpose-item-list</em>
with a <em>transpose-col-list</em>. The <em>transpose-item-list</em> can be a list
of expressions or a list of expression lists enclosed in parentheses.
The <em>transpose-col-list</em> can be a single column name or a list of column
names enclosed in parentheses.</p>
</div>
<div class="paragraph">
<p>For example, in the <em>transpose-set</em> TRANSPOSE (A,X),(B,Y),(C,Z) AS
(V1,V2), the items in the <em>transpose-item-list</em> are (A,X),(B,Y), and
(C,Z), and the <em>transpose-col-list</em> is (V1,V2). The number of
expressions in each item must be the same as the number of value columns
in the column list.</p>
</div>
<div class="paragraph">
<p>In the example TRANSPOSE A,B,C AS V, the items are A,B, and C, and the
value column is V. This form can be thought of as a shorter way of writing TRANSPOSE
(A),(B),&#169; AS (V).</p>
</div>
</li>
<li>
<p><code><em>transpose-item-list</em></code></p>
<div class="paragraph">
<p>specifies a list of items. An item is a value expression or a list of
value expressions enclosed in parentheses.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression-list</em></code></p>
<div class="paragraph">
<p>specifies a list of SQL value expressions, separated by commas. The
expressions must have compatible data types.</p>
</div>
<div class="paragraph">
<p>For example, in the transpose set TRANSPOSE A,B,C AS V, the expressions
A,B, and C have compatible data types.</p>
</div>
</li>
<li>
<p><code>(<em>expression-list</em>) [,(<em>expression-list</em>)]&amp;8230;</code></p>
<div class="paragraph">
<p>specifies a list of expressions enclosed in parentheses, followed by
another list of expressions enclosed in parentheses, and so on. The
number of expressions within parentheses must be equal for each list.
The expressions in the same ordinal position within the parentheses must
have compatible data types.</p>
</div>
<div class="paragraph">
<p>For example, in the transpose set TRANSPOSE (A,X),(B,Y),(C,Z) AS
(V1,V2), the expressions A,B, and C have compatible data types, and the
expressions X,Y, and Z have compatible data types.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code><em>transpose-col-list</em></code></p>
<div class="paragraph">
<p>specifies the columns that consist of the evaluation of expressions in
the item list as the expressions are applied to rows of the source
table.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>colname</em></code></p>
<div class="paragraph">
<p>is an SQL identifier that specifies a column name. It identifies the
column consisting of the values in <em>expression-list</em>.</p>
</div>
<div class="paragraph">
<p>For example, in the transpose set TRANSPOSE A,B,C AS V, the column V
corresponds to the values of the expressions A,B, and C.</p>
</div>
</li>
<li>
<p><code>(<em>colname-list</em>)</code></p>
<div class="paragraph">
<p>specifies a list of column names enclosed in parentheses. Each column
consists of the values of the expressions in the same ordinal position
within the parentheses in the transpose item list.</p>
</div>
<div class="paragraph">
<p>For example, in the transpose set TRANSPOSE (A,X),(B,Y),(C,Z) AS
(V1,V2), the column V1 corresponds to the expressions A,B, and C, and
the column V2 corresponds to the expressions X,Y, and Z.</p>
</div>
</li>
</ul>
</div>
</li>
<li>
<p><code>KEY BY <em>key-colname</em></code></p>
<div class="paragraph">
<p>optionally specifies which expression (the value in the transpose column
list corresponds to) by its position in the item list. <em>key-colname</em> is
an SQL identifier. The data type of the key column is exact numeric, and
the value is NOT NULL.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_transpose">6.5.1. Considerations for TRANSPOSE</h4>
<div class="sect4">
<h5 id="multiple_transpose_clauses_and_sets">Multiple TRANSPOSE Clauses and Sets</h5>
<div class="ulist">
<ul>
<li>
<p>Multiple TRANSPOSE clauses can be used in the same query. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT keycol1, valcol1, keycol2, valcol2
FROM mytable
TRANSPOSE a, b, c AS valcol1 KEY BY keycol1
TRANSPOSE d, e, f AS valcol2 KEY BY keycol2</code></pre>
</div>
</div>
</li>
<li>
<p>A TRANSPOSE clause can contain multiple transpose sets. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT keycol, valcol1, valcol2
FROM mytable
TRANSPOSE a, b, c AS valcol1
d, e, f AS valcol2
KEY BY keycol</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="degree_and_column_order_of_the_transpose_result">Degree and Column Order of the TRANSPOSE Result</h5>
<div class="paragraph">
<p>The degree of the TRANSPOSE result is the degree of the source table
(the result table derived from the table reference or references in the
FROM clause and a WHERE clause if specified), plus one if the key column
is specified, plus the cardinalities of all the transpose column lists.</p>
</div>
<div class="paragraph">
<p>The columns of the TRANSPOSE result are ordered beginning with the
columns of the source table, followed by the key column if specified,
and then followed by the list of column names in the order in which they
are specified.</p>
</div>
</div>
<div class="sect4">
<h5 id="data_type_of_the_transpose_result">Data Type of the TRANSPOSE Result</h5>
<div class="paragraph">
<p>The data type of each of the value columns is the union compatible data
type of the corresponding expressions in the <em>transpose-item-list</em>.
You cannot have expressions with data types that are not compatible in a
<em>transpose-item-list</em>.</p>
</div>
<div class="paragraph">
<p>For example, in TRANSPOSE (A,X),(B,Y),(C,Z) AS (V1,V2), the data type of
V1 is the union compatible type for A, B, and C, and the data type of V2
is the union compatible type for X, Y, and Z.</p>
</div>
<div class="paragraph">
<p>See <a href="#comparable_and_compatible_data_types">Comparable and Compatible Data Types</a>.</p>
</div>
</div>
<div class="sect4">
<h5 id="cardinality_of_the_transpose_result">Cardinality of the TRANSPOSE Result</h5>
<div class="paragraph">
<p>The items in each <em>transpose-item-list</em> are enumerated from 1 to N,
where N is the total number of items in all the item lists in the
transpose sets.</p>
</div>
<div class="paragraph">
<p>In this example with a single transpose set, the value of N is 3:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TRANSPOSE (a,x),(b,y),(c,z) AS (v1,v2)</code></pre>
</div>
</div>
<div class="paragraph">
<p>In this example with two transpose sets, the value of N is 5:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TRANSPOSE (a,x),(b,y),(c,z) AS (v1,v2) l,m AS v3</code></pre>
</div>
</div>
<div class="paragraph">
<p>The values 1 to N are the key values <em>k_i. The items in each
_transpose-item-list</em> are the expression values _v_i.</p>
</div>
<div class="paragraph">
<p>The cardinality of the result of the TRANSPOSE clause is the cardinality
of the source table times N, the total number of items in all the
transpose item lists.</p>
</div>
<div class="paragraph">
<p>For each row of the source table and for each value in the key values
_k_i, the TRANSPOSE result contains a row with all the attributes of
the source table, the key value _k_i in the key column, the expression
values vi in the value columns of the corresponding transpose set, and
NULL in the value columns of other transpose sets.</p>
</div>
<div class="paragraph">
<p>For example, consider this TRANSPOSE clause:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TRANSPOSE (a,x),(b,y),(c,z) AS (v1,v2)
l,m AS v3
KEY BY k</code></pre>
</div>
</div>
<div class="paragraph">
<p>The value of N is 5. One row of the SELECT source table produces this
TRANSPOSE result:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top"><em>columns-of-source</em></th>
<th class="tableblock halign-left valign-top">K</th>
<th class="tableblock halign-left valign-top">V1</th>
<th class="tableblock halign-left valign-top">V2</th>
<th class="tableblock halign-left valign-top">V3</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>source-row</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>value-of-A</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>value-of-X</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NULL</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>source-row</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>value-of-B</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>value-of-Y</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NULL</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>source-row</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>value-of-C</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>value-of-Z</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NULL</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>source-row</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">4</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NULL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NULL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>value-of-L</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>source-row</em></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">5</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NULL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">NULL</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>value-of-M</em></p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_transpose">6.5.2. Examples of TRANSPOSE</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that MYTABLE has been created as:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE mining.mytable
( A INTEGER, B INTEGER, C INTEGER, D CHAR(2), E CHAR(2), F CHAR(2) );</code></pre>
</div>
</div>
<div class="paragraph">
<p>The table MYTABLE has columns A, B, C, D, E, and F with related data.
The columns A, B, and C are type INTEGER, and columns D, E, and F are
type CHAR.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 16.6666%;">
<col style="width: 16.6666%;">
<col style="width: 16.6666%;">
<col style="width: 16.6666%;">
<col style="width: 16.6666%;">
<col style="width: 16.667%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">A</th>
<th class="tableblock halign-left valign-top">B</th>
<th class="tableblock halign-left valign-top">C</th>
<th class="tableblock halign-left valign-top">D</th>
<th class="tableblock halign-left valign-top">E</th>
<th class="tableblock halign-left valign-top">F</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p>Suppose that MYTABLE has only the first three columns: A, B, and C.
The result of the TRANSPOSE clause has three times as many rows (because
three items exist in the transpose item list) as rows exist in MYTABLE:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM mytable
TRANSPOSE a, b, c AS valcol KEY BY keycol;</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result table of the TRANSPOSE query is:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 12.5%;">
<col style="width: 12.5%;">
<col style="width: 12.5%;">
<col style="width: 12.5%;">
<col style="width: 12.5%;">
<col style="width: 12.5%;">
<col style="width: 12.5%;">
<col style="width: 12.5%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">A</th>
<th class="tableblock halign-left valign-top">B</th>
<th class="tableblock halign-left valign-top">C</th>
<th class="tableblock halign-left valign-top">D</th>
<th class="tableblock halign-left valign-top">E</th>
<th class="tableblock halign-left valign-top">F</th>
<th class="tableblock halign-left valign-top">KEYCOL</th>
<th class="tableblock halign-left valign-top">VALCOL</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
</tr>
</tbody>
</table>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This query shows that the items in the transpose item list can be any
valid scalar expressions:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT keycol, valcol, a, b, c FROM mytable
TRANSPOSE a + b, c + 3, 6 AS valcol KEY BY keycol;</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result table of the TRANSPOSE query is:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">KEYCOL</th>
<th class="tableblock halign-left valign-top">VALCOL</th>
<th class="tableblock halign-left valign-top">A</th>
<th class="tableblock halign-left valign-top">B</th>
<th class="tableblock halign-left valign-top">C</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">103</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">6</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">22</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">203</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">6</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p>This query shows how the TRANSPOSE clause can be used with a GROUP BY
clause. This query is typical of queries used to obtain cross-table
information, where A, B, and C are the independent variables, and D is
the dependent variable.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT keycol, valcol, d, COUNT(*)
FROM mytable
TRANSPOSE a, b, c AS valcol
KEY BY keycol
GROUP BY keycol, valcol, d;</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result table of the TRANSPOSE query is:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">KEYCOL</th>
<th class="tableblock halign-left valign-top">VALCOL</th>
<th class="tableblock halign-left valign-top">D</th>
<th class="tableblock halign-left valign-top">COUNT(*)</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
</tbody>
</table>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This query shows how to use COUNT applied to VALCOL. The result table
of the TRANSPOSE query shows the number of distinct values in VALCOL.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT COUNT(DISTINCT valcol) FROM mytable
TRANSPOSE a, b, c AS valcol KEY BY keycol
GROUP BY keycol;
(EXPR)
--------------------
2
2
2
--- 3 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>This query shows how multiple TRANSPOSE clauses can be used in the
same query. The result table from this query has nine times as many rows
as rows exist in MYTABLE:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT keycol1, valcol1, keycol2, valcol2 FROM mytable
TRANSPOSE a, b, c AS valcol1 KEY BY keycol1
TRANSPOSE d, e, f AS valcol2 KEY BY keycol2;</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result table of the TRANSPOSE query is:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">KEYCOL1</th>
<th class="tableblock halign-left valign-top">VALCOL1</th>
<th class="tableblock halign-left valign-top">KEYCOL2</th>
<th class="tableblock halign-left valign-top">VALCOL2</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p>This query shows how a TRANSPOSE clause can contain multiple transpose
sets—that is, multiple <em>transpose-item-list</em> AS <em>transpose-col-list</em>.
The expressions A, B, and C are of type integer, and expressions D, E,
and F are of type character.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT keycol, valcol1, valcol2
FROM mytable
TRANSPOSE a, b, c AS valcol1
d, e, f AS valcol2
KEY BY keycol;</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result table of the TRANSPOSE query is:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 33.3333%;">
<col style="width: 33.3333%;">
<col style="width: 33.3334%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">KEYCOL</th>
<th class="tableblock halign-left valign-top">VALCOL1</th>
<th class="tableblock halign-left valign-top">VALCOL2</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">4</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">5</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">6</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">4</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">5</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">6</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>A question mark (?) in a value column indicates no value for the given KEYCOL.</p>
</div>
</li>
<li>
<p>This query shows how the preceding query can include a GROUP BY clause:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT keycol, valcol1, valcol2, COUNT(*)
FROM mytable
TRANSPOSE a, b, c AS valcol1
d, e, f AS valcol2
KEY BY keycol
GROUP BY keycol, valcol1, valcol2;</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result table of the TRANSPOSE query is:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">KEYCOL</th>
<th class="tableblock halign-left valign-top">VALCOL1</th>
<th class="tableblock halign-left valign-top">VALCOL2</th>
<th class="tableblock halign-left valign-top">(EXPR)</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">4</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">5</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">6</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">4</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">5</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">6</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">?</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p>This query shows how an item in the transpose item list can contain a
list of expressions and that the KEY BY clause is optional:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM mytable
TRANSPOSE (1, A, 'abc'), (2, B, 'xyz') AS (VALCOL1, VALCOL2, VALCOL3);</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result table of the TRANSPOSE query is:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 11.1111%;">
<col style="width: 11.1111%;">
<col style="width: 11.1111%;">
<col style="width: 11.1111%;">
<col style="width: 11.1111%;">
<col style="width: 11.1111%;">
<col style="width: 11.1111%;">
<col style="width: 11.1111%;">
<col style="width: 11.1112%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">A</th>
<th class="tableblock halign-left valign-top">B</th>
<th class="tableblock halign-left valign-top">C</th>
<th class="tableblock halign-left valign-top">D</th>
<th class="tableblock halign-left valign-top">E</th>
<th class="tableblock halign-left valign-top">F</th>
<th class="tableblock halign-left valign-top">VALCOL1</th>
<th class="tableblock halign-left valign-top">VALCOL2</th>
<th class="tableblock halign-left valign-top">VALCOL3</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">abc</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">xyz</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">abc</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">d2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">e2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">f2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">20</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">xyz</p></td>
</tr>
</tbody>
</table>
</li>
</ul>
</div>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="sql_functions_and_expressions">7. SQL Functions and Expressions</h2>
<div class="sectionbody">
<div class="paragraph">
<p>This section describes the syntax and semantics of specific functions
and expressions that you can use in Trafodion SQL statements. The
functions and expressions are categorized according to their
functionality.</p>
</div>
<div class="sect2">
<h3 id="standard_normalization">7.1. Standard Normalization</h3>
<div class="paragraph">
<p>For datetime functions, the definition of standard normalization is: If
the ending day of the resulting date is invalid, the day will be rounded
DOWN to the last day of the result month.</p>
</div>
</div>
<div class="sect2">
<h3 id="_aggregate_set_functions">7.2. Aggregate (Set) Functions</h3>
<div class="paragraph">
<p>An aggregate (or set) function operates on a group or groups of rows
retrieved by the SELECT statement or the subquery in which the aggregate
function appears.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#avg_function">AVG Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Computes the average of a group of numbers derived from the evaluation
of the expression argument of the function.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#count_function">COUNT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Counts the number of rows that result from a query (by using
*) or the number of rows that contain a distinct value in the one-column
table derived from the expression argument of the function (optionally
distinct values).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#group_concat_function">GROUP_CONCAT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">This function returns a string result with the concatenated non-NULL
values from a group.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#max_function">MAX/MAXIMUM Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Determines a maximum value from the group of values derived from the
evaluation of the expression argument.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#min_function">MIN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Determines a minimum value from the group of values derived from the
evaluation of the expression argument.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#stddev_function">STDDEV Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Computes the statistical standard deviation of a group of numbers
derived from the evaluation of the expression argument of the function.
The numbers can be weighted.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#sum_function">SUM Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Computes the sum of a group of numbers derived from the evaluation of
the expression argument of the function.
"VARIANCE Function"
Computes the statistical variance of a group of numbers derived from the
evaluation of the expression argument of the function. The numbers can
be weighted.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>Columns and expressions can be arguments of an aggregate function. The
expressions cannot contain aggregate functions or subqueries.</p>
</div>
<div class="paragraph">
<p>An aggregate function can accept an argument specified as DISTINCT,
which eliminates duplicate values before the aggregate function is
applied. See <a href="#distinct_aggregate_functions">DISTINCT Aggregate Functions</a>.</p>
</div>
<div class="paragraph">
<p>If you include a GROUP BY clause in the SELECT statement, the columns
you refer to in the select list must be either grouping columns or
arguments of an aggregate function. If you do not include
a GROUP BY clause but you specify an aggregate function in the select
list, all rows of the SELECT result table form the one and only group.</p>
</div>
<div class="paragraph">
<p>See the individual entry for the function.</p>
</div>
</div>
<div class="sect2">
<h3 id="character_string_functions">7.3. Character String Functions</h3>
<div class="paragraph">
<p>These functions manipulate character strings and use a character value
expression as an argument or return a result of a character data type.
Character string functions treat each single-byte or multi-byte character
in an input string as one character, regardless of the byte length of
the character.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#ascii_function">ASCII Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the ASCII code value of the first character of a character value
expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#char_function">CHAR Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the specified code value in a character set.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#char_length_function">CHAR_LENGTH Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the number of characters in a string. You can also use
CHARACTER_LENGTH.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#code_value_function">CODE_VALUE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an unsigned integer that is the code point of the first
character in a character value expression that can be associated with
one of the supported character sets.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#concat_function">CONCAT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the concatenation of two character value expressions as a string
value. You can also use the concatenation operator (||).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#insert_function">INSERT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns a character string where a specified number of characters within
the character string have been deleted and then a second character
string has been inserted at a specified start position.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#lcase_function">LCASE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Down-shifts alphanumeric characters. You can also use LOWER.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#left_function">LEFT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the leftmost specified number of characters from a character expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#locate_function">LOCATE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the position of a specified substring within a character string.
You can also use POSITION.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#lower_function">LOWER Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Down-shifts alphanumeric characters. You can also use LCASE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#lpad_function">LPAD Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Replaces the leftmost specified number of characters in a character
expression with a padding character.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#ltrim_function">LTRIM Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes leading spaces from a character string.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#octet_length_function">OCTET_LENGTH Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the length of a character string in bytes.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#position_function">POSITION Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the position of a specified substring within a character string.
You can also use LOCATE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#repeat_function">REPEAT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns a character string composed of the evaluation of a character
expression repeated a specified number of times.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#replace_function">REPLACE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns a character string where all occurrences of a specified
character string in the original string are replaced with another
character string.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#right_function">RIGHT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the rightmost specified number of characters from a character
expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#rpad_function">RPAD Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Replaces the rightmost specified number of characters in a character
expression with a padding character.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#rtrim_function">RTRIM Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes trailing spaces from a character string.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#space_function">SPACE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns a character string consisting of a specified number of spaces.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#substring_function">SUBSTRING/SUBSTR Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Extracts a substring from a character string.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#translate_function">TRANSLATE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Translates a character string from a source character set to a target
character set.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#trim_function">TRIM Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Removes leading or trailing characters from a character string.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#ucase_function">UCASE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Up-shifts alphanumeric characters. You can also use UPSHIFT or UPPER.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#upper_function">UPPER Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Up-shifts alphanumeric characters. You can also use UPSHIFT or UCASE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#upshift_function">UPSHIFT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Up-shift alphanumeric characters. You can also use UPPER or UCASE.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>See the individual entry for the function.</p>
</div>
</div>
<div class="sect2">
<h3 id="datetime_functions">7.4. Datetime Functions</h3>
<div class="paragraph">
<p>These functions use either a datetime value expression as an argument or
return a result of datetime data type:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#add_months_function">ADD_MONTHS Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Adds the integer number of months specified by <em>intr_expr</em>
to <em>datetime_expr</em> and normalizes the result.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#converttimestamp_function">CONVERTTIMESTAMP Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a Julian timestamp to a TIMESTAMP value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_function">CURRENT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the current timestamp. You can also use the
<a href="#current_timestamp_function">CURRENT_TIMESTAMP Function</a>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_date_function">CURRENT_DATE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the current date.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_time_function">CURRENT_TIME Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the current time.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_timestamp_function">CURRENT_TIMESTAMP Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the current timestamp. You can also use the <a href="#current_function">CURRENT Function</a>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#date_add_function">DATE_ADD Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Adds the interval specified by <em>interval_expression</em>
to <em>datetime_expr</em>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#date_part_function_of_an_interval">DATE_PART Function (of an Interval)</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Extracts the datetime field specified by <em>text</em> from the interval value
specified by interval and returns the result as an exact numeric value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#date_part_function_of_a_timestamp">DATE_PART Function (of a Timestamp)</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Extracts the datetime field specified by <em>text</em> from the datetime value
specified by timestamp and returns the result as an exact numeric value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#date_sub_function">DATE_SUB Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Subtracts the specified <em>interval_expression</em> from
<em>datetime_expr.</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#date_trunc_function">DATE_TRUNC Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the date with the time portion of the day truncated.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#dateadd_function">DATEADD Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Adds the interval specified by <em>datepart</em> and <em>num_expr</em>
to <em>datetime_expr</em>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#datediff_function">DATEDIFF Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the integer value for the number of <em>datepart</em> units of time
between <em>startdate</em> and <em>enddate</em>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#dateformat_function">DATEFORMAT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Formats a datetime value for display purposes.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#day_function">DAY Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 1 through 31 that represents the
corresponding day of the month. You can also use DAYOFMONTH.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#dayname_function">DAYNAME Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the name of the day of the week from a date or timestamp
expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#dayofmonth_function">DAYOFMONTH Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 1 through 31 that represents the
corresponding day of the month. You can also use DAY.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#dayofweek_function">DAYOFWEEK Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 1 through 7 that represents the
corresponding day of the week.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#dayofyear_function">DAYOFYEAR Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 1 through 366 that represents the
corresponding day of the year.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#extract_function">EXTRACT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns a specified datetime field from a datetime value expression or
an interval value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#hour_function">HOUR Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 0 through 23 that represents the
corresponding hour of the day.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#juliantimestamp_function">JULIANTIMESTAMP Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a datetime value to a Julian timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#minute_function">MINUTE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 0 through 59 that represents the
corresponding minute of the hour.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#month_function">MONTH Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 1 through 12 that represents the
corresponding month of the year.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#monthname_function">MONTHNAME Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns a character literal that is the name of the month of the year
(January, February, and so on).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#quarter_function">QUARTER Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 1 through 4 that represents the
corresponding quarter of the year.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#second_function">SECOND Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 0 through 59 that represents the
corresponding second of the minute.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#timestampadd_function">TIMESTAMPADD Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Adds the interval of time specified by <em>interval-ind</em> and
<em>num_expr</em> to <em>datetime_expr</em>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#timestampdiff_function">TIMESTAMPDIFF Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the integer value for the number of <em>interval-ind</em>
units of time between <em>startdate</em> and <em>enddate</em>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#to_char_function">TO_CHAR Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a datetime value to a character value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#to_date_function">TO_DATE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a character value to a date or timestamp value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#to_time_function">TO_TIME Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a character value to a time value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#to_timestamp_function">TO_TIMESTAMP Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a character value to a timestamp value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#week_function">WEEK Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value in the range 1 through 54 that represents the
corresponding week of the year.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#year_function">YEAR Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an integer value that represents the year.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>See the individual entry for the function.</p>
</div>
</div>
<div class="sect2">
<h3 id="mathematical_functions">7.5. Mathematical Functions</h3>
<div class="paragraph">
<p>Use these mathematical functions within an SQL numeric value expression:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#abs_function">ABS Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the absolute value of a numeric value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#acos_function">ACOS Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the arccosine of a numeric value expression as an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#asin_function">ASIN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the arcsine of a numeric value expression as an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#atan_function">ATAN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the arctangent of a numeric value expression as an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#atan2_function">ATAN2 Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the arctangent of the x and y coordinates, specified by two numeric value expressions, as an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#ceiling_function">CEILING Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the smallest integer greater than or equal to a numeric value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#cos_function">COS Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the cosine of a numeric value expression, where the expression is an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#crc32_function">CRC32 Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns CRC32 checksum</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#cosh_function">COSH Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the hyperbolic cosine of a numeric value expression, where the expression is an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#degrees_function">DEGREES Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a numeric value expression expressed in radians to the number of degrees.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#exp_function">EXP Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the exponential value (to the base e) of a numeric value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#floor_function">FLOOR Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the largest integer less than or equal to a numeric value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#log_function">LOG Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the natural logarithm of a numeric value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#log10_function">LOG10 Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the base 10 logarithm of a numeric value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#mod_function">MOD Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the remainder (modulus) of an integer value expression divided by an integer value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#nullifzero_function">NULLIFZERO Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the value of the operand unless it is zero, in which case it returns NULL.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#pi_function">PI Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the constant value of pi as a floating-point value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#power_function">POWER Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the value of a numeric value expression raised to the power of an integer value expression. You can also use the exponential operator *\*.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#radians_function">RADIANS Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a numeric value expression expressed in degrees to the number of radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#round_function">ROUND Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the value of <em>numeric_expr</em> round to <em>num</em> places to the right of the decimal point.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#sign_function">SIGN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns an indicator of the sign of a numeric value expression. If value is less than zero, returns -1 as the indicator. If value is zero,
returns 0. If value is greater than zero, returns 1.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#sin_function">SIN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the sine of a numeric value expression, where the expression is an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#sinh_function">SINH Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the hyperbolic sine of a numeric value expression, where the expression is an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#sqrt_function">SQRT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the square root of a numeric value expression.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#tan_function">TAN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the tangent of a numeric value expression, where the expression is an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#tanh_function">TANH Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the hyperbolic tangent of a numeric value expression, where the expression is an angle expressed in radians.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#zeroifnull_function">ZEROIFNULL Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the value of the operand unless it is NULL, in which case it returns zero.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>See the individual entry for the function.</p>
</div>
<div id="encryption_functions" class="literalblock">
<div class="content">
<pre>== Encryption Functions
Use these functions within an SQL value expression to do data encryption or hashing:</pre>
</div>
</div>
<div class="literalblock">
<div class="content">
<pre>[cols="25%,75%"]
|===
| &lt;&lt;md5_function,MD5 Function&gt;&gt; | Returns MD5 checksum
| &lt;&lt;sha_function,SHA Function&gt;&gt; | Returns SHA-1 160-bit checksum
| &lt;&lt;sha2_function,SHA2 Function&gt;&gt; | Returns SHA-2 checksum
|===</pre>
</div>
</div>
</div>
<div class="sect2">
<h3 id="sequence_functions">7.6. Sequence Functions</h3>
<div class="paragraph">
<p>Sequence functions operate on ordered rows of the intermediate result
table of a SELECT statement that includes a SEQUENCE BY clause. Sequence
functions are categorized generally as difference, moving, offset, or
running.</p>
</div>
<div class="paragraph">
<p>Some sequence functions, such as ROWS SINCE, require sequentially
examining every row in the history buffer until the result is computed.
Examining a large history buffer in this manner for a condition that has
not been true for many rows could be an expensive operation. In
addition, such operations may not be parallelized because the entire
sorted result set must be available to compute the result of the
sequence function.</p>
</div>
<div class="sect3">
<h4 id="difference_sequence_functions">7.6.1. Difference sequence functions</h4>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#diff1_function">DIFF1 Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Calculates differences between values of a column expression in the current row and previous rows.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#diff2_function">DIFF2 Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Calculates differences between values of the result of DIFF1 of the current row and DIFF1 of previous rows.</p></td>
</tr>
</tbody>
</table>
</div>
<div class="sect3">
<h4 id="moving_sequence_functions">7.6.2. Moving sequence functions</h4>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#movingcount_function">MOVINGCOUNT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the number of non-null values of a column expression in the current window.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#movingmax_function">MOVINGMAX Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the maximum of non-null values of a column expression in the current window.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#movingmin_function">MOVINGMIN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the minimum of non-null values of a column expression in the current window.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#movingstddev_function">MOVINGSTDDEV Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the standard deviation of non-null values of a column expression in the current window.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#movingsum_function">MOVINGSUM Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the sum of non-null values of a column expression in the current window.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#movingvariance_function">MOVINGVARIANCE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the variance of non-null values of a column expression in the current window.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>Offset sequence function
=== Offset sequence function</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#offset_function">OFFSET Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Retrieves columns from previous rows.</p></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="running_sequence_functions">7.6.3. Running sequence functions</h4>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#runningavg_function">RUNNINGAVG Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the average of non-null values of a column expression up to and including the current row.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#runningcount_function">RUNNINGCOUNT Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the number of rows up to and including the current row.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#runningmax_function">RUNNINGMAX Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the maximum of values of a column expression up to and including the current row.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#runningmin_function">RUNNINGMIN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the minimum of values of a column expression up to and including the current row.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#runningrank_function">RUNNINGRANK Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the rank of the given value of an intermediate result table ordered by a SEQUENCE BY clause in a SELECT statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#runningstddev_function">RUNNINGSTDDEV Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the standard deviation of non-null values of a column expression up to and including the current row.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#runningsum_function">RUNNINGSUM Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the sum of non-null values of a column expression up to and including the current row.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#runningvariance_function">RUNNINGVARIANCE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the variance of non-null values of a column expression up to and including the current row.</p></td>
</tr>
</tbody>
</table>
</div>
<div class="sect3">
<h4 id="other_sequence_functions">7.6.4. Other sequence functions</h4>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#lastnotnull_function">LASTNOTNULL Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the last non-null value for the specified column expression. If only null values have been returned, returns null.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#rows_since_function">ROWS SINCE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the number of rows counted since the specified condition was last true.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#rows_since_changed_function">ROWS SINCE CHANGED Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the number of rows counted since the specified set of values last changed.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#this_function">THIS Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Used in ROWS SINCE to distinguish between the value of the column in the current row and the value of the column in previous rows.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>See <a href="#sequence_by_clause">SEQUENCE BY Clause</a> and the individual entry for each function.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="other_functions_and_expressions">7.7. Other Functions and Expressions</h3>
<div class="paragraph">
<p>Use these other functions and expressions in an SQL value expression:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 75%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#authname_function">AUTHNAME Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the authorization name associated with the specified authorization ID number.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#bitand_function">BITAND Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Performs 'and' operation on corresponding bits of the two operands.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#case_expression">CASE (Conditional) Expression</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">A conditional expression. The two forms of the CASE expression are simple and searched.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#cast_expression">CAST Expression</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts a value from one data type to another data type that you specify.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#coalesce_function">COALESCE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the value of the first expression in the list that does not have a NULL value or if all
the expressions have NULL values, the function returns a NULL value.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#converttohex_function">CONVERTTOHEX Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Converts the specified value expression to hexadecimal for display purposes.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#current_user_function">CURRENT_USER Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the database user name of the current user who invoked the function.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#decode_function">DECODE Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Compares <em>expr</em> to each <em>test_expr</em> value one by one in the order provided.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#explain_function">EXPLAIN Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Generates a result table describing an access plan for a SELECT, INSERT, DELETE, or UPDATE statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#isnull_function">ISNULL Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the first argument if it is not null, otherwise it returns the second argument.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#is_ipv4_function">IS_IPV4 Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns 1 if the argument is a valid IPv4 address specified as a string, 0 otherwise.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#is_ipv6_function">IS_IPV6 Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns 1 if the argument is a valid IPv6 address specified as a string, 0 otherwise.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#inet_aton_function">INET_ATON Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Given the dotted-quad representation of an IPv4 network address as a string, returns an integer that represents the numeric value of the address in network byte order (big endian). INET_ATON() returns NULL if it does not understand its argument.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#inet_ntoa_function">INET_NTOA Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Given a numeric IPv4 network address in network byte order, returns the dotted-quad string representation of the address as a nonbinary string in the connection character set. INET_NTOA() returns NULL if it does not understand its argument.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#nullif_function">NULLIF Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the value of the first operand if the two operands are not equal, otherwise it returns NULL.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#nvl_function">NVL Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns the value of the first operand unless it is NULL, in which case it returns the value of the second operand.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock"><a href="#user_function">USER Function</a></p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Returns either the database user name of the current user who invoked the function or the database user name
associated with the specified user ID number.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>See the individual entry for the function.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="abs_function">7.8. ABS Function</h3>
<div class="paragraph">
<p>The ABS function returns the absolute value of a numeric value
expression. ABS is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ABS (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the ABS function. The result is returned as an unsigned
numeric value if the precision of the argument is less than 10 or as a
LARGEINT if the precision of the argument is greater than or equal to
10. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_abs">7.8.1. Examples of ABS</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 8:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ABS (-20 + 12)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="acos_function">7.9. ACOS Function</h3>
<div class="paragraph">
<p>The ACOS function returns the arccosine of a numeric value expression as
an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>ACOS is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ACOS (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the ACOS function. The range for the value of the argument is
from -1 to +1. See <a href="#numeric_value_expressions">Numeric Value_Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_acos">7.9.1. Examples of ACOS</h4>
<div class="ulist">
<ul>
<li>
<p>The ACOS function returns the value 3.49044274380724416E-001 or
approximately 0.3491 in radians (which is 20 degrees).</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ACOS (0.9397)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 0.3491. The function ACOS is the
inverse of the function COS.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ACOS (COS (0.3491))</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="add_months_function">7.9.2. ADD_MONTHS Function</h4>
<div class="paragraph">
<p>The ADD_MONTHS function adds the integer number of months specified by
<em>int_expr</em> to <em>datetime_expr</em> and normalizes the result. ADD_MONTHS is a Trafodion SQL
extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ADDMONTHS (datetimeexpr, intexpr [, int2 ])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime_expr</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. The return value is the same type as the <em>datetime_expr.</em> See
<a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>int_expr</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of data type SMALLINT or INTEGER that
specifies the number of months. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>int2</em></code></p>
<div class="paragraph">
<p>is an unsigned integer constant. If <em>int2</em> is omitted or is the literal
0, the normalization is the standard normalization. If <em>int2</em> is the
literal 1, the normalization includes the standard normalization and if
the starting day (the day part of <em>datetime_expr</em>) is the last day of
the starting month, then the ending day (the day part of the result
value) is set to the last valid day of the result month. See
<a href="#standard_normalization">Standard Normalization</a>. See
<a href="#numeric_value_expressions">Numeric Value Expressions</a> .</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="examples_of_add_months">7.9.3. Examples of ADD_MONTHS</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value DATE '2007-03-31':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ADD_MONTHS(DATE '2007-02-28', 1, 1)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '2007-03-28':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ADD_MONTHS(DATE '2007-02-28', 1, 0)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '2008-03-28':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ADD_MONTHS(DATE '2008-02-28', 1, 1)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the timestamp '2009-02-28 00:00:00':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ADD_MONTHS(timestamp'2008-02-29 00:00:00',12,1)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="ascii_function">7.10. ASCII Function</h3>
<div class="paragraph">
<p>The ASCII function returns the integer that is the ASCII code of the
first character in a character string expression associated with either
the ISO8891 character set or the UTF8 character set.</p>
</div>
<div class="paragraph">
<p>ASCII is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ASCII (character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>_character-expression</code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies a string of
characters. See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_ascii">7.10.1. Considerations For ASCII</h4>
<div class="paragraph">
<p>For a string expression in the UTF8 character set, if the value of the
first byte in the string is greater than 127, Trafodion SQL returns this
error message:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ERROR[8428] The argument to function ASCII is not valid.</code></pre>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_ascii">7.10.2. Examples of ASCII</h4>
<div class="ulist">
<ul>
<li>
<p>Select the column JOBDESC and return the ASCII code of the first
character of the job description:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT jobdesc, ASCII (jobdesc) FROM persnl.job;
JOBDESC (EXPR)
----------------- --------
MANAGER 77
PRODUCTION SUPV 80
ASSEMBLER 65
SALESREP 83
... ...
--- 10 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="asin_function">7.11. ASIN Function</h3>
<div class="paragraph">
<p>The ASIN function returns the arcsine of a numeric value expression as
an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>ASIN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ASIN (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the ASIN function. The range for the value of the argument is
from -1 to +1. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_ascii">7.11.1. Considerations for ASCII</h4>
<div class="paragraph">
<p>For a string expression in the UTF8 character set, if the value of the
first byte in the string is greater than 127, Trafodion SQL returns this
error message:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ERROR[8428] The argument to function ASCII is not valid.</code></pre>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_ascii">7.11.2. Examples of ASCII</h4>
<div class="ulist">
<ul>
<li>
<p>Select the column JOBDESC and return the ASCII code of the first
character of the job description:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT jobdesc, ASCII (jobdesc) FROM persnl.job;
JOBDESC (EXPR)
----------------- --------
MANAGER 77
PRODUCTION SUPV 80
ASSEMBLER 65
SALESREP 83
... ...
--- 10 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="asin_function">7.12. ASIN Function</h3>
<div class="paragraph">
<p>The ASIN function returns the arcsine of a numeric value expression as
an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>ASIN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ASIN (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the ASIN function. The range for the value of the argument
is from -1 to +1. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_asin">7.12.1. Examples of ASIN</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 3.49044414403046400e-001 or
approximately 0.3491 in radians (which is 20 degrees):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ASIN(0.3420)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 0.3491. The function ASIN is the
inverse of the function SIN.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ASIN(SIN(0.3491))</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="atan_function">7.13. ATAN Function</h3>
<div class="paragraph">
<p>The ATAN function returns the arctangent of a numeric value expression
as an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>ATAN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ATAN ( numeric-expression )</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>_numeric-expression _</code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the atan function. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
<div class="sect3">
<h4 id="examples_of_atan">7.13.1. Examples of ATAN</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 8.72766423249958272E-001 or
approximately 0.8727 in radians (which is 50 degrees):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ATAN (1.192)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 0.8727. The function ATAN is the
inverse of the function TAN.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ATAN (TAN (0.8727))</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="atan2_function">7.14. ATAN2 Function</h3>
<div class="paragraph">
<p>The ATAN2 function returns the arctangent of the x and y coordinates,
specified by two numeric value expressions, as an angle expressed in
radians.</p>
</div>
<div class="paragraph">
<p>ATAN2 is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ATAN2 (numeric-expression-x,numeric-expression-y)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression-x</em>, <em>numeric-expression-y</em></code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>are SQL numeric value expressions that specify the value for the x and y
coordinate arguments of the ATAN2 function. See
<a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
<div class="sect3">
<h4 id="examples_of_atan2">7.14.1. Examples of ATAN2</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 2.66344329881899520E+000, or
approximately 2.6634:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ATAN2 (1.192,-2.3)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="authname_function">7.15. AUTHNAME Function</h3>
<div class="paragraph">
<p>The AUTHNAME function returns the name of the authorization ID that is
associated with the specified authorization ID number.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">AUTHNAME (auth-id)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>auth-id</em></code></p>
<div class="paragraph">
<p>is the 32-bit number associated with an authorization ID. See
<a href="#authorization_ids">Authorization IDs</a>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The AUTHNAME function is similar to the <a href="#user function">USER Function</a>.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_authname">7.15.1. Considerations for AUTHNAME</h4>
<div class="ulist">
<ul>
<li>
<p>This function can be specified only in the top level of a SELECT statement.</p>
</li>
<li>
<p>The value returned is string data type VARCHAR(128) and is in ISO8859-1 encoding.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_authname">7.15.2. Examples of AUTHNAME</h4>
<div class="ulist">
<ul>
<li>
<p>This example shows the authorization name associated with the
authorization ID number, 33333:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SELECT AUTHNAME (33333) FROM (values(1)) x(a);
(EXPR)
-------------------------
DB ROOT
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="avg_function">7.16. AVG Function</h3>
<div class="paragraph">
<p>AVG is an aggregate function that returns the average of a set of
numbers.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">AVG ([ALL | DISTINCT] expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ALL | DISTINCT</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the AVG of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included. If you specify DISTINCT, duplicate
values are eliminated before the AVG function is applied.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a numeric or interval value <em>expression</em> that determines the
values to average. The <em>expression</em> cannot contain an aggregate function
or a subquery. The DISTINCT clause specifies that the AVG function
operates on distinct values from the one-column table derived from the
evaluation of <em>expression</em>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>See <a href="#numeric_value_expressions">Numeric Value Expressions</a> and
<a href="#interval_value_expressions">Interval Value Expressions</a>.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_avg">7.16.1. Considerations for AVG</h4>
<div class="sect4">
<h5 id="data-type-of-the-result">Data Type of the Result</h5>
<div class="paragraph">
<p>The data type of the result depends on the data type of the argument. If
the argument is an exact numeric type, the result is LARGEINT. If the
argument is an approximate numeric type, the result
is DOUBLE PRECISION. If the argument is INTERVAL data type, the result
is INTERVAL with the same precision as the argument.</p>
</div>
<div class="paragraph">
<p>The scale of the result is the same as the scale of the argument. If the
argument has no scale, the result is truncated.</p>
</div>
</div>
<div class="sect4">
<h5 id="operands-of-the-expression">Operands of the Expression</h5>
<div class="paragraph">
<p>The expression includes columns from the rows of the SELECT result table but
cannot include an aggregate function. These expressions are valid:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">AVG (SALARY)
AVG (SALARY * 1.1)
AVG (PARTCOST * QTY_ORDERED)</code></pre>
</div>
</div>
</div>
<div class="sect4">
<h5 id="avg_nulls">Nulls</h5>
<div class="paragraph">
<p>All nulls are eliminated before the function is applied to the set of
values. If the result table is empty, AVG returns NULL.</p>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_avg">Examples of AVG</h5>
<div class="ulist">
<ul>
<li>
<p>Return the average value of the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG (salary) FROM persnl.employee;
(EXPR)
---------------------
49441.52
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Return the average value of the set of unique SALARY values:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT AVG(DISTINCT salary) AS Avg_Distinct_Salary FROM persnl.employee;
AVG_DISTINCT_SALARY
---------------------
53609.89
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Return the average salary by department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT deptnum, AVG (salary) AS &quot;AVERAGE SALARY&quot;
FROM persnl.employee
WHERE deptnum &lt; 3000 GROUP BY deptnum;
Dept/Num &quot;AVERAGE SALARY&quot;
-------- ---------------------
1000 52000.17
2000 50000.10
1500 41250.00
2500 37000.00
--- 4 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="bitand_function">7.17. BITAND Function</h3>
<div class="paragraph">
<p>The BITAND function performs an AND operation on corresponding bits of
the two operands. If both bits are 1, the result bit is 1. Otherwise the
result bit is 0.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">BITAND (expression, expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>The result data type is a binary number. Depending on the precision of
the operands, the data type of the result can either be an INT (32-bit
integer) or a LARGEINT (64-bit integer).</p>
</div>
<div class="paragraph">
<p>If the max precision of either operand is greater than 9, LARGEINT is
chosen (numbers with precision greater than 9 are represented by
LARGEINT). Otherwise, INT is chosen.</p>
</div>
<div class="paragraph">
<p>If both operands are unsigned, the result is unsigned. Otherwise, the
result is signed. Both operands are converted to the result data type
before performing the bit operation.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_bitand">7.17.1. Considerations for BITAND</h4>
<div class="paragraph">
<p>BITAND can be used anywhere in an SQL query where an expression could be
used. This includes SELECT lists, WHERE predicates, VALUES clauses, SET
statement, and so on.</p>
</div>
<div class="paragraph">
<p>This function returns a numeric data type and can be used in arithmetic
expressions.</p>
</div>
<div class="paragraph">
<p>Numeric operands can be positive or negative numbers. All numeric data
types are allowed with the exceptions listed in the
<a href="#restrictions_for_bitand">Restrictions for BITAND</a> section.</p>
</div>
<div class="sect4">
<h5 id="restrictions_for_bitand">Restrictions for BITAND</h5>
<div class="paragraph">
<p>The following are BITAND restrictions:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Must have two operands</p>
</li>
<li>
<p>Operands must be binary or decimal exact numerics</p>
</li>
<li>
<p>Operands must have scale of zero</p>
</li>
<li>
<p>Operands cannot be floating point numbers</p>
</li>
<li>
<p>Operands cannot be an extended precision numeric (the maximum precision of an extended numeric data type is 128)</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_bitand">7.17.2. Examples of BITAND</h4>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;select bitand(1,3) from (values(1)) x(a);
(EXPR)
--------------
1
--- 1 row(s) selected
&gt;&gt;select 1 &amp; 3 from (values(1)) x(a);
(EXPR)
--------------
1
--- 1 row(s) selected
&gt;&gt;select bitand(1,3) + 0 from (values(1)) x(a);
(EXPR)
--------------
1
--- 1 row(s) selected</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="case_expression">7.18. CASE (Conditional) Expression</h3>
<div class="paragraph">
<p>The CASE expression is a conditional expression with two forms: simple
and searched.</p>
</div>
<div class="paragraph">
<p>In a simple CASE expression, Trafodion SQL compares a value to a
sequence of values and sets the CASE expression to the value associated
with the first match &#8212; if a match exists. If no match exists, Trafodion
SQL returns the value specified in the ELSE clause (which can be null).</p>
</div>
<div class="paragraph">
<p>In a searched CASE expression, Trafodion SQL evaluates a sequence of
conditions and sets the CASE expression to the value associated with the
first condition that is true &#8212; if a true condition exists. If no true
condition exists, Trafodion SQL returns the value specified in the ELSE
clause (which can be null).</p>
</div>
<div class="paragraph">
<p><strong>Simple CASE is</strong>:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CASE case-expression
WHEN expression-1 THEN {result-expression-1 | NULL}
WHEN expression-2 THEN {result-expression-2 | NULL}
...
WHEN expression-n THEN {result-expression-n | NULL}
[ELSE {result-expression | NULL}]
END</code></pre>
</div>
</div>
<div class="paragraph">
<p><strong>Searched CASE is</strong>:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CASE
WHEN _condition-1_ THEN {_result-expression-1_ | NULL}
WHEN _condition-2_ THEN {_result-expression-2_ | NULL}
...
WHEN _condition-n_ THEN {_result-expression-n_ | NULL}
[ELSE {_result-expression_ | NULL}]
END</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>case-expression</em></code></p>
<div class="paragraph">
<p>specifies a value expression that is compared to the value expressions
in each WHEN clause of a simple CASE. The data type of each <em>expression</em>
in the WHEN clause must be comparable to the data type of
<em>case-expression</em>.</p>
</div>
</li>
<li>
<p><code><em>expression-1</em> &#8230; <em>expression-n</em></code></p>
<div class="paragraph">
<p>specifies a value associated with each <em>result-expression</em>. If the
value of an <em>expression</em> in a WHEN clause matches the value of
<em>case-expression</em>, simple CASE returns the associated
<em>result-expression</em> value. If no match exists, the CASE expression
returns the value expression specified in the ELSE clause, or NULL if
the ELSE value is not specified.</p>
</div>
</li>
<li>
<p><code><em>result-expression-1</em> &#8230; <em>result-expression-n</em></code></p>
<div class="paragraph">
<p>specifies the result value expression associated with each <em>expression</em>
in a WHEN clause of a simple CASE, or with each <em>condition</em> in a WHEN
clause of a searched CASE. All of the <em>result-expressions</em> must have
comparable data types, and at least one of the
<em>result-expressions</em> must return non-null.</p>
</div>
</li>
<li>
<p><code><em>result-expression</em></code></p>
<div class="paragraph">
<p>follows the ELSE keyword and specifies the value returned if none of the
expressions in the WHEN clause of a simple CASE are equal to the case
expression, or if none of the conditions in the WHEN clause of a
searched CASE are true. If the ELSE <em>result-expression</em> clause is not
specified, CASE returns NULL. The data type of <em>result-expression</em> must
be comparable to the other results.</p>
</div>
</li>
<li>
<p><code><em>condition-1</em> &#8230; <em>condition-n</em></code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>specifies conditions to test for in a searched CASE. If a <em>condition</em> is
true, the CASE expression returns the associated <em>result-expression</em>
value. If no <em>condition</em> is true, the CASE expression returns the value
expression specified in the ELSE clause, or NULL if the ELSE value is
not specified.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_case">7.18.1. Considerations for CASE</h4>
<div class="sect4">
<h5 id="data_type_of_the_case_expression">Data Type of the CASE Expression</h5>
<div class="paragraph">
<p>The data type of the result of the CASE expression depends on the data
types of the result expressions. If the results all have the same data
type, the CASE expression adopts that data type. If the results have
comparable but not identical data types, the CASE expression adopts the
data type of the union of the result expressions. This result data type
is determined in these ways.</p>
</div>
</div>
<div class="sect4">
<h5 id="character_data_type">Character Data Type</h5>
<div class="paragraph">
<p>If any data type of the result expressions is variable-length character
string, the result data type is variable-length character string with
maximum length equal to the maximum length of the result expressions.</p>
</div>
<div class="paragraph">
<p>Otherwise, if none of the data types is variable-length character
string, the result data type is fixed-length character string with length
equal to the maximum of the lengths of the result expressions.</p>
</div>
</div>
<div class="sect4">
<h5 id="numeric_data_type">Numeric Data Type</h5>
<div class="paragraph">
<p>If all of the data types of the result expressions are exact numeric,
the result data type is exact numeric with precision and scale equal to
the maximum of the precisions and scales of the result expressions.</p>
</div>
<div class="paragraph">
<p>For example, if <em>result-expression-1</em> and <em>result-expression-2</em> have
data type NUMERIC(5) and <em>result-expression-3</em> has data type
NUMERIC(8,5), the result data type is NUMERIC(10,5).</p>
</div>
<div class="paragraph">
<p>If any data type of the result expressions is approximate numeric, the
result data type is approximate numeric with precision equal to the
maximum of the precisions of the result expressions.</p>
</div>
</div>
<div class="sect4">
<h5 id="datetime_data_type">Datetime Data Type</h5>
<div class="paragraph">
<p>If the data type of the result expressions is datetime, the result data
type is the same datetime data type.</p>
</div>
</div>
<div class="sect4">
<h5 id="interval_data_type">Interval Data Type</h5>
<div class="paragraph">
<p>If the data type of the result expressions is interval, the result data
type is the same interval data type (either year-month or day-time) with
the start field being the most significant of the start fields of the
result expressions and the end field being the least significant of the
end fields of the result expressions.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_case">7.18.2. Examples of CASE</h4>
<div class="ulist">
<ul>
<li>
<p>Use a simple CASE to decode JOBCODE and return NULL if JOBCODE does
not match any of the listed values:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
last_name
, first_name
, CASE jobcode
WHEN 100 THEN 'MANAGER'
WHEN 200 THEN 'PRODUCTION SUPV'
WHEN 250 THEN 'ASSEMBLER'
WHEN 300 THEN 'SALESREP'
WHEN 400 THEN 'SYSTEM ANALYST'
WHEN 420 THEN 'ENGINEER'
WHEN 450 THEN 'PROGRAMMER'
WHEN 500 THEN 'ACCOUNTANT'
WHEN 600 THEN 'ADMINISTRATOR ANALYST'
WHEN 900 THEN 'SECRETARY'
ELSE NULL
END
FROM persnl.employee;
LAST_NAME FIRST_NAME (EXPR)
-------------------- --------------- -----------------
GREEN ROGER MANAGER
HOWARD JERRY MANAGER
RAYMOND JANE MANAGER
...
CHOU JOHN SECRETARY
CONRAD MANFRED PROGRAMMER
HERMAN JIM SALESREP
CLARK LARRY ACCOUNTANT
HALL KATHRYN SYSTEM ANALYST
...
--- 62 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Use a searched CASE to return LAST_NAME, FIRST_NAME and a value based
on SALARY that depends on the value of DEPTNUM:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
last_name
, first_name
, deptnum
, CASE
WHEN deptnum = 9000 THEN salary * 1.10
WHEN deptnum = 1000 THEN salary * 1.12 ELSE salary
END
FROM persnl.employee;
LAST_NAME FIRST_NAME DEPTNUM (EXPR)
---------------- ------------ ------- -------------------
GREEN ROGER 9000 193050.0000
HOWARD JERRY 1000 153440.1120
RAYMOND JANE 3000 136000.0000
...
--- 62 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="cast_expression">7.19. CAST Expression</h3>
<div class="paragraph">
<p>The CAST expression converts data to the data type you specify.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CAST ({expression | NULL} AS data-type)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em> | NULL</code></p>
<div class="paragraph">
<p>specifies the operand to convert to the data type <em>data-type</em>.</p>
</div>
<div class="paragraph">
<p>If the operand is an <em>expression</em>, then <em>data-type</em> depends on the
data type of <em>expression</em> and follows the rules outlined in
<a href="#valid_conversions_for_cast">Valid Conversions for CAST</a>.</p>
</div>
<div class="paragraph">
<p>If the operand is NULL, or if the value of the <em>expression</em> is null, the
result of CAST is NULL, regardless of the data type you specify.</p>
</div>
</li>
<li>
<p><code><em>data-type</em></code></p>
<div class="paragraph">
<p>specifies a data type to associate with the operand of CAST. See
<a href="#data_types">Data Types</a>.</p>
</div>
<div class="paragraph">
<p>When casting data to a CHAR or VARCHAR data type, the resulting data
value is left justified. Otherwise, the resulting data value is right
justified. Further, when you are casting to a CHAR or VARCHAR data type,
you must specify the length of the target value.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_cast">7.19.1. Considerations for CAST</h4>
<div class="ulist">
<ul>
<li>
<p>Fractional portions are discarded when you use CAST of a numeric value to an INTERVAL type.</p>
</li>
<li>
<p>Depending on how your file is set up, using CAST might cause poor
query performance by preventing the optimizer from choosing the most
efficient plan and requiring the executor to perform a complete table or
index scan.</p>
</li>
</ul>
</div>
<div class="sect4">
<h5 id="valid_conversions_for_cast">Valid Conversions for CAST</h5>
<div class="ulist">
<ul>
<li>
<p>An exact or approximate numeric value to any other numeric data type.</p>
</li>
<li>
<p>An exact or approximate numeric value to any character string data type.</p>
</li>
<li>
<p>An exact numeric value to either a single-field year-month or day-time interval such as INTERVAL DAY(2).</p>
</li>
<li>
<p>A character string to any other data type, with one restriction:</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>The contents of the character string to be converted must be consistent
in meaning with the data type of the result. For example, if you are
converting to DATE, the contents of the character string must be 10
characters consisting of the year, a hyphen, the month, another hyphen,
and the day.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>A date value to a character string or to a TIMESTAMP (Trafodion SQL fills in the time part with 00:00:00.00).</p>
</li>
<li>
<p>A time value to a character string or to a TIMESTAMP (Trafodion SQL fills in the date part with the current date).</p>
</li>
<li>
<p>A timestamp value to a character string, a DATE, a TIME, or another TIMESTAMP with different fractional seconds precision.</p>
</li>
<li>
<p>A year-month interval value to a character string, an exact numeric,
or to another year-month INTERVAL with a different start field precision.</p>
</li>
<li>
<p>A day-time interval value to a character string, an exact numeric, or
to another day-time INTERVAL with a different start field precision.</p>
</li>
</ul>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_cast">7.19.2. Examples of CAST</h4>
<div class="ulist">
<ul>
<li>
<p>In this example, the fractional portion is discarded:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CAST (123.956 as INTERVAL DAY(18))</code></pre>
</div>
</div>
</li>
<li>
<p>This example returns the difference of two timestamps in minutes:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CAST((d.step_end - d.step_start) AS INTERVAL MINUTE)</code></pre>
</div>
</div>
</li>
<li>
<p>Suppose that your database includes a log file of user information.
This example converts the current timestamp to a character string and
concatenates the result to a character literal. Note the length must be
specified.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO stats.logfile (user_key, user_info)
VALUES (001, 'User JBrook, executed at ' || CAST (CURRENT_TIMESTAMP AS CHAR(26)));</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="ceiling_function">7.20. CEILING Function</h3>
<div class="paragraph">
<p>The CEILING function returns the smallest integer, represented as a
FLOAT data type, greater than or equal to a numeric value expression.</p>
</div>
<div class="paragraph">
<p>CEILING is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CEILING (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the CEILING function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_ceiling">7.20.1. Examples of CEILING</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the integer value 3.00000000000000000E+000,
represented as a FLOAT data type:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CEILING (2.25)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="char_function">7.20.2. CHAR Function</h4>
<div class="paragraph">
<p>The CHAR function returns the character that has the specified code
value, which must be of exact numeric with scale 0.</p>
</div>
<div class="paragraph">
<p>CHAR is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CHAR(code-value, [,char-set-name])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>code-value</em></code></p>
<div class="paragraph">
<p>is a valid code value in the character set in use.</p>
</div>
</li>
<li>
<p><code><em>char-set-name</em></code></p>
<div class="paragraph">
<p>can be ISO88591 or UTF8. The returned character will be associated with
the character set specified by <em>char-set-name</em>.</p>
</div>
<div class="paragraph">
<p>The default for <em>char-set-name</em> is ISO88591.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="considerations_for_char">7.20.3. Considerations for CHAR</h4>
<div class="ulist">
<ul>
<li>
<p>For the ISO88591 character set, the return type is VARCHAR(1).</p>
</li>
<li>
<p>For the UTF8 character set, the return type is VARCHAR(1).</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_char">7.20.4. Examples of CHAR</h4>
<div class="ulist">
<ul>
<li>
<p>Select the column CUSTNAME and return the ASCII code of the first
character of the customer name and its CHAR value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT custname, ASCII (custname), CHAR (ASCII (custname))
FROM sales.customer;
CUSTNAME (EXPR) ( EXPR)
------------------ ------- -------
CENTRAL UNIVERSITY 67 C
BROWN MEDICAL CO 66 B
STEVENS SUPPLY 83 S
PREMIER INSURANCE 80 P
... ... ...
--- 15 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="char_length_function">7.21. CHAR_LENGTH Function</h3>
<div class="paragraph">
<p>The CHAR_LENGTH function returns the number of characters in a string.
You can also use CHARACTER_LENGTH. Every character, including multi-byte
characters, counts as one character.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CHAR[ACTER]_LENGTH (string-value-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>string-value-expression</em></code></p>
<div class="paragraph">
<p>specifies the string value expression for which to return the length in
characters. Trafodion SQL returns the result as a two-byte signed
integer with a scale of zero. If <em>string-value-expression</em> is null,
Trafodion SQL returns a length of
null. See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_char_length">7.21.1. Considerations for CHAR_LENGTH</h4>
<div class="sect4">
<h5 id="char_and_varchar_operands">CHAR and VARCHAR Operands</h5>
<div class="paragraph">
<p>For a column declared as fixed CHAR, Trafodion SQL returns the maximum
length of that column. For a VARCHAR column, Trafodion SQL returns the
actual length of the string stored in that column.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_char_length">7.21.2. Examples of CHAR_LENGTH</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns 12 as the result. The concatenation operator is
denoted by two vertical bars (\|\|).</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CHAR_LENGTH ('ROBERT' || ' ' || 'SMITH')</code></pre>
</div>
</div>
</li>
<li>
<p>The string '' is the null (or empty) string. This function returns 0
(zero):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CHAR_LENGTH ('')</code></pre>
</div>
</div>
</li>
<li>
<p>The DEPTNAME column has data type CHAR(12). Therefore, this function
always returns 12:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CHAR_LENGTH (deptname)</code></pre>
</div>
</div>
</li>
<li>
<p>The PROJDESC column in the PROJECT table has data type VARCHAR(18).
This function returns the actual length of the column value &#8212; not 18 for
shorter strings &#8212; because it is a VARCHAR value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CHAR_LENGTH (projdesc) FROM persnl.project;
(EXPR)
----------
14
13
13
17
9
9
--- 6 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="coalesce_function">7.22. COALESCE Function</h3>
<div class="paragraph">
<p>The COALESCE function returns the value of the first expression in the
list that does not have a NULL value or if all the expressions have NULL
values, the function returns a NULL value.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COALESCE (expr1, expr2, ...)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expr1</em></code></p>
<div class="paragraph">
<p>an expression to be compared.</p>
</div>
</li>
<li>
<p><code><em>expr2</em></code></p>
<div class="paragraph">
<p>an expression to be compared.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_coalesce">7.22.1. Examples of COALESCE</h4>
<div class="ulist">
<ul>
<li>
<p>COALESCE returns the value of the first operand that is not NULL:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT COALESCE (office_phone, cell_phone, home_phone, pager, fax_num, '411')
from emptbl;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="code_value_function">7.23. CODE_VALUE Function</h3>
<div class="paragraph">
<p>The CODE_VALUE function returns an unsigned integer (INTEGER UNSIGNED)
that is the code point of the first character in a character value
expression that can be associated with one of the supported character
sets.</p>
</div>
<div class="paragraph">
<p>CODE_VALUE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CODE_VALUE(character-value-expression)
character-set</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-value-expression</em></code></p>
<div class="paragraph">
<p>is a character string.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_code_value_function">7.23.1. Examples of CODE_VALUE Function</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns 97 as the result:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;select code_value('abc') from (values(1))x;
(EXPR)
----------
97</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="concat_function">7.23.2. CONCAT Function</h4>
<div class="paragraph">
<p>The CONCAT function returns the concatenation of two character value
expressions as a character string value. You can also use the
concatenation operator (\|\|).</p>
</div>
<div class="paragraph">
<p>CONCAT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CONCAT (character-expr-1, character-expr-2)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expr-1</em>, <em>character-expr-2</em></code></p>
<div class="paragraph">
<p>are SQL character value expressions (of data type CHAR or VARCHAR) that
specify two strings of characters. Both character value expressions must
be either ISO8859-1 character expressions or UTF8 character expressions.
The result of the CONCAT function is the concatenation of
<em>character-expr-1</em> with <em>character-expr-2</em>. The result type is CHAR if
both expressions are of type CHAR and it is VARCHAR if either of the
expressions is of type VARCHAR.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="concatenation_operator">7.23.3. Concatenation Operator (||)</h4>
<div class="paragraph">
<p>The concatenation operator, denoted by two vertical bars (||),
concatenates two string values to form a new string value. To indicate
that two strings are concatenated, connect the strings with two vertical
bars (\|\|):</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">character-expr-1 || character-expr-2</code></pre>
</div>
</div>
<div class="paragraph">
<p>An operand can be any SQL value expression of data type CHAR or VARCHAR.</p>
</div>
</div>
<div class="sect3">
<h4 id="considerations_for_concat">7.23.4. Considerations for CONCAT</h4>
</div>
<div class="sect3">
<h4 id="operands">7.23.5. Operands</h4>
<div class="paragraph">
<p>A string value can be specified by any character value expression, such
as a character string literal, character string function, column
reference, aggregate function, scalar subquery, CASE expression, or CAST
expression. The value of the operand must be of type CHAR or VARCHAR.</p>
</div>
<div class="paragraph">
<p>If you use the CAST expression, you must specify the length of CHAR or
VARCHAR.</p>
</div>
</div>
<div class="sect3">
<h4 id="sql-parameters">7.23.6. SQL Parameters</h4>
<div class="paragraph">
<p>You can concatenate an SQL parameter and a character value expression.
The concatenated parameter takes on the data type attributes of the
character value expression. Consider this example, where ?p is assigned
a string value of '5 March':</p>
</div>
<div class="paragraph">
<p>?p || ' 2002'</p>
</div>
<div class="paragraph">
<p>The type assignment of the parameter ?p becomes CHAR(5), the same data
type as the character literal ' 2002'. Because you assigned a string
value of more than five characters to ?p, Trafodion SQL returns a
truncation warning, and the result of the concatenation is 5 Mar 2002.</p>
</div>
<div class="paragraph">
<p>To specify the type assignment of the parameter, use the CAST expression
on the parameter as:</p>
</div>
<div class="paragraph">
<p>CAST(?p AS CHAR(7)) || '2002'</p>
</div>
<div class="paragraph">
<p>In this example, the parameter is not truncated, and the result of the
concatenation is 5 March 2002.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_concat">7.23.7. Examples of CONCAT</h4>
<div class="ulist">
<ul>
<li>
<p>Insert information consisting of a single character string. Use the
CONCAT function to construct and insert the value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO stats.logfile (user_key, user_info)
VALUES (001, CONCAT ('Executed at ', CAST (CURRENT_TIMESTAMP AS CHAR(26))));</code></pre>
</div>
</div>
</li>
<li>
<p>Use the concatenation operator || to construct and insert the value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO stats.logfile (user_key, user_info)
VALUES (002, 'Executed at ' || CAST (CURRENT_TIMESTAMP AS CHAR(26)));</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="converttohex_function">7.24. CONVERTTOHEX Function</h3>
<div class="paragraph">
<p>The CONVERTTOHEX function converts the specified value expression to
hexadecimal for display purposes.</p>
</div>
<div class="paragraph">
<p>CONVERTTOHEX is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CONVERTTOHEX (expression)</code></pre>
</div>
</div>
<div class="paragraph">
<p><em>expression</em></p>
</div>
<div class="paragraph">
<p>is any numeric, character, datetime, or interval expression.</p>
</div>
<div class="paragraph">
<p>The primary purpose of the CONVERTTOHEX function is to eliminate any
doubt as to the exact value in a column. It is particularly useful for
character expressions where some characters may be from character sets
that are not supported by the client terminal&#8217;s locale or may be control
codes or other non-displayable characters.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_converttohex">7.24.1. Considerations for CONVERTTOHEX</h4>
<div class="paragraph">
<p>Although CONVERTTOHEX is usable on datetime and interval expressions,
the displayed output shows the internal value and is, consequently, not
particularly meaningful to general users and is subject to change in
future releases.</p>
</div>
<div class="paragraph">
<p>CONVERTTOHEX returns ASCII characters in ISO8859-1 encoding.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="examples_of_converttohex">7.24.2. Examples of CONVERTTOHEX</h4>
<div class="ulist">
<ul>
<li>
<p>Display the contents of a smallint, integer, and largeint in
hexadecimal:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE EG (S1 smallint, I1 int, L1 largeint);
INSERT INTO EG VALUES( 37, 2147483647, 2305843009213693951);
SELECT CONVERTTOHEX(S1), CONVERTTOHEX(I1), CONVERTTOHEX(L1) from EG;
(EXPR) (EXPR) EXPR)
------ -------- ----------------
0025 7FFFFFFF 1FFFFFFFFFFFFFFF</code></pre>
</div>
</div>
</li>
<li>
<p>Display the contents of a CHAR(4) column, a VARCHAR(4) column, and a
CHAR(4) column that uses the UTF8 character set. The varchar column does
not have a trailing space character as the fixed-length columns have:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE EG_CH (FC4 CHAR(4), VC4 VARCHAR(4), FC4U CHAR(4) CHARACTER SET UTF8);
INSERT INTO EG_CH values('ABC', 'abc', _UTF8'abc');
SELECT CONVERTTOHEX(FC4), CONVERTTOHEX(VC4), CONVERTTOHEX(FC4U) from EG_CH;
(EXPR) (EXPR) (EXPR)
-------- -------- ----------------
41424320 616263 0061006200630020</code></pre>
</div>
</div>
</li>
<li>
<p>Display the internal values for a DATE column, a TIME column, a
TIMESTAMP(2) column, and a TIMESTAMP(6) column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE DT (D1 date, T1 time, TS1 timestamp(2), TS2 timestamp(6) );
INSERT INTO DT values(current_date, current_time, current_timestamp, current_timestamp);
SELECT CONVERTTOHEX(D1), CONVERTTOHEX(T1), CONVERTTOHEX(TS1), CONVERTTOHEX(TS2) from DT;
(EXPR) (EXPR) (EXPR) (EXPR)
----------- --------- ------------------------- -------------------------
07D8040F 0E201E 07D8040F0E201E00000035 07D8040F0E201E00081ABB</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Display the internal values for an INTERVAL YEAR column, an INTERVAL
YEAR(2) TO MONTH column, and an INTERVAL DAY TO SECOND column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE IVT ( IV1 interval year, IV2 interval year(2) to month, IV3 interval day to second);
INSERT INTO IVT values( interval '1' year, interval '3-2' year(2) to
month, interval '31:14:59:58' day to second);
SELECT CONVERTTOHEX(IV1), CONVERTTOHEX(IV2), CONVERTTOHEX(IV3) from IVT;
(EXPR) (EXPR) (EXPR)
------ -------- -----------------------
0001 0026 0000027C2F9CB780</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="converttimestamp_function">7.25. CONVERTTIMESTAMP Function</h3>
<div class="paragraph">
<p>The CONVERTTIMESTAMP function converts a Julian timestamp to a value
with data type TIMESTAMP.</p>
</div>
<div class="paragraph">
<p>CONVERTTIMESTAMP is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CONVERTTIMESTAMP (julian-timestamp)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>julian-timestamp</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a Julian timestamp, which is a
LARGEINT value.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_converttimestamp">7.25.1. Considerations for CONVERTTIMESTAMP</h4>
<div class="paragraph">
<p>The <em>julian-timestamp</em> value must be in the range from 148731
63200000000 to 274927348799999999.</p>
</div>
<div class="sect4">
<h5 id="relationship_to_the_juliantimestamp_function">Relationship to the JULIANTIMESTAMP Function</h5>
<div class="paragraph">
<p>The operand of CONVERTTIMESTAMP is a Julian timestamp, and the function
result is a value of data type TIMESTAMP. The operand of the
CONVERTTIMESTAMP function is a value of data type TIMESTAMP, and the
function result is a Julian timestamp. That is, the two functions have
an inverse relationship to one another.</p>
</div>
</div>
<div class="sect4">
<h5 id="use_of_converttimestamp">Use of CONVERTTIMESTAMP</h5>
<div class="paragraph">
<p>You can use the inverse relationship between the JULIANTIMESTAMP and
CONVERTTIMESTAMP functions to insert Julian timestamp columns into your
database and display these column values in a TIMESTAMP format.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_converttimestamp">7.25.2. Examples of CONVERTTIMESTAMP</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that the EMPLOYEE table includes a column, named HIRE_DATE,
which contains the hire date of each employee as a Julian timestamp.
Convert the Julian timestamp into a TIMESTAMP value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CONVERTTIMESTAMP (hire_date) FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>This example illustrates the inverse relationship between
JULIANTIMESTAMP and CONVERTTIMESTAMP.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CONVERTTIMESTAMP (JULIANTIMESTAMP (ship_timestamp)) FROM persnl.project;</code></pre>
</div>
</div>
<div class="paragraph">
<p>If, for example, the value of SHIP_TIMESTAMP is 2008-04-03
21:05:36.143000, the result of CONVERTTIMESTAMP(JULIANTIMESTAMP(ship_timestamp))
is the same value, 2008-04-03 21:05:36.143000.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="cos_function">7.26. COS Function</h3>
<div class="paragraph">
<p>The COS function returns the cosine of a numeric value expression, where
the expression is an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>COS is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COS (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the COS function.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
<div class="sect3">
<h4 id="examples_of_cos">7.26.1. Examples of COS</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 9.39680940386503680E-001, or
approximately 0.9397, the cosine of 0.3491 (which is 20 degrees):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COS (0.3491)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="cosh_function">7.26.2. COSH Function</h4>
<div class="paragraph">
<p>The COSH function returns the hyperbolic cosine of a numeric value
expression, where the expression is an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>COSH is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COSH (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the COSH function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_cosh">7.26.3. Examples of COSH</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 1.88842387716101568E+000, or
approximately 1.8884, the hyperbolic cosine of 1.25 in radians:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COSH (1.25)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="count_function">7.26.4. COUNT Function</h4>
<div class="paragraph">
<p>The COUNT function counts the number of rows that result from a query or
the number of rows that contain a distinct value in a specific column.
The result of COUNT is data type LARGEINT. The result can never be NULL.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COUNT {(*) | ([ALL | DISTINCT] expression)}</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>COUNT (*)</code></p>
<div class="paragraph">
<p>returns the number of rows in the table specified in the FROM clause of
the SELECT statement that contains COUNT (*). If the result table is
empty (that is, no rows are returned by the query) COUNT (*) returns
zero.</p>
</div>
</li>
<li>
<p><code>ALL | DISTINCT</code></p>
<div class="paragraph">
<p>returns the number of all rows or the number of distinct rows in the
one-column table derived from the evaluation of <em>expression</em>. The
default option is ALL, which causes duplicate values to be included. If
you specify DISTINCT, duplicate values are eliminated before the COUNT
function is applied.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a value expression that determines the values to count. The
<em>expression</em> cannot contain an aggregate function or a subquery. The
DISTINCT clause specifies that the COUNT function operates on distinct
values from the one-column table derived from the evaluation of
<em>expression</em>. See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="considerations_for_count">7.26.5. Considerations for COUNT</h4>
<div class="sect4">
<h5 id="operands-of-the-expression-1">Operands of the Expression</h5>
<div class="paragraph">
<p>The operand of COUNT is either * or an expression that includes columns
from the result table specified by the SELECT statement that contains
COUNT. However, the expression cannot include an aggregate function or a
subquery. These expressions are valid:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COUNT (*)
COUNT (DISTINCT JOBCODE)
COUNT (UNIT_PRICE * QTY_ORDERED)</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="count_nulls">Nulls</h5>
<div class="paragraph">
<p>COUNT is evaluated after eliminating all nulls from the one-column table
specified by the operand. If the table has no rows, COUNT returns zero.</p>
</div>
<div class="paragraph">
<p>COUNT(*) does not eliminate null rows from the table specified in the
FROM clause of the SELECT statement. If all rows in a table are null,
COUNT(\*) returns the number of rows in the table.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_count">7.26.6. Examples of COUNT</h4>
<div class="ulist">
<ul>
<li>
<p>Count the number of rows in the EMPLOYEE table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT COUNT (*) FROM persnl.employee;
(EXPR)
-----------
62
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Count the number of employees who have a job code in the EMPLOYEE
table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT COUNT (jobcode) FROM persnl.employee;
(EXPR)
-----------
56
--- 1 row(s) selected.
SELECT COUNT(*)
FROM persnl.employee
WHERE jobcode IS NOT NULL;
(EXPR)
-----------
56
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Count the number of distinct departments in the EMPLOYEE table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT COUNT (DISTINCT deptnum) FROM persnl.employee;
(EXPR)
-----------
11
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div id="crc32_function" class="literalblock">
<div class="content">
<pre>== CRC32 Function</pre>
</div>
</div>
<div class="paragraph">
<p>Computes a cyclic redundancy check value and returns a 32-bit unsigned value.
The result is NULL if the argument is NULL. The argument is expected to be a
string and (if possible) is treated as one if it is not.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CRC32{ expression)}</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a value expression that determines the values to count. The
<em>expression</em> cannot contain an aggregate function or a subquery.
See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_crc32">7.26.7. examples of CR32</h4>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SELECT CRC32('Trafodion') from dual;
(EXPR)
----------
1960931967
&gt;&gt;SELECT CRC32(2016) from dual;
(EXPR)
----------
2177070256</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="current_function">7.27. CURRENT Function</h3>
<div class="paragraph">
<p>The CURRENT function returns a value of type TIMESTAMP based on the
current local date and time.</p>
</div>
<div class="paragraph">
<p>The function is evaluated once when the query starts execution and is
not reevaluated (even if it is a long running query).</p>
</div>
<div class="paragraph">
<p>You can also use <a href="#current_timestamp_function">CURRENT_TIMESTAMP Function</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CURRENT [(precision)]</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>precision</em></code></p>
<div class="paragraph">
<p>is an integer value in the range 0 to 6 that specifies the precision of
(the number of decimal places in) the fractional seconds in the returned
value. The default is 6.</p>
</div>
<div class="paragraph">
<p>For example, the function CURRENT (2) returns the current date and time
as a value of data type TIMESTAMP, where the precision of the fractional
seconds is 2, for example, 2008-06-26 09:01:20.89. The value returned is
not a string value.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_current">7.27.1. Examples of CURRENT</h4>
<div class="ulist">
<ul>
<li>
<p>The PROJECT table contains a column SHIP_TIMESTAMP of data type
TIMESTAMP. Update a row by using the CURRENT value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE persnl.project
SET ship_timestamp = CURRENT WHERE projcode = 1000;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="current_date_function">7.28. CURRENT_DATE Function</h3>
<div class="paragraph">
<p>The CURRENT_DATE function returns the local current date as a value of
type DATE.</p>
</div>
<div class="paragraph">
<p>The function is evaluated once when the query starts execution and is
not reevaluated (even if it is a long running query).</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CURRENT_DATE</code></pre>
</div>
</div>
<div class="paragraph">
<p>The CURRENT_DATE function returns the current date, such as 2008-09-28.
The value returned is a value of type DATE, not a string value.</p>
</div>
<div class="sect3">
<h4 id="examples_of_current_date">7.28.1. Examples of CURRENT_DATE</h4>
<div class="ulist">
<ul>
<li>
<p>Select rows from the ORDERS table based on the current date:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM sales.orders
WHERE deliv_date &gt;= CURRENT_DATE;</code></pre>
</div>
</div>
</li>
<li>
<p>The PROJECT table has a column EST_COMPLETE of type INTERVAL DAY. If
the current date is the start date of your project, determine the
estimated date of completion:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT projdesc, CURRENT_DATE + est_complete FROM persnl.project;
Project/Description (EXPR)
------------------- ----------
SALT LAKE CITY 2008-01-18
ROSS PRODUCTS 2008-02-02
MONTANA TOOLS 2008-03-03
AHAUS TOOL/SUPPLY 2008-03-03
THE WORKS 2008-02-02
THE WORKS 2008-02-02
--- 6 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="current_time_function">7.29. CURRENT_TIME Function</h3>
<div class="paragraph">
<p>The CURRENT_TIME function returns the current local time as a value of
type TIME.</p>
</div>
<div class="paragraph">
<p>The function is evaluated once when the query starts execution and is
not reevaluated (even if it is a long running query).</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CURRENT_TIME [(precision)]</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>precision</em></code></p>
<div class="paragraph">
<p>is an integer value in the range 0 to 6 that specifies the precision of
(the number of decimal places in) the fractional seconds in the returned
value. The default is 0.</p>
</div>
<div class="paragraph">
<p>For example, the function CURRENT_TIME (2) returns the current time as a
value of data type TIME, where the precision of the fractional seconds
is 2, for example, 14:01:59.30. The value returned is not a string
value.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_current_time">7.29.1. Examples of CURRENT_TIME</h4>
<div class="ulist">
<ul>
<li>
<p>Use CURRENT_DATE and CURRENT_TIME as a value in an inserted row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT INTO stats.logfile (user_key, run_date, run_time, user_name)
VALUES (001, CURRENT_DATE, CURRENT_TIME, 'JuBrock');</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="current_timestamp_function">7.30. CURRENT_TIMESTAMP Function</h3>
<div class="paragraph">
<p>The CURRENT_TIMESTAMP function returns a value of type TIMESTAMP based
on the current local date and time.</p>
</div>
<div class="paragraph">
<p>The function is evaluated once when the query starts execution and is
not reevaluated (even if it is a long running query).</p>
</div>
<div class="paragraph">
<p>You can also use the <a href="#current_function">CURRENT Function</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CURRENT_TIMESTAMP [(_precision_)]</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>precision</em></code></p>
<div class="paragraph">
<p>is an integer value in the range 0 to 6 that specifies the precision of
(the number of decimal places in) the fractional seconds in the returned
value. The default is 6.</p>
</div>
<div class="paragraph">
<p>For example, the function CURRENT_TIMESTAMP (2) returns the current date
and time as a value of data type TIMESTAMP, where the precision of the
fractional seconds is 2; for example, 2008-06-26 09:01:20.89. The value
returned is not a string value.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_current_timestamp">7.30.1. Examples of CURRENT_TIMESTAMP</h4>
<div class="ulist">
<ul>
<li>
<p>The PROJECT table contains a column SHIP_TIMESTAMP of data type
TIMESTAMP. Update a row by using the CURRENT_TIMESTAMP value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE persnl.project
SET ship_timestamp = CURRENT_TIMESTAMP WHERE projcode = 1000;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="current_user_function">7.31. CURRENT_USER Function</h3>
<div class="paragraph">
<p>The CURRENT_USER function returns the database user name of the current
user who invoked the function. The current user is the authenticated
user who started the session. That database user name is used for
authorization of SQL statements in the current session.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CURRENT_USER</code></pre>
</div>
</div>
<div class="paragraph">
<p>The CURRENT_USER function is similar to the <a href="#user_function">USER Function</a>.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_current_user">7.31.1. Considerations for CURRENT_USER</h4>
<div class="ulist">
<ul>
<li>
<p>This function can be specified only in the top level of a SELECT statement.</p>
</li>
<li>
<p>The value returned is string data type VARCHAR(128) and is in ISO8859-1 encoding.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_current_user">7.31.2. Examples of CURRENT_USER</h4>
<div class="ulist">
<ul>
<li>
<p>This example retrieves the database user name for the current user:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CURRENT_USER FROM (values(1)) x(a);
(EXPR)
-----------------------
TSHAW
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="date_add_function">7.32. DATE_ADD Function</h3>
<div class="paragraph">
<p>The DATE_ADD function adds the interval specified by
<em>interval_expression</em> to <em>datetime_expr</em>. If the specified interval is
in years or months, DATE_ADD normalizes the result. See
<a href="#standard_normalization">Standard Normalization</a>. The type of the
<em>datetime_expr</em> is returned, unless the <em>interval_expression</em> contains
any time components, then a timestamp is returned.</p>
</div>
<div class="paragraph">
<p>DATE_ADD is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_ADD (datetime-expr, interval-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expr</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>interval-expression</em></code></p>
<div class="paragraph">
<p>is an expression that can be combined in specific ways with addition
operators. The <em>interval_expression</em> accepts all interval expression
types that the Trafodion database software considers as valid interval
expressions. See <a href="#interval_value_expressions">Interval Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_date_add">7.32.1. Examples of DATE_ADD</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value DATE '2007-03-07'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_ADD(DATE '2007-02-28', INTERVAL '7' DAY)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '2008-03-06'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_ADD(DATE '2008-02-28', INTERVAL '7' DAY)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the timestamp '2008-03-07 00:00:00'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_ADD(timestamp'2008-02-29 00:00:00', INTERVAL '7' DAY)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the timestamp '2008-02-28 23:59:59'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_ADD(timestamp '2007-02-28 23:59:59', INTERVAL '12' MONTH)</code></pre>
</div>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
compare this example with the last example under DATE_SUB.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="date_sub_function">7.33. DATE_SUB Function</h3>
<div class="paragraph">
<p>The DATE_SUB function subtracts the specified <em>interval_expression</em> from
<em>datetime_expr</em>. If the specified interval is in years or months,
DATE_SUB normalizes the result. See <a href="#standard_normalization">Standard Normalization</a>.</p>
</div>
<div class="paragraph">
<p>The type of the <em>datetime_expr</em> is returned, unless the <em>interval_expression</em> contains
any time components, then a timestamp is returned.</p>
</div>
<div class="paragraph">
<p>DATE_SUB is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_SUB (datetime-expr, interval-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expr</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime_Value_Expression</a>.</p>
</div>
</li>
<li>
<p><code><em>interval-expression</em></code></p>
<div class="paragraph">
<p>is an expression that can be combined in specific ways with subtraction
operators. The <em>interval_expression</em> accepts all interval expression
types that the Trafodion database software considers as valid interval
expressions. see <a href="#interval_value_expressions">Interval Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_date_sub">7.33.1. Examples of DATE_SUB</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value DATE '2009-02-28'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_SUB(DATE '2009-03-07', INTERVAL'7' DAY)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '2008-02-29'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_SUB(DATE '2008-03-07', INTERVAL'7' DAY)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the timestamp '2008-02-29 00:00:00'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_SUB(timestamp '2008-03-31 00:00:00', INTERVAL '31' DAY)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the timestamp '2007-02-28 23:59:59'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_SUB(timestamp '2008-02-29 23:59:59', INTERVAL '12' MONTH)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="dateadd_function">7.34. DATEADD Function</h3>
<div class="paragraph">
<p>The DATEADD function adds the interval of time specified by <em>datepart</em>
and <em>num-expr</em> to <em>datetime-expr</em>. If the specified interval is in
years or months, DATEADD normalizes the result. See
<a href="#standard_normalization">Standard Normalization</a>. The type of the
<em>datetime-expr</em> is returned, unless the interval expression contains any
time components, then a timestamp is returned.</p>
</div>
<div class="paragraph">
<p>DATEADD is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEADD(datepart, num-expr, datetime-expr)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datepart</em></code></p>
<div class="paragraph">
<p>is YEAR, MONTH, DAY, HOUR, MINUTE, SECOND, QUARTER, WEEK, or one of the
following abbreviations:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 15%;">
<col style="width: 85%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">YEAR</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>YY</em> and <em>YYYY</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MONTH</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>M</em> and <em>MM</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DAY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>D</em> and <em>DD</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">HOUR</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>HH</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MINUTE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>MI</em> and <em>M</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SECOND</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>SS</em> and <em>S</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">QUARTER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>Q</em> and <em>QQ</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">WEEK</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>WW</em> and <em>WK</em></p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p><code><em>num-expr</em></code></p>
<div class="paragraph">
<p>is an SQL exact numeric value expression that specifies how many
<em>datepart</em> units of time are to be added to <em>datetime_expr</em>. If
<em>num_expr</em> has a fractional portion, it is ignored. If <em>num_expr</em> is
negative, the return value precedes <em>datetime_expr</em> by the specified
amount of time. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>datetime-expr</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. The type of the <em>datetime_expression</em> is returned, unless the
interval expression contains any time components, then a timestamp is
returned. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_dateadd">7.34.1. Examples of DATEADD</h4>
<div class="ulist">
<ul>
<li>
<p>This function adds seven days to the date specified in <em>start_date</em></p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEADD(DAY, 7,start_date)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '2009-03-07'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEADD(DAY, 7 , DATE '2009-02-28')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '2008-03-06'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEADD(DAY, 7, DATE '2008-02-28')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the timestamp '2008-03-07 00:00:00'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEADD(DAY, 7, timestamp'2008-02-29 00:00:00')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="datediff_function">7.35. DATEDIFF Function</h3>
<div class="paragraph">
<p>The DATEDIFF function returns the integer value for the number of
<em>datepart</em> units of time between <em>startdate</em> and <em>enddate</em>. If
<em>enddate</em> precedes <em>startdate</em>, the return value is negative or zero.</p>
</div>
<div class="paragraph">
<p>DATEDIFF is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEDIFF (datepart, startdate, enddate)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>datepart</code></p>
<div class="paragraph">
<p>is YEAR, MONTH, DAY, HOUR, MINUTE, SECOND, QUARTER, WEEK, or one of the
following abbreviations:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 15%;">
<col style="width: 85%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">YEAR</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>YY</em> and <em>YYYY</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MONTH</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>M</em> and <em>MM</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">DAY</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>D</em> and <em>DD</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">HOUR</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>HH</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">MINUTE</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>MI</em> and <em>M</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SECOND</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>SS</em> and <em>S</em></p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">QUARTER</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>Q</em> and QQ</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">WEEK</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock"><em>WW</em> and <em>WK</em></p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p><code>startdate</code></p>
<div class="paragraph">
<p>may be of type DATE or TIMESTAMP.
See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code>enddate</code></p>
<div class="paragraph">
<p>may be of type DATE or TIMESTAMP.
See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The method of counting crossed boundaries such as days, minutes, and
seconds makes the result given by DATEDIFF consistent across all data
types. The result is a signed integer value equal to the number of
datepart boundaries crossed between the first and second date.</p>
</div>
<div class="paragraph">
<p>For example, the number of weeks between Sunday, January 4, and Sunday,
January 1 , is 1. The number of months between March 31 and April 1
would be 1 because the month boundary is crossed from March to April.
The DATEDIFF function generates an error if the result is out of range
for integer values. For seconds, the maximum number is equivalent to
approximately 68 years. The DATEDIFF function generates an error if a
difference in weeks is requested and one of the two dates precedes
January 7 of the year 0001.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_datediff">7.35.1. Examples of DATEDIFF</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value of 0 because no one-second boundaries
are crossed.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEDIFF( SECOND
, TIMESTAMP '2006-09-12 11:59:58.999998'
, TIMESTAMP '2006-09-12 11:59:58.999999'
)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 1 because a one-second boundary is
crossed even though the two timestamps differ by only one microsecond.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEDIFF( SECOND
, TIMESTAMP '2006-09-12 11:59:58.999999'
, TIMESTAMP '2006-09-12 11:59:59.000000'
)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 0.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEDIFF( YEAR
, TIMESTAMP '2006-12-31 23:59:59.999998'
, TIMESTAMP '2006-12-31 23:59:59.999999'
)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 1 because a year boundary is
crossed.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEDIFF( YEAR
, TIMESTAMP '2006-12-31 23:59:59.999999'
, TIMESTAMP '2007-01-01 00:00:00.000000'
)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 2 because two WEEK boundaries are
crossed.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEDIFF(WEEK, DATE '2006-01-01', DATE '2006-01-09')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of -29.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEDIFF(DAY, DATE '2008-03-01', DATE '2008-02-01')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="dateformat_function">7.35.2. DATEFORMAT Function</h4>
<div class="paragraph">
<p>The DATEFORMAT function returns a datetime value as a character string
literal in the DEFAULT, USA, or EUROPEAN format. The data type of the
result is CHAR.</p>
</div>
<div class="paragraph">
<p>DATEFORMAT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEFORMAT (datetime-expression,{DEFAULT | USA | EUROPEAN})</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE, TIME,
or TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code>DEFAULT | USA | EUROPEAN</code></p>
<div class="paragraph">
<p>specifies a format for a datetime value. See <a href="#datetime_literals">Datetime Literals</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="considerations_for_dateformat">7.35.3. Considerations for DATEFORMAT</h4>
<div class="paragraph">
<p>The DATEFORMAT function returns the datetime value in ISO8859-1
encoding.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_dateformat">7.35.4. Examples of DATEFORMAT</h4>
<div class="ulist">
<ul>
<li>
<p>Convert a datetime literal in DEFAULT format to a string in USA
format: DATEFORMAT (TIMESTAMP '2008-06-20 14:20:20.00', USA) The
function returns this string literal:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">'06/20/2008 02:20:20.00 PM'</code></pre>
</div>
</div>
</li>
<li>
<p>Convert a datetime literal in DEFAULT format to a string in European
format: DATEFORMAT (TIMESTAMP '2008-06-20 14:20:20.00', EUROPEAN) The
function returns this string literal:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">'20.06.2008 14.20.20.00'</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="date_part_function_of_an_interval">7.36. DATE_PART Function (of an Interval)</h3>
<div class="paragraph">
<p>The DATE_PART function extracts the datetime field specified by <em>text</em>
from the <em>interval</em> value specified by <em>interval</em> and returns the result
as an exact numeric value. The DATE_PART function accepts the
specification of 'YEAR', 'MONTH', 'DAY', 'HOUR', 'MINUTE', or 'SECOND'
for text.</p>
</div>
<div class="paragraph">
<p>DATE_PART is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEPART (text, interval)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>text</em></code></p>
<div class="paragraph">
<p>specifies YEAR, MONTH, DAY, HOUR, MINUTE, or SECOND. The value must be
enclosed in single quotes.</p>
</div>
</li>
<li>
<p><code><em>interval</em></code></p>
<div class="paragraph">
<p><em>interval</em> accepts all interval expression types that the Trafodion
database software considers as valid interval expressions. See
<a href="#interval_value_expressions">Interval Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The DATE_PART(<em>text</em>, <em>interval</em>) is equivalent to EXTRACT(<em>text</em>,
<em>interval</em>), except that the DATE_PART function requires single quotes
around the text specification, where EXTRACT does not allow single
quotes.</p>
</div>
<div class="paragraph">
<p>When SECOND is specified the fractional part of the second is returned.</p>
</div>
<div class="sect3">
<h4 id="examples_of_date_part">7.36.1. Examples of DATE_PART</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value of 7.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_PART('DAY', INTERVAL '07:04' DAY TO HOUR)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 6.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_PART('MONTH', INTERVAL '6' MONTH)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 36.33.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_PART('SECOND', INTERVAL '5:2:15:36.33' DAY TO SECOND(2))</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="date_part_function_of_a_timestamp">7.37. DATE_PART Function (of a Timestamp)</h3>
<div class="paragraph">
<p>The DATE_PART function extracts the datetime field specified by <em>text</em>
from the datetime value specified by <em>datetime_expr</em> and returns the
result as an exact numeric value. The DATE_PART function accepts the
specification of 'YEAR', 'YEARQUARTER', 'YEARMONTH', 'YEARWEEK',
'MONTH', 'DAY', 'HOUR', 'MINUTE', or 'SECOND' for text.</p>
</div>
<div class="paragraph">
<p>The DATE_PART function of a timestamp can be changed to DATE_PART
function of a datetime because the second argument can be either a
timestamp or a date expression.</p>
</div>
<div class="paragraph">
<p>DATE_PART is a Trafodion extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATEPART(text, datetime-expr)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>text</em></code></p>
<div class="paragraph">
<p>specifies YEAR, YEARQUARTER, YEARMONTH, YEARWEEK, MONTH, DAY, HOUR,
MINUTE, or SECOND. The value must be enclosed in single quotes.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><strong>YEARMONTH</strong>: Extracts the year and the month, as a 6-digit integer of
the form yyyymm (100 \* year + month).</p>
</li>
<li>
<p><strong>YEARQUARTER</strong>: Extracts the year and quarter, as a 5-digit integer of
the form yyyyq, (10 \* year + quarter) with q being 1 for the first
quarter, 2 for the second, and so on.</p>
</li>
<li>
<p><strong>YEARWEEK</strong>: Extracts the year and week of the year, as a 6-digit integer
of the form yyyyww (100 \* year + week). The week number will be computed
in the same way as in the WEEK function.</p>
</li>
</ul>
</div>
</li>
<li>
<p><code><em>datetime-expr</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>DATE_PART(<em>text</em>, <em>datetime-expr</em>) is mostly equivalent to
EXTRACT(<em>text</em>, <em>datetime-expr</em>), except that DATE_PART requires
single quotes around the text specification where EXTRACT does not allow
single quotes. In addition, you cannot use the YEARQUARTER, YEARMONTH,
and YEARWEEK text specification with EXTRACT.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_date_part">7.37.1. Examples of DATE_PART</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value of 12.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_PART('month', date'12/05/2006')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 2006.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_PART('year', date'12/05/2006')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 31.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_PART('day', TIMESTAMP '2006-12-31 11:59:59.999999')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 201 07.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_PART('YEARMONTH', date '2011-07-25')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="date_trunc_function">7.38. DATE_TRUNC Function</h3>
<div class="paragraph">
<p>The DATE_TRUNC function returns a value of type TIMESTAMP, which has all
fields of lesser precision than <em>text</em> set to zero (or 1 in the case of
months or days).</p>
</div>
<div class="paragraph">
<p>DATE_TRUNC is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_TRUNC(text, datetime-expr)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>text</em></code></p>
<div class="paragraph">
<p>specifies 'YEAR', 'MONTH', 'DAY', 'HOUR', 'MINUTE', or 'SECOND'. The
DATE_TRUNC function also accepts the specification of 'CENTURY' or 'DECADE'.</p>
</div>
</li>
<li>
<p><code><em>datetime_expr</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. DATE_TRUNC returns a value of type TIMESTAMP which has all
fields of lesser precision than <em>text</em> set to zero (or 1 in the case of
months or days). See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_date_trunc">7.38.1. Examples of DATE_TRUNC</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value of TIMESTAMP '2006-12-31 00:00:00'.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_TRUNC('day', TIMESTAMP '2006-12-31 11:59:59')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of TIMESTAMP '2006-01-01 00:00:00'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_TRUNC('YEAR', TIMESTAMP '2006-12-31 11:59:59')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of TIMESTAMP '2006-12-01 00:00:00'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DATE_TRUNC('MONTH', DATE '2006-12-31')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Restrictions:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>DATE_TRUNC( 'DECADE', &#8230;) cannot be used on years less than 10.</p>
</li>
<li>
<p>DATE_TRUNC( 'CENTURY', &#8230;) cannot be used on years less than 100.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="day_function">7.39. DAY Function</h3>
<div class="paragraph">
<p>The DAY function converts a DATE or TIMESTAMP expression into an INTEGER
value in the range 1 through 31 that represents the corresponding day of
the month. The result returned by the DAY function is equal to the
result returned by the DAYOFMONTH function.</p>
</div>
<div class="paragraph">
<p>DAY is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DAY (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_day">7.39.1. Examples of Day</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the day of the month from the
start date column of the project table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, DAY(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ------
2008-04-10 2008-04-21 08:15:00.000000 10</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="dayname_function">7.40. DAYNAME Function</h3>
<div class="paragraph">
<p>The DAYNAME function converts a DATE or TIMESTAMP expression into a
character literal that is the name of the day of the week (Sunday,
Monday, and so on).</p>
</div>
<div class="paragraph">
<p>DAYNAME is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DAYNAME (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_dayname">7.40.1. Considerations for DAYNAME</h4>
<div class="paragraph">
<p>The DAYNAME function returns the name of the day in ISO8859-1.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_dayname">7.40.2. Examples of DAYNAME</h4>
<div class="paragraph">
<p>Return the name of the day of the week from the start date column in the
project table:</p>
</div>
<div class="paragraph">
<p>+</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, DAYNAME(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ---------
2008-04-10 2008-04-21 08:15:00.000000 Thursday</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="dayofmonth_function">7.41. DAYOFMONTH Function</h3>
<div class="paragraph">
<p>The DAYOFMONTH function converts a DATE or TIMESTAMP expression into an
INTEGER value in the range 1 through 31 that represents the
corresponding day of the month. The result returned by the DAYOFMONTH
function is equal to the result returned by the DAY function.</p>
</div>
<div class="paragraph">
<p>DAYOFMONTH is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DAYOFMONTH (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_dayofmonth">7.41.1. Examples of DAYOFMONTH</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the day of the month from the
start date column of the project table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, DAYOFMONTH(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ------
2008-04-10 2008-04-21 08:15:00.000000 10</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="dayofweek_function">7.42. DAYOFWEEK Function</h3>
<div class="paragraph">
<p>The DAYOFWEEK function converts a DATE or TIMESTAMP expression into an
INTEGER value in the range 1 through 7 that represents the corresponding
day of the week. The value 1 represents Sunday, 2 represents Monday, and
so forth.</p>
</div>
<div class="paragraph">
<p>DAYOFWEEK is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DAYOFWEEK (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_dayofweek">7.42.1. Examples of DAYOFWEEK</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the day of the week from the
START_DATE column in the PROJECT table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, DAYOFWEEK(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ------
2008-04-10 2008-04-21 08:15:00.000000 5</code></pre>
</div>
</div>
<div class="paragraph">
<p>The value returned is 5, representing Thursday. The week begins on Sunday.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="dayofyear_function">7.43. DAYOFYEAR Function</h3>
<div class="paragraph">
<p>The DAYOFYEAR function converts a DATE or TIMESTAMP expression into an
INTEGER value in the range 1 through 366 that represents the
corresponding day of the year.</p>
</div>
<div class="paragraph">
<p>DAYOFYEAR is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DAYOFYEAR (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_dayofyear">7.43.1. Examples of DAYOFYEAR</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the day of the year from the
start date column in the project table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, DAYOFYEAR(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- --------------------
2008-04-10 2008-04-21 08:15:00.000000 |101</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="Decode_function">7.44. DECODE Function</h3>
<div class="paragraph">
<p>The DECODE function compares <em>expr</em> to each <em>test_expr</em> value one by one
in the order provided. If <em>expr</em> is equal to a <em>test_expr</em>, then the
corresponding <em>retval</em> is returned. If no match is found, <em>default</em> is
returned. If no match is found and <em>default</em> is omitted, NULL is
returned.</p>
</div>
<div class="paragraph">
<p>DECODE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DECODE (expr, test-expr, retval [, test-expr2, retval2 ... ] [ , default ] )</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expr</em></code></p>
<div class="paragraph">
<p>is an SQL expression.</p>
</div>
</li>
<li>
<p><code><em>test-expr</em>, <em>test-expr</em>, &#8230;</code></p>
<div class="paragraph">
<p>are each an SQL expression of a type comparable to that of <em>expr</em>.</p>
</div>
</li>
<li>
<p><code><em>retval</em></code></p>
<div class="paragraph">
<p>is an SQL expression.</p>
</div>
</li>
<li>
<p><code><em>default</em>, <em>retval2</em>, &amp;#8230</code></p>
<div class="paragraph">
<p>are each an SQL expression of a type comparable to that of <em>retval</em>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_decode">7.44.1. Considerations for DECODE</h4>
<div class="paragraph">
<p>In a DECODE function, two nulls are considered to be equivalent. If
<em>expr</em> is null, then the returned value is the <em>retval</em> of the first
<em>test-expr</em> that is also null.</p>
</div>
<div class="paragraph">
<p>The <em>expr</em>, <em>test-expr</em>, <em>retval</em>, and <em>default</em> values can be
derived from expressions.</p>
</div>
<div class="paragraph">
<p>The arguments can be any of the numeric types or character types.
However, <em>expr</em> and each <em>test-expr</em> value must be of comparable types.
If <em>expr</em> and <em>test-expr</em> values are character types, they must be in
the same character set (to be comparable types.)</p>
</div>
<div class="paragraph">
<p>All the <em>retval</em> values and the <em>default</em> value, if any, must be of
comparable types.</p>
</div>
<div class="paragraph">
<p>If <em>expr</em> and a <em>test-expr</em> value are character data, the comparison is
made using non-padded comparison semantics.</p>
</div>
<div class="paragraph">
<p>If <em>expr</em> and a <em>test-expr</em> value are numeric data, the comparison is
made with a temporary copy of one of the numbers, according to defined
rules of conversion. For example, if one number is INTEGER and the other
is DECIMAL, the comparison is made with a temporary copy of the integer
converted to a decimal.</p>
</div>
<div class="paragraph">
<p>If all the possible return values are of fixed-length character types,
the returned value is a fixed-length character string with size equal to
the maximum size of all the possible return value types.</p>
</div>
<div class="paragraph">
<p>If any of the possible return values is a variable-length character
type, the returned value is a variable-length character string with
maximum size of all the possible return value types.</p>
</div>
<div class="paragraph">
<p>If all the possible return values are of integer types, the returned
value is the same type as the largest integer type of all the possible
return values.</p>
</div>
<div class="paragraph">
<p>If the returned value is of type FLOAT, the precision is the maximum
precision of all the possible return values.</p>
</div>
<div class="paragraph">
<p>If all the possible returned values are of the same non-integer, numeric
type (REAL, FLOAT, DOUBLE PRECISION, NUMERIC, or DECIMAL), the returned
value is of that same type.</p>
</div>
<div class="paragraph">
<p>If all the possible return values are of numeric types but not all the
same, and at least one is REAL, FLOAT, or DOUBLE PRECISION, then the
returned value is of type DOUBLE PRECISION.</p>
</div>
<div class="paragraph">
<p>If all the possible return values are of numeric types but not all the
same, none are REAL, FLOAT, or DOUBLE PRECISION, and at least one is of
type NUMERIC, then the returned value is of type NUMERIC.</p>
</div>
<div class="paragraph">
<p>If all the possible return values are of numeric types, none are
NUMERIC, REAL, FLOAT, or DOUBLE PRECISION, and at least one is of type
DECIMAL, then the returned value will be of type DECIMAL.</p>
</div>
<div class="paragraph">
<p>If the returned value is of type NUMERIC or DECIMAL, it has a precision
equal to the sum of:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The maximum scale of all the possible return value types and</p>
</li>
<li>
<p>The maximum value of (precision - scale) for all the possible return value types.
However, the precision will not exceed 18.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>The scale of the returned value is the minimum of:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The maximum scale of all the possible return value types and</p>
</li>
<li>
<p>18 - (the maximum value of (precision - scale) for all the possible
return value types).</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>The number of components in the DECODE function, including <em>expr</em>,
<em>test-exprs</em>, <em>retvals</em>, and <em>default</em>, has no limit other than
the general limit of how big an SQL expression can be. However, large
lists do not perform well.</p>
</div>
<div class="paragraph">
<p>The syntax</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DECODE (expr, test_expr, retval [, test_expr2, retval2 ... ] [, default ] ):</code></pre>
</div>
</div>
<div class="paragraph">
<p>is logically equivalent to the following:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CASE
WHEN (expr IS NULL AND test-expr IS NULL) OR expr = test-expr THEN retval
WHEN (expr IS NULL AND test-expr2 IS NULL) OR expr = test_expr2 THEN retval2
...
ELSE default /* or ELSE NULL if _default_ not specified */
END</code></pre>
</div>
</div>
<div class="paragraph">
<p>No special conversion of <em>expr</em>, <em>test-exprN</em>, or <em>retvalN</em> exist
other than what a CASE statement normally does.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="_examples_of_decode">7.44.2. Examples of DECODE</h4>
<div class="ulist">
<ul>
<li>
<p>Example of the DECODE function:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
emp_name
, DECODE( CAST (( yrs_of_service + 3) / 4 AS INT )
, 0,0.04
, 1,0.04
, 0.06
) as perc_value
FROM employees;
SELECT
supplier_name
, DECODE( supplier_id
, 10000
, 'Company A'
, 10001
, 'Company B'
, 10002
, 'Company C'
, 'Company D'
) as result
FROM suppliers;</code></pre>
</div>
</div>
</li>
<li>
<p>This example shows a different way of handling NULL specified as
default and not specified as default explicitly:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT DECODE( (?p1 || ?p2), trim(?p1), 'Hi', ?p3, null ) from emp;
..
*** ERROR[4049] A CASE expression cannot have a result data type of both CHAR(2) and NUMERIC(18,6).
*** ERROR[4062] The preceding error actually occurred in function DECODE((?P1 || ?P2),(' ' TRIM ?P1), 'Hi', ?P3, NULL)
*** ERROR[8822] The statement was not prepared.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The last <em>ret-val</em> is an explicit NULL. When Trafodion SQL encounters
this situation, it assumes that the return value will be NUMERIC(18,6).
Once Trafodion SQL determines that the return values are numeric, it
determines that all possible return values must be numeric. When 'Hi' is
encountered in a <em>ret-val</em> position, the error is produced because the
CHAR(2) type argument is not comparable with a NUMERIC(18,6) type return
value.</p>
</div>
<div class="paragraph">
<p>This statement is equivalent and will not produce an error:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT DECODE( (?p1 || ?p2), trim(?p1), 'Hi' ) from emp;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="degrees_function">7.45. DEGREES Function</h3>
<div class="paragraph">
<p>The DEGREES function converts a numeric value expression expressed in
radians to the number of degrees.</p>
</div>
<div class="paragraph">
<p>DEGREES is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DEGREES (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the DEGREES function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_degrees">7.45.1. Examples of Degrees</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 45.0001059971939008 in degrees:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DEGREES(0.78540)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 45. The function degrees is the
inverse of the function radians.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DEGREES(RADIANS(45))</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="diff1_function">7.46. DIFF1 Function</h3>
<div class="paragraph">
<p>The DIFF1 function is a sequence function that calculates the amount of
change in an expression from row to row in an intermediate result table
ordered by a sequence by clause in a select statement.
See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>DIFF1 is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DIFF1 (column-expression-a [,column-expression-b])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression-a</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression. If you specify only one column as an argument, DIFF1 returns
the difference between the value of the column in the current row and
its value in the previous row; this version calculates the unit change
in the value from row to row.</p>
</div>
</li>
<li>
<p><code><em>column-expression-b</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression. If you specify two columns as arguments, DIFF1 returns the
difference in consecutive values in <em>column-expression-a</em> divided by
the difference in consecutive values in <em>column-expression-b</em>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The purpose of the second argument is to distribute the amount of change
from row to row evenly over some unit of change (usually time) in
another column.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_diff1">7.46.1. Considerations for DIFF1</h4>
<div class="sect4">
<h5 id="equivalent-result">Equivalent Result</h5>
<div class="paragraph">
<p>If you specify one argument, the result of DIFF1 is equivalent to:
column-expression-a - OFFSET(column-expression-a, 1) If you specify two
arguments, the result of DIFF1 is equivalent to:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DIFF1(column-expression-a) / DIFF1(column-expression-b)</code></pre>
</div>
</div>
<div class="paragraph">
<p>The two-argument version involves division by the result of the DIFF1
function. To avoid divide-by-zero errors, be sure that
<em>column-expression-b</em> does not contain any duplicate values whose DIFF1
computation could result in a divisor of zero.</p>
</div>
</div>
<div class="sect4">
<h5 id="datetime-arguments">Datetime Arguments</h5>
<div class="paragraph">
<p>In general, Trafodion SQL does not allow division by a value of INTERVAL
data type. However, to permit use of the two-argument version of DIFF1
with times and dates, Trafodion SQL relaxes this restriction and allows
division by a value of INTERVAL data type.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_diff1">7.46.2. Examples of DIFF1</h4>
<div class="ulist">
<ul>
<li>
<p>Retrieve the difference between the I1 column in the current row and
the I1 column in the previous row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT DIFF1 (I1) AS DIFF1_I1
FROM mining.seqfcn SEQUENCE BY TS;
DIFF1_I1
------------
?
21959
-9116
-14461
7369
--- 5 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The first row retrieved displays null because the offset from the
current row does not fall within the results set.</p>
</div>
</li>
<li>
<p>Retrieve the difference between the TS column in the current row and
the TS column in the previous row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT DIFF1 (TS) AS DIFF1_TS
FROM mining.seqfcn SEQUENCE BY TS;
DIFF1_TS
--------------------
?
30002620.000000
134157861.000000
168588029.000000
114055223.000000
--- 5 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The results are expressed as the number of seconds. For example, the
difference between TIMESTAMP '1951-02-15 14:35:49' and TIMESTAMP
'1950-03-05 08:32:09' is approximately 347 days. The difference between
TIMESTAMP '1955-05-18 08:40:10' and TIMESTAMP '1951-02-15 14:35:49' is
approximately 4 years and 3 months, and so on.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This query retrieves the difference in consecutive values in I1
divided by the difference in consecutive values in TS:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT DIFF1 (I1,TS) AS DIFF1_I1TS
FROM mining.seqfcn SEQUENCE BY TS;
DIFF1_I1TS
-------------------
?
.0007319
-.0000679
-.0000857
.0000646
--- 5 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The results are equivalent to the quotient of the results from the two
preceding examples. For example, in the second row of the output of this
example, 0.0007319 is equal to 21959 divided by 30002620.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="diff2_function">7.47. DIFF2 Function</h3>
<div class="paragraph">
<p>The DIFF2 function is a sequence function that calculates the amount of
change in a DIFF1 value from row to row in an intermediate result table
ordered by a SEQUENCE BY clause in a SELECT statement. See
<a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>DIFF2 is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DIFF2 (column-expression-a [,column-expression-b])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression-a</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression. If you specify only one column as an argument, DIFF2 returns
the difference between the value of DIFF1(<em>column-expression-a</em>) in
the current row and the same result in the previous row.</p>
</div>
</li>
<li>
<p><code><em>column-expression-b</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression. If you specify two columns as arguments, DIFF2 returns the
difference in consecutive values of DIFF1(<em>column-expression-a</em>)
divided by the difference in consecutive values in
<em>column-expression-b</em>.
See <a href="#diff1_function">DIFF1 Function</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_diff2">7.47.1. Considerations for DIFF2</h4>
<div class="sect4">
<h5 id="equivalent_result_1">Equivalent Result</h5>
<div class="ulist">
<ul>
<li>
<p>If you specify one argument, the result of DIFF2 is equivalent to:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DIFF1(column-expression-a)- OFFSET(DIFF1(column-expression-a),1)</code></pre>
</div>
</div>
</li>
<li>
<p>If you specify two arguments, the result of DIFF2 is equivalent to:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DIFF2(column-expression-a) / DIFF1(column-expression-b)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The two-argument version involves division by the result of the DIFF1
function. To avoid divide-by-zero errors, be sure that
<em>column-expression-b</em> does not contain any duplicate values whose DIFF1
computation could result in a divisor of zero.</p>
</div>
</div>
<div class="sect4">
<h5 id="datetime_arguments">Datetime Arguments</h5>
<div class="paragraph">
<p>In general, Trafodion SQL does not allow division by a value of INTERVAL
data type. However, to permit use of the two-argument version of DIFF2
with times and dates, Trafodion SQL relaxes this restriction and allows
division by a value of INTERVAL data type.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_diff2">7.47.2. Examples of DIFF2</h4>
<div class="ulist">
<ul>
<li>
<p>Retrieve the difference between the value of DIFF1(I1) in the current
row and the same result in the previous row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT DIFF2 (I1) AS DIFF2_I1
FROM mining.seqfcn SEQUENCE BY TS;
DIFF2_I1
--------------------
?
?
-31075
-5345
21830
--- 5 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The results are equal to the difference of DIFF1(I1) for the current row
and DIFF1(I1) of the previous row. For example, in the third row of the
output of this example, -31075 is equal to
-91 6 minus 21959. The value -91 6 is the result of DIFF1(I1) for the
current row, and the
value 21959 is the result of DIFF1(I1) for the previous row.
See <a href="#examples_of_diff1">Examples of DIFF1</a>.</p>
</div>
</li>
<li>
<p>Retrieve the difference in consecutive values of DIFF1(I1) divided by
the difference in consecutive values of TS:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT DIFF2 (I1,TS) AS DIFF2_I1TS
FROM mining.seqfcn SEQUENCE BY TS;
DIFF2_I1TS
---------------------
?
?
-.000231
-.000031
.000191
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="exp_function">7.48. EXP Function</h3>
<div class="paragraph">
<p>This function returns the exponential value (to the base e) of a numeric
value expression. EXP is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXP (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the EXP function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The minimum input value must be between -744.4400719 and -744.4400720.</p>
</div>
<div class="paragraph">
<p>The maximum input value must be between 709.78271289338404 and
709.78271289338405.</p>
</div>
<div class="sect3">
<h4 id="examples_of_exp">7.48.1. Examples of EXP</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 3.49034295746184128E+000, or
approximately 3.4903:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXP (1.25)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 2.0. The function EXP is the inverse
of the function LOG:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXP (LOG(2.0))</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="explain_function">7.49. EXPLAIN Function</h3>
<div class="paragraph">
<p>The EXPLAIN function is a table-valued stored function that generates a
result table describing an access plan for a SELECT, INSERT, DELETE, or
UPDATE statement.
See <a href="#result_of_the_explain_function">Result of the EXPLAIN Function</a>.</p>
</div>
<div class="paragraph">
<p>The EXPLAIN function can be specified as a table reference (<em>table</em>)
in the FROM clause of a SELECT statement if it is preceded by the
keyword TABLE and surrounded by parentheses.</p>
</div>
<div class="paragraph">
<p>For information on the EXPLAIN statement,
see <a href="#explain_statement">EXPLAIN Statement</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXPLAIN (module,'statement-pattern')</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>module</em> is:</code></p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">'module-name' | NULL</code></pre>
</div>
</div>
</li>
<li>
<p><code>'<em>module-name</em>'</code></p>
<div class="paragraph">
<p>Reserved for future use.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The module name is enclosed in single quotes and is case-sensitive. If a
module name is uppercase, the value you specify within single quotes
must be uppercase. For example: 'MYCAT.MYSCH.MYPROG'</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code>NULL</code></p>
<div class="paragraph">
<p>explains statements prepared in the session. '<em>statement-pattern</em>'</p>
</div>
<div class="paragraph">
<p>A statement pattern is enclosed in single quotes and is case-sensitive.
The statement name must be in uppercase, unless you delimit the statement
name in a PREPARE statement.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_explain_function">7.49.1. Considerations for EXPLAIN Function</h4>
<div class="sect4">
<h5 id="using_a_statement_pattern">Using a Statement Pattern</h5>
<div class="paragraph">
<p>Using a statement pattern is analogous to using a LIKE pattern. You can
use the LIKE pattern in the following ways:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM table (EXPLAIN(NULL,'S%'));
SELECT * FROM table (EXPLAIN(NULL,'S1'));
SELECT * FROM table (EXPLAIN(NULL,'%1'));</code></pre>
</div>
</div>
<div class="paragraph">
<p>However, you cannot use the LIKE pattern in this way:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM table (EXPLAIN (NULL, '%'))</code></pre>
</div>
</div>
<div class="paragraph">
<p>This statement returns the EXPLAIN result for all prepared statements
whose names begin with the uppercase letter 'S':</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM table (EXPLAIN (NULL,'S%'))</code></pre>
</div>
</div>
<div class="paragraph">
<p>If the statement pattern does not find any matching statement names, no
rows are returned as the result of the SELECT statement.</p>
</div>
</div>
<div class="sect4">
<h5 id="obtaining_an_explain_plan_while_queries_are_running">Obtaining an EXPLAIN Plan While Queries Are Running</h5>
<div class="paragraph">
<p>Trafodion SQL provides the ability to capture an EXPLAIN plan for a
query at any time while the query is running with the QID option. By
default, this behavior is disabled for a Trafodion session.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
Enable this feature before you start preparing and executing
queries.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>After this feature is enabled, use the following syntax in an EXPLAIN
function to get the query execution plan of a running query:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM table (EXPLAIN(NULL, 'QID=_qid_'))</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>qid</em></code> is a case-sensitive identifier, which represents the query ID. For
example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">'QID=MXID01001011194212103659400053369000000085905admin00_2605_S1'</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The EXPLAIN function or statement returns the plan that was generated
when the query was prepared. EXPLAIN for QID retrieves all the
information from the original plan of the executing query. The plan is
available until the query finishes executing and is removed or
deallocated.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect4">
<h5 id="result_of_the_explain_function">Result of the EXPLAIN Function</h5>
<div class="paragraph">
<p>The result table of the EXPLAIN function describes the access plans for
SELECT, INSERT, DELETE, or UPDATE statements.</p>
</div>
<div class="paragraph">
<p>In this description of the result of the EXPLAIN function, an operator
tree is a structure that represents operators used in an access plan as
nodes, with at most one parent node for each node in the tree, and with
only one root node.</p>
</div>
<div class="paragraph">
<p>A node of an operator tree is a point in the tree that represents an
event (involving an operator) in a plan. Each node might have
subordinate nodes &#8212; that is, each event might generate a subordinate event
or events in the plan.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 30%;">
<col style="width: 30%;">
<col style="width: 40%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Column Name</th>
<th class="tableblock halign-left valign-top">Data Type</th>
<th class="tableblock halign-left valign-top">Description</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MODULE_NAME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHAR(60)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Reserved for future use.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>STATEMENT_ NAME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHAR(60)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Statement name; truncated on the right if longer than 60 characters.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PLAN_ID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LARGEINT</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unique system-generated plan ID automatically assigned by Trafodion SQL;
generated at compile time.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SEQ_NUM</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INT</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Sequence number of the current operator in the operator tree; indicates
the sequence in which the operator tree is generated.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OPERATOR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHAR(30)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Current operator type.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LEFT_CHILD_ SEQ_NUM</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INT</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Sequence number for the first child operator of the current operator;
null if node has no child operators.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RIGHT_CHILD_ SEQ_NUM</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INT</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Sequence number for the second child operator of the current operator;
null if node does not have a second child.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TNAME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHAR(60)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">For operators in scan group, full name of base table, truncated on the
right if too long for column. If correlation name differs from table
name, simple correlation name first and then table name in parentheses.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CARDINALITY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REAL</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Estimated number of rows that will be returned by the current operator.
Cardinality appears as ROWS/REQUEST in some forms of EXPLAIN output. For
the right child of a nested join, multiply the cardinality by the number
of requests to get the total number of rows produced by this operator.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OPERATOR_COST</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REAL</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Estimated cost associated with the current operator to execute the
operator.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TOTAL_COST</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REAL</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Estimated cost associated with the current operator to execute the
operator, including the cost of all subtrees in the operator tree.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DETAIL_COST</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VARCHAR (200)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Cost vector of five items, described in the next table.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DESCRIPTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VARCHAR (3000)</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Additional information about the operator.</p></td>
</tr>
</tbody>
</table>
<div class="paragraph">
<p>The DETAIL_COST column of the EXPLAIN function results contains these
cost factors:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 80%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CPU_TIME</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">An estimate of the number of seconds of processor time it might take to
execute the instructions for this operator. A value of 1.0 is 1 second.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>IO_TIME</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">An estimate of the number of seconds of I/O time (seeks plus data
transfer) to perform the I/O for this operator.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MSG_TIME</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">An estimate of the number of seconds it takes for the messaging for this
operator. The estimate includes the time for the number of local and
remote messages and the amount of data sent.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>IDLETIME</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">An estimate of the number of seconds to wait for an event to happen. The
estimate includes the amount of time to open a table or start an ESP
process.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PROBES</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The number of times the operator will be executed. Usually, this value
is 1, but it can be greater when you have, for example, an inner scan of
a nested-loop join.</p></td>
</tr>
</tbody>
</table>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_explain_function">7.49.2. Examples of EXPLAIN Function</h4>
<div class="ulist">
<ul>
<li>
<p>Display the specified columns in the result table of the EXPLAIN
function for the prepared statement REGION:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SELECT seq_num, operator, operator_cost FROM table (EXPLAIN (null, 'REG'));
SEQ_NUM OPERATOR OPERATOR_COST
----------- ------------------------------ ---------------
1 TRAFODION_SCAN 0.43691027
2 ROOT 0.0
--- 2 row(s) selected.
&gt;&gt;log;</code></pre>
</div>
</div>
<div class="paragraph">
<p>The example displays only part of the result table of the EXPLAIN
function. It first uses the EXPLAIN function to generate the table and
then selects the desired columns.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="extract_function">7.50. EXTRACT Function</h3>
<div class="paragraph">
<p>The EXTRACT function extracts a datetime field from a datetime or
interval value expression. It returns an exact numeric value.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXTRACT (datetime-field FROM extract-source)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-field</em></code> is:</p>
<div class="paragraph">
<p>YEAR \| MONTH \| DAY \| HOUR \| MINUTE \| SECOND</p>
</div>
</li>
<li>
<p><code><em>extract-source</em></code> is:</p>
<div class="paragraph">
<p>datetime-expression \| interval-expression</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>See <a href="#datetime_value_expressions">Datetime Value Expressions</a> and
<a href="#interval_value_expressions">Interval Value Expressions</a>.</p>
</div>
<div class="sect3">
<h4 id="examples_of_extract">7.50.1. Examples of EXTRACT</h4>
<div class="ulist">
<ul>
<li>
<p>Extract the year from a DATE value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXTRACT (YEAR FROM DATE '2007-09-28')</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result is 2007.</p>
</div>
</li>
<li>
<p>Extract the year from an INTERVAL value:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">EXTRACT (YEAR FROM INTERVAL '01-09' YEAR TO MONTH)</code></pre>
</div>
</div>
<div class="paragraph">
<p>The result is 1.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="hour_function">7.50.2. HOUR Function</h4>
<div class="paragraph">
<p>The HOUR function converts a TIME or TIMESTAMP expression into an
INTEGER value in the range 0 through 23 that represents the
corresponding hour of the day.</p>
</div>
<div class="paragraph">
<p>HOUR is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">HOUR (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type TIME or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_hour">7.50.3. Examples of HOUR</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the hour of the day from the
ship timestamp column in the project table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, HOUR(ship_timestamp)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ------
2007-04-10 2007-04-21 08:15:00.000000 8</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="group_concat_function">7.51. GROUP_CONCAT Function</h3>
<div class="paragraph">
<p>This function returns a string result with the concatenated non-NULL values from a group.
It returns NULL if there are no non-NULL values.
The syntax is as follows:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GROUP_CONCAT([DISTINCT] expr [,expr ...]
[ORDER BY {unsigned_integer | col_name | expr}
[ASC | DESC] [,col_name ...]]
[SEPARATOR str_val])</code></pre>
</div>
</div>
<div class="paragraph">
<p>Get the concatenated values of expression combinations. To eliminate duplicate values,
use the DISTINCT clause.
To sort values in the result, use the ORDER BY clause. To sort in reverse order, add
the DESC (descending) keyword to the name of the column you are sorting by in the
ORDER BY clause. The default is ascending order; this may be specified explicitly using
the ASC keyword. The default separator between values in a group is comma (,). To specify
a separator explicitly, use SEPARATOR followed by the string literal value that should be
inserted between group values. To eliminate the separator altogether, specify SEPARATOR ''.</p>
</div>
<div class="sect3">
<h4 id="examples_of_group_concat">7.51.1. Examples of GROUP_CONCAT</h4>
<div class="paragraph">
<p>The following example returns concatenated strings for column test_score for each student.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt; SELECT student_name,
GROUP_CONCAT(DISTINCT test_score
ORDER BY test_score DESC SEPARATOR ' ')
FROM student
GROUP BY student_name;
STUDENT_NAME (EXPR)
-------------- --------------
scott 91 90 80 56
tom 91 77 43</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="insert_function">7.52. INSERT Function</h3>
<div class="paragraph">
<p>The INSERT function returns a character string where a specified number
of characters within the character string has been deleted, beginning at
a specified start position, and where another character string has been
inserted at the start position. Every character, including multi-byte
characters, is treated as one character.</p>
</div>
<div class="paragraph">
<p>INSERT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">INSERT (char-expr-1, start, length, char-expr-2)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>char-expr-1</em>, <em>char-expr-2</em></code></p>
<div class="paragraph">
<p>are SQL character value expressions (of data type CHAR or VARCHAR) that
specify two strings of characters. The character string <em>char-expr-2</em> is
inserted into the character string_char-expr-1_.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>start</em></code></p>
<div class="paragraph">
<p>specifies the starting position start within char-expr-1 at which to
start deleting length number of characters. after the deletion, the
character string char-expr-2 is inserted into the character string
char-expr-1 , beginning at the start position specified by the number
start . The number start must be a value greater than zero of exact
numeric data type and with a scale of zero.</p>
</div>
</li>
<li>
<p><code><em>length</em></code></p>
<div class="paragraph">
<p>specifies the number of characters to delete from <em>char-expr-1</em>. The
number <em>length</em> must be a value greater than or equal to zero of exact
numeric data type and with a scale of zero. <em>length</em> must be less than
or equal to the length of <em>char-expr-1</em>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_insert">7.52.1. Examples of INSERT</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that your JOB table includes an entry for a sales
representative. Use the INSERT function to change SALESREP to SALES REP:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE persnl.job
SET jobdesc = INSERT (jobdesc, 6, 3, ' REP')
WHERE jobdesc = 'SALESREP';</code></pre>
</div>
</div>
<div class="paragraph">
<p>Now check the row you updated:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT jobdesc FROM persnl.job WHERE jobdesc = 'SALES REP';
Job Description
------------------
SALES REP
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="is_ipv4_function">7.53. IS_IPV4 Function</h3>
<div class="paragraph">
<p>For a given argument, if it is a valid IPV4 string, IS_IPV4() returns 1 else returns 0.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">IS_IPV4( expression )</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies an expression that determines the values to include in the
validation of the IP address. The <em>expression</em> cannot contain an aggregate
function or a subquery. If the input value is NULL, IS_IPV4 returns NULL.
See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_is_ipv4">7.53.1. Examples of IS_IPV4</h4>
<div class="paragraph">
<p>This function returns 1 for the first input argument, since it is a valid IPV4 string;
0 for the second input argument, since it is an invalid IPV4 string.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SELECT IS_IPV4('10.0.5.9'), IS_IPV4('10.0.5.256') from dual;
(EXPR) (EXPR)
------- -------
1 0</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="is_ipv6_function">7.54. IS_IPV6 Function</h3>
<div class="paragraph">
<p>Returns 1 if the argument is a valid IPv6 address specified as a string, 0 otherwise.
This function does not consider IPv4 addresses to be valid IPv6 addresses.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">IS_IPV6( expression )</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies an expression that determines the values to include in the
validation of the IP address. The <em>expression</em> cannot contain an aggregate
function or a subquery. If the input value is NULL, IS_IPV6 returns NULL.
See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_is_ipv6">7.54.1. Examples of IS_IPV6</h4>
<div class="paragraph">
<p>This function returns 0 for the second input argument, since it is a valid IPV6 string;
1 for the second input argument, since it is an invalid IPVr6 string.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SELECT IS_IPV6('10.0.5.9'), IS_IPV6('::1') from dual;
(EXPR) (EXPR)
-------- -------
1 0</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="literalblock">
<div class="content">
<pre>+[[inet_aton_function]]
+== INET_ATON Function
+
+Given the dotted-quad representation of an IPv4 network address as a string,
+returns an integer that represents the numeric value of the address in network
+byte order (big endian). INET_ATON() returns NULL if it does not understand its argument.
+
+```
+INET_ATON( expression )
+```
+
+* `_expression_`
++
+specifies an expression that determines the values to include in the
+conversion of the IP address. The _expression_ cannot contain an aggregate
+function or a subquery. If the input value is NULL, INET_ATON returns NULL.
+See &lt;&lt;expressions,Expressions&gt;&gt;.
+
+[[examples_of_inet_aton]]
+=== Examples of INET_ATON
+
+
+```
+&gt;&gt;SELECT INET_ATON('10.0.5.9') from dual;
+
+(EXPR)
+-----------
+167773449
+```
+&lt;&lt;&lt;
+[[inet_ntoa_function]]
+== INET_NTOA Function
+
+Given a numeric IPv4 network address in network byte order, returns the
+dotted-quad string representation of the address as a nonbinary string in
+the connection character set. INET_NTOA() returns NULL if it does
+not understand its argument.
+
+```
+INET_NTOA( expression )
+```
+
+* `_expression_`
++
+specifies an expression that determines the values to include in the
+conversion of the number to IP address. The _expression_ cannot contain
+an aggregate function or a subquery. If the input value is NULL, INET_NTOA
+returns NULL.
+See &lt;&lt;expressions,Expressions&gt;&gt;.
+
+[[examples_of_inet_ntoa]]
+=== Examples of INET_NTOA
+
+this function will convert an integer into the dotted-quad string
+representation of the IP address.
+
+```
+&gt;&gt;SELECT INET_NTOA(167773449) from dual
+
+(EXPR)
+-------------
+'10.0.5.9'
+```
+&lt;&lt;&lt;</pre>
</div>
</div>
</div>
</div>
<div class="sect2">
<h3 id="isnull_function">7.55. ISNULL Function</h3>
<div class="paragraph">
<p>The ISNULL function returns the value of the first argument if it is not
null, otherwise it returns the value of the second argument. Both
expressions must be of comparable types.</p>
</div>
<div class="paragraph">
<p>ISNULL is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ISNULL(ck-expr, repl-value)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>ck-expr</em></code></p>
<div class="paragraph">
<p>an expression of any valid SQL data type.</p>
</div>
</li>
<li>
<p><code><em>repl-value</em></code></p>
<div class="paragraph">
<p>an expression of any valid SQL data type, but must be a comparable type
with that of <em>ck-expr</em>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_isnull">7.55.1. Examples of ISNULL</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns a 0 instead of a null if value is null.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ISNULL(value,0)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the date constant if date_col is null.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ISNULL(date_col, DATE '2006-01-01')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'Smith' if the string column last_name is null.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ISNULL(last_name, 'Smith')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="juliantimestamp_function">7.56. JULIANTIMESTAMP Function</h3>
<div class="paragraph">
<p>The JULIANTIMESTAMP function converts a datetime value into a 64-bit
Julian timestamp value that represents the number of microseconds that
have elapsed between 4713 B.C., January 1, 00:00, and the specified
datetime value. JULIANTIMESTAMP returns a value of data type LARGEINT.</p>
</div>
<div class="paragraph">
<p>The function is evaluated once when the query starts execution and is
not reevaluated (even if it is a long running query).</p>
</div>
<div class="paragraph">
<p>JULIANTIMESTAMP is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">JULIANTIMESTAMP(datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a value of type DATE, TIME, or
TIMESTAMP. If <em>datetime-expression</em> does not contain all the fields from YEAR through
SECOND, Trafodion SQL extends the value before converting it to a Julian
timestamp. Datetime fields to the left of the specified datetime value
are set to current date fields. Datetime fields to the right of the
specified datetime value are set to zero. See
<a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_juliantimestamp">7.56.1. Considerations for JULIANTIMESTAMP</h4>
<div class="paragraph">
<p>The <em>datetime-expression</em> value must be a date or timestamp value from
the beginning of year 0001 to the end of year 9999.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_juliantimestamp">7.56.2. Examples of JULIANTIMESTAMP</h4>
<div class="paragraph">
<p>The project table consists of five columns using the data types NUMERIC,
VARCHAR, DATE, TIMESTAMP, and INTERVAL.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Convert the TIMESTAMP value into a Julian timestamp representation:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ship_timestamp, JULIANTIMESTAMP (ship_timestamp)
FROM persnl.project
WHERE projcode = 1000;
SHIP_TIMESTAMP (EXPR)
-------------------------- --------------------
2008-04-21 08:15:00.000000 212075525700000000
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Convert the DATE value into a Julian timestamp representation:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, JULIANTIMESTAMP (start_date)
FROM persnl.project
WHERE projcode = 1000;
START_DATE (EXPR)
---------- --------------------
2008-04-10 212074545600000000
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="lastnotnull_function">7.57. LASTNOTNULL Function</h3>
<div class="paragraph">
<p>The LASTNOTNULL function is a sequence function that returns the last
non-null value of a column in an intermediate result table ordered by a
SEQUENCE BY clause in a SELECT statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>LASTNOTNULL is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LASTNOTNULL(column-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression. If only null values have been returned, LASTNOTNULL returns null.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_lastnotnull">7.57.1. Examples of LASTNOTNULL</h4>
<div class="ulist">
<ul>
<li>
<p>Return the last non-null value of a column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT LASTNOTNULL(I1) AS lastnotnull
FROM mining.seqfcn SEQUENCE BY ts;
lastnotnull
-----------
6215
6215
19058
19058
11966
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="lcase_function">7.58. LCASE Function</h3>
<div class="paragraph">
<p>The LCASE function down-shifts alphanumeric characters. For
non-alphanumeric characters, LCASE returns the same character. LCASE can
appear anywhere in a query where a value can be used, such as in a
select list, an ON clause, a WHERE clause, a HAVING clause, a LIKE
predicate, an expression, or as qualifying a new value in an UPDATE or
INSERT statement. The result returned by the LCASE function is equal to
the result returned by the <a href="#lower_function">LOWER Function</a>.</p>
</div>
<div class="paragraph">
<p>LCASE returns a string of fixed-length or variable-length character
data, depending on the data type of the input string.</p>
</div>
<div class="paragraph">
<p>LCASE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LCASE (character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies a string of
characters to down-shift. See
<a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_lcase">7.58.1. Examples of LCASE</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that your CUSTOMER table includes an entry for Hotel Oregon.
Select the column CUSTNAME and return in uppercase and lowercase letters
by using the UCASE and LCASE functions:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT custname,UCASE(custname),LCASE(custname) FROM sales.customer;
(EXPR) (EXPR) (EXPR)
--------------- --------------------- ------------------
... ... ...
Hotel Oregon HOTEL OREGON hotel oregon
--- 17 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>See <a href="#ucase_function">UCASE Function</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="left_function">7.58.2. LEFT Function</h4>
<div class="paragraph">
<p>The LEFT function returns the leftmost specified number of characters
from a character expression. Every character, including multi-byte
characters, is treated as one character.</p>
</div>
<div class="paragraph">
<p>LEFT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LEFT (character-expr, count)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expr</em></code></p>
<div class="paragraph">
<p>specifies the source string from which to return the leftmost specified
number of characters. The source string is an SQL character value expression.
The operand is the result of evaluating <em>character-expr</em>.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>count</em></code></p>
<div class="paragraph">
<p>specifies the number of characters to return from <em>character-expr</em>.
The number count must be a value of exact numeric data type greater
than or equal to 0 with a scale of zero.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_left">7.58.3. Examples of LEFT</h4>
<div class="ulist">
<ul>
<li>
<p>Return_'robert':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">left('robert john smith', 6)</code></pre>
</div>
</div>
</li>
<li>
<p>Use the LEFT function to append the company name to the job
descriptions:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE persnl.job SET jobdesc = LEFT (jobdesc, 11) ||' COMNET';
SELECT jobdesc FROM persnl.job;
Job Description
------------------
MANAGER COMNET
PRODUCTION COMNET
ASSEMBLER COMNET
SALESREP COMNET
SYSTEM ANAL COMNET
ENGINEER COMNET
PROGRAMMER COMNET
ACCOUNTANT COMNET
ADMINISTRAT COMNET
SECRETARY COMNET
--- 10 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="locate_function">7.59. LOCATE Function</h3>
<div class="paragraph">
<p>The LOCATE function searches for a given substring in a character
string. If the substring is found, Trafodion SQL returns the character
position of the substring within the string. Every character, including
multi-byte characters, is treated as one character. The result returned
by the LOCATE function is equal to the result returned by the
<a href="#position_function">Position Function</a>.</p>
</div>
<div class="paragraph">
<p>LOCATE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LOCATE(substring-expression,source-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>substring-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies the substring to
search for in <em>source-expression</em>. The <em>substring-expression</em> cannot be NULL.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>source-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies the source string.
the <em>source-expression</em> cannot be null.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Trafodion SQL returns the result as a 2-byte signed integer with a scale
of zero. If substring-expression is not found in source-expression , Trafodion
SQL returns 0.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_locate">7.59.1. Considerations for LOCATE</h4>
<div class="sect4">
<h5 id="result_of_locate">Result of LOCATE</h5>
<div class="ulist">
<ul>
<li>
<p>If the length of <em>source-expression</em> is zero and the length of
<em>substring-expression</em> is greater than zero, Trafodion SQL returns 0.</p>
</li>
<li>
<p>If the length of <em>substring-expression</em> is zero, Trafodion SQL returns 1.</p>
</li>
<li>
<p>If the length of <em>substring-expression</em> is greater than the length of
<em>source-expression</em>, Trafodion SQL returns 0.</p>
</li>
<li>
<p>If <em>source-expression</em> is a null value, Trafodion SQL returns a null value.</p>
</li>
</ul>
</div>
</div>
<div class="sect4">
<h5 id="using_ucase">Using UCASE</h5>
<div class="paragraph">
<p>To ignore case in the search, use the UCASE function (or the LCASE
function) for both the <em>substring-expression</em> and the <em>source-expression</em>.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_locate">7.59.2. Examples of LOCATE</h4>
<div class="ulist">
<ul>
<li>
<p>Return the value 8 for the position of the substring 'John' within the string:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LOCATE ('John','Robert John Smith')</code></pre>
</div>
</div>
</li>
<li>
<p>Suppose that the EMPLOYEE table has an EMPNAME column that contains
both the first and last names. This SELECT statement returns all records
in table EMPLOYEE that contain the substring 'SMITH', regardless of
whether the column value is in uppercase or lowercase characters:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM persnl.employee
WHERE LOCATE ('SMITH',UCASE(empname)) &gt; 0 ;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="log_function">7.60. LOG Function</h3>
<div class="paragraph">
<p>The LOG function returns the natural logarithm of a numeric value
expression. LOG is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LOG (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the LOG function. The value of the argument must be greater
than zero. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_log">7.60.1. Examples of LOG</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 6.93147180559945344e-001, or
approximately 0.69315:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LOG (2.0)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="log10_function">7.60.2. LOG10 Function</h4>
<div class="paragraph">
<p>The LOG10 function returns the base 10 logarithm of a numeric value
expression.</p>
</div>
<div class="paragraph">
<p>LOG10 is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LOG10 (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the LOG10 function. The value of the argument must be
greater than zero.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_log10">7.60.3. Examples of LOG10</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 1.39794000867203776E+000, or
approximately 1.3979:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LOG10 (25)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="lower_function">7.61. LOWER Function</h3>
<div class="paragraph">
<p>The LOWER function down-shifts alphanumeric characters. For
non-alphanumeric characters, LOWER returns the same character. LOWER can
appear anywhere in a query where a value can be used, such as in a
select list, an ON clause, a WHERE clause, a HAVING clause, a LIKE
predicate, an expression, or as qualifying a new value in an UPDATE or
INSERT statement. The result returned by the LOWER function is equal to
the result returned by the <a href="#lcase_function">LCASE Function</a>.</p>
</div>
<div class="paragraph">
<p>LOWER returns a string of fixed-length or variable-length character
data, depending on the data type of the input string.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LOWER (character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies a string of
characters to down-shift.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_lower">7.61.1. Considerations for LOWER</h4>
<div class="paragraph">
<p>For a UTF8 character expression, the LOWER function down-shifts all the
uppercase or title case characters in a given string to lowercase and
returns a character string with the same data type and character set as
the argument.</p>
</div>
<div class="paragraph">
<p>A lower case character is a character that has the "alphabetic" property
in Unicode Standard 2 whose Unicode name includes lower. An uppercase
character is a character that has the "alphabetic" property in the
Unicode Standard 2 and whose Unicode name includes <em>upper</em>. A title
case character is a character that has the Unicode "alphabetic" property
and whose Unicode name includes <em>title</em>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="examples_of_lower">7.61.2. Examples of LOWER</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that your CUSTOMER table includes an entry for Hotel Oregon.
Select the column CUSTNAME and return the result in uppercase and
lowercase letters by using the UPPER and LOWER functions:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT custname,UPPER(custname),LOWER(custname) FROM sales.customer;
(EXPR) (EXPR) (EXPR)
----------------- ------------------- ---------------------
... ... ...
Hotel Oregon HOTEL OREGON hotel oregon
--- 17 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>See <a href="#upper_function">UPPER Function</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="lpad_function">7.61.3. LPAD Function</h4>
<div class="paragraph">
<p>The LPAD function pads the left side of a string with the specified
string. Every character in the string, including multi-byte characters,
is treated as one character.</p>
</div>
<div class="paragraph">
<p>LPAD is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LPAD (str, len [,padstr])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>str</em></code></p>
<div class="paragraph">
<p>can be an expression.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>len</em></code></p>
<div class="paragraph">
<p>identifies the desired number of characters to be returned and can be an
expression but must be an integral value. If <em>len</em> is equal to the
length of the string, no change is made. If <em>len</em> is smaller than the
string size, the string is truncated.</p>
</div>
</li>
<li>
<p><code><em>pad-character</em></code></p>
<div class="paragraph">
<p>can be an expression and may be a string.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_lpad">7.61.4. Examples of LPAD</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns ' kite':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LPAD('kite', 7)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'ki':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LPAD('kite', 2)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns '0000kite':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LPAD('kite', 8, '0')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'go fly a kite':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LPAD('go fly a kite', 13, 'z')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'John,John, go fly a kite'':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LPAD('go fly a kite', 23, 'John,')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="ltrim_function">7.62. LTRIM Function</h3>
<div class="paragraph">
<p>The LTRIM function removes leading spaces from a character string. If
you must remove any leading character other than space, use the TRIM
function and specify the value of the character. See the <a href="#trim_function">TRIM Function</a>.</p>
</div>
<div class="paragraph">
<p>LTRIM is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LTRIM (character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression and specifies the string from which
to trim leading spaces.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_ltrim">7.62.1. Considerations for LTRIM</h4>
<div class="sect4">
<h5 id="result_of_ltrim">Result of LTRIM</h5>
<div class="paragraph">
<p>The result is always of type VARCHAR, with maximum length equal to the
fixed length or maximum variable length of <em>character-expression</em>.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_ltrim">7.62.2. Examples of LTRIM</h4>
<div class="ulist">
<ul>
<li>
<p>Return 'Robert ':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LTRIM (' Robert ')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>See <a href="#trim_function">TRIM Function</a> and <a href="#rtrim_function">RTRIM Function</a>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="max_function">7.63. MAX/MAXIMUM Function</h3>
<div class="paragraph">
<p>MAX is an aggregate function that returns the maximum value within a set
of values. MAXIMUM is the equivalent of MAX wherever the function name
MAX appears within a statement. The data type of the result is the same
as the data type of the argument.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MAX | MAXIMUM ([ALL | DISTINCT] expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ALL | DISTINCT</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the maximum of the <em>expression</em>. The default option is ALL, which
causes duplicate values to be included. If you specify DISTINCT,
duplicate values are eliminated before the MAX/MAXIMUM function is
applied.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies an expression that determines the values to include in the
computation of the maximum. The <em>expression</em> cannot contain an aggregate
function or a subquery. The DISTINCT clause specifies that the
MAX/MAXIMUM function operates on distinct values from the one-column
table derived from the evaluation of <em>expression</em>. All nulls are
eliminated before the function is applied to the set of values. If the
result table is empty, MAX/MAXIMUM returns NULL.
See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_max">7.63.1. Considerations for MAX/MAXIMUM</h4>
</div>
<div class="sect3">
<h4 id="operands_of_the_expression">7.63.2. Operands of the Expression</h4>
<div class="paragraph">
<p>The expression includes columns from the rows of the SELECT result table
but cannot include an aggregate function. These expressions are valid:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MAX (SALARY)
MAX (SALARY * 1.1)
MAX (PARTCOST * QTY_ORDERED)</code></pre>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_max">7.63.3. Examples of MAX/MAXIMUM</h4>
<div class="ulist">
<ul>
<li>
<p>Display the maximum value in the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MAX (salary) FROM persnl.employee;
(EXPR)
-----------
175500.00
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="md5_function">7.64. MD5 Function</h3>
<div class="paragraph">
<p>Calculates an MD5 128-bit checksum for the string. The value is returned
as a string of 32 hexadecimal digits, or NULL if the argument was NULL.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MD5( _expression_)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies an expression that determines the values to include in the
computation of the MD5. The <em>expression</em> cannot contain an aggregate
function or a subquery. If the input value is NULL, MD5 returns NULL.
See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_md5">7.64.1. Examples of MD5</h4>
<div class="paragraph">
<p>The return value is a nonbinary string in the connection character set.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SELECT MD5('testing') from dual;
(EXPR)
---------------------------------
'ae2b1fca515949e5d54fb22b8ed95575'</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="min_function">7.65. MIN Function</h3>
<div class="paragraph">
<p>MIN is an aggregate function that returns the minimum value within a set
of values. The data type of the result is the same as the data type of
the argument.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MIN ([ALL | DISTINCT] _expression_)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ALL | DISTINCT</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the minimum of the <em>expression</em>. The default option is ALL, which
causes duplicate values to be included. If you specify DISTINCT,
duplicate values are eliminated before the MIN function is applied.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies an expression that determines the values to include in the
computation of the minimum. The <em>expression</em> cannot contain an aggregate
function or a subquery. The DISTINCT clause specifies that the MIN
function operates on distinct values from the one-column table derived
from the evaluation of <em>expression</em>. All nulls are eliminated before
the function is applied to the set of values. If the result table is
empty, MIN returns NULL.
See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_min">7.65.1. Considerations for MIN</h4>
<div class="sect4">
<h5 id="operands_of_the_expression_3">Operands of the Expression</h5>
<div class="paragraph">
<p>The expression includes columns from the rows of the SELECT result
table &#8212; but cannot include an aggregate function. These expressions are
valid:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MIN (SALARY)
MIN (SALARY * 1.1)
MIN (PARTCOST * QTY_ORDERED)</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_min">7.65.2. Examples of MIN</h4>
<div class="ulist">
<ul>
<li>
<p>Display the minimum value in the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MIN (salary) FROM persnl.employee;
(EXPR)
-----------
17000.00
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="minute_function">7.66. MINUTE Function</h3>
<div class="paragraph">
<p>The MINUTE function converts a TIME or TIMESTAMP expression into an
INTEGER value, in the range 0 through 59, that represents the
corresponding minute of the hour.</p>
</div>
<div class="paragraph">
<p>MINUTE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MINUTE (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type TIME or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_minute">7.66.1. Examples of minute</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the minute of the hour from the
ship timestamp column in the project table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, MINUTE(ship_timestamp)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ------
2008-04-10 2008-04-21 08:15:00.000000 15</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="mod_function">7.67. MOD Function</h3>
<div class="paragraph">
<p>The MOD function returns the remainder (modulus) of an integer value
expression divided by an integer value expression.</p>
</div>
<div class="paragraph">
<p>MOD is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOD (integer-expression-1,integer-expression-2)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>integer-expression-1</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of data type SMALLINT, INTEGER, or
LARGEINT that specifies the value for the dividend argument of the MOD
function.</p>
</div>
</li>
<li>
<p><code><em>integer-expression-2</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of data type SMALLINT, INTEGER, or
LARGEINT that specifies the value for the divisor argument of the MOD
function. The divisor argument cannot be zero.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_mod">7.67.1. Examples of MOD</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 2 as the remainder or modulus:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOD(11,3)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="month_function">7.68. MONTH Function</h3>
<div class="paragraph">
<p>The MONTH function converts a DATE or TIMESTAMP expression into an
INTEGER value in the range 1 through 12 that represents the
corresponding month of the year.</p>
</div>
<div class="paragraph">
<p>MONTH is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MONTH (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_month">7.68.1. Examples of MONTH</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the month of the year from the
start date column in the project table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, MONTH(start_date) FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ------
2008-04-10 2008-04-21 08:15:00.000000 4</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="monthname_function">7.69. MONTHNAME Function</h3>
<div class="paragraph">
<p>The MONTHNAME function converts a DATE or TIMESTAMP expression into a
character literal that is the name of the month of the year (January,
February, and so on).</p>
</div>
<div class="paragraph">
<p>MONTHNAME is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MONTHNAME (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_monthname">7.69.1. Considerations for MONTHNAME</h4>
<div class="paragraph">
<p>The MONTHNAME function returns the name of the month in ISO8859-1.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_monthname">7.69.2. Examples of MONTHNAME</h4>
<div class="ulist">
<ul>
<li>
<p>Return a character literal that is the month of the year from the
start date column in the project table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, MONTHNAME(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ---------
2008-04-10 2008-04-21 08:15:00.000000 April</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="movingavg_function">7.70. MOVINGAVG Function</h3>
<div class="paragraph">
<p>The MOVINGAVG function is a sequence function that returns the average
of non-null values of a column in the current window of an intermediate
result table ordered by a SEQUENCE BY clause in a SELECT statement. See
<a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>MOVINGAVG is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOVINGAVG(column-expression, integer-expression [, max-rows])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
</li>
<li>
<p><code><em>integer-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the current window. The current window is defined
as the current row and the previous (<em>integer-expression</em> - 1) rows.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows in the current window.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Note these considerations for the window size:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The actual value for the window size is the minimum of
integer-<em>expression</em> and <em>max-rows</em>.</p>
</li>
<li>
<p>If these conditions are met, MOVINGAVG returns the same result as
RUNNINGAVG:</p>
<div class="ulist">
<ul>
<li>
<p>The <em>integer-expression</em> is out of range, and <em>max-rows</em> is not
specified. This condition includes the case in which both
<em>integer-expression</em> and <em>max-rows</em> are larger than the result table.</p>
</li>
<li>
<p>The minimum of <em>integer-expression</em> and <em>max-rows</em> is out of range.
In this case, <em>integer-expression</em> could be within range, but <em>max-rows</em>
might be the minimum value of the two and be out of range (for example,
a negative number).</p>
</li>
</ul>
</div>
</li>
<li>
<p>The number of rows is out of range if it is larger than the size of
the result table, negative, or NULL.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_movingavg">7.70.1. Examples of MOVINGAVG</h4>
<div class="ulist">
<ul>
<li>
<p>Return the average of non-null values of a column in the current window
of three rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE db.mining.seqfcn (I1 INTEGER, ts TIMESTAMP);
SELECT MOVINGAVG (I1,3) AS MOVINGAVG3
FROM mining.seqfcn SEQUENCE BY ts;
I1 TS
6215 TIMESTAMP '1950-03-05 08:32:09'
28174 TIMESTAMP '1951-02-15 14:35:49'
null TIMESTAMP '1955-05-18 08:40:10'
4597 TIMESTAMP '1960-09-19 14:40:39'
11966 TIMESTAMP '1964-05-01 16:41:02'
MOVINGAVG3
---------------------
6215
17194
17194
16385
8281
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="movingcount_function">7.71. MOVINGCOUNT Function</h3>
<div class="paragraph">
<p>The MOVINGCOUNT function is a sequence function that returns the number
of non-null values of a column in the current window of an intermediate
result table ordered by a SEQUENCE BY clause in a SELECT statement. See
<a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>MOVINGCOUNT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOVINGCOUNT (column-expression, integer-expression [, max-rows])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
</li>
<li>
<p><code><em>integer-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the current window. The current window is defined
as the current row and the previous (<em>integer-expression</em> - 1) rows.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows in the current window.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Note these considerations for the window size:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The actual value for the window size is the minimum of
<em>integer-expression</em> and <em>max-rows</em>.</p>
</li>
<li>
<p>If these conditions are met, MOVINGCOUNT returns the same result as
RUNNINGCOUNT:</p>
<div class="ulist">
<ul>
<li>
<p>The <em>integer-expression</em> is out of range, and <em>max-rows</em> is not
specified. This condition includes the case in which both
<em>integer-expression</em> and <em>max-rows</em> are larger than the result table.</p>
</li>
<li>
<p>The minimum of <em>integer-expression</em> and <em>max-rows</em> is out of range.
In this case, <em>integer-expression</em> could be within range, but <em>max-rows</em>
might be the minimum value of the two and be out of range (for example,
a negative number).</p>
</li>
</ul>
</div>
</li>
<li>
<p>The number of rows is out of range if it is larger than the size of
the result table, negative, or NULL.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="considerations_for_movingcount">7.71.1. Considerations for MOVINGCOUNT</h4>
<div class="paragraph">
<p>The MOVINGCOUNT sequence function is defined differently from the COUNT
aggregate function. If you specify DISTINCT for the COUNT aggregate
function, duplicate values are eliminated before COUNT is applied. You
cannot specify DISTINCT for the MOVINGCOUNT sequence function; duplicate
values are counted.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_movingcount">7.71.2. Examples of MOVINGCOUNT</h4>
<div class="ulist">
<ul>
<li>
<p>Return the number of non-null values of a column in the current window of
three rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MOVINGCOUNT (I1,3) AS MOVINGCOUNT3
FROM mining.seqfcn SEQUENCE BY ts;
MOVINGCOUNT3
------------
1
2
2
2
2
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="movingmax_function">7.72. MOVINGMAX Function</h3>
<div class="paragraph">
<p>The MOVINGMAX function is a sequence function that returns the maximum
of non-null values of a column in the current window of an intermediate
result table ordered by a SEQUENCE BY clause in a SELECT statement. See
<a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>MOVINGMAX is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOVINGMAX (column-expression, integer-expression [, max-rows])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
</li>
<li>
<p><code><em>integer-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the current window. The current window is defined
as the current row and the previous (<em>integer-expression</em> - 1) rows.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows in the current window.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Note these considerations for the window size:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The actual value for the window size is the minimum of
<em>integer-expression</em> and <em>max-rows</em>.</p>
</li>
<li>
<p>If these conditions are met, MOVINGMAX returns the same result as
RUNNINGMAX:</p>
<div class="ulist">
<ul>
<li>
<p>The <em>integer-expression</em> is out of range, and <em>max-rows</em> is not
specified. This condition includes the case in which both
<em>integer-expression</em> and <em>max-rows</em> are larger than the result table.</p>
</li>
<li>
<p>The minimum of <em>integer-expression</em> and <em>max-rows</em> is out of range.
In this case, <em>integer-expression</em> could be within range, but <em>max-rows</em>
might be the minimum value of the two and be out of range (for example,
a negative number).</p>
</li>
</ul>
</div>
</li>
<li>
<p>The number of rows is out of range if it is larger than the size of
the result table, negative, or NULL.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_movingmax">7.72.1. Examples of MOVINGMAX</h4>
<div class="ulist">
<ul>
<li>
<p>Return the maximum of non-null values of a column in the current window
of three rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MOVINGMAX (I1,3) AS MOVINGMAX3
FROM mining.seqfcn SEQUENCE BY ts;
MOVINGMAX3
------------
6215
28174
28174
28174
11966
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="movingmin_function">7.73. MOVINGMIN Function</h3>
<div class="paragraph">
<p>The MOVINGMIN function is a sequence function that returns the minimum
of non-null values of a column in the current window of an intermediate
result table ordered by a SEQUENCE BY clause in a SELECT statement. See
<a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>MOVINGMIN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOVINGMIN (column-expression, integer-expression [, max-rows])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
</li>
<li>
<p><code><em>integer-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the current window. The current window is defined
as the current row and the previous (<em>integer-expression</em> - 1) rows.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows in the current window.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Note these considerations for the window size:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The actual value for the window size is the minimum of
<em>integer-expression</em> and <em>max-rows</em>.</p>
</li>
<li>
<p>If these conditions are met, MOVINGMIN returns the same result as
RUNNINGMIN:</p>
<div class="ulist">
<ul>
<li>
<p>The <em>integer-expression</em> is out of range, and <em>max-rows</em> is not
specified. This condition includes the case in which both
<em>integer-expression</em> and <em>max-rows</em> are larger than the result table.</p>
</li>
<li>
<p>The minimum of <em>integer-expression</em> and <em>max-rows</em> is out of range.
In this case, <em>integer-expression</em> could be within range, but <em>max-rows</em>
might be the minimum value of the two and be out of range (for example,
a negative number).</p>
</li>
</ul>
</div>
</li>
<li>
<p>The number of rows is out of range if it is larger than the size of
the result table, negative, or NULL.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_movingmin">7.73.1. Examples of MOVINGMIN</h4>
<div class="ulist">
<ul>
<li>
<p>Return the minimum of non-null values of a column in the current window
of three rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MOVINGMIN (I1,3) AS MOVINGMIN3
FROM mining.seqfcn SEQUENCE BY ts;
MOVINGMIN3
------------
6215
6215
6215
4597
4597
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="movingstddev_function">7.74. MOVINGSTDDEV Function</h3>
<div class="paragraph">
<p>The MOVINGSTDDEV function is a sequence function that returns the
standard deviation of non-null values of a column in the current window
of an intermediate result table ordered by a SEQUENCE BY clause in a
SELECT statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>MOVINGSTDDEV is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOVINGSTDDEV (column-expression, integer-expression [, max-rows])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
</li>
<li>
<p><code><em>integer-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the current window. The current window is defined
as the current row and the previous (<em>integer-expression</em> - 1) rows.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows in the current window.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Note these considerations for the window size:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The actual value for the window size is the minimum of
<em>integer-expression</em> and <em>max-rows</em>.</p>
</li>
<li>
<p>If these conditions are met, MOVINGSTDDEV returns the same result as
RUNNINGSTDDEV:</p>
<div class="ulist">
<ul>
<li>
<p>The <em>integer-expression</em> is out of range, and <em>max-rows</em> is not
specified. This condition includes the case in which both
<em>integer-expression</em> and <em>max-rows</em> are larger than the result table.</p>
</li>
<li>
<p>The minimum of <em>integer-expression</em> and <em>max-rows</em> is out of range.
In this case, <em>integer-expression</em> could be within range, but <em>max-rows</em>
might be the minimum value of the two and be out of range (for example,
a negative number).</p>
</li>
</ul>
</div>
</li>
<li>
<p>The number of rows is out of range if it is larger than the size of
the result table, negative, or NULL.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_movingstddev">7.74.1. Examples of MOVINGSTDDEV</h4>
<div class="ulist">
<ul>
<li>
<p>Return the standard deviation of non-null values of a column in the
current window of three rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MOVINGSTDDEV (I1,3) AS MOVINGSTDDEV3
FROM mining.seqfcn SEQUENCE BY ts;
MOVINGSTDDEV3
-------------------------
0.00000000000000000E+000
1.55273578080753976E+004
1.48020166531456112E+004
1.51150124820766640E+004
6.03627542446499008E+003
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>You can use the CAST function for display purposes. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CAST(MOVINGSTDDEV (I1,3) AS DEC (18,3))
FROM mining.seqfcn SEQUENCE BY ts;
(EXPR)
--------------------
.000
15527.357
14802.016
15115.012
6036.275
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="movingsum_function">7.75. MOVINGSUM Function</h3>
<div class="paragraph">
<p>The MOVINGSUM function is a sequence function that returns the sum of
non-null values of a column in the current window of an intermediate
result table ordered by a SEQUENCE BY clause in a SELECT statement. See
<a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>MOVINGSUM is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOVINGSUM (column-expression, integer-expression [, max-rows])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
</li>
<li>
<p><code><em>integer-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the current window. The current window is defined
as the current row and the previous (<em>integer-expression</em> - 1) rows.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows in the current window.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Note these considerations for the window size:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The actual value for the window size is the minimum of
<em>integer-expression</em> and <em>max-rows</em>.</p>
</li>
<li>
<p>If these conditions are met, MOVINGSUM returns the same result as
RUNNINGSUM:</p>
<div class="ulist">
<ul>
<li>
<p>The <em>integer-expression</em> is out of range, and <em>max-rows</em> is not
specified. This condition includes the case in which both
<em>integer-expression</em> and <em>max-rows</em> are larger than the result table.</p>
</li>
<li>
<p>The minimum of <em>integer-expression</em> and <em>max-rows</em> is out of range.
In this case, <em>integer-expression</em> could be within range, but <em>max-rows</em>
might be the minimum value of the two and be out of range (for example,
a negative number).</p>
</li>
</ul>
</div>
</li>
<li>
<p>The number of rows is out of range if it is larger than the size of
the result table, negative, or NULL.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_movingsum">7.75.1. Examples of MOVINGSUM</h4>
<div class="ulist">
<ul>
<li>
<p>Return the sum of non-null values of a column in the current window of
three rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MOVINGSUM (I1,3) AS MOVINGSUM3
FROM mining.seqfcn SEQUENCE BY ts;
MOVINGSUM3
------------
6215
34389
34389
32771
16563
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="movingvariance_function">7.76. MOVINGVARIANCE Function</h3>
<div class="paragraph">
<p>The MOVINGVARIANCE function is a sequence function that returns the
variance of non-null values of a column in the current window of an
intermediate result table ordered by a SEQUENCE BY clause in a SELECT
statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>MOVINGVARIANCE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MOVINGVARIANCE (column-expression, integer-expression [, max-rows])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
</li>
<li>
<p><code><em>integer-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the current window. The current window is defined
as the current row and the previous (<em>integer-expression</em> - 1) rows.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows in the current window.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Note these considerations for the window size:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The actual value for the window size is the minimum of
<em>integer-expression</em> and <em>max-rows</em>.</p>
</li>
<li>
<p>If these conditions are met, MOVINGVARIANCE returns the same result as
RUNNINGVARIANCE:</p>
<div class="ulist">
<ul>
<li>
<p>The <em>integer-expression</em> is out of range, and <em>max-rows</em> is not
specified. This condition includes the case in which both
<em>integer-expression</em> and <em>max-rows</em> are larger than the result table.</p>
</li>
<li>
<p>The minimum of <em>integer-expression</em> and <em>max-rows</em> is out of range.
In this case, <em>integer-expression</em> could be within range, but <em>max-rows</em>
might be the minimum value of the two and be out of range (for example,
a negative number).</p>
</li>
</ul>
</div>
</li>
<li>
<p>The number of rows is out of range if it is larger than the size of
the result table, negative, or NULL.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_movingvariance">7.76.1. Examples of MOVINGVARIANCE</h4>
<div class="ulist">
<ul>
<li>
<p>Return the variance of non-null values of a column in the current window
of three rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT MOVINGVARIANCE (I1,3) AS MOVINGVARIANCE3
FROM mining.seqfcn SEQUENCE BY ts;
MOVINGVARIANCE3
-------------------------
0.00000000000000000E+000
2.41098840499999960E+008
2.19099696999999968E+008
2.28463602333333304E+008
3.64366210000000016E+007
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>You can use the CAST function for display purposes. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CAST(MOVINGVARIANCE (I1,3) AS DEC (18,3))
FROM mining.seqfcn SEQUENCE BY ts;
(EXPR)
--------------------
.000
241098840.500
219099697.000
228463602.333
36436621.000
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="nullif_function">7.76.2. NULLIF Function</h4>
<div class="paragraph">
<p>The NULLIF function compares the value of two expressions. Both
expressions must be of comparable types. The return value is NULL when
the two expressions are equal. Otherwise, the return value
is the value of the first expression.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">NULLIF(expr1, expr2)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expr1</em></code></p>
<div class="paragraph">
<p>an expression to be compared.</p>
</div>
</li>
<li>
<p><code><em>expr2</em></code></p>
<div class="paragraph">
<p>an expression to be compared.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The NULLIF(<em>expr1</em>, <em>expr2</em>) is equivalent to:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CASE
WHEN expr1 = expr2 THEN NULL
ELSE expr1
END</code></pre>
</div>
</div>
<div class="paragraph">
<p>NULLIF returns a NULL if both arguments are equal. The return value is
the value of the first argument when the two expressions are not equal.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_nullif">7.76.3. Examples of NULLIF</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns a null if the <em>value</em> is equal to 7. The return
value is the value of the first argument when that value is not 7.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">NULLIF(value,7)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="nullifzero_function">7.77. NULLIFZERO Function</h3>
<div class="paragraph">
<p>The NULLIFZERO function returns the value of the expression if that
value is not zero. It returns NULL if the value of the expression is
zero.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">NULLIFZERO (expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a value expression. It must be a numeric data type.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_nullifzero">7.77.1. Examples of NULLIFZERO</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value of the column named salary for each
row where the column&#8217;s value is not zero. It returns a NULL for each row
where the column&#8217;s value is zero.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT NULLIFZERO(salary) FROM employee_tab;</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns a value of 1 for each row of the table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT NULLIFZERO(1) FROM employee_tab;</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns a value of NULL for each row of the table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT NULLIFZERO(0) FROM employee_tab;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="nvl_function">7.78. NVL Function</h3>
<div class="paragraph">
<p>The NVL function determines if the selected column has a null value and
then returns the new-operand value; otherwise the operand value is
returned.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">NVL (operand, new-operand)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>operand</em></code></p>
<div class="paragraph">
<p>specifies a value expression.</p>
</div>
</li>
<li>
<p><code><em>new-operand</em></code></p>
<div class="paragraph">
<p>specifies a value expression. <em>operand</em> and <em>new-operand</em> must be
comparable data types.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>If <em>operand</em> is a null value, NVL returns <em>new-operand</em>. If <em>operand</em>
is not a null value, NVL returns <em>operand</em>.</p>
</div>
<div class="paragraph">
<p>The <em>operand</em> and <em>new-operand</em> can be a column name, subquery,
Trafodion SQL string functions, math functions, or constant values.</p>
</div>
<div class="sect3">
<h4 id="examples_of_nvl">7.78.1. Examples of NVL</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns a value of z:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT NVL(CAST(NULL AS CHAR(1)), 'z') FROM (VALUES(1)) x(a);
(EXPR)
------
&quot;z&quot;
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns a value of 1:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT NVL(1, 2) FROM (VALUES(0)) x(a)
(EXPR)
-------
1
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns a value of 9999999 for the null value in the
column named a1:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT NVL(a1, 9999999) from t1;
(EXPR)
-------
123
34
9999999
--- 3 row(s) selected.
select * from t1;
A1
-------
123
34
?
--- 3 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="octet_length_function">7.79. OCTET_LENGTH Function</h3>
<div class="paragraph">
<p>The OCTET_LENGTH function returns the length of a character string in
bytes.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">OCTET_LENGTH (string-value-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>string-value-expression</em></code></p>
<div class="paragraph">
<p>specifies the string value expression for which to return the length in
bytes. Trafodion SQL returns the result as a 2-byte signed integer with
a scale of zero. If <em>string-value-expression</em> is null, Trafodion SQL returns
a length of zero.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_octet_length">7.79.1. Considerations for OCTET_LENGTH</h4>
<div class="sect4">
<h5 id="char_and_varchar_operands_1">CHAR and VARCHAR Operands</h5>
<div class="paragraph">
<p>For a column declared as fixed CHAR, Trafodion SQL returns the length of
that column as the maximum number of storage bytes. For a VARCHAR
column, Trafodion SQL returns the length of the string stored in that
column as the actual number of storage bytes.</p>
</div>
</div>
<div class="sect4">
<h5 id="similarity_to_char_length_function">Similarity to CHAR_LENGTH Function</h5>
<div class="paragraph">
<p>The OCTET_LENGTH and CHAR_LENGTH functions are similar. The OCTET_LENGTH
function returns the number of bytes, rather than the number of
characters, in the string. This distinction is important for multi-byte
implementations. For an example of selecting a double-byte column, see
<a href="#examples_of_octet_length">Example of OCTET_LENGTH</a>.</p>
</div>
</div>
<div class="sect4">
<h5 id="examples_of_octet_length">Examples of OCTET_LENGTH</h5>
<div class="ulist">
<ul>
<li>
<p>If a character string is stored as two bytes for each character, this
function returns the value 12. Otherwise, the function returns 6:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">OCTET_LENGTH ('Robert')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="offset_function">7.79.2. OFFSET Function</h4>
<div class="paragraph">
<p>The OFFSET function is a sequence function that retrieves columns from
previous rows of an intermediate result table ordered by a SEQUENCE BY
clause in a SELECT statement. See <a href="#sequence_by
clause">[sequence_by
clause]</a>._offset_is_a_trafodion_sql_extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">OFFSET ( column-expression , number-rows [, max-rows ])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
</li>
<li>
<p><code><em>number-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the offset as the number of rows from the current
row. If the number of rows exceeds <em>max-rows</em>, OFFSET returns
OFFSET(<em>column-expression</em>,<em>max-rows</em>). If the number of rows is out
of range and <em>max-rows</em> is not specified or is out of range, OFFSET
returns null. The number of rows is out of range if it is larger than
the size of the result table, negative, or NULL.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows of the offset.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_offset">7.79.3. Examples of OFFSET</h4>
<div class="ulist">
<ul>
<li>
<p>Retrieve the I1 column offset by three rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT OFFSET(I1,3) AS offset3
FROM mining.seqfcn SEQUENCE BY ts;
offset3
------------
?
?
?
6215
28174
--- 5 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>The first three rows retrieved display null because the offset from the
current row does not fall within the result table.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="pi_function">7.80. PI Function</h3>
<div class="paragraph">
<p>The PI function returns the constant value of pi as a floating-point
value.</p>
</div>
<div class="paragraph">
<p>PI is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">PI()</code></pre>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_pi">7.80.1. Examples of PI</h4>
<div class="ulist">
<ul>
<li>
<p>This constant function returns the value 3.14159260000000000E+000:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">PI()</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="position_function">7.81. POSITION Function</h3>
<div class="paragraph">
<p>The POSITION function searches for a given substring in a character
string. If the substring is found, Trafodion SQL returns the character
position of the substring within the string. Every character, including
multi-byte characters, is treated as one character. The result returned
by the POSITION function is equal to the result returned by the
<a href="#locate_function">LOCATE Function</a>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">POSITION (substring-expression IN source-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>substring-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies the substring to
search for in <em>source-expression</em>. The <em>substring-expression</em> cannot be NULL.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>source-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies the source string.
the <em>source-expression</em> cannot be null.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Trafodion SQL returns the result as a 2-byte signed integer with a scale
of zero. If <em>substring-expression</em> is not found in <em>source-expression</em>,
Trafodion SQL returns zero.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_position">7.81.1. Considerations for POSITION</h4>
<div class="sect4">
<h5 id="result_of_position">Result of POSITION</h5>
<div class="paragraph">
<p>If the length of <em>source-expression</em> is zero and the length of
<em>substring-expression</em> is greater than zero, Trafodion SQL returns 0. If
the length of <em>substring-expression</em> is zero, Trafodion SQL returns 1.</p>
</div>
<div class="paragraph">
<p>If the length of <em>substring-expression</em> is greater than the length of
<em>source-expression</em>, Trafodion SQL returns zero. If
<em>source-expression</em> is a null value, Trafodion SQL returns a null value.</p>
</div>
</div>
<div class="sect4">
<h5 id="using_the_upshift_function">Using the UPSHIFT Function</h5>
<div class="paragraph">
<p>To ignore case in the search, use the UPSHIFT function (or the LOWER
function) for both the <em>substring-expression</em> and the <em>source-expression</em>.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_position">7.81.2. Examples of POSITION</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 8 for the position of the substring
'John' within the string:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">POSITION ('John' IN 'Robert John Smith')</code></pre>
</div>
</div>
</li>
<li>
<p>Suppose that the EMPLOYEE table has an EMPNAME column that contains
both the first and last names. Return all records in table EMPLOYEE that
contain the substring 'Smith' regardless of whether the column value is
in uppercase or lowercase characters:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT * FROM persnl.employee
WHERE POSITION ('SMITH' IN UPSHIFT(empname)) &gt; 0 ;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="power_function">7.82. POWER Function</h3>
<div class="paragraph">
<p>The POWER function returns the value of a numeric value expression
raised to the power of an integer value expression. You can also use the
exponential operator *\*.</p>
</div>
<div class="paragraph">
<p>POWER is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">POWER (numeric-expression-1, numeric-expression-2)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression-1</em>, <em>numeric-expression-2</em></code></p>
<div class="paragraph">
<p>are SQL numeric value expressions that specify the values for the base
and exponent arguments of the POWER function. See
<a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
<div class="paragraph">
<p>If base <em>numeric-expression-1 _is_zero, the exponent _numeric-expression-2</em>
must be greater than zero, and the result is zero. If the exponent is zero,
the base cannot be 0, and the result is 1. If the base is negative, the
exponent must be a value with an exact numeric data type and a scale of zero.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_power">7.82.1. Examples of POWER</h4>
<div class="ulist">
<ul>
<li>
<p>Return the value 15.625:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">POWER (2.5,3)</code></pre>
</div>
</div>
</li>
<li>
<p>Return the value 27. The function POWER raised to the power of 2 is
the inverse of the function SQRT:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">POWER (SQRT(27),2)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="quarter_function">7.83. QUARTER Function</h3>
<div class="paragraph">
<p>The QUARTER function converts a DATE or TIMESTAMP expression into an
INTEGER value in the range 1 through 4 that represents the corresponding
quarter of the year. Quarter 1 represents January 1 through March 31,
and so on.</p>
</div>
<div class="paragraph">
<p>QUARTER is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">QUARTER (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_quarter">7.83.1. Examples of QUARTER</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the quarter of the year from the
START_DATE column in the PROJECT table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, QUARTER(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ------
2008-04-10 2008-04-21 08:15:00.000000 2</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="radians_function">7.84. RADIANS Function</h3>
<div class="paragraph">
<p>The RADIANS function converts a numeric value expression (expressed in
degrees) to the number of radians.</p>
</div>
<div class="paragraph">
<p>RADIANS is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RADIANS (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the RADIANS function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_radians">7.84.1. Examples of RADIANS</h4>
<div class="ulist">
<ul>
<li>
<p>Return the value 7.85398150000000000E-001, or approximately 0.78540 in degrees:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RADIANS (45)</code></pre>
</div>
</div>
</li>
<li>
<p>Return the value 45 in degrees. The function DEGREES is the inverse of
the function RADIANS.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DEGREES (RADIANS (45))</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="runningrank_function">7.85. RANK/RUNNINGRANK Function</h3>
<div class="paragraph">
<p>The RANK/RUNNINGRANK function is a sequence function that returns the
rank of the given value of an intermediate result table ordered by a
SEQUENCE BY clause in a SELECT statement. RANK is an alternative syntax
for RANK/RUNNINGRANK.</p>
</div>
<div class="paragraph">
<p>RANK/RUNNINGRANK is a Trafodion extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGRANK(expression) | RANK(expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><em>expression</em></p>
<div class="paragraph">
<p>specifies the expression on which to perform the rank.</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>RANK/RUNNINGRANK returns the rank of the expression within the
intermediate result table. The definition of rank is as follows:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RANK = 1 for the first value of the intermediate result table.
= the previous value of RANK if the previous value of expression is
the same as the current value of expression.
= RUNNINGCOUNT(*) otherwise.</code></pre>
</div>
</div>
<div class="paragraph">
<p>In other words, RANK starts at 1. Values that are equal have the same
rank. The value of RANK advances to the relative position of the row in
the intermediate result when the value changes.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_runningrank">7.85.1. Considerations for RANK/RUNNINGRANK</h4>
<div class="sect4">
<h5 id="sequence_order_dependency">Sequence Order Dependency</h5>
<div class="paragraph">
<p>The RUNNINGRANK function is meaningful only when the given expression is
the leading column of the SEQUENCE BY clause. This is because the
RUNNINGRANK function assumes that the values of expression are in order
and that like values are contiguous. If an ascending order is specified
for expression in the SEQUENCE BY clause, then the RUNNINGRANK function
assigns a rank of 1 to the lowest value of expression. If a descending
order is specified for expression in the SEQUENCE BY clause, then the
RUNNINGRANK function assigns a rank of 1 to the highest value of
expression.</p>
</div>
</div>
<div class="sect4">
<h5 id="runningrank_null_values">NULL Values</h5>
<div class="paragraph">
<p>For the purposes of RUNNINGRANK, NULL values are considered to be equal.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_runningrank">7.85.2. Examples of RANK/RUNNINGRANK</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that <em>seqfcn</em> has been created as:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">CREATE TABLE cat.sch.seqfcn (i1 INTEGER, i2 INTEGER);</code></pre>
</div>
</div>
<div class="paragraph">
<p>The table SEQFCN has columns <em>i1</em> and <em>i2</em> with data:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 15%;">
<col style="width: 85%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">i1</th>
<th class="tableblock halign-left valign-top">i2</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">1</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">3</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">4</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">100</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">2</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">200</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">5</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">300</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">10</p></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">null</p></td>
</tr>
</tbody>
</table>
</li>
<li>
<p>Return the rank of <em>i1</em>:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT i1, RUNNINGRANK(i1) AS rank
FROM cat.sch.seqfcn SEQUENCE BY i1;
i1 rank
----------- --------------------
1 1
2 2
3 3
4 4
5 5
6 6
8 7
10 8
--- 8 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Return the rank of <em>i1</em> descending:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT i1, RUNNINGRANK (i1) AS rank
FROM cat.sch.seqfcn SEQUENCE BY i1 DESC;
i1 rank
----------- --------------------
10 1
8 2
6 3
5 4
4 5
3 6
2 7
1 8
--- 8 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Return the rank of <em>i2</em>, using the alternative RANK syntax:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT i2, RANK (i2) AS rank
FROM cat.sch.seqfcn SEQUENCE BY i2;
i2 rank
----------- --------------------
100 1
100 1
200 3
200 3
200 3
300 6
? 7
? 7
--- 8 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>Notice that the two NULL values received the same rank.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Return the rank of <em>i2</em> descending, using the alternative RANK syntax:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT i2, RANK (i2) AS rank
FROM cat.sch.seqfcn SEQUENCE BY i2 DESC;
i2 rank
----------- --------------------
? 1
? 1
300 3
200 4
200 4
200 4
100 7
100 7
--- 8 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Return the rank of <em>i2</em> descending, excluding NULL values:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT i2, RANK (i2) AS rank
FROM cat.sch.seqfcn WHERE i2 IS NOT NULL SEQUENCE BY i2 DESC;
i2 rank
----------- --------------------
300 1
200 2
200 2
200 2
100 5
100 5
--- 6 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="repeat_function">7.86. REPEAT Function</h3>
<div class="paragraph">
<p>The REPEAT function returns a character string composed of the
evaluation of a character expression repeated a specified number of
times.</p>
</div>
<div class="paragraph">
<p>REPEAT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REPEAT (character-expr, count)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expr</em></code></p>
<div class="paragraph">
<p>specifies the source string from which to return the specified number of
repeated strings. The source string is an SQL character value expression.
The operand is the result of evaluating <em>character-expr</em>.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>count</em></code></p>
</li>
</ul>
</div>
<div class="paragraph">
<p>specifies the number of times the source string <em>character-expr</em> is to
be repeated. The number count must be a value greater than or equal
to zero of exact numeric data type and with a scale of zero.</p>
</div>
<div class="sect3">
<h4 id="examples_of_repeat">7.86.1. Examples of REPEAT</h4>
<div class="ulist">
<ul>
<li>
<p>Return this quote from Act 5, Scene 3, of King Lear:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REPEAT ('Never,', 5)
Never,Never,Never,Never,Never,</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="replace_function">7.87. REPLACE Function</h3>
<div class="paragraph">
<p>The REPLACE function returns a character string where all occurrences of
a specified character string in the original string are replaced with
another character string. All three character value expressions must be
comparable types. The return value is the VARCHAR type.</p>
</div>
<div class="paragraph">
<p>REPLACE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">REPLACE (char-expr-1, char-expr-2, char-expr-3)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>char-expr-1</em>, <em>char-expr-2</em>, <em>char-expr-3</em></code></p>
<div class="paragraph">
<p>are SQL character value expressions. The operands are the result of
evaluating the character expressions. All occurrences of <em>char-expr-2</em>
in <em>char-expr-1</em> are replaced by <em>char-expr-3</em>.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_replace">7.87.1. Examples of REPLACE</h4>
<div class="ulist">
<ul>
<li>
<p>Use the REPLACE function to change job descriptions so that occurrences
of the company name are updated:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT jobdesc FROM persnl.job;
job_description
------------------
MANAGER COMNET
PRODUCTION COMNET
ASSEMBLER COMNET
SALESREP COMNET
SYSTEM ANAL COMNET
...
--- 10 row(s) selected.
UPDATE persnl.job
SET jobdesc = REPLACE(jobdesc, 'COMNET', 'TDMNET');
Job Description
------------------
MANAGER TDMNET
PRODUCTION TDMNET
ASSEMBLER TDMNET
SALESREP TDMNET
SYSTEM ANAL TDMNET
...
--- 10 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="right_function">7.88. RIGHT Function</h3>
<div class="paragraph">
<p>The RIGHT function returns the rightmost specified number of characters
from a character expression. Every character, including multi-byte
characters, is treated as one character.</p>
</div>
<div class="paragraph">
<p>RIGHT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RIGHT (character-expr, count)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expr</em></code></p>
<div class="paragraph">
<p>specifies the source string from which to return the rightmost specified
number of characters. The source string is an SQL character value expression.
The operand is the result of evaluating <em>character-expr</em>.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>count</em></code></p>
<div class="paragraph">
<p>specifies the number of characters to return from <em>character-expr</em>.
The number count must be a value of exact numeric data type with a scale
of zero.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_right">7.88.1. Examples of RIGHT</h4>
<div class="ulist">
<ul>
<li>
<p>Return 'smith':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RIGHT('robert_john_smith', 5)</code></pre>
</div>
</div>
</li>
<li>
<p>Suppose that a six-character company literal has been concatenated as
the first six characters to the job descriptions in the JOB table. Use
the RIGHT function to remove the company literal from the job
descriptions:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPDATE persnl.job
SET jobdesc = RIGHT (jobdesc, 12);</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="round_function">7.89. ROUND Function</h3>
<div class="paragraph">
<p>The ROUND function returns the value of <em>numeric_expr</em> rounded to <em>num</em>
places to the right of the decimal point.</p>
</div>
<div class="paragraph">
<p>ROUND is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(numeric-expr [ , num ] )</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expr</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression.</p>
</div>
</li>
<li>
<p><code><em>num</em></code></p>
<div class="paragraph">
<p>specifies the number of places to the right of the decimal point for
rounding. If <em>num</em> is a negative number, all places to the right of the
decimal point and <em>num</em> places to the left of the decimal point are
zeroed. If <em>num</em> is not specified or is 0, then all places to the right
of the decimal point are zeroed.</p>
</div>
<div class="paragraph">
<p>For any exact numeric value, the value <em>numeric_expr</em> is rounded away
from 0 (for example, to x+1 when x.5 is positive and to x-1 when x.5 is
negative). For the inexact numeric values (real, float, and double) the
value <em>numeric_expr</em> is rounded toward the nearest even number.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_round">7.89.1. Examples of ROUND</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value of 123.46.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(123.4567,2)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 123.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(123.4567,0)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 120.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(123.4567,-1)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 0.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(999.0,-4)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 1000.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(999.0.-3)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 2.0E+000.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(1.5E+000,0)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 2.0E+00.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(2.5E+000,0)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of 1.0E+00.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROUND(1.4E+000,0)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="rows_since_function">7.90. ROWS SINCE Function</h3>
<div class="paragraph">
<p>The ROWS SINCE function is a sequence function that returns the number
of rows counted since the specified condition was last true in the
intermediate result table ordered by a SEQUENCE BY clause in a SELECT
statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>Rows since is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROWS_SINCE [INCLUSIVE] (condition [, max-rows])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>INCLUSIVE</code></p>
<div class="paragraph">
<p>specifies the current row is to be considered. If you specify INCLUSIVE,
the condition is evaluated in the current row. Otherwise, the condition
is evaluated beginning with the previous row. If you specify INCLUSIVE
and the condition is true in the current row, ROWS SINCE returns 0.</p>
</div>
</li>
<li>
<p><code><em>condition</em></code></p>
<div class="paragraph">
<p>specifies a condition to be considered for each row in the result table.
Each column in <em>condition</em> must be a column that exists in the result
table. If the condition has never been true for the result table, ROWS
SINCE returns null.</p>
</div>
</li>
<li>
<p><code><em>max-rows</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression of signed data type SMALLINT or
INTEGER that specifies the maximum number of rows from the current row
to consider. If the condition has never been true for <em>max-rows</em> from
the current row, or if <em>max-rows</em> is negative or null, ROWS SINCE
returns null.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_rows_since">7.90.1. Considerations for ROWS SINCE</h4>
<div class="sect4">
<h5 id="counting_the_rows">Counting the Rows</h5>
<div class="paragraph">
<p>If you specify INCLUSIVE, the condition in each row of the result table
is evaluated starting with the current row as row 0 (zero) (up to the
maximum number of rows or the size of the result table). Otherwise, the
condition is evaluated starting with the previous row as row 1.</p>
</div>
<div class="paragraph">
<p>If a row is reached where the condition is true, ROWS SINCE returns the
number of rows counted so far. Otherwise, if the condition is never true
within the result table being considered, ROWS SINCE returns null.
Trafodion SQL then goes to the next row as the new current row.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_rows_since">7.90.2. Examples of ROWS SINCE</h4>
<div class="ulist">
<ul>
<li>
<p>Return the number of rows since the condition <em>i1 IS NULL</em> became true:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ROWS SINCE (i1 IS NULL) AS rows_since_null
FROM mining.seqfcn SEQUENCE BY ts;
rows_since_null
---------------
?
?
1
2
1
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Return the number of rows since the condition <em>i1 &lt; i2</em> became true:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ROWS SINCE (i1&lt;i2), ROWS SINCE INCLUSIVE (i1&lt;i2)
FROM mining.seqfcn SEQUENCE BY ts;
(EXPR) (EXPR)
--------------- ---------------
? 0
1 1
2 0
1 1
2 0
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="rows_since_changed_function">7.91. ROWS SINCE CHANGED Function</h3>
<div class="paragraph">
<p>The ROWS SINCE CHANGED function is a sequence function that returns the
number of rows counted since the specified set of values last changed in
the intermediate result table ordered by a SEQUENCE BY clause in a
SELECT statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>ROWS SINCE CHANGED is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROWS SINCE CHANGED (column-expression-list)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression-list</em></code></p>
<div class="paragraph">
<p>is a comma-separated list that specifies a derived column list
determined by the evaluation of the column expression list.
ROWS SINCE CHANGED returns the number of rows counted since the
values of <em>column-expression-list</em> changed.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_rows_since_changed">7.91.1. Considerations for ROWS SINCE CHANGED</h4>
<div class="sect4">
<h5 id="counting_the_rows">Counting the Rows</h5>
<div class="paragraph">
<p>For the first row in the intermediate result table, the count is 1. For
subsequent rows that have the same value for <em>column-expression-list</em> as
the previous row, the count is 1 plus the count
in the previous row. For subsequent rows that have a different value of
<em>column-expression-list</em>
than the previous row, the count is 1.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_rows_since_changed">7.91.2. Examples of ROWS SINCE CHANGED</h4>
<div class="ulist">
<ul>
<li>
<p>Return the number of rows since the value <em>i1</em> last changed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ROWS SINCE CHANGED (i1)
FROM mining.seqfcn SEQUENCE BY ts;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the number of rows since the values <em>i1</em> and <em>ts</em> last changed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ROWS SINCE CHANGED (i1, ts)
FROM mining.seqfcn SEQUENCE BY ts;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="rpad_function">7.92. RPAD Function</h3>
<div class="paragraph">
<p>The RPAD function pads the right side of a string with the specified
string. Every character in the string, including multi-byte characters,
is treated as one character.</p>
</div>
<div class="paragraph">
<p>RPAD is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RPAD (str, len [, padstr])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>str</em></code></p>
<div class="paragraph">
<p>can be an expression.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>len</em></code></p>
<div class="paragraph">
<p>identifies the desired number of characters to be returned and can be an
expression but must be an integral value. If <em>len</em> is equal to the
length of the string, no change is made. If <em>len</em> is smaller than the
string size, the string is truncated.</p>
</div>
</li>
<li>
<p><code><em>pad-character</em></code></p>
<div class="paragraph">
<p>can be an expression and may be a string.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_rpad_function">7.92.1. Examples of RPAD Function</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns 'kite ':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RPAD('kite', 7)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'ki':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RPAD('kite', 2)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'kite0000':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RPAD('kite', 8, '0')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'go fly a kite':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RPAD('go fly a kite', 13, 'z')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'go fly a kitez'</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RPAD('go fly a kite', 14, 'z')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns 'kitegoflygoflygof':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RPAD('kite', 17, 'gofly' )</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="rtrim_function">7.93. RTRIM Function</h3>
<div class="paragraph">
<p>The RTRIM function removes trailing spaces from a character string. If
you must remove any leading character other than space, use the TRIM
function and specify the value of the character.
See the <a href="#trim_function">TRIM Function</a>.</p>
</div>
<div class="paragraph">
<p>RTRIM is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RTRIM (character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression and specifies the string from which
to trim trailing spaces.</p>
</div>
<div class="paragraph">
<p>See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_rtrim">7.93.1. Considerations for RTRIM</h4>
<div class="sect4">
<h5 id="result_of_rtrim">Result of RTRIM</h5>
<div class="paragraph">
<p>The result is always of type VARCHAR, with maximum length equal to the
fixed length or maximum variable length of <em>character-expression</em>.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_rtrim">7.93.2. Examples of RTRIM</h4>
<div class="ulist">
<ul>
<li>
<p>Return ' Robert':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RTRIM (' Robert ')</code></pre>
</div>
</div>
<div class="paragraph">
<p>See <a href="#trim_function">TRIM Function</a> and <a href="#ltrim_function">LTRIM Function</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="runningavg_function">7.94. RUNNINGAVG Function</h3>
<div class="paragraph">
<p>The RUNNINGAVG function is a sequence function that returns the average
of non-null values of a column up to and including the current row of an
intermediate result table ordered by a SEQUENCE BY clause in a SELECT
statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>RUNNINGAVG is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGAVG (_column-expression_)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
<div class="paragraph">
<p>RUNNINGAVG returns the average of non-null values of <em>column-expression</em>
up to and including the current row.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_runningavg">7.94.1. Considerations for RUNNINGAVG</h4>
<div class="sect4">
<h5 id="equivalent_result">Equivalent Result</h5>
<div class="paragraph">
<p>The result of RUNNINGAVG is equivalent to:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGSUM(column-expr) / RUNNINGCOUNT(*)</code></pre>
</div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_runningavg">7.94.2. Examples of RUNNINGAVG</h4>
<div class="ulist">
<ul>
<li>
<p>Return the average of non-null values of <em>i1</em> up to and including the
current row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT RUNNINGAVG(i1) AS avg_i1
FROM mining.seqfcn SEQUENCE BY ts;
avg_i1
--------------------
6215
17194
11463
9746
10190
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="runningcount_function">7.95. RUNNINGCOUNT Function</h3>
<div class="paragraph">
<p>The RUNNINGCOUNT function is a sequence function that returns the number
of rows up to and including the current row of an intermediate result
table ordered by a SEQUENCE BY clause in a SELECT statement. See
<a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>RUNNINGCOUNT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGCOUNT {(*) | (column-expression)}</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>*</code></p>
<div class="paragraph">
<p>as an argument causes RUNNINGCOUNT(*) to return the number of rows in
the intermediate result table up to and including the current row.</p>
</div>
</li>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression. If <em>column-expression</em> is the argument, RUNNINGCOUNT returns
the number of rows containing non-null values of <em>column-expression</em> in the
intermediate result table up to and including the current row.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_runningcount">7.95.1. Considerations for RUNNINGCOUNT</h4>
<div class="sect4">
<h5 id="no_distinct_clause">No DISTINCT Clause</h5>
<div class="paragraph">
<p>The RUNNINGCOUNT sequence function is defined differently from the COUNT
aggregate function. If you specify DISTINCT for the COUNT aggregate
function, duplicate values are eliminated before COUNT is applied. You
cannot specify DISTINCT for the RUNNINGCOUNT sequence function;
duplicate values are counted.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_runningcount">7.95.2. Examples of RUNNINGCOUNT</h4>
<div class="ulist">
<ul>
<li>
<p>Return the number of rows that include non-null values of <em>i1</em> up to and
including the current row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT RUNNINGCOUNT (i1) AS count_i1
FROM mining.seqfcn SEQUENCE BY ts;
count_i1
------------
1
2
2
3
4
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="runningmax_function">7.96. RUNNINGMAX Function</h3>
<div class="paragraph">
<p>The RUNNINGMAX function is a sequence function that returns the maximum
of values of a column up to and including the current row of an
intermediate result table ordered by a SEQUENCE BY clause in a SELECT
statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>RUNNINGMAX is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGMAX (column-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
<div class="paragraph">
<p>RUNNINGMAX returns the maximum of values of <em>column-expression</em> up to
and including the current row.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_runningmax">7.96.1. Examples of RUNNINGMAX</h4>
<div class="ulist">
<ul>
<li>
<p>Return the maximum of values of <em>i1</em> up to and including the current row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT RUNNINGMAX(i1) AS max_i1
FROM mining.seqfcn SEQUENCE BY ts;
max_i1
------------
6215
28174
28174
28174
28174
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="runningmin_function">7.97. RUNNINGMIN Function</h3>
<div class="paragraph">
<p>The RUNNINGMIN function is a sequence function that returns the minimum
of values of a column up to and including the current row of an
intermediate result table ordered by a SEQUENCE BY clause in a SELECT
statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>RUNNINGMIN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGMIN (column-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
<div class="paragraph">
<p>RUNNINGMIN returns the minimum of values of <em>column-expression</em> up to
and including the current row.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_runningmin">7.97.1. Examples of RUNNINGMIN</h4>
<div class="ulist">
<ul>
<li>
<p>Return the minimum of values of <em>i1</em> up to and including the current row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT RUNNINGMIN(i1) AS min_i1
FROM mining.seqfcn SEQUENCE BY ts;
min_i1
------------
6215
6215
6215
4597
4597
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="runningstddev_function">7.97.2. RUNNINGSTDDEV Function</h4>
<div class="paragraph">
<p>The RUNNINGSTDDEV function is a sequence function that returns the
standard deviation of non-null values of a column up to and including the
current row of an intermediate result table ordered by a SEQUENCE BY
clause in a SELECT statement.
See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>RUNNINGSTDDEV is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGSTDDEV (_column-expression_)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
<div class="paragraph">
<p>RUNNINGSTDDEV returns the standard deviation of non-null values of
<em>column-expression</em> up to and including the current row.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="considerations_for_runningstddev">7.97.3. Considerations for RUNNINGSTDDEV</h4>
<div class="sect4">
<h5 id="equivalent_result">Equivalent Result</h5>
<div class="paragraph">
<p>The result of RUNNINGSTDDEV is equivalent to:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQRT(RUNNINGVARIANCE(column-expression))</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_runningstddev">7.97.4. Examples of RUNNINGSTDDEV</h4>
<div class="ulist">
<ul>
<li>
<p>Return the standard deviation of non-null values of <em>i1</em> up to and
including the current row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT RUNNINGSTDDEV (i1) AS stddev_i1
FROM mining.seqfcn SEQUENCE BY ts;
STDDEV_I1
-------------------------
0.00000000000000000E+000
1.55273578080753976E+004
1.48020166531456112E+004
1.25639147428923072E+004
1.09258501408357232E+004
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>You can use the CAST function for display purposes. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CAST(RUNNINGSTDDEV(i1) AS DEC(18,3))
FROM mining.seqfcn SEQUENCE BY ts;
(EXPR)
--------------------
.000
5527.357
14802.016
12563.914
10925.850
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="runningsum_function">7.98. RUNNINGSUM Function</h3>
<div class="paragraph">
<p>The RUNNINGSUM function is a sequence function that returns the sum of
non-null values of a column up to and including the current row of an
intermediate result table ordered by a SEQUENCE BY clause in a SELECT
statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>RUNNINGSUM is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGSUM (column-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
<div class="paragraph">
<p>RUNNINGSUM returns the sum of non-null values of <em>column-expression</em> up
to and including the current row.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_runningsum">7.98.1. Examples of RUNNINGSUM</h4>
<div class="ulist">
<ul>
<li>
<p>Return the sum of non-null values of <em>i1</em> up to and including the current
row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT RUNNINGSUM(i1) AS sum_i1
FROM mining.seqfcn SEQUENCE BY ts;
sum_i1
--------------------
6215
34389
34389
38986
50952
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="runningvariance_function">7.99. RUNNINGVARIANCE Function</h3>
<div class="paragraph">
<p>The RUNNINGVARIANCE function is a sequence function that returns the
variance of non-null values of a column up to and including the current
row of an intermediate result table ordered by a SEQUENCE BY clause in a
SELECT statement. See <a href="#sequence_by_clause">SEQUENCE BY Clause</a>.</p>
</div>
<div class="paragraph">
<p>RUNNINGVARIANCE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RUNNINGVARIANCE (column-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression.</p>
</div>
<div class="paragraph">
<p>RUNNINGVARIANCE returns the variance of non-null values of
<em>column-expression</em> up to and including the current row.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_runningvariance">7.99.1. Examples of RUNNINGVARIANCE</h4>
<div class="ulist">
<ul>
<li>
<p>Return the variance of non-null values of <em>i1</em> up to and including the
current row:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT RUNNINGVARIANCE(i1) AS variance_i1
FROM mining.seqfcn SEQUENCE BY TS;
variance_i1
-------------------------
0.00000000000000000E+000
2.41098840499999960E+008
2.19099696999999968E+008
1.57851953666666640E+008
1.19374201299999980E+008
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>You can use the CAST function for display purposes. For example:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CAST(RUNNINGVARIANCE (i1) AS DEC (18,3))
FROM mining.seqfcn SEQUENCE BY ts;
(EXPR)
--------------------
.000
241098840.500
219099697.000
157851953.666
119374201.299
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="second_function">7.100. SECOND Function</h3>
<div class="paragraph">
<p>The SECOND function converts a TIME or TIMESTAMP expression into an
INTEGER value in the range 0 through 59 that represents the
corresponding second of the hour.</p>
</div>
<div class="paragraph">
<p>SECOND is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SECOND (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type TIME or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_second">7.100.1. Examples of SECOND</h4>
<div class="ulist">
<ul>
<li>
<p>Return a numeric value that represents the second of the hour from the
<em>ship_timestamp</em> column:</p>
</li>
</ul>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, SECOND(ship_timestamp)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- -----------
2008-04-10 2008-04-21 08:15:00.000000 .000000</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sha_function">7.101. SHA Function</h3>
<div class="paragraph">
<p>Calculates an SHA-1 160-bit checksum for the string, as described in
RFC 3174 (Secure Hash Algorithm). The value is returned as a string of
40 hexadecimal digits, or NULL if the argument was NULL.</p>
</div>
<div class="sect3">
<h4 id="examples_of_sha">7.101.1. examples of SHA</h4>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SELECT SHA1('abc') from dual;
(EXPR)
-----------------------------------------
'a9993e364706816aba3e25717850c26c9cd0d89d'</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sha2_function">7.102. SHA2 Function</h3>
<div class="paragraph">
<p>Calculates the SHA-2 family of hash functions (SHA-224, SHA-256, SHA-384,
and SHA-512). The first argument is the cleartext string to be hashed.
The second argument indicates the desired bit length of the result, which
must have a value of 224, 256, 384, 512.
If either argument is NULL or the hash length is not one of the permitted values,
the return value is NULL. Otherwise, the function result is a hash value containing
the desired number of bits. See the notes at the beginning of this section
about storing hash values efficiently.</p>
</div>
<div class="sect3">
<h4 id="examples_of_sha2">7.102.1. examples of SHA2</h4>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">&gt;&gt;SELECT SHA2('abc', 224) from dual;
(EXPR)
--------------------------------------------------------
'23097d223405d8228642a477bda255b32aadbce4bda0b3f7e36c9da7'</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sign_function">7.103. SIGN Function</h3>
<div class="paragraph">
<p>The SIGN function returns an indicator of the sign of a numeric value
expression. If the value is less than zero, the function returns -1 as
the indicator. If the value is zero, the function returns 0. If the
value is greater than zero, the function returns 1.</p>
</div>
<div class="paragraph">
<p>SIGN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SIGN (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the SIGN function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_sign">7.103.1. Examples of SIGN</h4>
<div class="ulist">
<ul>
<li>
<p>Return the value -1:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SIGN(-20 + 12)</code></pre>
</div>
</div>
</li>
<li>
<p>Return the value 0:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SIGN(-20 + 20)</code></pre>
</div>
</div>
</li>
<li>
<p>Return the value 1:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SIGN(-20 + 22)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sin_function">7.104. SIN Function</h3>
<div class="paragraph">
<p>The SIN function returns the SINE of a numeric value expression, where
the expression is an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>SIN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SIN (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the SIN function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_sin">7.104.1. Examples of SIN</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 3.42052233254419840E-001, or
approximately 0.3420, the sine of 0.3491 (which is 20 degrees):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SIN (0.3491)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sinh_function">7.105. SINH Function</h3>
<div class="paragraph">
<p>The SINH function returns the hyperbolic sine of a numeric value
expression, where the expression is an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>SINH is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SINH (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the SINH function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_sinh">7.105.1. Examples of SINH</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 1.60191908030082560E+000, or
approximately 1.6019, the hyperbolic sine of 1.25:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SINH (1.25)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="space_function">7.105.2. SPACE Function</h4>
<div class="paragraph">
<p>The SPACE function returns a character string consisting of a specified
number of spaces, each of which is 0x20 or 0x0020, depending on the
chosen character set.</p>
</div>
<div class="paragraph">
<p>SPACE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SPACE (length [, char-set-name])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>length</em></code></p>
<div class="paragraph">
<p>specifies the number of characters to be returned. The number <em>count</em>
must be a value greater than or equal to zero of exact numeric data type
and with a scale of zero. <em>length</em> cannot exceed 32768 for the ISO8859-1
or UTF8 character sets.</p>
</div>
</li>
<li>
<p><code><em>char-set-name</em></code></p>
<div class="paragraph">
<p>can be ISO88591 or UTF8. If you do not specify this second argument, the
default is the default character set.</p>
</div>
<div class="paragraph">
<p>The returned character string will be of data type VARCHAR associated
with the character set specified by <em>char-set-name</em>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_space">7.105.3. Examples of SPACE</h4>
<div class="ulist">
<ul>
<li>
<p>Return three spaces:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SPACE(3)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sqrt_function">7.106. SQRT Function</h3>
<div class="paragraph">
<p>The SQRT function returns the square root of a numeric value expression.
SQRT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQRT (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the SQRT function. The value of the argument must not be a
negative number. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_sqrt">7.106.1. Examples of SQRT</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 5.19615242270663232e+000, or
approximately 5.196:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQRT(27)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="stddev_function">7.107. STDDEV Function</h3>
<div class="paragraph">
<p>STDDEV is an aggregate function that returns the standard deviation of a
set of numbers. STDDEV is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">STDDEV ([ALL | DISTINCT] expression [, weight])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ALL | DISTINCT</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the STDDEV of the <em>expression</em>. The default option is ALL, which
causes duplicate values to be included. If you specify DISTINCT,
duplicate values are eliminated before the STDDEV function is applied.
If DISTINCT is specified, you cannot specify <em>weight</em>.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a numeric value expression that determines the values for
which to compute the standard deviation. The <em>expression</em> cannot contain
an aggregate function or a subquery. The DISTINCT clause specifies that
the STDDEV function operates on distinct values from the one-column
table derived from the evaluation of <em>expression</em>.</p>
</div>
</li>
<li>
<p><code><em>weight</em></code></p>
<div class="paragraph">
<p>specifies a numeric value expression that determines the weights of the
values for which to compute the standard deviation. <em>weight</em> cannot
contain an aggregate function or a subquery. <em>weight</em> is defined on
the same table as <em>expression</em>. The one-column table derived from the
evaluation of <em>expression</em> and the one-column table derived from the
evaluation of <em>weight</em> must have the same cardinality.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_stddev">7.107.1. Considerations for STDDEV</h4>
<div class="sect4">
<h5 id="definition_of_stddev">Definition of STDDEV</h5>
<div class="paragraph">
<p>The standard deviation of a value expression is defined to be the square
root of the variance of the expression.
See <a href="#variance_function">VARIANCE Function</a>.</p>
</div>
<div class="paragraph">
<p>Because the definition of variance has <em>N-1</em> in the denominator of the
expression (if weight is not specified), Trafodion SQL returns a
system-defined default setting of zero (and no error) if the number of
rows in the table, or a group of the table, is equal to 1.</p>
</div>
</div>
<div class="sect4">
<h5 id="data_type_of_the_result">Data Type of the Result</h5>
<div class="paragraph">
<p>The data type of the result is always DOUBLE PRECISION.</p>
</div>
</div>
<div class="sect4">
<h5 id="operands_of_the_expression">Operands of the Expression</h5>
<div class="paragraph">
<p>The expression includes columns from the rows of the SELECT result table
but cannot include an aggregate function. These are valid:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">STDDEV (SALARY) STDDEV (SALARY * 1.1)
STDDEV (PARTCOST * QTY_ORDERED)</code></pre>
</div>
</div>
</div>
<div class="sect4">
<h5 id="stddev_nulls">Nulls</h5>
<div class="paragraph">
<p>STDDEV is evaluated after eliminating all nulls from the set. If the
result table is empty, STDDEV returns NULL.</p>
</div>
</div>
<div class="sect4">
<h5 id="float54_and_double_precision_data">FLOAT(54) and DOUBLE PRECISION Data</h5>
<div class="paragraph">
<p>Avoid using large FLOAT(54) or DOUBLE PRECISION values as arguments to
STDDEV. If SUM(x * x) exceeds the value of 1.15792089237316192e77 during the computation
of STDDEV(x), a numeric overflow occurs.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_stddev">7.107.2. Examples of STDDEV</h4>
<div class="ulist">
<ul>
<li>
<p>Compute the standard deviation of the salary of the current employees:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT STDDEV(salary) AS StdDev_Salary FROM persnl.employee;
STDDEV_SALARY
-------------------------
3.57174062500000000E+004
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Compute the standard deviation of the cost of parts in the current
inventory:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT STDDEV (price * qty_available) FROM sales.parts;
(EXPR)
-------------------------
7.13899499999999808E+006
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="substring_function">7.108. SUBSTRING/SUBSTR Function</h3>
<div class="paragraph">
<p>The SUBSTRING function extracts a substring out of a given character
expression. It returns a character string of data type VARCHAR, with a
maximum length equal to the smaller of these two:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The fixed length of the input string (for CHAR-type strings) or the
maximum variable length (for VARCHAR-type strings)</p>
</li>
<li>
<p>The value of the length argument (when a constant is specified) or
32708 (when a non-constant is specified)</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>SUBSTR is equivalent to SUBSTRING.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING (character-expr FROM start-position [FOR length])</code></pre>
</div>
</div>
<div class="paragraph">
<p>or:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING (character-expr, start-position [, length])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expr</em></code></p>
<div class="paragraph">
<p>specifies the source string from which to extract the substring. The
source string is an SQL character value expression. The operand is the
result of evaluating <em>character-expr</em>. See
<a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>start-position</em></code></p>
<div class="paragraph">
<p>specifies the starting position <em>start-position</em> within <em>character-expr</em>
at which to start extracting the substring. <em>start-position</em> must be a
value with an exact numeric data type and a scale of zero.</p>
</div>
</li>
<li>
<p><code><em>length</em></code></p>
<div class="paragraph">
<p>specifies the number of characters to extract from <em>character-expr</em>.
Keep in mind that every character, including multi-byte characters,
counts as one character. <em>length</em> is the length of the extracted
substring and must be a value greater than or equal to zero of exact
numeric data type and with a scale of zero. The <em>length</em> field is
optional, so if you do not specify the substring <em>length</em>, all
characters starting at <em>start-position</em> and continuing until the end of
the character expression are returned.</p>
</div>
<div class="paragraph">
<p>The length field is optional. If you do not specify it, all characters
starting at <em>start-position</em>
and continuing until the end of the <em>character-expr</em> are returned.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="alternative_forms">7.108.1. Alternative Forms</h4>
<div class="ulist">
<ul>
<li>
<p>The SUBSTRING function treats SUBSTRING( <em>string</em> FOR <em>int</em> )
equivalent to SUBSTRING( <em>string</em> FROM 1 FOR <em>int</em> ). The Trafodion
database software already supports the ANSI standard form as:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING(string FROM int [ FOR int ])</code></pre>
</div>
</div>
</li>
<li>
<p>The SUBSTRING function treats SUBSTRING (<em>string</em>, Fromint)
equivalent to SUBSTRING(<em>string</em> FROM <em>Fromint</em>). The Trafodion
database software already supports SUBSTRING (<em>string</em>, <em>Fromint</em>,
<em>Forint</em>) as equivalent to the ANSI standard form:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING(string FROM Fromint FOR Forint)</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="considerations_for_substring">7.108.2. Considerations for SUBSTRING/SUBSTR</h4>
<div class="sect4">
<h5 id="requirements_for_the_expression_length_and_start_position">Requirements for the Expression, Length, and Start Position</h5>
<div class="ulist">
<ul>
<li>
<p>The data types of the substring length and the start position must be
numeric with a scale of zero. Otherwise, an error is returned.</p>
</li>
<li>
<p>If the sum of the start position and the substring length is greater
than the length of the character expression, the substring from the
start position to the end of the string is returned.</p>
</li>
<li>
<p>If the start position is greater than the length of the character
expression, an empty string ('') is returned.</p>
</li>
<li>
<p>The resulting substring is always of type VARCHAR. If the source
character string is an up-shifted CHAR or VARCHAR string, the result is
an up-shifted VARCHAR type.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_substring">7.108.3. Examples of SUBSTRING/SUBSTR</h4>
<div class="ulist">
<ul>
<li>
<p>Extract 'Ro':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING('Robert John Smith' FROM 0 FOR 3)
SUBSTR('Robert John Smith' FROM 0 FOR 3)</code></pre>
</div>
</div>
</li>
<li>
<p>Extract 'John':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING ('Robert John Smith' FROM 8 FOR 4)
SUBSTR ('Robert John Smith' FROM 8 FOR 4)</code></pre>
</div>
</div>
</li>
<li>
<p>Extract 'John Smith':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING ('Robert John Smith' FROM 8)
SUBSTR ('Robert John Smith' FROM 8)</code></pre>
</div>
</div>
</li>
<li>
<p>Extract 'Robert John Smith':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING ('Robert John Smith' FROM 1 FOR 17)
SUBSTR ('Robert John Smith' FROM 1 FOR 17)</code></pre>
</div>
</div>
</li>
<li>
<p>Extract 'John Smith':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING ('Robert John Smith' FROM 8 FOR 15)
SUBSTR ('Robert John Smith' FROM 8 FOR 15)</code></pre>
</div>
</div>
</li>
<li>
<p>Extract 'Ro':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING ('Robert John Smith' FROM -2 FOR 5)
SUBSTR ('Robert John Smith' FROM -2 FOR 5)</code></pre>
</div>
</div>
</li>
<li>
<p>Extract an empty string '':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUBSTRING ('Robert John Smith' FROM 8 FOR 0)
SUBSTR ('Robert John Smith' FROM 8 FOR 0)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sum_function">7.109. SUM Function</h3>
<div class="paragraph">
<p>SUM is an aggregate function that returns the sum of a set of numbers.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUM ([ALL | DISTINCT] expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ALL | DISTINCT</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the SUM of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included. If you specify DISTINCT, duplicate
values are eliminated before the SUM function is applied.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a numeric or interval value expression that determines the
values to sum. The <em>expression</em> cannot contain an aggregate function or
a subquery. The DISTINCT clause specifies that the SUM function operates
on distinct values from the one-column table derived from the evaluation
of <em>expression</em>. All nulls are eliminated before the function is
applied to the set of values. If the result table is empty, SUM returns
NULL. See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_sum">7.109.1. Considerations for SUM</h4>
<div class="sect4">
<h5 id="data_type_and_scale_of_the_result">Data Type and Scale of the Result</h5>
<div class="paragraph">
<p>The data type of the result depends on the data type of the argument. If
the argument is an exact numeric type, the result is LARGEINT. If the
argument is an approximate numeric type, the result
is DOUBLE PRECISION. If the argument is INTERVAL data type, the result
is INTERVAL with the same precision as the argument. The scale of the
result is the same as the scale of the argument. If the argument has no
scale, the result is truncated.</p>
</div>
</div>
<div class="sect4">
<h5 id="operands_of_the_expression">Operands of the Expression</h5>
<div class="paragraph">
<p>The expression includes columns from the rows of the SELECT result
table &#8212; but cannot include an aggregate function. The valid expressions
are:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUM (SALARY)
SUM (SALARY * 1.1)
SUM (PARTCOST * QTY_ORDERED)</code></pre>
</div>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_sum">7.109.2. Examples of SUM</h4>
<div class="ulist">
<ul>
<li>
<p>Compute the total value of parts in the current inventory:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT SUM (price * qty_available) FROM sales.parts;
(EXPR)
---------------------
117683505.96
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="tan_function">7.110. TAN Function</h3>
<div class="paragraph">
<p>The TAN function returns the tangent of a numeric value expression,
where the expression is an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>TAN is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TAN (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the TAN function.
See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_tan">7.110.1. Examples of TAN</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 3.64008908293626880E-001, or
approximately 0.3640, the tangent of 0.3491 (which is 20 degrees):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TAN (0.3491)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="tanh_function">7.110.2. TANH Function</h4>
<div class="paragraph">
<p>The TANH function returns the hyperbolic tangent of a numeric value
expression, where the expression is an angle expressed in radians.</p>
</div>
<div class="paragraph">
<p>TANH is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TANH (numeric-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>numeric-expression</em></code></p>
<div class="paragraph">
<p>is an SQL numeric value expression that specifies the value for the
argument of the TANH
function. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_tanh">7.110.3. Examples of TANH</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 8.48283639957512960E-001 or
approximately 0.8483, the hyperbolic tangent of 1.25:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TANH (1.25)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="this_function">7.111. THIS Function</h3>
<div class="paragraph">
<p>The THIS function is a sequence function that is used in the ROWS SINCE
function to distinguish between the value of the column in the current
row and the value of the column in previous rows (in an intermediate
result table ordered by a SEQUENCE BY clause in a SELECT statement).
See <a href="#rows_since_function">ROWS SINCE Function</a>.</p>
</div>
<div class="paragraph">
<p>THIS is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">THIS (column-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>column-expression</em></code></p>
<div class="paragraph">
<p>specifies a derived column determined by the evaluation of the column
expression. If the value of the expression is null, THIS returns null.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_this">7.111.1. Considerations for THIS</h4>
<div class="sect4">
<h5 id="counting_the_rows">Counting the Rows</h5>
<div class="paragraph">
<p>You can use the THIS function only within the ROWS SINCE function. For
each row, the ROWS SINCE condition is evaluated in two steps:</p>
</div>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>The expression for THIS is evaluated for the current row. This value
becomes a constant.</p>
</li>
<li>
<p>The condition is evaluated for the result table, using a combination
of the THIS constant and the data for each row in the result table,
starting with the previous row as row 1 (up to the maximum number of
rows or the size of the result table).</p>
</li>
</ol>
</div>
<div class="paragraph">
<p>If a row is reached where the condition is true, ROWS SINCE returns the
number of rows counted so far. Otherwise, if the condition is never true
within the result table being considered, ROWS SINCE returns null.
Trafodion SQL then goes to the next row as the new current row and the
THIS constant is reevaluated.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_this">7.111.2. Examples of THIS</h4>
<div class="ulist">
<ul>
<li>
<p>Return the number of rows since the condition <em>i1</em> less than a previous
row became true:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ROWS SINCE (THIS(i1) &lt; i1) AS rows_since_this
FROM mining.seqfcn SEQUENCE BY ts;
rows_since_this
---------------
?
?
1
1
?
--- 5 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="timestampadd_function">7.112. TIMESTAMPADD Function</h3>
<div class="paragraph">
<p>The TIMESTAMPADD function adds the interval of time specified by
<em>interval-ind</em> and <em>num_expr</em> to <em>datetime_expr</em>. If the specified
interval is in years, months, or quarters and the resulting date is not
a valid date, the day will be rounded down to the last day of the result
month. The type of the <em>datetime_expr</em> is returned except when the
<em>interval-ind</em> contains any time component, in which case a TIMESTAMP is
returned.</p>
</div>
<div class="paragraph">
<p>TIMESTAMPADD is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPADD (interval-ind, num-expr, datetime-expr)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>interval-ind</em></code></p>
<div class="paragraph">
<p>is SQL_TSI_YEAR, SQL_TSI_MONTH, SQL_TSI_DAY, SQL_TSI_HOUR,
SQL_TSI_MINUTE, SQL_TSI_SECOND, SQL_TSI_QUARTER, or SQL_TSI_WEEK</p>
</div>
</li>
<li>
<p><code><em>num_expr</em></code></p>
<div class="paragraph">
<p>is an SQL exact numeric value expression that specifies how many
<em>interval-ind</em> units of time are to be added to <em>datetime_expr</em>. If
<em>num_expr</em> has a fractional portion, it is ignored. If <em>num_expr</em> is
negative, the return value precedes <em>datetime_expr</em> by the specified
amount of time.</p>
</div>
</li>
<li>
<p><code><em>datetime_expr</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. The type of the <em>datetime_expr</em> is returned except when the
<em>interval-ind</em> contains any time component, in which case a TIMESTAMP is
returned.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_timestampadd">7.112.1. Examples of TIMESTAMPADD</h4>
<div class="ulist">
<ul>
<li>
<p>This function adds seven days to the date specified in <em>start-date</em>:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPADD (SQL_TSI_DAY, 7, start-date)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '2008-03-06':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPADD (SQL_TSI_WEEK, 1, DATE '2008-02-28')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '1999-02-28':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPADD (SQL_TSI_YEAR, -1, DATE '2000-02-29')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value TIMESTAMP '2003-02-28 13:27:35':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPADD (SQL_TSI_MONTH, -12, TIMESTAMP '2004-02-29 13:27:35')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value TIMESTAMP '2004-02-28 13:27:35':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPADD (SQL_TSI_MONTH, 12, TIMESTAMP '2003-02-28 13:27:35')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value DATE '2008-06-30':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPADD (SQL_TSI_QUARTER, -2, DATE '2008-12-31')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value TIMESTAMP '2008-06-30 23:59:55':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPADD (SQL_TSI_SECOND, -5, DATE '2008-07-01')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="timestampdiff_function">7.113. TIMESTAMPDIFF Function</h3>
<div class="paragraph">
<p>The TIMESTAMPDIFF function returns the integer value for the number of
<em>interval-ind</em> units of time between <em>startdate</em> and <em>enddate</em>. If
<em>enddate</em> precedes <em>startdate</em>, the return value is negative or zero.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPDIFF (interval-ind, startdate, enddate)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>interval-ind</em></code></p>
<div class="paragraph">
<p>is SQL_TSI_YEAR, SQL_TSI_MONTH, SQL_TSI_DAY, SQL_TSI_HOUR,
SQL_TSI_MINUTE, SQL_TSI_SECOND, SQL_TSI_QUARTER, or SQL_TSI_WEEK</p>
</div>
</li>
<li>
<p><code><em>startdate</em></code> and <code><em>enddate</em></code></p>
<div class="paragraph">
<p>are each of type DATE or TIMESTAMP</p>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The method of counting crossed boundaries such as days, minutes, and
seconds makes the result given by TIMESTAMPDIFF consistent across all
data types. The TIMESTAMPDIFF function makes these boundary assumptions:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>A year begins at the start of January 1.</p>
</li>
<li>
<p>A new quarter begins on January 1, April 1, July 1, and October 1.</p>
</li>
<li>
<p>A week begins at the start of Sunday.</p>
</li>
<li>
<p>A day begins at midnight.</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>The result is a signed integer value equal to the number of
<em>interval-ind</em> boundaries crossed between the first and second date. For
example, the number of weeks between Sunday, January 4 and Sunday,
January 1 is 1. The number of months between March 31 and April 1 would
be 1 because the month boundary is crossed from March to April.</p>
</div>
<div class="paragraph">
<p>The TIMESTAMPDIFF function generates an error if the result is out of
range for integer values. For seconds, the maximum number is equivalent
to approximately 68 years. The TIMESTAMPDIFF function generates an error
if a difference in weeks is requested and one of the two dates precedes
January 7 of the year 0001.</p>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_timestampdiff">7.113.1. Examples of TIMESTAMPDIFF</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the value 1 because a 1-second boundary is
crossed even though the two timestamps differ by only one microsecond:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPDIFF
(
SQL_TSI_SECOND
, TIMESTAMP '2006-09-12 11:59:58.999999'
, TIMESTAMP '2006-09-12 11:59:59.000000'
)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 0 because no 1-second boundaries are
crossed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPDIFF
( SQL_TSI_YEAR
, TIMESTAMP '2006-12-31 23:59:59.00000
, TIMESTAMP '2006-12-31 23:59:59.999999'
)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 1 because a year boundary is crossed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPDIFF
( SQL_TSI_YEAR
, TIMESTAMP '2006-12-31 23:59:59.999999'
, TIMESTAMP '2007-01-01 00:00:00.000000;
)</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value 1 because a WEEK boundary is crossed:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPDIFF (SQL_TSI_WEEK, DATE '2006-01-01', DATE '2006-01-09')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the value of -29:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TIMESTAMPDIFF (SQL_TSI_DAY, DATE '2004-03-01', DATE '2004-02-01')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="to_char_function">7.114. TO_CHAR Function</h3>
<div class="paragraph">
<p>The TO_CHAR function converts a datetime value to a character value. The optional
second argument describes the format of the character value.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_CHAR(character-expression [,format-string])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an expression that gives a datetime value.</p>
</div>
</li>
<li>
<p><code><em>format-string</em></code></p>
<div class="paragraph">
<p>is one of the following character string literals:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>'YYYY-MM-DD'</p>
</li>
<li>
<p>'MM/DD/YYYY'</p>
</li>
<li>
<p>'DD.MM.YYYY'</p>
</li>
<li>
<p>'YYYY-MM'</p>
</li>
<li>
<p>'MM/DD/YYYY'</p>
</li>
<li>
<p>'YYYY/MM/DD'</p>
</li>
<li>
<p>'YYYYMMDD'</p>
</li>
<li>
<p>'YY/MM/DD'</p>
</li>
<li>
<p>'MM/DD/YY'</p>
</li>
<li>
<p>'MM-DD-YYYY'</p>
</li>
<li>
<p>'YYYYMM'</p>
</li>
<li>
<p>'DD-MM-YYYY'</p>
</li>
<li>
<p>'DD-MON-YYYY'</p>
</li>
<li>
<p>'DDMONYYYY'</p>
</li>
<li>
<p>'HH:MI:SS'</p>
</li>
<li>
<p>'HH24:MI:SS'</p>
</li>
<li>
<p>'YYYYMMDDHH24MISS'</p>
</li>
<li>
<p>'DD.MM.YYYY:HH24.MI.SS'</p>
</li>
<li>
<p>'YYYY-MM-DD HH24:MI:SS'</p>
</li>
<li>
<p>'YYYYMMDD:HH24:MI:SS'</p>
</li>
<li>
<p>'MMDDYYYY HH24:MI:SS'</p>
</li>
<li>
<p>'MM/DD/YYYY HH24:MI:SS'</p>
</li>
<li>
<p>'DD-MON-YYYY HH:MI:SS'</p>
</li>
<li>
<p>'MONTH DD, YYYY, HH:MI'</p>
</li>
<li>
<p>'DD.MM.YYYY HH24.MI.SS'</p>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Here, YYYY refers to a 4-digit year. YY refers to a two-digit year. MM refers to a two-digit month. MON refers to
a three-letter abbreviation for month ('JAN', 'FEB', 'MAR', 'APR', 'MAY', 'JUN', 'JUL', 'AUG', 'SEP',
'OCT', 'NOV' or 'DEC'). MONTH refers to the month spelled out. In the output value, the month abbreviation or month
will appear in upper case.</p>
</div>
<div class="paragraph">
<p>HH and HH24 refer to a 2-digit hour field. MI refers to a two-digit minutes field. SS refers to a 2-digit seconds field.</p>
</div>
<div class="paragraph">
<p>If the <em>format-string</em> argument is omitted, 'YYYY-MM-DD' is used as the
default for date and timestamp values, and 'HH:MI:SS' is used for time values.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_to_char">7.114.1. Considerations for TO_CHAR</h4>
<div class="paragraph">
<p>If the <em>format-string</em> contains only hour, minute or seconds fields, the input data type must be time or timestamp.</p>
</div>
<div class="paragraph">
<p>If the <em>format-string</em> contains only year, month or day fields, the input data type must be date or timestamp.</p>
</div>
<div class="paragraph">
<p>If the <em>format-string</em> contains all fields, and the input data type is date, the hour, minute and second fields in the result will be filled with zeroes.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_to_char">7.114.2. Examples of TO_CHAR</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the character value '01MAR2016':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_CHAR (DATE '2016-03-01', 'DDMONYYYY')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the character value '01.03.2016 00:00:00':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_CHAR (DATE '2016-03-01', 'DD.MM.YYYY HH24.MI.SS')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the character value '12:05:10':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_CHAR (TIME '12:05:10')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the character value '20160301120510':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_CHAR (TIMESTAMP '2016-03-01 12:05:10','YYYYMMDDHH24MISS')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="to_date_function">7.115. TO_DATE Function</h3>
<div class="paragraph">
<p>The TO_DATE function converts a character value to a date. The optional
second argument describes the format of the character value.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_DATE(character-expression [,format-string])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an expression that gives a character value.</p>
</div>
</li>
<li>
<p><code><em>format-string</em></code></p>
<div class="paragraph">
<p>is one of the following character string literals:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>'YYYY-MM-DD'</p>
</li>
<li>
<p>'MM/DD/YYYY'</p>
</li>
<li>
<p>'DD.MM.YYYY'</p>
</li>
<li>
<p>'YYYY-MM'</p>
</li>
<li>
<p>'MM/DD/YYYY'</p>
</li>
<li>
<p>'YYYY/MM/DD'</p>
</li>
<li>
<p>'YYYYMMDD'</p>
</li>
<li>
<p>'YY/MM/DD'</p>
</li>
<li>
<p>'MM/DD/YY'</p>
</li>
<li>
<p>'MM-DD-YYYY'</p>
</li>
<li>
<p>'YYYYMM'</p>
</li>
<li>
<p>'DD-MM-YYYY'</p>
</li>
<li>
<p>'DD-MON-YYYY'</p>
</li>
<li>
<p>'DDMONYYYY'</p>
</li>
<li>
<p>'YYYYMMDDHH24MISS'</p>
</li>
<li>
<p>'DD.MM.YYYY:HH24.MI.SS'</p>
</li>
<li>
<p>'YYYY-MM-DD HH24:MI:SS'</p>
</li>
<li>
<p>'YYYYMMDD:HH24:MI:SS'</p>
</li>
<li>
<p>'MMDDYYYY HH24:MI:SS'</p>
</li>
<li>
<p>'MM/DD/YYYY HH24:MI:SS'</p>
</li>
<li>
<p>'DD-MON-YYYY HH:MI:SS'</p>
</li>
<li>
<p>'MONTH DD, YYYY, HH:MI'</p>
</li>
<li>
<p>'DD.MM.YYYY HH24.MI.SS'</p>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Here, YYYY refers to a 4-digit year. YY refers to a two-digit year. MM refers to a two-digit month. MON refers to
a three-letter abbreviation for month ('JAN', 'FEB', 'MAR', 'APR', 'MAY', 'JUN', 'JUL', 'AUG', 'SEP',
'OCT', 'NOV' or 'DEC'). MONTH refers to the month spelled out. The month in either MON or MONTH form may be given in lower case, upper case or any mixture.</p>
</div>
<div class="paragraph">
<p>HH and HH24 refer to a 2-digit hour field. MI refers to a two-digit minutes field. SS refers to a 2-digit seconds field.</p>
</div>
<div class="paragraph">
<p>If the <em>format-string</em> argument is omitted, 'YYYY-MM-DD' is used as the
default.</p>
</div>
<div class="sect3">
<h4 id="considerations_for_to_date">7.115.1. Considerations for TO_DATE</h4>
<div class="paragraph">
<p>If the <em>format-string</em> contains hour, minute or seconds fields, the output data type is timestamp. Otherwise,
the output data type is date.</p>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_to_date">7.115.2. Examples of TO_DATE</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the date value '2016-12-07':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_DATE ('2016-12-07')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the date value '2016-07-12':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_DATE ('12-07-2016', 'DD-MM-YYYY')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the date value '2016-12-07':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_DATE ('07DEC2016', 'DDMONYYYY')</code></pre>
</div>
</div>
</li>
<li>
<p>This function returns the timestamp value '2016-12-07 17:05:01.000000':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_DATE ('07.12.2016:17.05.01', 'DD.MM.YYYY:HH24.MI.SS')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="to_time_function">7.116. TO_TIME Function</h3>
<div class="paragraph">
<p>The TO_TIME function converts a character value to a time. The
second argument describes the format of the character value.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_TIME(character-expression ,format-string)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an expression that gives a character value.</p>
</div>
</li>
<li>
<p><code><em>format-string</em></code></p>
<div class="paragraph">
<p>is one of the following character string literals:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>'HH:MI:SS'</p>
</li>
<li>
<p>'HH24:MI:SS'</p>
</li>
</ul>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>Here, HH and HH24 refer to a 2-digit hour field. MI refers to a two-digit minutes field. SS refers to a 2-digit seconds field.</p>
</div>
<div class="sect3">
<h4 id="examples_of_to_time">7.116.1. Examples of TO_TIME</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the time value '17:05:01':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_TIME ('17:05:01', 'HH24:MI:SS')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="to_timestamp_function">7.117. TO_TIMESTAMP Function</h3>
<div class="paragraph">
<p>The TO_TIMESTAMP function converts a character value to a timestamp.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_TIMESTAMP(character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an expression that gives a character value. The expression ia assumed to have the format YYYY-MM-DD HH:MI:SS[.FFFFFF],
where YYYY is a 4-digit year, MM is a 2-digit month, DD is a 2-digit day, HH is a 2-digit hours field, MI is a 2-digit
minutes field, SS is a two-digit seconds field and FFFFFF is an optional microseconds field.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_to_timestamp">7.117.1. Example of TO_TIMESTAMP</h4>
<div class="ulist">
<ul>
<li>
<p>This function returns the timestamp value '2016-12-07 10:01:00':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TO_TIMESTAMP ('2016-12-07 10:01:00')</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="translate_function">7.118. TRANSLATE Function</h3>
<div class="paragraph">
<p>The TRANSLATE function translates a character string from a source
character set to a target character set. The TRANSLATE function changes
both the character string data type and the character set encoding of
the string.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TRANSLATE(character-value-expression USING translation-name)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-value-expression</em></code></p>
<div class="paragraph">
<p>is a character string.</p>
</div>
</li>
<li>
<p><code><em>translation-name</em></code></p>
<div class="paragraph">
<p>is one of these translation names:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 25%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Translation Name</th>
<th class="tableblock halign-left valign-top">Source Character Set</th>
<th class="tableblock halign-left valign-top">Target Character Set</th>
<th class="tableblock halign-left valign-top">Comments</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ISO88591TOUTF8</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ISO88591</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UTF8</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Translates ISO8859-1 characters to UTF8 characters. No data loss is possible.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UTF8TOISO88591</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UTF8</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ISO88591</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Translates UTF8 characters to ISO88591 characters. Trafodion SQL will
display an error if it encounters a Unicode character that cannot be converted to the target character set.</p></td>
</tr>
</tbody>
</table>
</li>
</ul>
</div>
<div class="paragraph">
<p><em>translation-name</em> identifies the translation, source and target
character set. When you translate to the UTF8 character set, no data
loss is possible. However, when Trafodion SQL translates a
<em>character-value-expression</em> from UTF8, it may be that certain
characters cannot be converted to the target character set. Trafodion
SQL reports an error in this case.</p>
</div>
<div class="paragraph">
<p>Trafodion SQL returns a variable-length character string with character
repertoire equal to the character repertoire of the target character set
of the translation and the maximum length equal to the fixed length or
maximum variable length of the source <em>character-value-expression</em>.</p>
</div>
<div class="paragraph">
<p>If you enter an illegal <em>translation-name</em>, Trafodion SQL returns an
error.</p>
</div>
<div class="paragraph">
<p>If the character set for <em>character-value-expression</em> is different from
the source character set as specified in the <em>translation-name</em>,
Trafodion SQL returns an error.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="trim_function">7.119. TRIM Function</h3>
<div class="paragraph">
<p>The TRIM function removes leading and trailing characters from a
character string. Every character, including multi-byte characters, is
treated as one character.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TRIM ([[trim-type] [trim-char] FROM] trim-source)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>trim-type</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">LEADING | TRAILING | BOTH</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>trim-type</em></code></p>
<div class="paragraph">
<p>specifies whether characters are to be trimmed from the leading end
(LEADING), trailing end (TRAILING), or both ends (BOTH) of
<em>trim-source</em>. If you omit <em>trim-type</em>, the default is BOTH.</p>
</div>
</li>
<li>
<p><code><em>trim_char</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression and specifies the character to be
trimmed from <em>trim-source. trim_char</em> has a maximum length of 1. If you omit
<em>trim_char</em>, SQL trims blanks (' ') from <em>trim-source</em>.</p>
</div>
</li>
<li>
<p><code><em>trim-source</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression and specifies the string from which
to trim characters. See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_trim">7.119.1. Considerations for TRIM</h4>
<div class="sect4">
<h5 id="result_of_trim">Result of TRIM</h5>
<div class="paragraph">
<p>The result is always of type VARCHAR, with maximum length equal to the
fixed length or maximum variable length of <em>trim-source</em>. If the
source character string is an up-shifts CHAR or VARCHAR string, the
result is an up-shifts VARCHAR type.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_trim">7.119.2. Examples of TRIM</h4>
<div class="ulist">
<ul>
<li>
<p>Return 'Robert':</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TRIM(' Robert ')</code></pre>
</div>
</div>
</li>
<li>
<p>The EMPLOYEE table defines FIRST_NAME as CHAR(15) and LAST_NAME as
CHAR(20). This expression uses the TRIM function to return the value
'Robert Smith' without extra blanks:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TRIM(first_name) || ' ' || TRIM (last_name)</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="ucase_function">7.120. UCASE Function</h3>
<div class="paragraph">
<p>The UCASE function up-shifts alphanumeric characters. For
non-alphanumeric characters, UCASE returns the same character. UCASE can
appear anywhere in a query where a value can be used, such as in a
select list, an ON clause, a WHERE clause, a HAVING clause, a LIKE
predicate, an expression, or as qualifying a new value in an UPDATE or
INSERT statement. The result returned by the UCASE function is equal to
the result returned by the <a href="#upper_function">UPPER Function</a>
or <a href="#upshift_function">UPSHIFT Function</a>.</p>
</div>
<div class="paragraph">
<p>UCASE returns a string of fixed-length or variable-length character
data, depending on the data type of the input string.</p>
</div>
<div class="paragraph">
<p>UCASE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UCASE (character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies a string of
characters to upshift. See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_ucase">7.120.1. Considerations for UCASE</h4>
<div class="paragraph">
<p>For a UTF8 character_expression, the UCASE function up-shifts all
lowercase or title case characters to uppercase and returns a character
string. If the argument is of type CHAR(<em>n</em>) or VARCHAR(<em>n</em>), the
result is of type VARCHAR(min(3_n_, 2048)), where the maximum length
of VARCHAR is the minimum of 3_n_ or 2048, whichever is smaller.</p>
</div>
<div class="paragraph">
<p>A lowercase character is a character that has the "alphabetic" property
in Unicode Standard 2 and whose Unicode name includes lower. An
uppercase character is a character that has the "alphabetic" property
and whose Unicode name includes upper. A title case character is a
character that has the Unicode "alphabetic" property and whose Unicode
name includes <em>title</em>.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="examples_of_ucase">7.120.2. Examples of UCASE</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that your CUSTOMER table includes an entry for Hotel Oregon.
Select the column CUSTNAME and return in uppercase and lowercase letters
by using the UCASE and LCASE functions:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT custname,UCASE(custname),LCASE(custname) FROM sales.customer;
(EXPR) (EXPR) (EXPR)
----------------- ------------------- ------------------
... ... ...
Hotel Oregon HOTEL OREGON hotel oregon
--- 17 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>See <a href="#lcase_function">LCASE Function</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="upper_function">7.120.3. UPPER Function</h4>
<div class="paragraph">
<p>The UPPER function up-shifts alphanumeric characters. For
non-alphanumeric characters, UCASE returns the same character. UPPER can
appear anywhere in a query where a value can be used, such as in a
select list, an ON clause, a WHERE clause, a HAVING clause, a LIKE
predicate, an expression, or as qualifying a new value in an UPDATE or
INSERT statement. The result returned by the UPPER function is equal to
the result returned by the <a href="#upshift_function">UPSHIFT Function</a> or <a href="#ucase_function">UCASE Function</a>.</p>
</div>
<div class="paragraph">
<p>UPPER returns a string of fixed-length or variable-length character
data, depending on the data type of the input string.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPPER (character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies a string of
characters to upshift.
See <a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_upper">7.120.4. Examples of UPPER</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that your CUSTOMER table includes an entry for Hotel Oregon.
Select the column CUSTNAME and return in uppercase and lowercase letters
by using the UPPER and LOWER functions:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT custname,UPPER(custname),LOWER(custname) FROM sales.customer;
(EXPR) (EXPR) (EXPR)
----------------- ------------------- ------------------
... ... ...
Hotel Oregon HOTEL OREGON hotel oregon
--- 17 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>See <a href="#lower_function">LOWER Function</a>.</p>
</div>
<div class="paragraph">
<p>For examples of when to use the UPPER function,
see <a href="#upshift_function">UPSHIFT Function</a>.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="upshift_function">7.120.5. UPSHIFT Function</h4>
<div class="paragraph">
<p>The UPSHIFT function up-shifts alphanumeric characters. For
non-alphanumeric characters, UCASE returns the same character. UPSHIFT
can appear anywhere in a query where a value can be used, such as in a
select list, an ON clause, a WHERE clause, a HAVING clause, a LIKE
predicate, an expression, or as qualifying a new value in an UPDATE or
INSERT statement. The result returned by the UPSHIFT function is equal
to the result returned by the <a href="#upper_function">UPPER Function</a> or
<a href="#ucase_function">UCASE Function</a>.</p>
</div>
<div class="paragraph">
<p>UPSHIFT returns a string of fixed-length or variable-length character
data, depending on the data type of the input string.</p>
</div>
<div class="paragraph">
<p>UPSHIFT is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">UPSHIFT (character-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>character-expression</em></code></p>
<div class="paragraph">
<p>is an SQL character value expression that specifies a string of
characters to upshift. See
<a href="#character_value_expressions">Character Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_upshift">7.120.6. Examples of UPSHIFT</h4>
<div class="ulist">
<ul>
<li>
<p>Suppose that your CUSTOMER table includes an entry for Hotel Oregon.
Select the column CUSTNAME and return a result in uppercase and
lowercase letters by using the UPSHIFT, UPPER, and LOWER functions:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT UPSHIFT(custname), UPPER(custname), UCASE(custname)
FROM sales.customer;
(EXPR) (EXPR) (EXPR)
----------------- ------------------- ------------------
... ... ...
HOTEL OREGON HOTEL OREGON HOTEL OREGON
--- 17 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>Perform a case-insensitive search for the DataSpeed customer:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT *
FROM sales.customer
WHERE UPSHIFT (custname) = 'DATASPEED';
CUSTNAME STREET CITY ...
---------- -------------------- --------- ...
DataSpeed 300 SAN GABRIEL WAY NEW YORK ...
--- 1 row(s) selected.</code></pre>
</div>
</div>
<div class="paragraph">
<p>In the table, the name can be in lowercase, uppercase, or mixed case letters.</p>
</div>
</li>
<li>
<p>Suppose that your database includes two department tables: DEPT1 and
DEPT2. Return all rows from the two tables in which the department names
have the same value regardless of case:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT *
FROM persnl.dept1 D1, persnl.dept2 D2
WHERE UPSHIFT(D1.deptname) = UPSHIFT(D2.deptname);</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="user_function">7.121. USER Function</h3>
<div class="paragraph">
<p>The USER function returns either the database user name associated with
the specified user ID number or the database user name of the current
user who invoked the function. The current user</p>
</div>
<div class="paragraph">
<p>is the authenticated user who started the session. That database
user name is used for authorization of SQL statements in the current
session.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">USER [(user-id)]</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>user-id</em></code></p>
<div class="paragraph">
<p>is the 32-bit number associated with a database user name.</p>
</div>
<div class="paragraph">
<p>The USER function is similar to the <a href="#authname_function">AUTHNAME Function</a>
and the <a href="#current_user_function">CURRENT USER Function</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_user">7.121.1. Considerations for USER</h4>
<div class="ulist">
<ul>
<li>
<p>This function can be specified only in the top level of a SELECT statement.</p>
</li>
<li>
<p>The value returned is string data type VARCHAR(128) and is in ISO8859-1 encoding.</p>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_user">7.121.2. Examples of USER</h4>
<div class="ulist">
<ul>
<li>
<p>This example shows the database user name of the current user who is
logged in to the session:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT USER FROM (values(1)) x(a);
(EXPR)
-------------------------
TSHAW
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This example shows the database user name associated with the user ID number, 33333:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT USER (33333) FROM (values(1)) x(a);
(EXPR)
-------------------------
DB ROOT
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="variance_function">7.122. VARIANCE Function</h3>
<div class="paragraph">
<p>VARIANCE is an aggregate function that returns the statistical variance
of a set of numbers. VARIANCE is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">VARIANCE ([ALL | DISTINCT] expression [, weight])</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ALL | DISTINCT</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the VARIANCE of the <em>expression</em>. The default option is ALL, which
causes duplicate values to be included. If you specify DISTINCT,
duplicate values are eliminated before the VARIANCE function is applied.
If DISTINCT is specified, you cannot specify <em>weight</em>.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a numeric value expression that determines the values for
which to compute the variance. <em>expression</em> cannot contain an aggregate
function or a subquery. The DISTINCT clause specifies that the VARIANCE
function operates on distinct values from the one-column table derived
from the evaluation of <em>expression</em>.</p>
</div>
</li>
<li>
<p><code><em>weight</em></code></p>
<div class="paragraph">
<p>specifies a numeric value expression that determines the weights of the
values for which to compute the variance. <em>weight</em> cannot contain an
aggregate function or a subquery. <em>weight</em> is defined on the same table
as <em>expression</em>. The one-column table derived from the evaluation of
<em>expression</em> and the one-column table derived from the evaluation of
<em>weight</em> must have the same cardinality.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="considerations_for_variance">7.122.1. Considerations for VARIANCE</h4>
<div class="sect4">
<h5 id="definition_of_variance">Definition of VARIANCE</h5>
<div class="paragraph">
<p>Suppose that <em>vi</em> are the values in the one-column table derived from
the evaluation of <em>expression</em>. <em>N</em> is the cardinality of this
one-column table that is the result of applying the <em>expression</em> to each
row of the source table and eliminating rows that are null.</p>
</div>
<div class="paragraph">
<p>If <em>weight</em> is specified, <em>wi</em> are the values derived from the
evaluation of <em>weight</em>. <em>N</em> is the cardinality of the two-column table
that is the result of applying the <em>expression</em> and <em>weight</em> to each row
of the source table and eliminating rows that have nulls in either
column.</p>
</div>
<div class="sect5">
<h6 id="_definition_when_weight_is_not_specified">Definition When Weight Is Not Specified</h6>
<div class="paragraph">
<p>If <em>weight</em> is not specified, the statistical variance of the values in
the one-column result table is defined as:</p>
</div>
<div class="paragraph">
<p>where <em>vi</em> is the i-th value of <em>expression</em>, <em>v</em> is the average value
expressed in the common data type, and N is the cardinality of the
result table.</p>
</div>
<div class="paragraph">
<p>Because the definition of variance has <em>N-1</em> in the denominator of the
expression (when weight is not specified), Trafodion SQL returns a
default value of zero (and no error) if the number of rows in the table,
or a group of the table, is equal to 1.</p>
</div>
</div>
<div class="sect5">
<h6 id="_definition_when_weight_is_specified">Definition When Weight Is Specified</h6>
<div class="paragraph">
<p>If <em>weight</em> is specified, the statistical variance of the values in the
two-column result table is defined as:</p>
</div>
<div class="paragraph">
<p>where vi is the i-th value of <em>expression</em>, <em>wi</em> is the i-th value of
<em>weight</em>, <em>vw</em> is the weighted average value expressed in the common
data type, and N is the cardinality of the result table.</p>
</div>
</div>
<div class="sect5">
<h6 id="_weighted_average">Weighted Average</h6>
<div class="paragraph">
<p>The weighted average <em>vw</em> of <em>vi</em> and <em>wi</em> is defined as:</p>
</div>
<div class="paragraph">
<p>where vi is the i-th value of <em>expression</em>, <em>wi</em> is the i-th value of
<em>weight</em>, and N is the cardinality of the result table.</p>
</div>
</div>
</div>
<div class="sect4">
<h5 id="data_type_of_the_result">Data Type of the Result</h5>
<div class="paragraph">
<p>The data type of the result is always DOUBLE PRECISION.</p>
</div>
</div>
<div class="sect4">
<h5 id="operands_of_the_expression">Operands of the Expression</h5>
<div class="paragraph">
<p>The expression includes columns from the rows of the SELECT result
table &#8212; but cannot include an aggregate function. These expressions are
valid:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">VARIANCE (SALARY) VARIANCE (SALARY * 1.1)
VARIANCE (PARTCOST * QTY_ORDERED)</code></pre>
</div>
</div>
</div>
<div class="sect4">
<h5 id="variance_nulls">Nulls</h5>
<div class="paragraph">
<p>VARIANCE is evaluated after eliminating all nulls from the set. If the
result table is empty, VARIANCE returns NULL.</p>
</div>
</div>
<div class="sect4">
<h5 id="float54_and_double_precision_data">FLOAT(54) and DOUBLE PRECISION Data</h5>
<div class="paragraph">
<p>Avoid using large FLOAT(54) or DOUBLE PRECISION values as arguments to
VARIANCE. If SUM(x * x) exceeds the value of 1.15792089237316192e77 during
the computation of VARIANCE(x), then a numeric overflow occurs.</p>
</div>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_variance">7.122.2. Examples of VARIANCE</h4>
<div class="ulist">
<ul>
<li>
<p>Compute the variance of the salary of the current employees:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT VARIANCE(salary) AS Variance_Salary FROM persnl.employee;
VARIANCE_SALARY
-------------------------
1.27573263588496116E+009
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>Compute the variance of the cost of parts in the current inventory:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT VARIANCE (price * qty_available) FROM sales.parts;
(EXPR)
-------------------------
5.09652410092950336E+013
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="week_function">7.123. WEEK Function</h3>
<div class="paragraph">
<p>The WEEK function converts a DATE or TIMESTAMP expression into an
INTEGER value in the range 1 through 54 that represents the
corresponding week of the year. If the year begins on a Sunday, the
value 1 will be returned for any datetime that occurs in the first 7
days of the year. Otherwise, the value 1 will be returned for any
datetime that occurs in the partial week before the start of the first
Sunday of the year. The value 53 is returned for datetimes that occur in
the last full or partial week of the year except for leap years that
start on Saturday where December 31 is in the 54th full or partial week.</p>
</div>
<div class="paragraph">
<p>WEEK is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">WEEK (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_week">7.123.1. Examples of WEEK</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the week of the year from the
START_DATE column in the PROJECT table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, WEEK(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- --------------
2008-04-10 2008-04-21 08:15:00.000000 |15</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="year_function">7.124. YEAR Function</h3>
<div class="paragraph">
<p>The YEAR function converts a DATE or TIMESTAMP expression into an
INTEGER value that represents the year.</p>
</div>
<div class="paragraph">
<p>YEAR is a Trafodion SQL extension.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">YEAR (datetime-expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>datetime-expression</em></code></p>
<div class="paragraph">
<p>is an expression that evaluates to a datetime value of type DATE or
TIMESTAMP. See <a href="#datetime_value_expressions">Datetime Value Expressions</a>.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_year">7.124.1. Examples of YEAR</h4>
<div class="ulist">
<ul>
<li>
<p>Return an integer that represents the year from the start date column in
the project table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT start_date, ship_timestamp, YEAR(start_date)
FROM persnl.project
WHERE projcode = 1000;
Start/Date Time/Shipped (EXPR)
---------- -------------------------- ------
2008-04-10 2008-04-21 08:15:00.000000 2008</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="zeroifnull_function">7.125. ZEROIFNULL Function</h3>
<div class="paragraph">
<p>The ZEROIFNULL function returns a value of zero if the expression if
NULL. Otherwise, it returns the value of the expression.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ZEROIFNULL (expression)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a value expression. It must be a numeric data type.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_zeroifnull">7.125.1. Examples of ZEROIFNULL</h4>
<div class="ulist">
<ul>
<li>
<p>ZEROIFNULL returns the value of the column named salary whenever the
column value is not NULL and it returns 0 whenever the column value is
NULL.</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ZEROIFNULL (salary)</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="olap_functions">8. OLAP Functions</h2>
<div class="sectionbody">
<div class="paragraph">
<p>On-line Analytical Process (OLAP) functions provide the capability to partition source data into groups of rows, order the rows in each group and compute aggregates within a window frame for a row.</p>
</div>
<div class="paragraph">
<p>Typically, an OLAP function in SQL is expressed in two components &lt;FUNCTION&gt; and &lt;OVER&gt;: &lt;FUNCTION&gt; specifies the function and the arguments, and &lt;OVER&gt; specifies the partitioning, the ordering and the window frames. &lt;OVER&gt; is sometimes called the window. OLAP functions are used to perform analytic tasks against data sets stored in or computed from a set of tables, such as moving average and ranks.</p>
</div>
<div class="paragraph">
<p>This section describes the syntax and semantics of the OLAP window functions. The OLAP window functions
are ANSI compliant.</p>
</div>
<div class="paragraph">
<p>Trafodion OLAP functions have very similar semantics as Trafodion sequence functions which are SQL extensions and have to be used together with a SEQUENCE BY clause. For more information, see <a href="#sequence_functions">Sequence Functions</a>.</p>
</div>
<div class="sect2">
<h3 id="considerations_for_window_functions">8.1. Considerations for Window Functions</h3>
<div class="paragraph">
<p>These considerations apply to all window functions.</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>The window defined by the <em>inline-window-specification</em> consists of the
rows specified by the <em>window-frame-clause</em>, bounded by the current
partition. If no PARTITION BY clause is specified, the partition is
defined to be all the rows of the intermediate result. If a PARTITION BY
clause is specified, the partition is the set of rows which have the
same values for the expressions specified in the PARTITION clause.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>DISTINCT is not supported for window functions.</p>
</div>
<div class="paragraph">
<p>Use of a FOLLOWING term is not supported. Using a FOLLOWING term results
in an error.</p>
</div>
<div class="paragraph">
<p>If no <em>window-frame-clause</em> is specified, "ROWS BETWEEN UNBOUNDED
PRECEDING AND UNBOUNDED FOLLOWING" is assumed. This clause is not
supported because it involves a FOLLOWING term and will result in an
error.</p>
</div>
<div class="paragraph">
<p>"ROWS CURRENT ROW" is equivalent to "ROWS BETWEEN CURRENT ROW AND
CURRENT ROW".</p>
</div>
<div class="paragraph">
<p>"ROWS <em>preceding-row</em>" is equivalent to "ROWS BETWEEN <em>preceding-row</em>
AND CURRENT ROW".</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="_nulls">8.1.1. Nulls</h4>
<div class="paragraph">
<p>All nulls are eliminated before the function is applied to the set of
values. If the window contains all NULL values, the result of the window
function is NULL.</p>
</div>
<div class="paragraph">
<p>If the specified window for a particular row consists of rows that are
all before the first row of the partition (no rows in the window), the
result of the window function is NULL.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="order_by_clause_supports_expressions_for_olap_functions">8.2. ORDER BY Clause Supports Expressions For OLAP Functions</h3>
<div class="paragraph">
<p>The ORDER BY clause of the OLAP functions now supports expressions.
However, use of multiple OLAP functions with different expressions in
the same query is not supported. The following examples show how
expressions may be used in the ORDER BY clause.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
-1 * annualsalary neg_total
, RANK() OVER (ORDER BY -1 * annualsalary) olap_rank
FROM employee;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Using an aggregate in the ORDER BY clause:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
num
, RANK() OVER (ORDER BY SUM(annualsalary)) olap_rank
FROM employee
GROUP BY num;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Using multiple functions with the same expression in the ORDER BY clause:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
num
, workgroupnum
, RANK() OVER (ORDER BY SUM (annualsalary)*num) olap_rank
, DENSE_RANK() OVER (ORDER BY SUM (annualsalary)*num) olap_drank
, ROW_NUMBER() OVER (ORDER BY SUM (annualsalary)*num) olap_mum
FROM employee
GROUP BY num, workgroupnum, annualsalary;</code></pre>
</div>
</div>
<div class="paragraph">
<p>Using more functions with the same expression in the ORDER BY clause:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
num
, workgroupnum
, annualsalary
, SUM(AnnualSalary) OVER (ORDER BY SUM(annualsalary)*num ROWS UNBOUNDED PRECEDING)
, AVG(AnnualSalary) OVER (ORDER BY SUM(annualsalary)*num ROWS UNBOUNDED PRECEDING)
, MIN(AnnualSalary) OVER (ORDER BY SUM(annualsalary)*num ROWS UNBOUNDED PRECEDING)
, MAX(AnnualSalary) OVER (ORDER BY SUM(annualsalary)*num ROWS UNBOUNDED PRECEDING)
, VARIANCE(AnnualSalary) OVER (ORDER BY SUM(annualsalary)*num ROWS UNBOUNDED PRECEDING)
, STDDEV(AnnualSalary) OVER (ORDER BY SUM(annualsalary)*num ROWS UNBOUNDED PRECEDING)
, COUNT(AnnualSalary) OVER (ORDER BY SUM(annualsalary)*num ROWS UNBOUNDED PRECEDING)
FROM employee
GROUP BY num, workgroupnum, annualsalary;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="limitations_for_window_functions">8.3. Limitations for Window Functions</h3>
<div class="paragraph">
<p>Trafodion supports many ANSI compliant OLAP window functions. These functions include AVG, COUNT, DENSE_RANK, FIRST_VALUE, LAG, LAST_VALUE, LEAD, MAX, MIN, RANK, ROW_NUMBER, STDDEV, SUM, and VARIANCE. However, Trafodion imposes certain limitations on all window functions.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>The ANSI <em>window-clause</em> is not supported by Trafodion. Only the
<em>inline-window-specification</em> is supported. An attempt to use an ANSI
<em>window-clause</em> will result in a syntax error.</p>
</li>
</ul>
</div>
<div class="admonitionblock tip">
<table>
<tr>
<td class="icon">
<i class="fa icon-tip" title="Tip"></i>
</td>
<td class="content">
A window clause provides a mechanism to define and to refer to a window in a SQL query, as illustrated in the following example.
</td>
</tr>
</table>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT EmployeeID, Surname, Salary, State,
AVG( Salary ) OVER Salary_Window
FROM Employees
WINDOW Salary_Window AS ( PARTITION BY State )
ORDER BY State, Surname;</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p>The <em>window-frame-clause</em> cannot contain a FOLLOWING term, either
explicitly or implicitly. Because the default window frame clause
contains an implicit FOLLOWING ("ROWS BETWEEN UNBOUNDED PRECEDING AND
UNBOUNDED FOLLOWING"), the default is not supported. So, practically,
the <em>window-frame-clause</em> is not optional. An attempt to use a FOLLOWING
term, either explicitly or implicitly will result in the "4343" error
message.</p>
</li>
<li>
<p>The window frame units can only be ROWS. RANGE is not supported by
Trafodion. An attempt to use RANGE will result in a syntax error.</p>
<div class="paragraph">
<p>The difference between the two is that the frame with ROWS unit includes all rows regardless of the values in the ORDER BY clause. The frame with RANGE unit will include rows that are identical in value in the ORDER BY clause.</p>
</div>
</li>
<li>
<p>The ANSI <em>window-frame-exclusion-specification</em> is not supported by
Trafodion. An attempt to use a <em>window-frame-exclusion-specification</em>
will result in a syntax error.</p>
<div class="paragraph">
<p>The <em>window-frame-exclusion-specification</em> can exclude rows, such as the current one, the current group, or current ties, from the window is not supported. This specification is not widely implementation by other vendors.</p>
</div>
</li>
<li>
<p>Multiple <em>inline-window-specifications</em> in a single SELECT clause are
not supported. For each window function within a SELECT clause, the
ORDER BY clause and PARTITION BY specifications must be identical. The
window frame can vary within a SELECT clause. An attempt to use multiple
<em>inline-window-specifications</em> in a single SELECT clause will result in
the "4340" error message.</p>
</li>
<li>
<p>The ANSI <em>null-ordering-specification</em> within the ORDER BY clause is
not supported by Trafodion. Null values will always be sorted as if they
are greater than all non-null values. This is slightly different than a
null ordering of NULLS LAST. An attempt to use a
<em>null-ordering-specification</em> will result in a syntax error.</p>
</li>
<li>
<p>The ANSI <em>filter-clause</em> is not supported for window functions by
Trafodion. The <em>filter-clause</em> applies to all aggregate functions
(grouped and windowed) and that the <em>filter-clause</em> is not currently
supported for grouped aggregate functions. An attempt to use a
<em>filter-clause</em> will result in a syntax error.</p>
</li>
<li>
<p>The DISTINCT value for the <em>set-qualifier-clause</em> within a window
function is not supported. Only the ALL value is supported for the
<em>set-qualifier-clause</em> within a window function. An attempt to use
DISTINCT in a window function will result in the "4341" error message.</p>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="avg_window_function">8.4. AVG Window Function</h3>
<div class="paragraph">
<p>AVG is a window function that returns the average of non-null values of
the given expression for the current window specified by the
<em>inline-window specification</em>.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">AVG ([ALL] expression) OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]
[ window-frame-clause ]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> ROWS CURRENT ROW
| ROWS preceding-row
| ROWS BETWEEN preceding-row AND preceding-row
| ROWS BETWEEN preceding-row AND CURRENT ROW
| ROWS BETWEEN preceding-row AND following-row
| ROWS BETWEEN CURRENT ROW AND CURRENT ROW
| ROWS BETWEEN CURRENT ROW AND following-row
| ROWS BETWEEN following-row AND following-row</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>preceding-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED PRECEDING
| unsigned-integer PRECEDING</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>following-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED FOLLOWING
| unsigned-integer FOLLOWING</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the AVG of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a numeric or interval value <em>expression</em> that determines the
values to average. See <a href="#numeric_value_expressions">Numeric Value Expressions</a>
and <a href="#interval_value_expressions">Interval Value Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies_the_window_over_which_the_avg_is_computed. The
<em>inline-window-specification</em> can contain an optional partition by
clause, an optional ORDER BY clause and an optional window frame clause.
The PARTITION BY clause specifies how the intermediate result is
partitioned and the ORDER BY clause specifies how the rows are ordered
within each partition.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>specifies the window within the partition over which the AVG is
computed.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_avg_window_function">8.4.1. Examples of AVG Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the running average value of the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
empnum
, AVG(salary) OVER (ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the running average value of the SALARY column within each
department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, AVG(salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the moving average of salary within each department over a
window of the last 4 rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, AVG(SALARY) OVER (PARTITION BY deptnum ORDER BY empnum ROWS 3 PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="count_window_function">8.5. COUNT Window Function</h3>
<div class="paragraph">
<p>COUNT is a window function that returns the count of the non null values
of the given expression for the current window specified by the
inline-window-specification.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">COUNT {(*) | ([ALL] expression) } OVER inline-window-specification</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]
[ window-frame-clause ]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> ROW CURRENT ROW
| ROW preceding-row
| ROW BETWEEN preceding-row AND preceding-row
| ROW BETWEEN preceding-row AND CURRENT ROW
| ROW BETWEEN preceding-row AND following-row
| ROW BETWEEN CURRENT ROW AND CURRENT ROW
| ROW BETWEEN CURRENT ROW AND following-row
| ROW BETWEEN following-row AND following-row</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>preceding-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED PRECEDING
| unsigned-integer PRECEDING</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>following-row</em></code> is:</p>
</li>
</ul>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED FOLLOWING
| unsigned-integer FOLLOWING</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the COUNT of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a value <em>expression</em> that is to be counted. See
<a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the COUNT is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause, an optional ORDER BY clause and an optional window frame clause.
The PARTITION BY clause specifies how the intermediate result is
partitioned and the ORDER BY clause specifies how the rows are ordered
within each partition.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>specifies the window within the partition over which the COUNT is
computed.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_count_window_function">8.5.1. Examples of COUNT Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the running count of the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
empnum
, COUNT(salary) OVER (ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the running count of the SALARY column within each department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, COUNT(salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the moving count of salary within each department over a window
of the last 4 rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, COUNT(salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS 3 PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the running count of employees within each department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, COUNT(*) OVER (PARTITION BY deptnum ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="dense_rank_window_function">8.6. DENSE_RANK Window Function</h3>
<div class="paragraph">
<p>DENSE_RANK is a window function that returns the ranking of each row of
the current partition specified by the inline-window-specification. The
ranking is relative to the ordering specified in the
inline-window-specification. The return value of DENSE_RANK starts at 1
for the first row of the window. Values of the given expression that are
equal have the same rank. The value of DENSE_RANK advances 1 when the
value of the given expression changes.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">DENSE_RANK() OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the DENSE_RANK is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause and an optional ORDER BY clause. The PARTITION BY clause
specifies how the intermediate result is partitioned and the ORDER BY
clause specifies how the rows are ordered within each partition.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_dense_rank_window_function">8.6.1. Examples of DENSE_RANK Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the dense rank for each employee based on employee number:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
DENSE_RANK() OVER (ORDER BY empnum)
, *
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the dense rank for each employee within each department based
on salary:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
DENSE_RANK() OVER (PARTITION BY deptnum ORDER BY salary)
, *
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="first_value_window_function">8.7. FIRST_VALUE Window Function</h3>
<div class="paragraph">
<p>The FIRST_VALUE window function returns the first value from a sorted partition.</p>
</div>
<div class="paragraph">
<p><code>FIRST_VALUE (expression)</code></p>
</div>
<div class="ulist">
<ul>
<li>
<p><em>expression</em></p>
<div class="paragraph">
<p>Specifies a scalar expression or a column whose value from the first row in the partition is to be returned.</p>
</div>
</li>
</ul>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
Trafodion only supports the function to return first value including null, and it is the default behavior.
</td>
</tr>
</table>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_first_value_window_function">8.7.1. Examples of FIRST_VALUE Window Function</h4>
<div class="paragraph">
<p>Each row returned by the following query contains the employee name, the department number, the salary and the pay difference over the lowest salary in the department.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT ename, deptno, sal,
sal - FIRST_VALUE( sal ) OVER ( PARTITION BY deptno
ORDER BY sal ) diff
FROM emp
ORDER BY deptno, sal;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="lag_window_function">8.8. LAG Window Function</h3>
<div class="paragraph">
<p>The LAG window function can be used to access the previous rows from the same result set without using self-joins. The LAG function takes the same three parameters as the LEAD function with the exception that <code><em>offset</em></code> specifies the offset to access a row that comes before the current row. The return type of LAG is that of <code><em>expression</em></code>.</p>
</div>
<div class="paragraph">
<p><code>LAG (expression, offset, default-value)</code></p>
</div>
<div class="ulist">
<ul>
<li>
<p><em>expression</em></p>
<div class="paragraph">
<p>Specifies a scalar expression or a column whose value from the previous row is to be returned. If the previous row does not exist in the current group, <code><em>expression</em></code> returns NULL.</p>
</div>
</li>
<li>
<p><em>offset</em></p>
<div class="paragraph">
<p>Specifies an expression that can be evaluated to a positive integer indicating the offset before the current row. For example, a value of 1 accesses the previous row and a value of 3 accesses the third row before the current row.</p>
</div>
</li>
<li>
<p><em>default-value</em></p>
<div class="paragraph">
<p>Specifies the value if the value returned by <code><em>expression</em></code> is NULL.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_lag_window_function">8.8.1. Examples of LAG Window Function</h4>
<div class="paragraph">
<p>The LAG function in the following query returns the plan code of a previous plan and ’N/A’ for the first plan.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT CustomerCode, PlanCode AS CurrentPlanCode,
LAG(PlanCode, 1, 'NA')
OVER (PARTITION BY CustomerCode ORDER BY StartDate ASC) AS LastPlan
FROM CustomerPlan;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="last_value_window_function">8.9. LAST_VALUE Window Function</h3>
<div class="paragraph">
<p>The LAST_VALUE window function is similar to the FIRST_VALUE function with the exception that the value from the last row in a sorted partition is returned.</p>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="lead_window_function">8.10. LEAD Window Function</h3>
<div class="paragraph">
<p>The LEAD window function can be used to access the subsequent rows (or columns from the subsequence rows) from the current rows, without using self-joins. The return type of LEAD is that of <code><em>expression</em></code>.</p>
</div>
<div class="paragraph">
<p><code>LEAD (expression, offset, default-value)</code></p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>Specifies a scalar expression or a column whose value from the subsequent row is to be returned. If the subsequent row does not exist in the current group, <code><em>expression</em></code> returns NULL.</p>
</div>
</li>
<li>
<p><code><em>offset</em></code></p>
<div class="paragraph">
<p>Specifies an expression that can be evaluated to a positive integer indicating the offset after the current row. For example, a value of 1 accesses the next row and a value of 3 accesses the third row from the current row.</p>
</div>
</li>
<li>
<p><code><em>default-value</em></code></p>
<div class="paragraph">
<p>Specifies the value if the value returned by <em>expression</em> is NULL.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_lead_window_function">8.10.1. Examples of LEAD Window Function</h4>
<div class="paragraph">
<p>The LEAD function in the following query returns the start date of next plan and DATEADD function subtracts one day from that date as the end date of the current plan.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT *,
DATEADD(DAY, -1, LEAD(StartDate, 1,'01-Jan-2100')
OVER (PARTITION BY CustomerCode ORDER BY StartDate ASC)) AS EndDate
FROM CustomerPlan</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="max_window_function">8.11. MAX Window Function</h3>
<div class="paragraph">
<p>MAX is a window function that returns the maximum value of all non null
values of the given expression for the current window specified by the
inline-window-specification.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MAX ([ALL] expression) OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]
[ window-frame-clause ]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> ROWS CURRENT ROW
| ROWS preceding-row
| ROWS BETWEEN preceding-row AND preceding-row
| ROWS BETWEEN preceding-row AND CURRENT ROW
| ROWS BETWEEN preceding-row AND following-row
| ROWS BETWEEN CURRENT ROW AND CURRENT ROW
| ROWS BETWEEN CURRENT ROW AND following-row
| ROWS BETWEEN following-row AND following-row</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>preceding-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED PRECEDING
| unsigned-integer PRECEDING</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>following-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED FOLLOWING
| unsigned-integer FOLLOWING</code></pre>
</div>
</div>
</li>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the MAX of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies an expression that determines the values over which the MAX is
computed. See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the MAX is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause, an optional ORDER BY clause and an optional window frame clause.
The PARTITION BY clause specifies how the intermediate result is
partitioned and the ORDER BY clause specifies how the rows are ordered
within each partition.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>specifies the window within the partition over which the MAX is
computed.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_max_window_function">8.11.1. Examples of MAX Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the running maximum of the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
empnum
, MAX(salary) OVER (ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the running maximum of the SALARY column within each department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum, MAX(salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the moving maximum of salary within each department over a window of the last 4 rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, MAX(salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS 3 PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="min_window_function">8.12. MIN Window Function</h3>
<div class="paragraph">
<p>MIN is a window function that returns the minimum value of all non null
values of the given expression for the current window specified by the
inline-window-specification.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">MIN ([ALL] expression) OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]
[ window-frame-clause ]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> ROWS CURRENT ROW
| ROWS preceding-row
| ROWS BETWEEN preceding-row AND preceding-row
| ROWS BETWEEN preceding-row AND CURRENT ROW
| ROWS BETWEEN preceding-row AND following-row
| ROWS BETWEEN CURRENT ROW AND CURRENT ROW
| ROWS BETWEEN CURRENT ROW AND following-row
| ROWS BETWEEN following-row AND following-row</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>preceding-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED PRECEDING
| unsigned-integer PRECEDING</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>following-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED FOLLOWING
| unsigned-integer FOLLOWING</code></pre>
</div>
</div>
</li>
<li>
<p>`ALL1</p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the MIN of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies an expression that determines the values over which the MIN is
computed See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the MIN is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause, an optional ORDER BY clause and an optional window frame clause.
The PARTITION BY clause specifies how the intermediate result is
partitioned and the ORDER BY clause specifies how the rows are ordered
within each partition.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>specifies the window within the partition over which the MIN is
computed.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_min_window_function">8.12.1. Examples of MIN Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the running minimum of the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
empnum
, MIN(salary) OVER (ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the running minimum of the SALARY column within each department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, MIN(salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the moving minimum of salary within each department over a window of the last 4 rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, MIN(salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS 3 PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="rank_window_function">8.13. RANK Window Function</h3>
<div class="paragraph">
<p>RANK is a window function that returns the ranking of each row of the
current partition specified by the inline-window-specification. The
ranking is relative to the ordering specified in the
<em>inline-window-specification</em>. The return value of RANK starts at 1 for
the first row of the window. Values that are equal have the same rank.
The value of RANK advances to the relative position of the row in the
window when the value changes.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">RANK() OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the RANK is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause and an optional ORDER BY clause. The PARTITION BY clause
specifies how the intermediate result is partitioned and the ORDER BY
clause specifies how the rows are ordered within each partition.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_rank_window_function">8.13.1. Examples of RANK Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the rank for each employee based on employee number:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
RANK() OVER (ORDER BY empnum)
, *
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the rank for each employee within each department based on salary:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
RANK() OVER (PARTITION BY deptnum ORDER BY salary)
, *
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="row_number_window_function">8.13.2. ROW_NUMBER Window Function</h4>
<div class="paragraph">
<p>ROW_NUMBER is a window function that returns the row number of each row
of the current window specified by the inline-window-specification.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">ROW_NUMBER () OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the ROW_NUMBER is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause and an optional ORDER BY clause. The PARTITION BY clause
specifies how the intermediate result is partitioned and the ORDER BY
clause specifies how the rows are ordered within each partition.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>specifies the window within the partition over which the ROW_NUMBER is
computed.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_row_number_window_function">8.13.3. Examples of ROW_NUMBER Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the row number for each row of the employee table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
ROW_NUMBER () OVER(ORDER BY empnum)
, *
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the row number for each row within each department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
ROW_NUMBER () OVER(PARTITION BY deptnum ORDER BY empnum)
, *
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="stddev_window_function">8.13.4. STDDEV Window Function</h4>
<div class="paragraph">
<p>STDDEV is a window function that returns the standard deviation of non
null values of the given expression for the current window specified by
the inline-window-specification.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">STDDEV ([ALL] expression) OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]
[ window-frame-clause ]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> ROWS CURRENT ROW
| ROWS preceding-row
| ROWS BETWEEN preceding-row AND preceding-row
| ROWS BETWEEN preceding-row AND CURRENT ROW
| ROWS BETWEEN preceding-row AND following-row
| ROWS BETWEEN CURRENT ROW AND CURRENT ROW
| ROWS BETWEEN CURRENT ROW AND following-row
| ROWS BETWEEN following-row AND following-row</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>preceding-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED PRECEDING
| unsigned-integer PRECEDING</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>following-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED FOLLOWING
| unsigned-integer FOLLOWING</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the STDDEV of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a numeric or interval value <em>expression</em> that determines the
values over which STDDEV is computed.</p>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the STDDEV is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause, an optional ORDER BY clause and an optional window frame clause.
The PARTITION BY clause specifies how the intermediate result is
partitioned and the ORDER BY clause specifies how the rows are ordered
within each partition.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>specifies the window within the partition over which the STDDEV is
computed.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_stddev">8.13.5. Examples of STDDEV</h4>
<div class="ulist">
<ul>
<li>
<p>Return the standard deviation of the salary for each row of the
employee table:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
STDDEV(salary) OVER(ORDER BY empnum ROWS UNBOUNDED PRECEDING)
, *
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the standard deviation for each row within each department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
STDDEV() OVER(PARTITION BY deptnum ORDER BY empnum ROWS UNBOUNDED PRECEDING)
, *
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="sum_window_function">8.14. SUM Window Function</h3>
<div class="paragraph">
<p>SUM is a window function that returns the sum of non null values of the
given expression for the current window specified by the
inline-window-specification.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SUM ([ALL] expression) OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]
[ window-frame-clause ]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> ROWS CURRENT ROW
| ROWS preceding-row
| ROWS BETWEEN preceding-row AND preceding-row
| ROWS BETWEEN preceding-row AND CURRENT ROW
| ROWS BETWEEN preceding-row AND following-row
| ROWS BETWEEN CURRENT ROW AND CURRENT ROW
| ROWS BETWEEN CURRENT ROW AND following-row
| ROWS BETWEEN following-row AND following-row</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>preceding-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED PRECEDING
| unsigned-integer PRECEDING</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>following-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED FOLLOWING
| unsigned-integer FOLLOWING</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the SUM of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a numeric or interval value expression that determines the
values to sum. See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the SUM is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause, an optional ORDER BY clause and an optional window frame clause.
The PARTITION BY clause specifies how the intermediate result is
partitioned and the ORDER BY clause specifies how the rows are ordered
within each partition.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>specifies the window within the partition over which the SUM is computed.</p>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_sum_window_function">8.14.1. Examples of SUM Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the running sum value of the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
empnum
, SUM (salary) OVER (ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the running sum of the SALARY column within each department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum, SUM (salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the moving sum of the SALARY column within each department over a window of the last 4 rows:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, SUM (salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS 3 PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="variance_window_function">8.15. VARIANCE Window Function</h3>
<div class="paragraph">
<p>VARIANCE is a window function that returns the variance of non null
values of the given expression for the current window specified by the
inline-window-specification.</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">VARIANCE ([ALL] expression) OVER (inline-window-specification)</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>inline-window-specification</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">[PARTITION BY expression [, expression]...]
[ORDER BY expression [ASC[ENDING] | DESC[ENDING]]
[,expression [ASC[ENDING] | DESC[ENDING]]]...]
[ window-frame-clause ]</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> ROWS CURRENT ROW
| ROWS preceding-row
| ROWS BETWEEN preceding-row AND preceding-row
| ROWS BETWEEN preceding-row AND CURRENT ROW
| ROWS BETWEEN preceding-row AND following-row
| ROWS BETWEEN CURRENT ROW AND CURRENT ROW
| ROWS BETWEEN CURRENT ROW AND following-row
| ROWS BETWEEN following-row AND following-row</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>preceding-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED PRECEDING
| unsigned-integer PRECEDING</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>following-row</em></code> is:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text"> UNBOUNDED FOLLOWING
| unsigned-integer FOLLOWING</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>specifies whether duplicate values are included in the computation of
the VARIANCE of the <em>expression</em>. The default option is ALL, which causes
duplicate values to be included.</p>
</div>
</li>
<li>
<p><code><em>expression</em></code></p>
<div class="paragraph">
<p>specifies a numeric or interval value expression that determines the
values over which the variance is computed.
See <a href="#expressions">Expressions</a>.</p>
</div>
</li>
<li>
<p><code><em>inline-window-specification</em></code></p>
<div class="paragraph">
<p>specifies the window over which the VARIANCE is computed. The
<em>inline-window-specification</em> can contain an optional PARTITION BY
clause, an optional ORDER BY clause and an optional window frame clause.
The PARTITION BY clause specifies how the intermediate result is
partitioned and the ORDER BY clause specifies how the rows are ordered
within each partition.</p>
</div>
</li>
<li>
<p><code><em>window-frame-clause</em></code></p>
<div class="paragraph">
<p>specifies the window within the partition over which the VARIANCE is
computed.</p>
</div>
</li>
</ul>
</div>
<div class="sect3">
<h4 id="examples_of_variance_window_function">8.15.1. Examples of VARIANCE Window Function</h4>
<div class="ulist">
<ul>
<li>
<p>Return the variance of the SALARY column:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
empnum
, VARIANCE (salary) OVER (ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
<li>
<p>Return the variance of the SALARY column within each department:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT
deptnum
, empnum
, VARIANCE (salary) OVER (PARTITION BY deptnum ORDER BY empnum ROWS UNBOUNDED PRECEDING)
FROM persnl.employee;</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="sql_runtime_statistics">9. SQL Runtime Statistics</h2>
<div class="sectionbody">
<div class="paragraph">
<p>The Runtime Management System (RMS) shows the status of queries while
they are running. RMS can service on-demand requests from the Trafodion
Command Interface (TrafCI) to get statistics for a given query ID or for
active queries in a given process. RMS also provides information about
itself to determine the health of the RMS infrastructure.</p>
</div>
<div class="paragraph">
<p>RMS provides the summary statistics for each fragment instance and
detailed statistics for each operator (TDB_ID) of a given active query.
A query is considered active if either the compilation or execution is
in progress. The variable_input column output is returned as a multiple
value pair of the form <em>token=value</em>. For more information, see
<a href="#considerations_obtaining_stats_fragment">Considerations For Obtaining Statistics For Each Fragment-Instance of an Active Query</a>.</p>
</div>
<div class="paragraph">
<p>RMS is enabled and available all the time.</p>
</div>
<div class="sect2">
<h3 id="_pertable_and_operator_statistics">9.1. PERTABLE and OPERATOR Statistics</h3>
<div class="paragraph">
<p>The SQL database engine determines which type of statistics collection
is appropriate for the query. The RMS infrastructure provides the
runtime metrics about a query while a query is executing. You can
identify queries that are using excessive resources, suspend a query to
determine its impact on resources, and cancel a query, when necessary.
PERTABLE statistics count rows and report rows estimated in the
operators in the disk processes and time spent in the ESP processes.
Although PERTABLE statistics can deduce when all the rows have been read
from the disks, it is impossible to correctly assess the current state
of the query.</p>
</div>
<div class="paragraph">
<p>Complex queries such as joins, sorts, and group result sets are often
too large to fit into memory, so intermediate results must overflow to
scratch files. These operators are called Big Memory Operators (BMOs).
Because of the BMOs, RMS provides OPERATOR statistics, which provide a
richer set of statistics so that the current state of a query can be
determined at any time.</p>
</div>
<div class="paragraph">
<p>With OPERATOR statistics, all SQL operators are instrumented and the
following statistics are collected:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>Node time spent in the operator</p>
</li>
<li>
<p>Actual number of rows flowing to the parent operator</p>
</li>
<li>
<p>Estimated number of rows flowing to the parent operator (estimated by the optimizer)</p>
</li>
<li>
<p>Virtual memory used in the BMO</p>
</li>
<li>
<p>Amount of data overflowed to scratch files and read back to the query</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>For more information,
see <a href="#displaying_sql_runtimestatistics">Displaying SQL Runtime Statistics</a>.</p>
</div>
</div>
<div class="sect2">
<h3 id="adaptive_statistics_collection">9.2. Adaptive Statistics Collection</h3>
<div class="paragraph">
<p>The SQL database engine chooses the appropriate statistics collection
type based on the type of query. By default, the SQL database engine
statistics collection is OPERATOR statistics. You can view the
statistics in different formats: PERTABLE, ACCUMULATED, PROGRESS, and
DEFAULT. Statistics Collection is adaptive to ensure that sufficient
statistics information is available without</p>
</div>
<div class="paragraph">
<p>causing any performance impact to the query&#8217;s execution. For some
queries, either no statistics or PERTABLE statistics are collected.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 50%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Query Type</th>
<th class="tableblock halign-left valign-top">Statistics Collection Type</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">OLT optimized queries</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PERTABLE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">Unique queries</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PERTABLE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">CQD</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No statistics</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">SET commands</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No statistics</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">EXPLAIN</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No statistics</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">GET STATISTICS</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No statistics</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><p class="tableblock">All other queries</p></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DEFAULT</pre></div></td>
</tr>
</tbody>
</table>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="retrieving_sql_runtime_statistics">9.3. Retrieving SQL Runtime Statistics</h3>
<div class="sect3">
<h4 id="using_the_get_statistics_command">9.3.1. Using the GET STATISTICS Command</h4>
<div class="paragraph">
<p>The GET STATISTICS command shows statistical information for:</p>
</div>
<div class="ulist">
<ul>
<li>
<p>A single query ID (QID)</p>
</li>
<li>
<p>Active queries for a process ID (PID)</p>
</li>
<li>
<p>RMS itself</p>
</li>
</ul>
</div>
<div class="paragraph">
<p>A query is considered active if either compilation or execution is in
progress. In the case of a SELECT statement, a query is in execution
until the statement or result set is closed. Logically, a query is
considered to be active when the compile end time is -1 and the compile
start time is not -1, or when the execute end time is -1 and the execute
start time is not -1.</p>
</div>
</div>
<div class="sect3">
<h4 id="syntax_of_get_statistics">9.3.2. Syntax of GET STATISTICS</h4>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">GET STATISTICS FOR QID { query-id | CURRENT } [stats-view-type] }
| PID { process-name | [ nodeid, pid ] } [ ACTIVE n ][ stats-view-type ]
| RMS node-num | ALL [ RESET ]
stats-view-type is:
ACCUMULATED | PERTABLE | PROGRESS | DEFAULT</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code>QID</code></p>
<div class="paragraph">
<p>Required keyword if requesting statistics for a specific query.</p>
</div>
</li>
<li>
<p><code><em>query-id</em></code></p>
<div class="paragraph">
<p>is the query ID. You must put the <em>query-id</em> in double quotes if the
user name in the query ID contains lower case letters or if the user
name contains a period.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
The <em>query-id</em> is a unique identifier for the SQL statement
generated when the query is compiled (prepared). The <em>query-id</em> is
visible for queries executed through certain TrafCI commands.
</td>
</tr>
</table>
</div>
</li>
<li>
<p><code>CURRENT</code></p>
<div class="paragraph">
<p>provides statistics for the most recently prepared or executed statement
in the same session where you run the GET STATISTICS FOR QID CURRENT
command. You must issue the GET STATISTICS FOR QID CURRENT command
immediately after the PREPARE or EXECUTE statement.</p>
</div>
</li>
<li>
<p><code>PID</code></p>
<div class="paragraph">
<p>Required keyword if requesting statistics for an active query in a given
process.</p>
</div>
</li>
<li>
<p><code><em>process-name</em></code></p>
<div class="paragraph">
<p>is the name of the process ID (PID) in the format: $Z_nnn_. The
process name can be for the master (MXOSRVR) or executor server process
(ESP). If the process name corresponds to the ESP, the ACTIVE <em>n</em> query
is just the _n_th query in that ESP and might not be the currently
active query in the ESP.</p>
</div>
</li>
<li>
<p><code>ACTIVE <em>n</em></code></p>
<div class="paragraph">
<p>describes which of the active queries for which RMS returns statistics.
ACTIVE 1 is the default. ACTIVE 1 returns statistics for the first
active query. ACTIVE 2 returns statistics for the second active query.</p>
</div>
</li>
<li>
<p><code><em>stats-view-type</em></code></p>
<div class="paragraph">
<p>sets the statistics view type to a different format. Statistics are
collected at the operator level by default. For exceptions, see
<a href="#adaptive_statistics_collection">Adaptive Statistics Collection</a>.</p>
</div>
</li>
<li>
<p><code>ACCUMULATED</code></p>
<div class="paragraph">
<p>causes the statistics to be displayed in an aggregated summary across
all tables in the query.</p>
</div>
</li>
<li>
<p><code>PERTABLE</code></p>
<div class="paragraph">
<p>displays statistics for each table in the query. This is the default
<em>stats-view-type</em> although statistics are collected at the operator
level. If the collection occurs at a lower level due to Adaptive
Statistics, the default is the lowered collection level. For more
information,
see <a href="#adaptive_statistics_collection">Adaptive Statistics Collection</a>.</p>
</div>
</li>
<li>
<p><code>progress</code></p>
<div class="paragraph">
<p>displays rows of information corresponding to each of the big memory
operators (BMO) operators involved in the query, in addition to pertable
<em>stats-view-type</em>. For more information about BMOs,
see <a href="#pertable_and_operator_statistics">Pertable and Operator Statistics</a>.</p>
</div>
</li>
<li>
<p><code>PROGRESS</code></p>
<div class="paragraph">
<p>displays rows of information corresponding to each of the big memory
operators (BMO) operators involved in the query, in addition to pertable
<em>stats-view-type</em>. For more information about BMOs,
see <a href="#pertable_and_operator_statistics">Pertable and Operator Statistics</a>.</p>
</div>
</li>
<li>
<p><code>default</code></p>
<div class="paragraph">
<p>displays statistics in the same way as it is collected.</p>
</div>
</li>
<li>
<p><code>RMS</code></p>
<div class="paragraph">
<p>required keyword if requesting statistics about RMS itself.</p>
</div>
</li>
<li>
<p><code><em>node-num</em></code></p>
<div class="paragraph">
<p>returns the statistics about the RMS infrastructure for a given node.</p>
</div>
</li>
<li>
<p><code>ALL</code></p>
<div class="paragraph">
<p>returns the statistics about the RMS infrastructure for every node in the cluster.</p>
</div>
</li>
<li>
<p><code>RESET</code></p>
<div class="paragraph">
<p>resets the cumulative RMS statistics counters.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="examples_of_get_statistics">9.3.3. Examples of GET STATISTICS</h4>
<div class="paragraph">
<p>These examples show the runtime statistics that various get statistics
commands return. for more information about the runtime statistics and
RMS counters,
see <a href="#displaying_sql_runtime_statistics">Displaying SQL Runtime Statistics</a>.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>This GET STATISTICS command returns PERTABLE statistics for the most
recently executed statement in the same session:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR QID CURRENT;
Qid MXID1100801837021216821167247667200000000030000_59_SQL_CUR_6
Compile Start Time 2011/03/30 07:29:15.332216
Compile End Time 2011/03/30 07:29:15.339467
Compile Elapsed Time 0:00:00.007251
Execute Start Time 2011/03/30 07:29:15.383077
Execute End Time 2011/03/30 07:29:15.470222
Execute Elapsed Time 0:00:00.087145
State CLOSE
Rows Affected 0
SQL Error Code 100
Stats Error Code 0
Query Type SQL_SELECT_NON_UNIQUE Estimated Accessed Rows 0
Estimated Used Rows 0
Parent Qid NONE
Child Qid NONE
Number of SQL Processes 1
Number of Cpus 1
Execution Priority -1
Transaction Id -1
Source String SELECT
CUR_SERVICE,PLAN,TEXT,CUR_SCHEMA,RULE_NAME,APPL_NAME,SESSION_NAME,DSN_NAME,ROLE_NAME,DEFAULT_SCHEMA_ACCESS_ONLY
FROM(VALUES(CAST('HP_DEFAULT_SERVICE' as VARCHAR(50)),CAST(0 AS INT),CAST(0 AS INT),CAST('NEO.USR' as
VARCHAR(260)),CAST('' as VARCHAR(
SQL Source Length 548
Rows Returned 1
First Row Returned Time 2011/03/30 07:29:15.469778
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
SQL Process Busy Time 0
UDR Process Busy Time 0
SQL Space Allocated 32 KB
SQL Space Used 3 KB
SQL Heap Allocated 7 KB
SQL Heap Used 1 KB
EID Space Allocated 0 KB
EID Space Used 0 KB
EID Heap Allocated 0 KB
EID Heap Used 0 KB
Processes Created 0
Process Create Time 0
Request Message Count 0
Request Message Bytes 0
Reply Message Count 0
Reply Message Bytes 0
Scr. Overflow Mode DISK
Scr File Count 0
Scr. Buffer Blk Size 0
Scr. Buffer Blks Read 0
Scr. Buffer Blks Written 0
Scr. Read Count 0
Scr. Write Count 0
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This GET STATISTICS command returns PERTABLE statistics for the
specified query ID (note that this command should be issued in the same
session):</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR QID
+&gt; &quot;MXID1100800517921216818752807267200000000030000_48_SQL_CUR_2&quot;
+&gt; ;
Qid MXID1100800517921216818752807267200000000030000_48_SQL_CUR_2
Compile Start Time 2011/03/30 00:53:21.382211
Compile End Time 2011/03/30 00:53:22.980201
Compile Elapsed Time 0:00:01.597990
Execute Start Time 2011/03/30 00:53:23.079979
Execute End Time -1
Execute Elapsed Time 7:16:13.494563
State OPEN
Rows Affected -1
SQL Error Code 0
Stats Error Code 0
Query Type SQL_SELECT_NON_UNIQUE
Estimated Accessed Rows 2,487,984
Estimated Used Rows 2,487,984
Parent Qid NONE
Child Qid NONE
Number of SQL Processes 129
Number of Cpus 9
Execution Priority -1
Transaction Id 34359956800
Source String select count(*) from
MANAGEABILITY.INSTANCE_REPOSITORY.EVENTS_TEXT K,
MANAGEABILITY.INSTANCE_REPOSITORY.EVENTS_TEXT J,
MANAGEABILITY.INSTANCE_REPOSITORY.EVENTS_TEXT H,
MANAGEABILITY.INSTANCE_REPOSITORY.EVENTS_TEXT G
SQL Source Length 220
Rows Returned 0
First Row Returned Time -1
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
SQL Process Busy Time 830,910,830,000
UDR Process Busy Time 0
SQL Space Allocated 179,049 KB
SQL Space Used 171,746 KB
SQL Heap Allocated 1,140,503 KB
SQL Heap Used 1,138,033 KB
EID Space Allocated 46,080 KB
EID Space Used 42,816 KB
EID Heap Allocated 18,624 KB
EID Heap Used 192 KB
Processes Created 32
Process Create Time 799,702
Request Message Count 202,214
Request Message Bytes 27,091,104
Reply Message Count 197,563
Reply Message Bytes 1,008,451,688
Scr. Overflow Mode DISK
Scr File Count 0
Scr. Buffer Blk Size 0
Scr. Buffer Blks Read 0
Scr. Buffer Blks Written 0
Scr. Read Count 0
Scr. Write Count 0
Table Name
Records Accessed Records Used Disk Message Message Lock Lock Disk Process Open Open
Estimated/Actual Estimated/Actual I/Os Count Bytes Escl wait Busy Time Count Time
MANAGEABILITY.INSTANCE_REPOSITORY.EVENTS_TEXT(H)
621,996 621,996
621,998 621,998 0 441 10,666,384 0 0 303,955 32 15,967
MANAGEABILITY.INSTANCE_REPOSITORY.EVENTS_TEXT(J) 621,996 621,996
621,996 621,996
621,998 621,998 0 439 10,666,384 0 0 289,949 32 19,680
MANAGEABILITY.INSTANCE_REPOSITORY.EVENTS_TEXT(K) 621,996 621,996
621,996 621,996
621,998 621,998 0 439 10,666,384 0 0 301,956 32 14,419
MANAGEABILITY.INSTANCE_REPOSITORY.EVENTS_TEXT(G)
0 621,996
0 0 0 192 4,548,048 0 0 0 32 40,019
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This GET STATISTICS command returns ACCUMULATED statistics for the
most recently executed statement in the same session:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR QID CURRENT ACCUMULATED;
Qid MXID1100802517321216821277534304000000000340000_957_SQL_CUR_6
Compile Start Time 2011/03/30 08:05:07.646667
Compile End Time 2011/03/30 08:05:07.647622
Compile Elapsed Time 0:00:00.000955
Execute Start Time 2011/03/30 08:05:07.652710
Execute End Time 2011/03/30 08:05:07.740461
Execute Elapsed Time 0:00:00.087751
State CLOSE
Rows Affected 0
SQL Error Code 100
Stats Error Code 0
Query Type SQL_SELECT_NON_UNIQUE
Estimated Accessed Rows 0
Estimated Used Rows 0
Parent Qid NONE
Child Qid NONE
Number of SQL Processes 0
Number of Cpus 0
Execution Priority -1
Transaction Id -1
Source String SELECT
CUR_SERVICE,PLAN,TEXT,CUR_SCHEMA,RULE_NAME,APPL_NAME,SESSION_NAME,DSN_NAME,ROLE_NAME,DEFAULT_SCHEMA_ACCESS_ONLY
FROM(VALUES(CAST('HP_DEFAULT_SERVICE' as VARCHAR(50)),CAST(0 AS INT),CAST(0 AS INT),CAST('NEO.SCH' as
VARCHAR(260)),CAST('' as VARCHAR(
SQL Source Length 548
Rows Returned 1
First Row Returned Time 2011/03/30 08:05:07.739827
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
Accessed Rows 0
Used Rows 0
Message Count 0
Message Bytes 0
Stats Bytes 0
Disk IOs 0
Lock Waits 0
Lock Escalations 0
Disk Process Busy Time 0
SQL Process Busy Time 0
UDR Process Busy Time 0
SQL Space Allocated 32 KB
SQL Space Used 3 KB
SQL Heap Allocated 7 KB
SQL Heap Used 1 KB
EID Space Allocated 0 KB
EID Space Used 0 KB
EID Heap Allocated 0 KB
EID Heap Used 0 KB
Opens 0
Open Time 0
Processes Created 0
Process Create Time 0
Request Message Count 0
Request Message Bytes 0
Reply Message Count 0
Reply Message Bytes 0
Scr. Overflow Mode UNKNOWN
Scr. File Count 0
Scr. Buffer Blk Size 0
Scr. Buffer Blks Read 0
Scr. Buffer Blks Written 0
Scr. Read Count 0
Scr. Write Count 0
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>These GET STATISTICS commands return PERTABLE statistics for the first
active query in the specified process ID:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR PID 0,27195;
SQL&gt; GET STATISTICS FOR PID $Z000F3R;</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
</div>
<div class="sect2">
<h3 id="displaying_sql_runtime_statistics">9.4. Displaying SQL Runtime Statistics</h3>
<div class="paragraph">
<p>By default, GET STATISTICS displays table-wise statistics (PERTABLE). If
you want to view the statistics in a different format, use the
appropriate view option of the GET STATISTICS command.</p>
</div>
<div class="paragraph">
<p>RMS provides abbreviated statistics information for prepared statements
and full runtime statistics for executed statements.</p>
</div>
<div class="paragraph">
<p>The following table shows the RMS counters that are returned by GET
STATISTICS, tokens from the STATISTICS table-valued function that relate
to the RMS counters, and descriptions of the counters and tokens.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 25%;">
<col style="width: 25%;">
<col style="width: 50%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Counter Name</th>
<th class="tableblock halign-left valign-top">Tokens in STATISTICS Table-Valued Function</th>
<th class="tableblock halign-left valign-top">Description</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Qid</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Qid</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">A unique ID generated for each query. Each time a SQL statement is prepared, a new query ID is generated.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Compile Start Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CompStartTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time when the query compilation started or time when PREPARE for this query started.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Compile End Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CompEndTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time when the query compilation ended or time when PREPARE for this query ended.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Compile Elapsed Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CompElapsedTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of actual time to prepare the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Execute Start Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ExeStartTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time when query execution started.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Execute End Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ExeEndTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time when query execution ended. When a query is executing, Execute End Time is -1.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Execute Elapsed Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ExeElapsedTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of actual time used by the SQL executor to execute the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>State</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>State</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Internally used.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Rows Affected</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RowsAffected</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Represents the number of rows affected by the INSERT, UPDATE, or DELETE (IUD) SQL statements.
Value of -1 for SELECT statements or non-IUD SQL statements.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL Error Code</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQLErrorCode</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Top-level error code returned by the query, indicating whether the query completed with warnings, errors,
or successfully. A positive number indicates a warning. A negative number indicates an error. The value returned may not be accurate up to the point GET STATISTICS was executed.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Stats Error Code</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>StatsErrorCode</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Error code returned to the statistics collector while obtaining statistics from RMS. If an error code,
counter values may be incorrect. Reissue the GET STATISTICS command.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Query Type</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Estimated Accessed Rows</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Type of DML statement and enum value:<br>
<br>
- SQL_SELECT_UNIQUE=1<br>
- SQL_SELECT_NON_UNIQUE=2<br>
- SQL_INSERT_UNIQUE=3<br>
- SQL_INSERT_NON_UNIQUE=4<br>
- SQL_UPDATE_UNIQUE=5<br>
- SQL_UPDATE_NON_UNIQUE=6<br>
- SQL_DELETE_UNIQUE=7<br>
- SQL_DELETE_NON_UNIQUE=8<br>
- SQL_CONTROL=9<br>
- SQL_SET_TRANSACTION=10<br>
- SQL_SET_CATALOG=11<br>
- SQL_SET_SCHEMA=12<br>
- SQL_CALL_NO_RESULT_SETS=13<br>
- SQL_CALL_WITH_RESULT_SETS=14<br>
- SQL_SP_RESULT_SET=15<br>
- SQL_INSERT_ROWSET_SIDETREE=16<br>
- SQL_CAT_UTIL=17<br>
- SQL_EXE_UTIL=18<br>
- SQL_OTHER=1<br>
- SQL_UNKNOWN=0</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>QueryType</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EstRowsAccessed</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Compiler&#8217;s estimated number of rows accessed by the executor in TSE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Estimated Used Rows</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EstRowsUsed</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Compiler&#8217;s estimated number of rows returned by the executor in TSE after applying the predicates.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Parent Qid</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>parentQid</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">A unique ID for the parent query. If there is no parent query ID associated with the query, RMS returns NONE.
For more information, see <a href="#using_the_parent_query_id">Using the Parent Query ID</a>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Child Qid</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>childQid</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">A unique ID for the child query. If there is no child query, then there will be no child query ID and
RMS returns NONE. For more information, see <a href="#child_query_id">Child Query ID</a>.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Number of SQL Processes</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>numSqlProcs</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Represents the number of SQL processes (excluding TSE processes) involved in executing the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Number of CPUs</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>numCpus</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Represents the number of nodes that SQL is processing the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Transaction ID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>transId</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Represents the transaction ID of the transaction involved in executing the query. When no transaction exists,
the Transaction ID is -1.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Source String</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>sqlSrc</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Contains the first 254 bytes of source string.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL Source Length</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>sqlSrcLen</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The actual length of the SQL source string.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Rows Returned</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>rowsReturned</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Represents the number of rows returned from the root operator at the master executor process.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>First Row Returned Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>firstRowReturnTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Represents the actual time that the first row is returned by the master root operator.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Last Error Before AQR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LastErrorBeforeAQR</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The error code that triggered Automatic Query Retry (AQR) for the most recent retry. If the value is not 0,
this is the error code that triggered the most recent AQR.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Number of AQR retries</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AQRNumRetries</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The number of retries for the current query until now.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Delay before AQR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DelayBeforeAQR</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Delay in seconds that SQL waited before initiating AQR.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No. of times reclaimed</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>reclaimSpaceCnt</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">When a process is under virtual memory pressure, the execution space occupied by the queries executed much
earlier will be reclaimed to free up space for the upcoming queries. This counter represents how many times this particular query is reclaimed.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>statsRowType</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">statsRowType can be one of the following:<br>
<br>
- SQLSTATS_DESC_OPER_STATS=0<br>
- SQLSTATS_DESC_ROOT_OPER_STATS=1<br>
- SQLSTATS_DESC_PERTABLE_STATS=11<br>
- SQLSTATS_DESC_UDR_STATS=13<br>
- SQLSTATS_DESC_MASTER_STATS=15<br>
- SQLSTATS_DESC_RMS_STATS=16<br>
- SQLSTATS_DESC_BMO_STATS=17</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Stats Collection Type</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>StatsType</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Collection type, which is OPERATOR_STATS by default. StatsType can be one of the following:<br>
<br>
- SQLCLI_NO_STATS=0<br>
- SQLCLI_ACCUMULATED_STATS=2<br>
- SQLCLI_PERTABLE_STATS=3<br>
- SQLCLI_OPERATOR_STATS=5</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Accessed Rows (Rows Accessed)</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AccessedRows</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Actual number of rows accessed by the executor in TSE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Used Rows (Rows Used)</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UsedRows</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of rows returned by TSE after applying the predicates. In a push down plan, TSE may not return all the used rows.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Message Count</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NumMessages</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Count of the number of messages sent to TSE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Message Bytes</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MessageBytes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Count of the message bytes exchanged with TSE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Stats Bytes</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>StatsBytes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of bytes returned for statistics counters from TSE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Disk IOs</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DiskIOs</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of physical disk reads for accessing the tables.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Lock Waits</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LockWaits</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of times this statement had to wait on a conflicting lock.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Lock Escalations</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Escalations</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of times row locks escalated to a file lock during the execution of this statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Disk Process Busy Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ProcessBusyTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">An approximation of the total node time in microseconds spent by TSE for executing the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL Process Busy Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CpuTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">An approximation of the total node time in microseconds spent in the master and ESPs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UDR Process Busy Time (same as UDR CPU Time)</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>udrCpuTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">An approximation of the total node time in microseconds spent in the UDR server process.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UDR Server ID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UDRServerId</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">MXUDR process ID.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Recent Request Timestamp</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Actual timestamp of the recent request sent to MXUDR.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Recent Reply Timestamp</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Actual timestamp of the recent request received by MXUDR.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL Space Allocated<sup>1</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SpaceTotal<sup>1</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The amount of "space" type of memory in KB allocated in the master and ESPs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL Space Used<sup>1</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SpaceUsed<sup>1</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "space" type of memory in KB used in master and ESPs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL Heap Allocated<sup>2</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>HeapTotal<sup>2</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "heap" type of memory in KB allocated in master and ESPs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL Heap Used<sup>2</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>HeapUsed<sup>2</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "heap" type of memory in KB used in master and ESPs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EID Space Allocated<sup>1</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Dp2SpaceTotal</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "space" type of memory in KB allocated in the executor in TSEs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EID Space Used<sup>1</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Dp2SpaceUsed</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "space" type of memory in KB used in the executor in TSEs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EID Heap Allocated<sup>2</sup></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Dp2HeapTotal</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "heap" memory in KB allocated in the executor in TSEs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EID Heap Used2</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Dp2HeapUsed</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "heap" memory in KB used in the executor in TSEs involved in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Opens</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Opens</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of OPEN calls performed by the SQL executor on behalf of this statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Open Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OpenTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Time (in microseconds) this process spent doing opens on behalf of this statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Processes Created</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Newprocess</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The number of processes (ESPs and MXCMPs) created by the master executor for this statement.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Process Create Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NewprocessTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The elapsed time taken to create these processes.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Table Name</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AnsiName</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Name of a table in the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Request Message Count</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>reqMsgCnt</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of messages initiated from the master to ESPs or from the ESP to ESPs.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Request Message Bytes</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>regMsgBytes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of message bytes that are sent from the master to ESPs or from the ESP to ESPs as part of the request messages.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Reply Message Count</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>replyMsgCnt</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of reply messages from the ESPs for the message requests.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Reply Message Bytes</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>replyMsgBytes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of bytes sent as part of the reply messages.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Scr. Overflow Mode</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>scrOverFlowMode</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Represents the scratch overflow mode. Modes are DISK_TYPE or SSD_TYPE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Scr. File Count</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>scrFileCount</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of scratch files created to execute the query. Default file size is 2 GB.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Scr. Buffer Blk Size</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>scrBufferBlockSize</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Size of buffer block that is used to read from/write to the scratch file.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Scr. Buffer Blks Read</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>scrBufferRead</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of scratch buffer blocks read from the scratch file.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Scr. Buffer Blks Written</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>scrBufferWritten</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of scratch buffer blocks written to the scratch file. Exact size of scratch file can be obtained
by multiplying Scr. Buffer Blk Size by this counter.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Scr. Read Count</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>scrReadCount</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of file-system calls involved in reading buffer blocks from scratch files. One call reads multiple
buffer blocks at once.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Scr. Write Count</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>scrWriteCount</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of file-system calls involved in writing buffer blocks to scratch files. One call writes multiple
buffer blocks at once.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BMO Heap Used</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>bmoHeapUsed</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "heap" type of memory in KB used in the BMO operator(s). The BMO operators are HASH_JOIN (and
all varieties of HASH_JOIN), HASH_GROUPBY (and all varieties of HASH_GROUPBY), and SORT (and all varieties of SORT).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BMO Heap Total</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>bmoHeapTotal</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of "heap" type of memory in KB allocated in the BMO operator(s).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BMO Heap High Watermark</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>bmoHeapWM</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Maximum amount of memory used in the BMO operator.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BMO Space Buffer Size</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>bmoSpaceBufferSize</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Size in KB for space buffers allocated for the type of memory.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BMO Space Buffer Count</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>bmoSpaceBufferCount</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Count of space buffers allocated for the type of memory.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Records Accessed (Estimated / Actual)</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Actual number of rows accessed by the executor in TSE.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Records Used (Estimated / Actual)</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of rows returned by TSE after applying the predicates. In a push-down plan, TSE may not return all the used rows.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">TDB ID of the operator at the time of execution of the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LCID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Left child operator ID.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RCID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Right child operator ID.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PaID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Parent operator ID (TDB-ID).</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ExID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Explain plan operator ID.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Frag</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Fragment ID to which this operator belongs.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Dispatches</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of times the operator is scheduled in SQL executor.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Oper CPU Time</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OperCpuTime</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Approximation of the node time spent by the operator to execute the query.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Est. Records Used</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Approximation of the number of tuples that would flow up to the parent operator.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Act. Records Used</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Actual number of tuples that flowed up to the parent operator.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ProcessId</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Name of the process ID (PID) in the format: $Znnn. The process name can be for the master (MXOSRVR) or executor
server process (ESP).</p></td>
</tr>
</tbody>
</table>
<div class="olist arabic">
<ol class="arabic">
<li>
<p>Space is memory allocated from a pool owned by the executor. The executor
operators requesting the memory are not expected to return the memory until
the statement is deallocated.</p>
</li>
<li>
<p>Heap memory is used for temporary allocations. Operators may return heap memory before the statement is deallocated.
This allows the memory to be reused as needed.</p>
</li>
</ol>
</div>
<div style="page-break-after: always;"></div>
<div class="sect3">
<h4 id="examples_of_displaying_sql_runtime_statistics">9.4.1. Examples of Displaying SQL Runtime Statistics</h4>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
Some of the output has been reformatted for better document readability.
</td>
</tr>
</table>
</div>
<div class="sect4">
<h5 id="statistics_of_a_prepared_statement">Statistics of a Prepared Statement</h5>
<div class="ulist">
<ul>
<li>
<p>This example shows the output of the currently prepared statement:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR QID CURRENT;
Qid MXID1100000649721215837305997952000000001930000_4200_Q1
Compile Start Time 2010/12/06 10:55:40.931000
Compile End Time 2010/12/06 10:55:42.131845
Compile Elapsed Time 0:00:01.200845
ExecuteStart Time -1
Execute End Time -1
Execute Elapsed Time 0:00:00.000000
State CLOSE
Rows Affected -1
SQL Error Code 0
Stats Error Code 0
Query Type SQL_SELECT_NON_UNIQUE
Estimated Accessed Rows 100,010
Estimated Used Rows 100,010
Parent Qid NONE
Child Qid NONE
Number of SQL Processes 0
Number of Cpus 0
Execution Priority -1
Transaction Id -1
Source String select * from t100k where b in (select b from t10)
SQL Source Length 50
Rows Returned 0
First Row Returned Time -1
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect3">
<h4 id="pertable_statistics_of_an_executing_statement">9.4.2. PERTABLE Statistics of an Executing Statement</h4>
<div class="ulist">
<ul>
<li>
<p>This example shows the PERTABLE statistics of an executing statement:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR QID CURRENT;
Qid MXID1100000649721215837305997952000000001930000_4200_Q1
Compile Start Time 2010/12/06 10:55:40.931000
Compile End Time 2010/12/06 10:55:42.131845
Compile Elapsed Time 0:00:01.200845
Execute Start Time 2010/12/06 10:56:16.254686
Execute End Time 2010/12/06 10:56:18.434873
Execute Elapsed Time 0:00:02.180187
State CLOSE
Rows Affected 0
SQL Error Code 100
Stats Error Code 0
Query Type SQL_SELECT_NON_UNIQUE
Estimated Accessed Rows 100,010
Estimated Used Rows 100,010
Parent Qid NONE
Child Qid NONE
Number of SQL Processes 7
Number of Cpus 1
Execution Priority -1
Transaction Id 18121
Source String select * from t100k where b in (select b from t10)
SQL Source Length 50
Rows Returned 100
First Row Returned Time 2010/12/06 10:56:18.150977
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
SQL Process Busy Time 600,000
UDR Process Busy Time 0
SQL Space Allocated 1,576 KB
SQL Space Used 1,450 KB
SQL Heap Allocated 199 KB
SQL Heap Used 30 KB
EID Space Allocated 704 KB
EID Space Used 549 KB
EID Heap Allocated 582 KB
EID Heap Used 6 KB
Processes Created 4
Process Create Time 750,762
Request Message Count 701
Request Message Bytes 135,088
Reply Message Count 667
Reply Message Bytes 3,427,664
Scr. Overflow Mode DISK
Scr File Count 0
Scr. Buffer Blk Size 0
Scr. Buffer Blks Read 0
Scr. Buffer Blks Written 0
Table Name
Records Accessed Records Used Disk Message Message Lock Lock Disk Process Open Open
Estimated/Actual Estimated/Actual I/Os Count Bytes Escl wait Busy Time Count Time
NEO.SCTEST.T10
10 10
10 10 0 2 5,280 0 0 2,000 32 15,967
NEO.SCTEST.T100K
100,000 100,000
100,000 100,000 0 110 3,235,720 0 0 351,941 4 48,747
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="accumulated_statistics_of_an_executing_statement">9.4.3. ACCUMULATED Statistics of an Executing Statement</h4>
<div class="ulist">
<ul>
<li>
<p>This example shows the ACCUMULATED statistics of an executing statement:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR QID CURRENT ACCUMULATED;
Qid MXID1100000649721215837305997952000000001930000_4200_Q1
Compile Start Time 2010/12/06 10:55:40.931000
Compile End Time 2010/12/06 10:55:42.131845
Compile Elapsed Time 0:00:01.200845
Execute Start Time 2010/12/06 10:56:16.254686
Execute End Time 2010/12/06 10:56:18.434873
Execute Elapsed Time 0:00:02.180187
State CLOSE
Rows Affected 0
SQL Error Code 100
Stats Error Code 0
Query Type SQL_SELECT_NON_UNIQUE
Estimated Accessed Rows 100,010
Estimated Used Rows 100,010
Parent Qid NONE
Child Qid NONE
Number of SQL Processes 7
Number of Cpus 1
Execution Priority -1
Transaction Id 18121
Source String select * from t100k where b in (select b from t10)
SQL Source Length 50
Rows Returned 100
First Row Returned Time 2010/12/06 10:56:18.150977
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
Accessed Rows 100,010
Used Rows 100,010
Message Count 112
Message Bytes 3,241,000
Stats Bytes 2,904
Disk IOs 0
Lock Waits 0
Lock Escalations 0
Disk Process Busy Time 353,941
SQL Process Busy Time 600,000
UDR Process Busy Time 0
SQL Space Allocated 1,576 KB
SQL Space Used 1,450 KB
SQL Heap Allocated 199 KB
SQL Heap Used 30 KB
EID Space Allocated 704 KB
EID Space Used 549 KB
EID Heap Allocated 582 KB
EID Heap Used 6 KB
Opens 4
Open Time 48,747
Processes Created 4
Process Create Time 750,762
Request Message Count 701
Request Message Bytes 135,088
Reply Message Count 667
Reply Message Bytes 3,427,664
Scr. Overflow Mode DISK
Scr. File Count 0
Scr. Buffer Blk Size 0
Scr. Buffer Blks Read 0
Scr. Buffer Blks Written 0
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="progress-statistics-of-an-executing-statement">9.4.4. PROGRESS Statistics of an Executing Statement</h4>
<div class="ulist">
<ul>
<li>
<p>This example shows the PROGRESS statistics of an executing statement:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR QID CURRENT PROGRESS;
Qid MXID1100000649721215837305997952000000001930000_4200_Q1
Compile Start Time 2010/12/06 10:55:40.931000
Compile End Time 2010/12/06 10:55:42.131845
Compile Elapsed Time 0:00:01.200845
Execute Start Time 2010/12/06 10:56:16.254686
Execute End Time 2010/12/06 10:56:18.434873
Execute Elapsed Time 0:00:02.180187
State CLOSE
Rows Affected 0
SQL Error Code 100
Stats Error Code 0
Query Type SQL_SELECT_NON_UNIQUE
Estimated Accessed Rows 100,010
Estimated Used Rows 100,010
Parent Qid NONE
Child Qid NONE
Number of SQL Processes 7
Number of Cpus 1
Execution Priority -1
Transaction Id 18121
Source String select * from t100k where b in (select b from t10)
SQL Source Length 50
Rows Returned 100
First Row Returned Time 2010/12/06 10:56:18.150977
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
SQL Process Busy Time 600,000
SQL Space Allocated 1,576 KB
SQL Space Used 1,450 KB
SQL Heap Allocated 199 KB
SQL Heap Used 30 KB
EID Space Allocated 704 KB
EID Space Used 549 KB
EID Heap Allocated 582 KB
EID Heap Used 6 KB
Processes Created 4
Process Create Time 750,762
Request Message Count 701
Request Message Bytes 135,088
Reply Message Count 667
Reply Message Bytes 3,427,664
Table Name
Records Accessed Records Used Disk Message Message Lock Lock Disk Process Open Open
Estimated/Actual Estimated/Actual I/Os Count Bytes Escl wait Busy Time Count Time
NEO.SCTEST.T10
10 10
10 10 0 2 5,280 0 0 2,000 0 0
NEO.SCTEST.T100K
100,000 100,000
100,000 100,000 0 110 3,235,720 0 0 351,941 4 48,747
Id TDB Mode Phase Phase BMO BMO BMO BMO BMO File Scratch Buffer Cpu
Name Phase Start Heap Heap Heap Space Spacez Count Size/Read/Written Time
Time Used Total WM BufSz BufCnt
16 EX_HASHJ DISK 0 0 56 0 0 -1 0 0 60,000</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="default_statistics_of_an_executing_statement">9.4.5. DEFAULT Statistics of an Executing Statement</h4>
<div class="ulist">
<ul>
<li>
<p>This example shows the DEFAULT statistics of an executing statement:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR QID CURRENT DEFAULT;
Qid MXID1100000649721215837305997952000000001930000_4200_Q1
Compile Start Time 2010/12/06 10:55:40.931000
Compile End Time 2010/12/06 10:55:42.131845
Compile Elapsed Time 0:00:01.200845
Execute Start Time 2010/12/06 10:56:16.254686
Execute End Time 2010/12/06 10:56:18.434873
Execute Elapsed Time 0:00:02.180187
State CLOSE
Rows Affected 0
SQL Error Code 100
Stats Error Code 0
Query Type SQL_SELECT_NON_UNIQUE
Estimated Accessed Rows 100,010
Estimated Used Rows 100,010
Parent Qid NONE
Child Qid NONE
Number of SQL Processes 7
Number of Cpus 1
Execution Priority -1
Transaction Id 18121
Source String select * from t100k where b in (select b from t10)
SQL Source Length 50
Rows Returned 100
First Row Returned Time 2010/12/06 10:56:18.150977
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
Id LCId RCId PaId ExId Frag TDB Name Dispatches Oper CPU Records Records
Time Est. Used Act. Used Details
21 20 . . 10 0 EX_ROOT 15 0 0 100
20 19 . 21 9 0 EX_SPLIT_TOP 13 0 100 100
19 18 . 20 9 0 EX_SEND_TOP 20 0 100 100
18 17 . 19 9 2 EX_SEND_BOTTOM 72 0 100 100
17 16 . 18 9 2 EX_SPLIT_BOTTOM 88 0 100 100
16 15 . 17 8 2 EX_HASHJ 1,314 60,000 100 100
15 14 . 16 7 2 EX_SPLIT_TOP 1,343 20,000 100,000 100,000
14 13 . 15 7 2 EX_SEND_TOP 1,342 120,000 100,000 100,000
13 12 . 14 7 5 EX_SEND_BOTTOM 1,534 200,000 100,000 100,000
12 11 . 13 7 5 EX_SPLIT_BOTTOM 493 70,000 100,000 100,000
11 10 . 12 6 5 EX_SPLIT_TOP 486 70,000 100,000 100,000
10 9 . 11 5 5 EX_PARTN_ACCESS 1,634 60,000 100,000 0
9 8 . 10 5 6 EX_EID_ROOT 12 0 100,000 100,000
8 7 . 9 4 6 EX_DP2_SUBS_OPER 160 170,000 100,000 10
7 6 . 8 3 2 EX_SPLIT_TOP 16 0 10 10
6 5 . 7 3 2 EX_SEND_TOP 17 0 10 10
5 4 . 6 3 3 EX_SEND_BOTTOM 17 0 10 10
4 3 . 5 3 3 EX_SPLIT_BOTTOM 9 0 10 10
3 2 . 4 2 3 EX_PARTN_ACCESS 6 0 10 10
2 1 . 3 2 4 EX_EID_ROOT 3 0 10 0
1 . . 1 1 4 EX_DP2_SUBS_OPER 3 100,000 10 10
--- SQL operation complete.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="using_the_parent_query_id">9.4.6. Using the Parent Query ID</h4>
<div class="paragraph">
<p>When executed, some SQL statements execute additional SQL statements,
resulting in a parent-child relationship. For example, when executed,
the UPDATE STATISTICS, MAINTAIN, and CALL statements execute other SQL
statements called child queries. The child queries might execute even
more child queries, thus introducing a hierarchy of SQL statements with
parent-child relationships. The parent query ID maps the child query to
the immediate parent SQL statement, helping you to trace the child SQL
statement back to the user-issued SQL statement.</p>
</div>
<div class="paragraph">
<p>The parent query ID is available as a counter, Parent Qid, in the
runtime statistics output. See Table 1-1 . A query directly
issued by a user will not have a parent query ID and the counter will
indicate "None."</p>
</div>
</div>
<div class="sect3">
<h4 id="child_query_id">9.4.7. Child Query ID</h4>
<div class="paragraph">
<p>In many cases, a child query will execute in the same node as its
parent. In such cases, the GET STATISTICS report on the parent query ID
will contain a query ID value for the child query which executed most
recently. Conversely, if no child query exists, or the child query is
executing in a different node, no child query ID will be reported.</p>
</div>
<div class="paragraph">
<p>The following examples shows GET STATISTICS output for both the parent
and one child query which are executed when the user issues a CREATE
TABLE AS command:</p>
</div>
<div style="page-break-after: always;"></div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; -- get statistics for the parent query
SQL&gt; GET STATISTICS FOR QID
+&gt; MXID01001091200212164828759544076000000000217DEFAULT_MXCI_USER00_34SQLCI_DML_LAST
+&gt; ;
Qid MXID11001091200212164828759544076000000000217DEFAULT_MXCI_USER00_34SQLCI_DML_LAST
Compile Start Time 2011/02/18 14:49:04.606513
Compile End Time 2011/02/18 14:49:04.631802
Compile Elapsed Time 0:00:00.025289
Execute Start Time 2011/02/18 14:49:04.632142
Execute End Time -1
Execute Elapsed Time 0:03:29.473604
State CLOSE
Rows Affected -1
SQL Error Code 0
Stats Error Code 0
Query Type SQL_INSERT_NON_UNIQUE
Estimated Accessed Rows 0
Estimated Used Rows 0
Parent Qid NONE
Child Qid MXID11001091200212164828759544076000000000217DEFAULT_MXCI_USER00_37_86
Number of SQL Processes 1
Number of Cpus 1
Execution Priority 148
Transaction Id -1
Source String create table odetail hash partition by (ordernum, partnum)
as select * from SALES.ODETAIL;
SQL Source Length 91
Rows Returned 0
First Row Returned Time -1
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
Id LCId RCId PaId ExId Frag TDB Name Dispatches Oper CPU Records Records
Time Est. Used Act. Used Details
2 1 . . 2 0 EX_ROOT 0 0 0 0
1 . . 2 1 0 CREATE_TABLE_AS 0 0 0 0
--- SQL operation complete.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; -- get statistics for the child query
SQL&gt; GET STATISTICS FOR QID
+&gt; MXID11001091200212164828759544076000000000217DEFAULT_MXCI_USER00_37_86
+&gt; ;
Qid MXID01001091200212164828759544076000000000217DEFAULT_MXCI_USER00_37_86
Compile Start Time 2011/02/18 14:49:07.632898
Compile End Time 2011/02/18 14:49:07.987334
Compile Elapsed Time 0:00:00.354436
Execute Start Time 2011/02/18 14:49:07.987539
Execute End Time -1
Execute Elapsed Time 0:02:33.173486
State OPEN
Rows Affected -1
SQL Error Code 0
Stats Error Code 0
Query Type SQL_INSERT_NON_UNIQUE
Estimated Accessed Rows 101
Estimated Used Rows 101
Parent Qid MXID101001091200212164828759544076000000000217DEFAULT_MXCI_USER00_34SQLCI_DML_LAST
Child Qid NONE
Number of SQL Processes 1
Number of Cpus 1
Execution Priority 148
Transaction Id \ARC0101(2).9.9114503
Source String insert using sideinserts into CAT.SCH.ODETAIL select * from SALES.ODETAIL;
SQL Source Length 75
Rows Returned 0
First Row Returned Time -1
Last Error before AQR 0
Number of AQR retries 0
Delay before AQR 0
No. of times reclaimed 0
Stats Collection Type OPERATOR_STATS
Id LCId RCId PaId ExId Frag TDB Name Dispatches Oper CPU Records Records
Time Est. Used Act. Used Details
4 3 . 9 3 0 EX_SPLIT_TOP 1 10,062 100 0
3 2 . 4 2 0 EX_PARTN_ACCESS 66 9,649 100 0
--- SQL operation complete.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="_gathering_statistics_about_rms">9.5. Gathering Statistics About RMS</h3>
<div class="paragraph">
<p>Use the GET STATISTICS FOR RMS command to get information about RMS
itself. The GET STATISTICS FOR RMS statement can be used to retrieve
information about one node or all nodes. An individual report is
provided for each node.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 30%;">
<col style="width: 70%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Counter</th>
<th class="tableblock halign-left valign-top">Description</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CPU</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The node number of the Trafodion cluster.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RMS Version</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Internal version of RMS.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSCP PID</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SQL Statistics control process ID.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSCP Creation Timestamp</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Actual timestamp when SQL statistics control process was created.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSMP PID</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">SQL statistics merge process ID.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSMP Creation Timestamp</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp when SQL statistics merge was created.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Source String Store Len</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Storage length of source string.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Stats Heap Allocated</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of memory allocated by all the queries executing in the given node in the RMS shared segments at this instance of time.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Stats Heap Used</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Amount of memory used by all the queries executing in the given node in the RMS shared segment at this instance of time.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Stats Heap High WM</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">High amount of memory used by all the queries executing in the given node in the RMS shared segment until now.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No. of Process Regd.</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of processes registered in the shared segment.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No. of Query Fragments Regd.</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of query fragments registered in the shared segment.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RMS Semaphore Owner</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Process ID that locked the semaphore at this instance of time.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No. of SSCPs Opened</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of Statistics Control Processes opened. Normally, this should be equal to the number of nodes in the Trafodion cluster.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>No. of SSCPs Open Deleted</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of Statistics Control Processes with broken communication. Usually, this should be 0.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Last GC Time</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">The recent timestamp at which the shared segment was garbage collected.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Queries GCed in Last Run</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of queries that were garbage collected in the recent GC run.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>Total Queries GCed</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Total number of queries that were garbage collected since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSMP Request Message Count</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Count of the number of messages sent from the SSMP process since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSMP Request Message Bytes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of messages bytes that are sent as part of the request from the SSMP process since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSMP Reply Message Count</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Count of the number of reply messages received by the SSMP process since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSMP Reply Message Bytes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of messages bytes that are sent as part of the reply messages received by the SSMP process since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSCP Request Message Count</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Count of the number of messages sent from the SSCP process since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSCP Request Message Bytes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of messages bytes are sent as part of the request from the SSCP process since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSCP Reply Message Count</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Count of the number of reply messages received by the SSCP process since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SSCP Reply Message Bytes</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Number of messages bytes that are sent as part of the reply messages received by the SSCP process since the statistics reset timestamp.</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RMS Stats Reset Timestamp</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Timestamp for resetting RMS statistics.</p></td>
</tr>
</tbody>
</table>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; GET STATISTICS FOR RMS ALL;
Node name
CPU 0
RMS Version 2511
SSCP PID 19521
SSCP Priority 0
SSCP Creation Timestamp 2010/12/05 02:32:33.642752
SSMP PID 19527
SSMP Priority 0
SSMP Creation Timestamp 2010/12/05 02:32:33.893440
Source String Store Len 254
Stats Heap Allocated 0
Stats Heap Used 3,002,416
Stats Heap High WM 3,298,976
No.of Process Regd. 157
No.of Query Fragments Regd. 296 RMS Semaphore Owner -1
No.of SSCPs Opened 1
No.of SSCPs Open Deleted 0
Last GC Time 2010/12/06 10:53:46.777432
Queries GCed in Last Run 55
Total Queries GCed 167
SSMP Request Message Count 58,071
SSMP Request Message Bytes 14,161,144
SSMP Reply Message Count 33,466
SSMP Reply Message Bytes 15,400,424
SSCP Request Message Count 3,737
SSCP Request Message Bytes 837,744
SSCP Reply Message Count 3,736 SSCP
Reply Message Bytes 5,015,176
RMS Stats Reset Timestamp 2010/12/05 14:32:33.891083
--- SQL operation complete.</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect2">
<h3 id="using_the_queryid_extract_function">9.6. Using the QUERYID_EXTRACT Function</h3>
<div class="paragraph">
<p>Use the QUERYID_EXTRACT function within an SQL statement to extract
components of a query ID for use in a SQL query. The query ID, or QID,
is a unique, cluster-wide identifier for a query and
is generated for dynamic SQL statements whenever a SQL string is
prepared.</p>
</div>
<div class="sect3">
<h4 id="_syntax_of_queryid_extract">9.6.1. Syntax of QUERYID_EXTRACT</h4>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">QUERYID_EXTRACT ('query-id', 'attribute')</code></pre>
</div>
</div>
<div class="paragraph">
<p>The syntax of the QUERYID_EXTRACT function is:</p>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>query-id</em></code></p>
<div class="paragraph">
<p>is the query ID in string format.</p>
</div>
</li>
<li>
<p><code><em>attribute</em></code></p>
<div class="paragraph">
<p>is the attribute to be extracted. The value of <em>attribute</em> can be one of
these parts of the query ID:</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 30%;">
<col style="width: 70%;">
</colgroup>
<thead>
<tr>
<th class="tableblock halign-left valign-top">Attribute Value</th>
<th class="tableblock halign-left valign-top">Description</th>
</tr>
</thead>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SEGMENTNUM</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Logical node ID in Trafodion cluster</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CPUNUM or CPU</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Logical node ID in Trafodion cluster</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PIN</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Linux process ID number</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EXESTARTTIME</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Executor start time</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SESSIONNUM</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Session number</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>USERNAME</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">User name</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SESSIONNAME</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Session name</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SESSIONID</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Session ID</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>QUERYNUM</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Query number</p></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>STMTNAME</pre></div></td>
<td class="tableblock halign-left valign-top"><p class="tableblock">Statement ID or handle</p></td>
</tr>
</tbody>
</table>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
The SEGMENTNUM and CPUNUM attributes are the same.
</td>
</tr>
</table>
</div>
</li>
</ul>
</div>
<div class="paragraph">
<p>The result data type of the QUERYID_EXTRACT function is a VARCHAR with a
length sufficient to hold the result. All values are returned in string
format. Here is the QUERYID_EXTRACT function in a SELECT statement:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SELECT QUERYID_EXTRACT('_query-id_', '_attribute-value_') FROM (VALUES(1)) AS t1;</code></pre>
</div>
</div>
<div style="page-break-after: always;"></div>
</div>
<div class="sect3">
<h4 id="examples_of_queryid_extract">9.6.2. Examples of QUERYID_EXTRACT</h4>
<div class="ulist">
<ul>
<li>
<p>This command returns the node number of the query ID:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; SELECT
+&gt; SUBSTR(
+&gt; QUERYID_EXTRACT(
+&gt; 'MXID11000022675212170554548762240000000000206U6553500_21_S1','CPU'
+&gt; ), 1, 20
+&gt; ) FROM (VALUES(1))
+&gt; AS t1;
(EXPR)
---------------------------------------------------------------------------
0
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
<li>
<p>This command returns the PIN of the query ID:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; SELECT
+&gt; SUBSTR(
+&gt; QUERYID_EXTRACT(
+&gt; 'MXID11000022675212170554548762240000000000206U6553500_21_S1','PIN'
+&gt; ), 1, 20
+&gt; ) FROM (VALUES(1)) AS t1;
(EXPR)
---------------------------------------------------------------------------
22675
--- 1 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
</div>
</div>
<div class="sect2">
<h3 id="stats_each_fragment_instance_active_query">9.7. Statistics for Each Fragment-Instance of an Active Query</h3>
<div class="paragraph">
<p>You can retrieve statistics for a query while it executes by using the
STATISTICS table-valued function. Depending on the syntax used, you can
obtain statistics summarizing each parallel fragment-instance of the
query, or for any operator in each fragment-instance.</p>
</div>
<div class="sect3">
<h4 id="syntax_of_statistics_table-valued_function">9.7.1. Syntax of STATISTICS Table-Valued Function</h4>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">TABLE(STATISTICS (NULL, 'qid-str'))
qid-str is:
QID=query-id [ ,{ TDBID_DETAIL=tdb-id | DETAIL=1 } ]</code></pre>
</div>
</div>
<div class="ulist">
<ul>
<li>
<p><code><em>query-id</em></code></p>
<div class="paragraph">
<p>is the system-generated query ID. For example:</p>
</div>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">QID=MXID11000022675212170554548762240000000000206U6553500_21_S1</code></pre>
</div>
</div>
</li>
<li>
<p><code><em>tdb-id</em></code></p>
<div class="paragraph">
<p>is the TDB ID of a given operator. TDB values can be obtained from the
report returned from the GET STATISTICS command.</p>
</div>
</li>
</ul>
</div>
</div>
<div class="sect3">
<h4 id="considerations_obtaining_stats_fragment">9.7.2. Considerations For Obtaining Statistics For Each Fragment-Instance of an Active Query</h4>
<div class="paragraph">
<p>If the DETAIL=1 or TDBID_DETAIL=<em>tdb_id</em> options are used when the
query is not executing, the STATISTICS table-valued function will not
return any results.</p>
</div>
<div class="paragraph">
<p>The STATISTICS table-valued function can be used with a SELECT statement
to return several columns. Many different counters exist in the
<em>variable_info</em> column. The counters in this column are formatted as
token-value pairs and the counters reported will depend on which option
is used: DETAIL=1 or TDBID_DETAIL=<em>tdb_id</em>. If the TDBID_DETAIL option
is used, the counters reported will also depend on the type of operator
specified by the <em>tdb_id</em>. The reported counters can also be
determined by the statsRowType counter.</p>
</div>
<div class="paragraph">
<p>The tokens for these counters are listed in the column
<a href="#displaying_sql_runtime_statistics">Displaying SQL Runtime Statistics</a>,Displaying SQL Runtime Statistics&gt;&gt;.</p>
</div>
<div class="ulist">
<ul>
<li>
<p>This query lists process names of all ESPs of an executing query
identified by the given QID:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt; SELECT
+&gt; SUBSTR(VARIABLE_INFO,
+&gt; POSITION('ProcessId:' IN variable_info), 20) AS processes
+&gt;FROM
+&gt;TABLE(statistics(NULL,
+&gt;'QID=MXID11000032684212170811581160672000000000206U6553500_19_S1,DETAIL=1'))
+&gt;GROUP BY 1;
PROCESSES
--------------------
ProcessId: $Z0000GS
ProcessId: $Z0000GT
ProcessId: $Z0000GU
ProcessId: $Z0000GV
ProcessId: $Z0102IQ
ProcessId: $Z000RNU
ProcessId: $Z0102IR
ProcessId: $Z0102IS
ProcessId: $Z0102IT
--- 9 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
<div style="page-break-after: always;"></div>
<div class="ulist">
<ul>
<li>
<p>This query gives BMO heap used for the hash join identified as TDB #15
in an executing query identified by the given QID:</p>
<div class="listingblock">
<div class="content">
<pre class="CodeRay highlight"><code data-lang="text">SQL&gt;SELECT CAST (
+&gt; SUBSTR(variable_info,
+&gt; POSITION('bmoHeapUsed:' IN variable_info),
+&gt; POSITION('bmoHeapUsed:' in variable_info) +
+&gt; 13 + (POSITION(' ' IN
+&gt; SUBSTR(variable_info,
+&gt; 13 + POSITION('bmoHeapUsed:' IN variable_info))) -
+&gt; POSITION('bmoHeapUsed:' IN variable_info)))
+&gt; AS CHAR(25))
+&gt; FROM TABLE(statistics(NULL,
+&gt;'QID=MXID11000021706212170733911504160000000000206U6553500_25_S1,TDBID_DETAIL=15'));
(EXPR)
-------------------------
bmoHeapUsed: 3147
bmoHeapUsed: 3147
bmoHeapUsed: 3147
bmoHeapUsed: 3147
bmoHeapUsed: 3147
bmoHeapUsed: 3147
bmoHeapUsed: 3147
bmoHeapUsed: 3147
--- 8 row(s) selected.</code></pre>
</div>
</div>
</li>
</ul>
</div>
</div>
</div>
</div>
</div>
<div class="sect1">
<h2 id="reserved_words">10. Reserved Words</h2>
<div class="sectionbody">
<div class="paragraph">
<p>The words listed in this appendix are reserved for use by Trafodion SQL.
To prevent syntax errors, avoid using these words as identifiers in
Trafodion SQL. In Trafodion SQL, if an operating system name contains a
reserved word, you must enclose the reserved word in double quotes (")
to access that column or object.</p>
</div>
<div class="admonitionblock note">
<table>
<tr>
<td class="icon">
<i class="fa icon-note" title="Note"></i>
</td>
<td class="content">
In Trafodion SQL, ABSOLUTE, DATA, EVERY, INITIALIZE, OPERATION,
PATH, SPACE, STATE, STATEMENT, STATIC, and START are not reserved words.
</td>
</tr>
</table>
</div>
<div class="paragraph">
<p>Trafodion SQL treats these words as reserved when they are part of
Trafodion SQL stored text. They cannot be used as identifiers unless you
enclose them in double quotes.</p>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_a">10.1. Reserved SQL Identifiers: A</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ACTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ADD</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ADMIN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AFTER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AGGREGATE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ALIAS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ALL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ALLOCATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ALTER</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AND</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ANY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ARE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ARRAY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AS</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ASC</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ASSERTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ASYNC</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>AUTHORIZATION</pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_b">10.2. Reserved SQL Identifiers: B</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BEFORE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BEGIN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BETWEEN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BINARY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BIT</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BIT_LENGTH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BLOB</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BOOLEAN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BOTH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BREADTH</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>BY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_c">10.3. Reserved SQL Identifiers: C</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CALL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CASCADE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CASCADED</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CASE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CAST</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CATALOG</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHAR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHARACTER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHARACTER_LENGTH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHAR_LENGTH</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CHECK</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CLASS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CLOB</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CLOSE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>COALESCE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>COLLATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>COLLATION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>COLUMN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>COMMIT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>COMPLETION</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CONNECT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CONNECTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CONSTRAINT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CONSTRAINTS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CONSTRUCTOR</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CONTINUE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CONVERT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CORRESPONDING</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>COUNT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CREATE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CROSS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CUBE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_DATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_PATH</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_ROLE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_TIME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_TIMESTAMP</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRENT_USER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURRNT_USR_INTN</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CURSOR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>CYCLE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_d">10.4. Reserved SQL Identifiers: D</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DATETIME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DAY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DEALLOCATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DEC</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DECIMAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DECLARE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DEFAULT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DEFERRABLE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DEFERRED</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DELETE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DEPTH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DEREF</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DESC</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DESCRIBE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DESCRIPTOR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DESTROY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DESTRUCTOR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DETERMINISTIC</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DIAGNOSTICS</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DICTIONARY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DISCONNECT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DISTINCT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DOMAIN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DOUBLE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DROP</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>DYNAMIC</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_e">10.5. Reserved SQL Identifiers: E</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EACH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ELSE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ELSEIF</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>END</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>END-EXEC</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EQUALS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ESCAPE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EXCEPT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EXCEPTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EXEC</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EXECUTE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EXISTS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EXTERNAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>EXTRACT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="_reserved_sql_identifers_f">10.6. Reserved SQL Identifers: F</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FALSE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FETCH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FIRST</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FLOAT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FOR</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FOREIGN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FOUND</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FRACTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FREE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FROM</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FULL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>FUNCTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_g">10.7. Reserved SQL Identifiers G</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GENERAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GET</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GLOBAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GO</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GOTO</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GRANT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GROUP</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>GROUPING</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_h">10.8. Reserved SQL Identifiers: H</h3>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_i">10.9. Reserved SQL Identifiers: I</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>IDENTITY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>IF</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>IGNORE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>IMMEDIATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>IN</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INDICATOR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INITIALLY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INNER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INOUT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INPUT</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INSENSITIVE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INSERT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTEGER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERSECT</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTERVAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>INTO</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>IS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ISOLATION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ITERATE</pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_j">10.10. Reserved SQL Identifiers J</h3>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_k">10.11. Reserved SQL Identifiers: K</h3>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_l">10.12. Reserved SQL Identifiers: L</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LANGUAGE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LARGE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LAST</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LATERAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LEADING</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LEAVE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LEFT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LESS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LEVEL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LIKE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LIMIT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LOCAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LOCALTIME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LOCALTIMESTAMP</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LOCATOR</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LOOP</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>LOWER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_m">10.13. Reserved SQL Identifiers: M</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MAINTAIN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MAP</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MATCH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MATCHED</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MAX</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MERGE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MIN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MINUTE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MODIFIES</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MODIFY</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MODULE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>MONTH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_n">10.14. Reserved SQL Identifiers: N</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NAMES</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NATIONAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NATURAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NCHAR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NCLOB</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NEW</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NEXT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NO</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NONE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NOT</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NULL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NULLIF</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>NUMERIC</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_o">10.15. Reserved SQL Identifiers: O</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OCTET_LENGTH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OF</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OFF</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OID</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OLD</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ON</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ONLY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OPEN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OPERATORS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OPTION</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OPTIONS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ORDER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ORDINALITY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OTHERS</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OUT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OUTER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OUTPUT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>OVERLAPS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_p">10.16. Reserved SQL Identifiers: P</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PAD</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PARAMETER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PARAMETERS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PARTIAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PENDANT</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>POSITION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>POSTFIX</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PRECISION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PREFIX</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PREORDER</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PREPARE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PRESERVE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PRIMARY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PRIOR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PRIVATE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PRIVILEGES</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PROCEDURE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PROTECTED</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PROTOTYPE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>PUBLIC</pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_q">10.17. Reserved SQL Identifiers: Q</h3>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_r">10.18. Reserved SQL Identifiers: R</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>READ</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>READS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RECURSIVE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REF</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REFERENCES</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REFERENCING</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RELATIVE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REORG</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REORGANIZE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REPLACE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RESIGNAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RESTRICT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RESULT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RETURN</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RETURNS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>REVOKE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>RIGHT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ROLLBACK</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ROLLUP</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ROUTINE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ROW</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>ROWS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_s">10.19. Reserved SQL Identifiers: S</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SAVEPOINT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SCHEMA</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SCOPE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SCROLL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SEARCH</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SECOND</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SECTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SELECT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SENSITIVE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SESSION</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SESSION_USER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SESSN_USR_INTN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SET</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SETS</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SIGNAL</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SIMILAR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SIZE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SMALLINT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SOME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SPECIFIC</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SPECIFICTYPE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_CHAR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_DATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_DECIMAL</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_DOUBLE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_FLOAT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_INT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_INTEGER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_REAL</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_SMALLINT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_TIME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_TIMESTAMP</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQL_VARCHAR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQLCODE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQLERROR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQLEXCEPTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQLSTATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SQLWARNING</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>STRUCTURE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SUBSTRING</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SUM</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SYNONYM</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>SYSTEM_USER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_t">10.20. Reserved SQL Identifiers: T</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TABLE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TEMPORARY</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TERMINATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TEST</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>THAN</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>THEN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>THERE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TIME</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TIMESTAMP</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TIMEZONE_HOUR</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TIMEZONE_MINUTE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TO</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TRAILING</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TRANSACTION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TRANSLATE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TRANSLATION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TRANSPOSE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TREAT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TRIGGER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TRIM</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>TRUE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_u">10.21. Reserved SQL Identifiers: U</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UNDER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UNION</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UNIQUE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UNKNOWN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UNNEST</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UPDATE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UPPER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>UPSHIFT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>USAGE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>USER</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>USING</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_v">10.22. Reserved SQL Identifiers: V</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VALUE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VALUES</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VARCHAR</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VARIABLE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VARYING</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VIEW</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VIRTUAL</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>VISIBLE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_w">10.23. Reserved SQL Identifiers: W</h3>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
<col style="width: 20%;">
</colgroup>
<tbody>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WAIT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WHEN</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WHENEVER</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WHERE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WHILE</pre></div></td>
</tr>
<tr>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WITH</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WITHOUT</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WORK</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre>WRITE</pre></div></td>
<td class="tableblock halign-left valign-top"><div class="literal"><pre></pre></div></td>
</tr>
</tbody>
</table>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_y">10.24. Reserved SQL Identifiers Y</h3>
</div>
<div class="sect2">
<h3 id="reserved_sql_identifiers_z">10.25. Reserved SQL Identifiers: Z</h3>
</div>
</div>
</div>
<div class="sect1">
<h2 id="limits">11. Limits</h2>
<div class="sectionbody">
<div class="paragraph">
<p>This section lists limits for various parts of Trafodion SQL.</p>
</div>
<table class="tableblock frame-all grid-all spread">
<colgroup>
<col style="width: 30%;">
<col style="width: 70%;">
</colgroup>
<tbody>
<tr>
<th class="tableblock halign-left valign-top"><p class="tableblock">Column Names</p></th>
<td class="tableblock halign-left valign-top"><p class="tableblock">Up to 128 characters long, or 256 bytes of UTF8 text, whichever is less.</p></td>
</tr>
<tr>
<th class="tableblock halign-left valign-top"><p class="tableblock">Schema Names</p></th>
<td class="tableblock halign-left valign-top"><p class="tableblock">Up to 128 characters long, or 256 bytes of UTF8 text, whichever is less.</p></td>
</tr>
<tr>
<th class="tableblock halign-left valign-top"><p class="tableblock">Table Names</p></th>
<td class="tableblock halign-left valign-top"><p class="tableblock">ANSI names are of the form <em>schema.object</em>, where each part can be up to 128 characters long,
or 256 bytes of UTF8 text, whichever is less.</p></td>
</tr>
</tbody>
</table>
</div>
</div>
</div>
<div id="footer">
<div id="footer-text">
Version 2.2.0<br>
Last updated 2016-11-03 22:36:05 UTC
</div>
</div>
<script>
var _gaq = _gaq || [];
_gaq.push(['_setAccount','UA-72491210-1']);
_gaq.push(['_trackPageview']);
(function() {
var ga = document.createElement('script');
ga.type = 'text/javascript';
ga.async = true;
ga.src = ('https:' == document.location.protocol ? 'https://ssl' : 'http://www') + '.google-analytics.com/ga.js';
var s = document.getElementsByTagName('script')[0];
s.parentNode.insertBefore(ga, s);
})();
</script>
</body>
</html>