Creates a web client function that makes an HTTP or SOAP over HTTP request.
CREATE [ OR REPLACE ] FUNCTION [ owner.]function-name ( [ parameter, ... ] ) RETURNS data-type URL url-string [ TYPE { http-type-spec-string | soap-type-spec-string } ] [ HEADER header-string ] [ CERTIFICATE certificate-string ] [ CLIENTPORT clientport-string ] [ PROXY proxy-string ] [ SET protocol-option-string ] [ SOAPHEADER soap-header-string ] [ NAMESPACE namespace-string ]
http-type-spec-string : HTTP[: { GET | POST[:MIME-type ] | PUT[:MIME-type ] | DELETE | HEAD | OPTIONS } ]
soap-type-spec-string : SOAP[:{ RPC | DOC }
parameter : [ IN ] parameter-name datatype [ DEFAULT expression ]
url-string : { HTTP | HTTPS | HTTPS_FIPS }://[user:password@]hostname[:port][/path]
protocol-option-string : option-list [, option-list ...]
option-list : HTTP( http-option [ ;http-option ...] ) | SOAP( soap-option [ ;soap-option ...] ) | REDIR( redir-option [ ;redir-option ...] )
http-option : CHUNK={ ON | OFF | AUTO } | EXCEPTIONS={ ON | OFF | AUTO } | VERSION={ 1.0 | 1.1 } | KTIMEOUT=number-of-seconds
soap-option :
OPERATION=soap-operation-name
redir-option : COUNT=count | STATUS=status-list
Specifying CREATE OR REPLACE FUNCTION creates a new function, or replaces an existing function with the same name. This clause changes the definition of the function, but preserves existing privileges. You cannot use the OR REPLACE clause with temporary functions.
The name of the function.
Parameter names must conform to the rules for database identifiers. They must have a valid SQL data type.
If a parameter has a default value, it need not be specified. Parameters with no default value must be specified.
Parameters can be prefixed by the keyword IN, signifying that the argument is an expression that provides a value to the function. However, function parameters are IN by default.
The data type of the parameter. Set the data type explicitly, or specify the %TYPE or %ROWTYPE attribute to set the data type to the data type of another object in the database. Use %TYPE to set it to the data type of a column in a table or view. Use %ROWTYPE to set the data type to a composite data type derived from a row in a table or view. However, defining the data type using a %ROWTYPE that is set to a table reference variable (TABLE REF (table-reference-variable) %ROWTYPE is not allowed.
Only SOAP requests support the transmission of typed data such as FLOAT, INT, and so on. HTTP requests support the transmission of strings only, so you are limited to CHAR types.
Specify one of the following to define the return type for the SOAP or HTTP function:
The value returned is the body of the HTTP response. No HTTP header information is included. If more information is required, such as status information, use a procedure instead of a function.
The data type does not affect how the HTTP response is processed.
Specifies the URI of the web service. The optional user name and password parameters provide a means of supplying the credentials needed for HTTP basic authentication. HTTP basic authentication base-64 encodes the user and password information and passes it in the Authentication header of the HTTP request. When specified in this way, the user name and password are passed unencrypted, as part of the URL.
For functions of type HTTP:GET, query parameters can be specified within the URL clause in addition to being automatically generated from parameters passed to a function.
URL 'http://localhost/service?parm=1
Specifying HTTPS_FIPS forces the system to use the FIPS-certified libraries. If HTTPS_FIPS is specified, but no FIPS-certified libraries are present, libraries that are not FIPS-certified are used instead.
To use a certificate from the operating system certificate store, specify a URL beginning with https://.
Specifies the format used when making the web service request. SOAP:RPC is used when SOAP is specified or no TYPE clause is included. HTTP:POST is used when HTTP is specified.
The TYPE clause allows the specification of a MIME-type for HTTP:POST and HTTP:PUT types. When HTTP:PUT is used, then a MIME-type must be specified.The MIME-type specification is used to set the Content-Type request header and set the mode of operation to allow only a single call parameter to populate the body of the request. Only zero or one parameter may remain when making a web service function call after parameter substitutions have been processed. Calling a web service function with a NULL value or no parameter (after substitutions) results in a request with no body and a content-length of zero. When a MIME-type is specified then the single body parameter is sent in the request as is, so the application must ensure that the content is formatted to match the MIME-type.
Some typical MIME-types include:
When no MIME-type is specified, parameter names and values (multiple parameters are permitted) are URL encoded within the body of the HTTP request.
The keywords for the TYPE clause have the following meanings:
By default, this type uses the application/x-www-form-urlencoded MIME-type for encoding parameters specified in the URL.
For example, the following request is produced when a client submits a request from the URL http://localhost/WebServiceName?arg1=param1&arg2=param2:
GET /WebServiceName?arg1=param1&arg2=param2 HTTP/1.1 // <End of Request - NO BODY>
By default, this type uses the application/x-www-form-urlencoded MIME-type for encoding parameters specified in the body of a POST request. URL parameters are stored in the body of the request.
For example, the following request is produced when a client submits a request from the URL http://localhost/WebServiceName?arg1=param1&arg2=param2:
POST /WebServiceName HTTP/1.1 Content-Type: application/x-www-form-urlencoded Content-Length: 19 arg1=param1&arg2=param2 // <End of Request>
HTTP:PUT is similar to HTTP:POST, but the HTTP:PUT type does not have a default media type.
The following example demonstrates how to configure a general purpose client function that uploads data to a database server running the %SQLANYSAMP17%\SQLAnywhere\HTTP\put_data.sql sample:
CREATE OR REPLACE FUNCTION CPUT([data] LONG VARCHAR, resnm LONG VARCHAR, mediatype LONG VARCHAR) RETURNS LONG BINARY URL 'http://localhost/resource/!resnm' TYPE 'HTTP:PUT:!mediatype'; SELECT CPUT('hello world', 'hello', 'text/plain' );
A web service client function can be configured to delete a resource located on a server. Specifying the media type is optional.
The following example demonstrates how to configure a general purpose client function that deletes a resource from a database server running the put_data.sql sample:
CREATE OR REPLACE FUNCTION CDEL(resnm LONG VARCHAR, mediatype LONG VARCHAR) RETURNS LONG BINARY URL 'http://localhost/resource/!resnm' TYPE 'HTTP:DELETE:!mediatype'; SELECT CDEL('hello', 'text/plain' );
The HEAD method is identical to a GET method but the server does not return a body. A media type can be specified.
CREATE OR REPLACE FUNCTION CHEAD(resnm LONG VARCHAR) RETURNS LONG BINARY URL 'http://localhost/resource/!resnm' TYPE 'HTTP:HEAD'; SELECT CHEAD( 'hello' );
The OPTIONS method is identical to a GET method but the server does not return a body. A media type can be specified. This method allows Cross-Origin Resource Sharing (CORS).
This type sets the Content-Type header to 'text/xml'. SOAP operations and parameters are encapsulated in SOAP envelope XML documents.
This type sets the Content-Type header to 'text/xml'. It is similar to the SOAP:RPC type but allows you to send richer data types. SOAP operations and parameters are encapsulated in SOAP envelope XML documents.
Specifying a MIME-type for the TYPE clause automatically sets the Content-Type header to that MIME-type.
When creating HTTP web service client functions, use this clause to add, modify, or delete HTTP request header entries. The specification of headers closely resembles the format specified in RFC2616 Hypertext Transfer Protocol, HTTP/1.1, and RFC822 Standard for ARPA Internet Text Messages, including the fact that only printable ASCII characters can be specified for HTTP headers, and they are case-insensitive.
Headers can be defined as header-name:value-name pairs. Each header must be delimited from its value with a colon ( : ) and therefore cannot contain a colon. You can define multiple headers by delimiting each pair with \n, \x0d\n, <LF> (line feed), or <CR><LF>. (carriage return followed by a line feed)
Multiple contiguous white spaces within the header are converted to a single white space.
To make a secure (HTTPS) request, a client must have access to the certificate used to sign the HTTP server's certificate (or any certificate higher in the signing chain). The necessary information is specified in a string of semicolon-separated keyword=value pairs. The following keywords are available:
Keyword | Abbreviation | Description |
---|---|---|
file | The file name of the certificate or specify * to use a certificate from the operating system certificate store. Cannot be specified if either the certificate or certificate_name keyword is specified. | |
certificate | cert | The certificate itself. Cannot be specified if either the file or certificate_name keyword is specified. |
certificate_name | cert_name | The name of a certificate stored in the database. Cannot be specified if either the file or certificate keyword is specified. |
company | co | The company specified in the certificate. |
unit | The company unit specified in the certificate. | |
name | The common name specified in the certificate. | |
skip_certificate_name_check |
Specify ON to prevent checking the database server certificate. Note
Setting this option to ON is not recommended because this setting prevents the database server from fully authenticating the HTTP server. |
Certificates are required only for requests that are either directed to an HTTPS server, or can be redirected from a non-secure to a secure server. Only PEM formatted certificates are supported.
Identifies the port number on which the HTTP client function communicates using TCP/IP. It is provided for and recommended only for connections through firewalls that filter "outgoing" TCP/IP connections. You can specify a single port number, ranges of port numbers, or a combination of both; for example, CLIENTPORT '85,90-97''.
PROXY http://proxy.example.com
Specifies protocol-specific behavior options for HTTP, SOAP, and REDIR (redirects). Only one SET clause is permitted. The following list describes the supported SET options. CHUNK, EXCEPTIONS, VERSION, and KTIMEOUT apply to the HTTP protocol, OPERATION applies to the SOAP protocol, and COUNT and STATUS apply to the REDIR option. REDIR options can be included with either HTTP or SOAP protocol options.
(short form CH) This HTTP option allows you to specify whether to use chunking. Chunking allows HTTP messages to be broken up into several parts. Possible values are ON (always chunk), OFF (never chunk), and AUTO (chunk only if the contents, excluding auto-generated markup, exceeds 8196 bytes). For example, the following SET clause enables chunking:
SET 'HTTP(CHUNK=ON)'
If the CHUNK option is not specified, the default behavior is AUTO. If a chunked request fails in AUTO mode with a status of 505 HTTP Version Not Supported, or with 501 Not Implemented, or with 411 Length Required, the client retries the request without chunked transfer-coding.
Set the CHUNK option to OFF (never chunk) if the HTTP server does not support chunked transfer-coded requests.
Since CHUNK mode is a transfer encoding supported starting in HTTP version 1.1, setting CHUNK to ON requires that the version (VER) be set to 1.1, or not be set at all, in which case 1.1 is used as the default version.
(short form EX) This HTTP option allows you to control status code handling. The default is ON.
When set to ON or AUTO, HTTP client functions will return a response for HTTP success status codes (1XX and 2XX) and all codes will raise the exception SQLE_HTTP_REQUEST_FAILED.
SET 'HTTP(EXCEPTIONS=AUTO)'
When set to OFF, HTTP client functions will always return a response, independent of the HTTP status code. The HTTP status code will not be available.
Exceptions that are not related to the HTTP status code (for example, SQLE_UNABLE_TO_CONNECT_TO_HOST) will be raised when appropriate regardless of the EXCEPTIONS setting.
(short form VER) This HTTP option allows you to specify the version of the HTTP protocol that is used for the format of the HTTP message. For example, the following SET clause sets the HTTP version to 1.1:
SET 'HTTP(VERSION=1.1)'
Possible values are 1.0 and 1.1. If VERSION is not specified:
if CHUNK is set to ON, 1.1 is used as the HTTP version
if CHUNK is set to OFF, 1.0 is used as the HTTP version
if CHUNK is set to AUTO, either 1.0 or 1.1 is used, depending on whether the client is sending in CHUNK mode
(short form KTO) This HTTP option allows you to specify the keep-alive timeout criteria, permitting a web client function to instantiate and cache a keep-alive HTTP/HTTPS connection for a period of time. To cache an HTTP keep-alive connection, the HTTP version must be set to 1.1 and KTIMEOUT set to a non-zero value. KTIMEOUT may be useful for HTTPS connections particularly, if you notice a significant performance difference between HTTP and HTTPS connections. A database connection can only cache a single keep-alive HTTP connection. Subsequent calls to a web client function using the same URI reuse the keep-alive connection. Therefore, the executing web client call must have a URI whose scheme, destination host and port match that of the cached URI, and the HEADER clause must not specify Connection: close. When KTIMEOUT is not specified, or is set to zero, HTTP/HTTPS connections are not cached.
(short form OP) This SOAP option allows you to specify the name of the SOAP operation, if it is different from the name of the function you are creating. The value of OPERATION is analogous to the name of a remote function call. For example, if you wanted to create a function called accounts_login that calls a SOAP operation called login, you would specify something like the following:
CREATE FUNCTION accounts_login( name LONG VARCHAR, pwd LONG VARCHAR ) RETURNS LONG BINARY SET 'SOAP(OPERATION=login)'
If the OPERATION option is not specified, the name of the SOAP operation must match the name of the function you are creating.
(short form CNT) This REDIR option allows you to control redirects. See STATUS below.
(short form STAT) This REDIR option allows you to control redirects. HTTP response status codes such as302 Found and 303 See Other are used to redirect web applications to a new URI, particularly after an HTTP POST has been performed. For example, a client request could be:
GET /people/alice HTTP/1.1 Host: www.example.com Accept: text/html, application/xhtml+xml Accept-Language: en, de
The web server response could be:
HTTP/1.1 302 Found Location: http://www.example.com/people/alice.en.html
In response, the client would send another HTTP request to the new URI. The REDIR options allow you to control the maximum number of redirections allowed and which HTTP response status codes to automatically redirect.
For example, SET 'REDIR(COUNT=3; STATUS=301,307)' allows a maximum limit of 3 re-directions and permits redirection for 301 and 307 statuses. If one of the other redirection status codes such as 302 or 303 is received, an error is issued (SQLE_HTTP_REQUEST_FAILED).
The default redirection limit count is 5. By default, an HTTP client function will automatically redirect in response to all HTTP redirection status codes (301, 302, 303, 307). To disallow all redirection status codes, use SET 'REDIR(COUNT=0)'. In this mode, a redirection response does not result in an error (SQLE_HTTP_REQUEST_FAILED). Instead, a result set is returned with the HTTP status and response headers. This permits a caller to conditionally reissue the request based on the URI contained in the Location header.
A web service function specifying a POST HTTP method which receives a 303 See Other status issues a redirect request using the GET HTTP method.
The Location header can contain either an absolute path or a relative path. The HTTP client function will handle either. The header can also include query parameters and these are forwarded to the redirected location. For example, if the header contained parameters such as the following, the subsequent GET or a POST will include these parameters.
Location: alternate_service?a=1&b=2
In the above example, the query parameters are a=1&b=2.
The following example shows how several option settings are combined in the same SET clause:
CREATE FUNCTION accounts_login( name LONG VARCHAR, pwd LONG VARCHAR ) RETURNS LONG BINARY SET 'HTTP( CHUNK=ON; VERSION=1.1 ), REDIR(COUNT=5;STATUS=302,303)' ...
The following example shows the use of short forms with uppercase and lowercase letters.
CREATE FUNCTION accounts_login( name LONG VARCHAR, pwd LONG VARCHAR ) RETURNS LONG BINARY SET 'HTTP( CH=ON; Ver=1.1 ), REDIR(CNT=5;Stat=302,303)' ...
(SOAP format only) When declaring a SOAP web service as a function, use this clause to specify one or more SOAP request header entries. A SOAP header can be declared as a static constant, or can be dynamically set using the parameter substitution mechanism (declaring IN, OUT, or INOUT parameters for hd1, hd2, and so on). A web service function can define one or more IN mode substitution parameters, but cannot define an INOUT or OUT substitution parameter.
The following example illustrates how a client can specify the sending of several header entries using parameter substitution and receiving the response SOAP header data:
CREATE FUNCTION soap_client( IN hd1 LONG VARCHAR, IN hd2 LONG VARCHAR, IN hd3 LONG VARCHAR) RETURNS LONG BINARY URL 'localhost/some_endpoint' SOAPHEADER '!hd1!hd2!hd3';
(SOAP format only) This clause identifies the method namespace usually required for both SOAP:RPC and SOAP:DOC requests. The SOAP server handling the request uses this namespace to interpret the names of the entities in the SOAP request message body. The namespace can be obtained from the WSDL (Web Services Description Language) of the SOAP service available from the web service server. The default value is the function's URL, up to but not including the optional path component.
You can specify a variable name for namespace-string. If the variable is NULL, the namespace property is ignored.
The CREATE FUNCTION statement creates a web services function in the database. A function can be created for another user by specifying an owner name.
When functions are executed, not all parameters need to be specified. If a DEFAULT value is provided in the CREATE FUNCTION statement, missing parameters are assigned the default values. If an argument is not provided by the caller and no default is set, an error is given.
Parameter values are passed as part of the request. The syntax used depends on the type of request. For HTTP:GET, the parameters are passed as part of the URL; for HTTP:POST requests, the values are placed in the body of the request. Parameters to SOAP requests are always bundled in the request body.
You must have the CREATE PROCEDURE system privilege to create functions owned by you.
You must have the CREATE ANY PROCEDURE or CREATE ANY OBJECT system privilege to create functions owned by others.
To replace an existing function, you must own the procedure or have one of the following:
CREATE ANY PROCEDURE and DROP ANY PROCEDURE system privileges.
CREATE ANY OBJECT and DROP ANY OBJECT system privileges.
ALTER ANY OBJECT or ALTER ANY PROCEDURE system privileges.
Automatic commit.
Not in the standard.
Not supported by Adaptive Server Enterprise.
The following statement creates a function named cli_test1 that returns images from the get_picture service running on localhost:
CREATE FUNCTION cli_test1( image LONG VARCHAR ) RETURNS LONG BINARY URL 'http://localhost/get_picture' TYPE 'HTTP:GET';
SELECT cli_test1( 'widget' );
The following statement uses a substitution parameter to allow the request URL to be passed as an input parameter. The secure HTTPS request uses a certificate stored in the database. The SET clause is used to turn off CHUNK mode transfer-encoding.
CREATE CERTIFICATE client_cert
FROM FILE 'C:\\Users\\Public\\Documents\\SQL Anywhere
17\\Samples\\Certificates\\rsaroot.crt';
CREATE FUNCTION cli_test2( image LONG VARCHAR, myurl LONG VARCHAR )
RETURNS LONG BINARY
URL '!myurl'
CERTIFICATE 'certificate_name=client_cert'
TYPE 'HTTPS:GET'
SET 'HTTP(CH=OFF)'
HEADER 'ASA-ID';
The following statement issues an HTTP request with the URL http://localhost/get_picture?image=widget:
CREATE VARIABLE a_binary LONG BINARY; SET a_binary = cli_test2( 'widget', 'https://localhost/get_picture' ); SELECT a_binary;
The following example creates a function using a variable in the NAMESPACE clause
The following statements create a variable for a NAMESPACE clause:
CREATE VARIABLE @ns LONG VARCHAR SET @ns = 'http://wsdl.domain.com/';
The following statement creates a function named FtoC that uses a variable in the NAMESPACE clause:
CREATE FUNCTION FtoC ( IN temperature LONG VARCHAR ) RETURNS LONG BINARY URL 'http://localhost:8082/FtoCService' TYPE 'SOAP:DOC' NAMESPACE @ns;