create function string

Description

Adds a function string to a function-string class. Replication Server uses function strings to generate instructions for data servers.

Syntax

create function string
	[replication_definition.]function[;function_string]
	for function_class [with overwrite]
	[scan 'input_template']
	[output
	{language 'lang_output_template' |
	rpc 'execute procedure
	[@param_name=]{constant |?variable!mod?}
		[, [@param_name=]
			{constant |?variable!mod?}]...' |
	writetext [use primary log | with log |
		no log] |
	none}]

Parameters

replication_definition

The name of the replication definition the function operates on. Use only for functions with replication definition scope.

Functions have either function-string-class scope or replication definition scope. Functions that direct transaction control have function-string class scope. User-defined functions, and functions that modify data, have replication definition scope.

function

The name of the function. Names for system functions must be provided as documented in Chapter 4, “Replication Server System Functions.” Names for user-defined functions must match an existing user-defined function.

function_string

A function string name is required when customizing rs_get_textptr, rs_textptr_init, and rs_writetext functions, and optional for others. For rs_get_textptr, rs_textptr_init, and rs_writetext, a function string is needed for each text, unitext, or image column in the replication definition. The function string name supplied must be:

Replication Server also uses the function string name in the generation of error messages.

function_class

The function-string class the new function string belongs to.

with overwrite

If the function string already exists, this option drops and re-creates the function string, as though you used alter function string instead.

scan

Precedes an input template.

input_template

A character string, enclosed in single quote characters, that Replication Server scans to associate an rs_select or rs_select_with_lock function string with the where clause in a create subscription command. An input template string is written as a SQL select statement, with user-defined variables instead of the literal values in the subscription’s where clause.

output

Precedes an output template.

language

Tells Replication Server to submit the output template commands to the data server using the Client/Server Interfaces language interface.

lang_output_template

A character string, enclosed in single quote characters, that contains instructions for a data server. A language output template string may contain embedded variables, which Replication Server replaces with run-time values before it sends the string to the data server.

rpc

An output template that tells Replication Server to use the Client/Server Interfaces remote procedure call (RPC) interface. Replication Server interprets the string and constructs a remote procedure call to send to the data server.

These keywords and options appear in RPC output templates:

procedure – the name of the remote procedure to execute. It could be an Adaptive Server stored procedure, a procedure processed by an Open Server gateway RPC handler, or a registered procedure in an Open Server gateway. Refer to the Open Server Server-Library/C Reference Manual for information about processing RPCs in a gateway program.

@param_name – the name of an argument to the procedure, as defined by the procedure. If the @param_name = value form is used, parameters can be supplied in any order. If parameter names are omitted, parameter values must be supplied in the order defined in the remote procedure.

constant – a literal value with the datatype of the parameter it is assigned to.

?variable!mod? – variable is the placeholder for a run-time value. It can be a column name, the name of a system-defined variable, the name of a parameter in a user-defined function, or the name of a variable defined in an input template. The variable must refer to a value with the same datatype as the parameter it is assigned to. For a list of system-defined variables, see “System-defined variables”.

The mod portion of a variable name identifies the type of data the variable represents. The variable modifier is required for all variables and must be one of the following:

Table 3-23: Function string variable modifiers

Modifier

Description

new, new_raw

A reference to the new value of a column in a row you are inserting or updating

old, old_raw

A reference to the existing value of a column in a row you are updating or deleting

user, user_raw

A reference to a variable that is defined in the input template of an rs_select or rs_select_with_lock function string

sys, sys_raw

A reference to a system-defined variable

param, param_raw

A reference to a function parameter

text_status

A reference to the text_status value for text, unitext, or image data. Possible values are:

  • 0x000 – Text field contains NULL value, and the text pointer has not been initialized.

  • 0x0002 – Text pointer is initialized.

  • 0x0004 – Real text data will follow.

  • 0x0008 – No text data will follow because the text data is not replicated.

  • 0x0010 – The text data is not replicated but it contains NULL values.

Table 3-24: Function string variable modifiers

Modifier

Description

new, new_raw

A reference to the new value of a column in a row you are inserting or updating

old, old_raw

A reference to the existing value of a column in a row you are updating or deleting

user, user_raw

A reference to a variable that is defined in the input template of an rs_select or rs_select_with_lock function string

sys, sys_raw

A reference to a system-defined variable

param, param_raw

A reference to a function parameter

text_status

A reference to the text_status value for text, unitext, or image data. Possible values are:

  • 0x000 – Text field contains NULL value, and the text pointer has not been initialized.

  • 0x0002 – Text pointer is initialized.

  • 0x0004 – Real text data will follow.

  • 0x0008 – No text data will follow because the text data is not replicated.

  • 0x0010 – The text data is not replicated but it contains NULL values.

NoteFunction strings for user-defined functions may not use the new or old modifiers.

writetext

instructs Replication Server to use the Client-Library™ function ct_send_data to update a text, unitext, or image column value. This option applies only to the rs_writetext function.

The following options appear in writetext output templates to specify the logging behavior of the text, unitext, or image column in the replicate database:

use primary log – logs the data in the replicate database, if the logging option was specified in the primary database.

with log – logs the data in the replicate database transaction log.

no log – does not log the data in the replicate database transaction log.

none

instructs Replication Server not to replicate a text, unitext, or image column value. This option applies only to the rs_writetext function.

Examples

Example 1

Creates a function string for the rs_begin function:

create function string rs_begin
 for sqlserver2_function_class
 output language
 'begin transaction'

Example 2

Creates a function string for the rs_commit function that contains two commands separated with a semicolon. The function string executes an Adaptive Server stored procedure that updates the rs_lastcommit system table and then commits the transaction:

create function string rs_commit
 for sqlserver2_function_class
 output language
 'execute sqlrs_update_lastcommit
   @origin = ?rs_origin!sys?,
   @origin_qid = ?rs_origin_qid!sys?,
   @secondary_qid = ?rs_secondary_qid!sys?;
   commit transaction'

Example 3

Examples 3 and 4 create a replication definition for the titles table and an rs_insert function string for the sqlserver2_function_class. The function string inserts data into the titles_rs table instead of into the titles table in the replicate database:

create replication definition titles_rep
 with primary at LDS.pubs2
 (title_id varchar(6), title varchar(80),
  type char(12), pub_id char(4), advance money,
  total_sales int, notes varchar(200),
  pubdate datetime, contract bit, price money)
 primary key (title_id)
 searchable columns (price)

Example 4

Examples 3 and 4 create a replication definition for the titles table and an rs_insert function string for the sqlserver2_function_class. The function string inserts data into the titles_rs table instead of into the titles table in the replicate database:

create function string titles_rep.rs_insert
 for sqlserver2_function_class
 output language
 'insert titles_rs values (?title_id!new?,
   ?title!new?, ?type!new?, ?pub_id!new?,
   ?advance!new?, ?total_sales!new?, ?notes!new?,
   ?pubdate!new?, ?contract!new?, ?price!new?)'

Example 5

Examples 5 and 6 create a user-defined function update_titles and a corresponding function string for the sqlserver2_function_class. The function string executes an Adaptive Server stored procedure named update_titles:

create function titles_rep.update_titles
 (@title_id varchar(6), title varchar(80),
  @price money)

Example 6

Examples 5 and 6 create a user-defined function update_titles and a corresponding function string for the sqlserver2_function_class. The function string executes an Adaptive Server stored procedure named update_titles:

create function string titles_rep.update_titles
 for sqlserver2_function_class
 output rpc
 'execute update_titles
   @title_id = ?title_id!param?,
   @title = ?title!param?,
   @price = ?price!param?'

Example 7

The rs_select function string in example 7 is used to materialize subscriptions that request rows with a specified value in the title_id column. Similar to example 8, the input templates given by the scan clauses differentiate the two function strings:

create function string
   titles_rep.rs_select;title_id_select
 for sqlserver2_function_class
 scan 'select * from titles
   where title_id = ?title_id!user?'
 output language
 'select * from titles
   where title_id = ?title_id!user?'

Example 8

The rs_select function string in example 8 is an example of an RPC function string. It is used to materialize subscriptions that request rows where the value of the price column falls within a given range:

create function string
   titles_rep.rs_select;price_range_select
 for sqlserver2_function_class
 scan 'select * from titles
   where price > ?price_min!user?
   and price < ?price_max!user?'
 output rpc
   'execute titles_price_select
   ?price_min!user?, ?price_max!user?'

Usage


Function strings and function-string classes


Function strings and replicate minimal columns


Input and output templates

Input templates

Output templates

System-defined variables

The following table lists system-defined variables that can be used in function-string output templates. Use the sys or sys_raw modifier for these variables:

Table 3-26: Replication Server system-defined variables

System variable

Datatype

Description

rs_default_fs

text

The default generated function-string text for the function

rs_deliver_as_name

varchar(200)

For execution of a replicated function, name of the procedure to be invoked at the destination

rs_destination_db

varchar(30)

Name of the database where a transaction was sent

rs_destination_ds

varchar(30)

Name of the data server where a transaction was sent

rs_destination_ldb

varchar(30)

Name of the logical database where a transaction was sent

rs_destination_lds

varchar(30)

Name of the logical data server where a transaction was sent

rs_destination_ptype

char(1)

Physical connection type (“A” for active or “S” for standby) for the database where a transaction was sent

rs_destination_user

varchar(30)

User who will execute the transaction at the destination

rs_dump_dbname

varchar(30)

Name of the database where a database or transaction dump originated

rs_dump_label

varchar(30)

Label information for a database or transaction dump. For Adaptive Server, this variable holds a datetime value that is the time the dump originated.

rs_dump_timestamp

varbinary(16)

Timestamp of a database or transaction dump

rs_lorigin

int(4)

ID of the originating logical database for a transaction

rs_isolation_level

varchar(30)

Transaction isolation level of a database connection.

rs_origin

int(4)

ID of the originating database for a transaction

rs_origin_begin_time

datetime

The time that a command was applied at the origin

NoteIf you execute select getdate() while ASE is still processing user database recovery, the returned value of select getdate() may be different from the value of rs_origin_begin_time.

rs_origin_commit_time

datetime

The time that a transaction was committed at the origin

NoteIf you execute select getdate() while ASE is still processing user database recovery, the returned value of select getdate() may be different from the value of rs_origin_begin_time.

rs_origin_db

varchar(30)

Name of the origin database

rs_origin_ds

varchar(30)

Name of the origin data server

rs_origin_ldb

varchar(30)

Name of the logical database for a warm standby application

rs_origin_lds

varchar(30)

Name of the logical data server for a warm standby application

rs_origin_qid

varbinary(36)

Origin queue ID of the first command in a transaction

rs_origin_user

varchar(30)

User who executed the transaction at the origin

rs_origin_xact_id

binary(120)

The system-assigned unique ID of a transaction

rs_origin_xact_name

varchar(30)

User-assigned name of the transaction at origin

rs_secondary_qid

varbinary(36)

Queue ID of a transaction in a subscription materialization or dematerialization queue

rs_last_text_chunk

int(4)

If the value is 0, this is not the last chunk of text data. If the value is 1, this is the last chunk of text data.

rs_writetext_log

int(4)

If the value is 0, rs_writetext has not finished logging text, unitext, and image data at the primary database transaction log. If the value is 1, rs_writetext has finished logging text, unitext, and image data at the primary database transaction log.

rs_origin_commit_time system variable

If you are not using parallel DSI to process large transactions before their commit has been read from the DSI queue, the value of the rs_origin_commit_time system variable contains the time when the last transaction in the transaction group committed at the primary site.

If you are using parallel DSI to process large transactions before their commit has been read from the DSI queue, when the DSI threads start processing one of these transactions, the value of the rs_origin_commit_time system variable is set to the value of the rs_origin_begin_time system variable. When the commit statement for the transaction is read, the value of rs_origin_commit_time is set to the actual commit time. Therefore, when the configuration parameter dsi_num_large_xact_threads is set to a value greater than zero, the value for rs_origin_commit_time is not reliable for any system function other than rs_commit.


System variables and NULL values


Replacing function strings

Permissions

create function string requires “create object” permission.

See also

alter function string,configure connection, create connection, create function string class, create subscription, define subscription, drop function string, alter function string