PK
\8–Aoa«, mimetypeapplication/epub+zipPK \8–A iTunesMetadata.plistZ¥û
The TimesTen ttIsql
utility is a general tool for working with a TimesTen data source. The ttIsql
command line interface is used to execute SQL statements and built-in ttIsql
commands to perform various operations. Some common tasks that are typically accomplished using ttIsql
include:
Database setup and maintenance. Creating tables and indexes, altering existing tables and updating table statistics can be performed quickly and easily using ttIsql
.
Retrieval of information on database structures. The definitions for tables, indexes and cache groups can be retrieved using built-in ttIsql
commands. In addition, the current size and state of the database can be displayed.
Optimizing database operations. The ttIsql
utility can be used to alter and display query optimizer plans for the purpose of tuning SQL operations. The time required to execute various ODBC function calls can also be displayed.
The following sections describe how the ttIsql
utility is used to perform these types of tasks:
For more information on ttIsql
commands, see the "ttIsql" section in the Oracle TimesTen In-Memory Database Reference.
The ttIsql
utility can be used in two distinctly different ways: batch mode or interactive mode. When ttIsql
is used in interactive mode, users type commands directly into ttIsql
from the console. When ttIsql
is used in batch mode, a prepared script of ttIsql
commands is executed by specifying the name of the file containing the commands.
Batch mode is commonly used for the following types of tasks:
Performing periodic maintenance operations including the updating of table statistics, compacting the database and purging log files.
Initializing a database by creating tables, indexes and cache groups and then populating the tables with data.
Generating simple reports by executing common queries.
Interactive mode is suited for the following types of tasks:
Experimenting with TimesTen features, testing design alternatives and improving query performance.
Solving database problems by examining database statistics.
Any other database tasks that are not performed routinely.
By default, when starting ttIsql
from the shell, ttIsql
is in interactive mode. The ttIsql
utility prompts you to type in a valid ttIsql
built-in command or SQL statement by printing the Command>
prompt. The following example starts ttIsql in interactive mode and then connects to a TimesTen database by executing the connect
command with the MY_DSN
DSN.
C:\>ttIsql Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql. Command> connect MY_DSN; Connection successful: DSN=MY_DSN;DataStore=E:\ds\MY_DSN; DRIVER=E:\WINNT\System32\TTdv1122.dll; (Default setting AutoCommit=1) Command>
When connecting to the database using ttIsql
, you can also specify the DSN or connection string on the ttIsql
command line. The connect
command is implicitly executed.
C:\>ttIsql MY_DSN Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql. connect "DSN=MY_DSN"; Connection successful: DSN=MY_DSN;DataStore=E:\ds\MY_DSN; DRIVER=E:\WINNT\System32\TTdv1122.dll; (Default setting AutoCommit=1) Command>
Batch mode can be accessed in two different ways. The most common way is to specify the -f
option on the ttIsql
command line followed by the name of file to run.
For example, executing a file containing a CREATE TABLE
statement will look like this:
C:\>ttIsql -f create.sql MY_DSN Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql. Command> connect "DSN=MY_DSN" Connection successful: DSN=MY_DSN;DataStore=E:\ds\MY_DSN; DRIVER=E:\WINNT\System32\TTdv1122.dll; (Default setting AutoCommit=1) Command> run "create.sql" CREATE TABLE LOOKUP (KEY NUMBER NOT NULL PRIMARY KEY, VALUE CHAR (64)) Command> exit Disconnecting... Done. C:\>
The other way to use batch mode is to enter the run
command directly from the interactive command prompt. The run
command is followed by the name of the file containing ttIsql
built-in commands and SQL statements to execute:
Command> run "create.sql"; CREATE TABLE LOOKUP (KEY NUMBER NOT NULL PRIMARY KEY, VALUE CHAR (64)) Command>
The ttIsql
utility can be customized to automatically execute a set of command line options every time a ttIsql
session is started from the command prompt. This is accomplished by setting an environment variable called TTISQL
to the value of the ttIsql
command line that you prefer. A summary of ttIsql
command line options is shown below. For a complete description of the ttIsql
command line options, see the "ttIsql" section in the Oracle TimesTen In-Memory Database Reference.
Usage: ttIsql [-h | -help | -helpcmds | -helpfull | -V] ttIsql [-f <filename>] [-v <verbosity>] [-e <commands>] [-interactive] [-N <ncharEncoding>] [-wait] [{<DSN> | -connstr <connection_string>}]
The TTISQL
environment variable has the same syntax requirements as the ttIsql
command line. When ttIsql
starts up it reads the value of the TTISQL
environment variable and applies all options specified by the variable to the current ttIsql
session. If a particular command line option is specified in both the TTISQL
environment variable and the command line then the command line version will always take precedence.
The procedure for setting the value of an environment variable differs based on the platform and shell that ttIsql
is started from. As an example, setting the TTISQL
environment variable on Windows could look like this:
C:\>set TTISQL=-connStr "DSN=MY_DSN" -e "autocommit 0;dssize;"
In this example, ttIsql
will automatically connect to a DSN called MY_DSN
, turn off autocommit and display the size of the database as shown below:
C:\>ttIsql Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql. Command> connect "DSN=MY_DSN"; Connection successful: DSN=MY_DSN;DataStore=E:\ds\MY_DSN; DRIVER=E:\WINNT\System32\TTdv1122.dll; (Default setting AutoCommit=1) Command> autocommit 0; Command> alltables; SYS.ACCESS$ SYS.ARGUMENT$ SYS.CACHE_GROUP SYS.COLUMNS SYS.COLUMN_HISTORY SYS.COL_STATS SYS.DEPENDENCY$ SYS.DIR$ SYS.DUAL SYS.ERROR$ SYS.IDL_CHAR$ SYS.IDL_SB4$ SYS.IDL_UB1$ SYS.IDL_UB2$ SYS.INDEXES SYS.MONITOR ... 59 tables found. Command>
You can customize the ttIsql
command prompt by using the set
command with the prompt
attribute:
Command> set prompt MY_DSN; MY_DSN
You can specify a string format (%c
) that returns the name of the current connection:
Command> set prompt %c; con1
If you want to embed spaces, you must quote the string:
Command> set prompt "MY_DSN %c> "; MY_DSN con1>
The ttIsql
utility has an online version of command syntax definitions and descriptions for all built-in ttIsql
commands. To access this online help from within ttIsql
use the help
command. To view a detailed description of any built-in ttIsql
commands type the help
command followed by one or more ttIsql
commands to display help for. The example below displays the online description for the connect
and disconnect
commands.
Command> help connect disconnect Arguments in <> are required. Arguments in [] are optional. Command Usage: connect [DSN|connection_string] [as <connection_id>] Command Aliases: (none) Description: Connects to the data source specified by the optional DSN or connection string argument. If an argument is not given, then the DSN or connection string from the last successful connection is used. A connection ID may optionally be specified, for use in referring to the connection when multiple connections are enabled. The DSN is used as the default connection ID. If that ID is already in use, the connection will be assigned the ID "conN", where N is some number larger than 0. Requires an active connection: NO Requires autocommit turned off: NO Reports elapsed execution time: YES Works only with a TimesTen data source: NO Example: connect; -or- connect RunData; -or- connect "DSN=RunData"; -or- connect RunData as rundata1; Command Usage: disconnect [all] Command Aliases: (none) Description: Disconnects from the currently connected data source or all connections when the "all" argument is included. If a transaction is active when disconnecting then the transaction will be rolled back automatically. If a connection exists when executing the "bye", "quit" or "exit" commands then the "disconnect" command will be executed automatically. Requires an active connection: NO Requires autocommit turned off: NO Reports elapsed execution time: YES Works only with a TimesTen data source: NO Example: disconnect;
To view a short description of all ttIsql
built-in commands type the help
command without an argument. To view a detailed description of all built-in ttIsql
commands type the help
command followed by the all
argument.
To view the list of attributes that can be set or shown by using ttIsql
, enter:
Command> help attributes
On UNIX systems, you can use the 'editline' library to set up emacs (default) or vi bindings that enable you to scroll through previous ttIsql
commands, as well as edit and resubmit them. This feature is not available or needed on Windows.
To disable the 'editline' feature in ttIsql
, use the ttIsql
command set editline off
.
The set up and keystroke information is described for each type of editor:
To use the emacs binding, create a file ~/.editrc
and put "bind
" on the last line of the file, run ttIsql
. The editline lib will print the current bindings.
The keystrokes when using ttIsql
with the emacs binding are:
Keystroke | Action |
---|---|
<Left-Arrow> | Move the insertion point left. Back up. |
<Right-Arrow> | Move the insertion point right. Move forward. |
<Up-Arrow> | Scroll to the command prior to the one being displayed. Places the cursor at the end of the line. |
<Down-Arrow> | Scroll to a more recent command history item and put the cursor at the end of the line. |
<Ctrl-A> | Move the insertion point to the beginning of the line. |
<Ctrl-E> | Move the insertion point to the end of the line. |
<Ctrl-K> | "Kill" (Save and erase) the characters on the command line from the current position to the end of the line. |
<Ctrl-Y> | "Yank" (Restore) the characters previously saved and insert them at the current insertion point. |
<Ctrl-F> | Forward char - move forward 1 (see Right Arrow) |
<Ctrl-B> | Backward char - move back 1 (see Left Arrow) |
<Ctrl-P> | Previous History (see Up Arrow) |
<Ctrl-N> | Next History (see up Down Arrow) |
To use the vi bindings, create a file ${HOME}/.editrc
and put "bind-v
" in the file, run ttIsql
. To get the current settings, create a file ${HOME}/.editrc
and put "bind
" on the last line of the file. When you execute ttIsql
, the editline lib will print the current bindings.
The keystrokes when using ttIsql
with the vi binding are:
Keystroke | Action |
---|---|
<Left-Arrow>, h | Move the insertion point left (back up) |
<Right-Arrow>, l | Move the insertion point right (forward) |
<Up-Arrow>, k | Scroll to the prior command in the history and put the cursor at the end of the line. |
<Down-Arrow>, j | Scroll to the next command in the history and put the cursor at the end of the line. |
ESC | Vi Command mode |
0, $ | Move the insertion point to the beginning of the line, Move to end of the line. |
i, I | Insert mode, Insert mode at beginning of the line |
a, A | Add ("Insert after") mode, Append at end of line |
R | Replace mode |
C | Change to end of line |
B | Move to previous word |
e | Move to end of word |
<Ctrl-P> | Previous History (see Up Arrow) |
<Ctrl-N> | Next History (see up Down Arrow) |
The ttIsql
utility stores a list of the last 100 commands executed within the current ttIsql
session. The commands in this list can be viewed or executed again without having to type the entire command over. Both SQL statements and built-in ttIsql
commands are stored in the history list. Use the history
command ("h
") to view the list of previously executed commands. For example:
Command> h; 8 INSERT INTO T3 VALUES (3) 9 INSERT INTO T1 VALUES (4) 10 INSERT INTO T2 VALUES (5) 11 INSERT INTO T3 VALUES (6) 12 autocommit 0 13 showplan 14 SELECT * FROM T1, t2, t3 WHERE A=B AND B=C AND A=B 15 trytbllocks 0 16 tryserial 0 17 SELECT * FROM T1, t2, t3 WHERE A=B AND B=C AND A=B Command>
The history
command displays the last 10 SQL statements or ttIsql
built-in commands executed. To display more than that last 10 commands specify the maximum number to display as an argument to the history
command.
Each entry in the history list is identified by a unique number. The !
character followed by the number of the command can be used to execute the command again. For example:
Command> Command> ! 12; autocommit 0 Command>
To execute the last command again simply type a sequence of two !
characters:
Command> !!; autocommit 0 Command>
To execute the last command that begins with a given string type the !
character followed by the first few letters of the command. For example:
Command> ! auto; autocommit 0 Command>
You can save the list of commands that ttIsql
stores by using the savehistory
command:
Command> savehistory history.txt;
If the output file already exists, use the -a
option to append the new command history to the file or the -f
option to overwrite the file. The next example shows how to append new command history to an existing file.
Command> savehistory -a history.txt;
You can clear the list of commands that ttIsql
stores by using the clearhistory
command:
Command> clearhistory;
The ttIsql
utility supports the character sets listed in "Supported character sets" in the Oracle TimesTen In-Memory Database Reference. The ability of ttIsql
to display characters depends on the native operating system locale settings of the terminal on which you are using ttIsql
.
To override the locale-based output format, use the ncharencoding
option or the -N
option. The valid values for these options are LOCALE
(the default) and ASCII
. If you choose ASCII
and ttIsql
encounters a Unicode character, it displays it in escaped format.
You do not need to have an active connection to change the output method.
There are several ttIsql
commands that display information on database structures. The most useful commands are summarized below:
dssize
- Reports the current sizes of the permanent and temporary database partitions.
tablesize
- Displays the size of tables that have been analyzed with the ttComputeTabSizes
tool.
monitor
- Displays a summary of the current state of the database.
Use the describe
command to display information on individual database objects. Displays parameters for prepared SQL statements and built-in procedures. The argument to the describe
command can be the name of a table, cache group, view, materialized view, materialized view log, sequence, synonym, a built-in procedure, a SQL statement or a command ID for a previously prepared SQL statement, a PL/SQL function, PL/SQL procedure or PL/SQL package.
The describe
command requires a semicolon character to terminate the command.
Command> CREATE TABLE T1 (KEY NUMBER NOT NULL PRIMARY KEY, VALUE CHAR (64)); Command> describe T1 > ; Table USER.T1: Columns: *KEY NUMBER NOT NULL VALUE CHAR (64) 1 table found. (primary key columns are indicated with *) Command> describe SELECT * FROM T1 WHERE KEY=?; Prepared Statement: Parameters: Parameter 1 NUMBER Columns: KEY NUMBER NOT NULL VALUE CHAR (64) Command> describe ttOptUseIndex; Procedure TTOPTUSEINDEX: Parameters: Parameter INDOPTION VARCHAR (1024) Columns: (none) 1 procedure found. Command>
The cachegroups
command is used to provide detailed information on cache groups defined in the current database. The attributes of the root and child tables defined in the cache group are displayed in addition to the WHERE
clauses associated with the cache group. The argument to the cachegroups
command is the name of the cache group that you want to display information for.
Command> cachegroups; Cache Group CACHEUSER.READCACHE: Cache Group Type: Read Only Autorefresh: Yes Autorefresh Mode: Incremental Autorefresh State: Paused Autorefresh Interval: 5 Seconds Autorefresh Status: ok Aging: No aging defined Root Table: ORATT.READTAB Table Type: Read Only Cache Group CACHEUSER.WRITECACHE: Cache Group Type: Asynchronous Writethrough global (Dynamic) Autorefresh: No Aging: LRU on Root Table: ORATT.WRITETAB Table Type: Propagate 2 cache groups found.
The dssize
command is used to report the current memory status of the permanent and temporary partitions as well as the maximum, allocated and in-use sizes for the database.
Command> dssize PERM_ALLOCATED_SIZE: 32768 PERM_IN_USE_SIZE: 8615 PERM_IN_USE_HIGH_WATER: 8615 TEMP_ALLOCATED_SIZE: 40960 TEMP_IN_USE_SIZE: 5794 TEMP_IN_USE_HIGH_WATER: 8959
The tablesize
command displays the detailed analysis of the amount of space used by a table. Once you execute the ttComputeTabSizes
built-in procedure, which analyzes the table size of the indicated tables, the tablesize
command displays the total size data for all analyzed tables.
Executing the tablesize
command with no arguments displays available sizing information for all tables that have had the ttComputeTabSizes
computation run. When you provide a table as an argument, tablesize
displays available sizing only for the indicated table.
The syntax for tablesize
is as follows:
tablesize [[owner_name_pattern.]table_name_pattern]
The following example invokes the ttComputeTabSizes
built-in procedure to calculate the table size of the employees
table. Then, the tablesize
command displays the sizing information gathered for the employees
table.
Command> call ttComputeTabSizes('employees'); Command> tablesize employees; Sizes of USER1.EMPLOYEES: INLINE_ALLOC_BYTES: 60432 NUM_USED_ROWS: 107 NUM_FREE_ROWS: 149 AVG_ROW_LEN: 236 OUT_OF_LINE_BYTES: 0 METADATA_BYTES: 1304 TOTAL_BYTES: 61736 LAST_UPDATED: 2011-06-29 12:55:28.000000 1 table found.
These values provide insights into overhead and how the total space is used for the table.
For example:
The NUM_FREE_ROWS
value describes the number of rows allocated for the table, but not currently in use. Space occupied by free rows cannot be used by the system for storing other system objects or structures.
Use the TOTAL_BYTES
value to calculate how much permanent space your table occupies.
LAST_UPDATED
is the time of the last size computation. If you want a more recent computation, re-execute ttComputeTabSizes
and display the new output.
You can find a description for each calculated value in the "SYS.ALL_TAB_SIZES" section in the Oracle TimesTen In-Memory Database System Tables and Views Reference.
The monitor
command displays all of the information provided by the dssize
command plus additional statistics on the number of connections, checkpoints, lock timeouts, commits, rollbacks and other information collected since the last time the database was loaded into memory.
Command> monitor; TIME_OF_1ST_CONNECT: Wed Apr 20 10:34:17 2011 DS_CONNECTS: 11 DS_DISCONNECTS: 0 DS_CHECKPOINTS: 0 DS_CHECKPOINTS_FUZZY: 0 DS_COMPACTS: 0 PERM_ALLOCATED_SIZE: 40960 PERM_IN_USE_SIZE: 5174 PERM_IN_USE_HIGH_WATER: 5174 TEMP_ALLOCATED_SIZE: 18432 TEMP_IN_USE_SIZE: 4527 TEMP_IN_USE_HIGH_WATER: 4527 SYS18: 0 TPL_FETCHES: 0 TPL_EXECS: 0 CACHE_HITS: 0 PASSTHROUGH_COUNT: 0 XACT_BEGINS: 2 XACT_COMMITS: 1 XACT_D_COMMITS: 0 XACT_ROLLBACKS: 0 LOG_FORCES: 0 DEADLOCKS: 0 LOCK_TIMEOUTS: 0 LOCK_GRANTS_IMMED: 17 LOCK_GRANTS_WAIT: 0 SYS19: 0 CMD_PREPARES: 1 CMD_REPREPARES: 0 CMD_TEMP_INDEXES: 0 LAST_LOG_FILE: 0 REPHOLD_LOG_FILE: -1 REPHOLD_LOG_OFF: -1 REP_XACT_COUNT: 0 REP_CONFLICT_COUNT: 0 REP_PEER_CONNECTIONS: 0 REP_PEER_RETRIES: 0 FIRST_LOG_FILE: 0 LOG_BYTES_TO_LOG_BUFFER: 64 LOG_FS_READS: 0 LOG_FS_WRITES: 0 LOG_BUFFER_WAITS: 0 CHECKPOINT_BYTES_WRITTEN: 0 CURSOR_OPENS: 1 CURSOR_CLOSES: 1 SYS3: 0 SYS4: 0 SYS5: 0 SYS6: 0 CHECKPOINT_BLOCKS_WRITTEN: 0 CHECKPOINT_WRITES: 0 REQUIRED_RECOVERY: 0 SYS11: 0 SYS12: 1 TYPE_MODE: 0 SYS13: 0 SYS14: 0 SYS15: 0 SYS16: 0 SYS17: 0 SYS9:
You can use ttIsql
to list tables, indexes, views, sequences, synonyms, PL/SQL functions, procedures and packages in a database. Commands prefixed by all
display all of this type of object. For example, the functions
command lists PL/SQL functions that are owned by the user, whereas allfunctions
lists all PL/SQL functions.
You can optionally specify patterns for object owners and object names.
Use these commands to list database objects:
tables
and alltables
- Lists tables
indexes
and allindexes
- Lists indexes
views
and allviews
- Lists views
sequences
and allsequences
- Lists sequences
synonyms
and allsynonyms
- Lists synonyms
functions
and allfunctions
- Lists PL/SQL functions
procedures
and allprocedures
- Lists PL/SQL procedures
packages
and allpackages
- Lists PL/SQL packages
Note: For details on each of these commands, see the "ttIsql" section in the Oracle TimesTen In-Memory Database Reference. |
The following example demonstrates the procedures
and allprocedures
commands. User TERRY
creates a procedure called proc1
while connected to myDSN
. Note that a slash character (/) is entered on a new line following the PL/SQL statements.
The procedures
command and the allprocedures
command show that it is the only PL/SQL procedure in the database.
$ ttisql myDSN Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql. connect "DSN=myDSN"; Connection successful: DSN=myDSN;UID=terry;DataStore=/scratch/terry/myDSN;DatabaseCharacter Set=AL32UTF8;ConnectionCharacterSet=US7ASCII;PermSize=32;TypeMode=0; (Default setting AutoCommit=1) Command> create or replace procedure proc1 as begin null; end; > / Procedure created. Command> procedures; TERRY.PROC1 1 procedure found. Command> allprocedures; TERRY.PROC1 1 procedure found.
Now connect to the same DSN as Pat and create a procedure called q
. The allprocedures
command shows the PL/SQL procedures created by Terry and pat
.
$ ttisql "dsn=myDSN;uid=PAT" Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql. connect "dsn=myDSN;uid=PAT"; Connection successful: DSN=myDSN;UID=PAT; DataStore=/scratch/terry/myDSN;DatabaseCharacterSet=AL32UTF8; ConnectionCharacterSet=US7ASCII;PermSize=32;TypeMode=0; (Default setting AutoCommit=1) Command> create or replace procedure q as begin null; end; > / Procedure created. Command> procedures; PAT.Q 1 procedure found. Command> allprocedures; TERRY.PROC1 PAT.Q 2 procedures found.
You can view and set connection attributes with the ttIsql
show
and set
commands. For a list of the attributes that you can view and set with ttIsql
, see "Connection Attributes" in Oracle TimesTen In-Memory Database Reference.
To view the setting for the Passthrough
attribute, enter:
Command> show passthrough; PassThrough = 0
To change the Passthrough
setting, enter:
Command> set passthrough 1;
The ttIsql
utility has several built-in commands for managing transactions. These commands are summarized below:
autocommit
- Turns on or off the autocommit feature. This can also be set as an attribute of the set
command.
commitdurable
- Commits the current transaction and ensures that the committed work will be recovered in case of database failure.
isolation
- Changes the transaction isolation level. This can also be set as an attribute of the set
command.
sqlquerytimeout
- Specifies the number of seconds to wait for a SQL statement to execute before returning to the application. This can also be set as an attribute of the set
command.
When starting ttIsql
, the autocommit feature is turned on by default, even within a SQL script. In this mode, every SQL operation against the database is committed automatically. When autocommit is turned off, then automatic commit depends on the setting for the DDLCommitBehavior
connection attribute and the user executing DDL. For more information, see "Relationship between autocommit and DDLCommitBehavior".
To turn the autocommit feature off, execute the ttIsql
autocommit
command with an argument of 0. When autocommit is turned off, transactions must be committed or rolled back manually by executing the ttIsql
commit
, commitdurable
or rollback
commands. The commitdurable
command ensures that the transaction's effect is preserved in case of database failure. If autocommit is off when ttIsql
exits, any uncommitted statements will be rolled back and reported by ttIsql
.
The ttIsql
isolation
command can be used to change the current connection's transaction isolation properties. The isolation can be changed only at the beginning of a transaction. The isolation
command accepts one of the following constants: READ_COMMITTED
and SERIALIZABLE
. If the isolation
command is modified without an argument then the current isolation level is reported.
The ttIsql
sqlquerytimeout
command sets the timeout period for SQL statements. If the execution time of a SQL statement exceeds the number of seconds set by the sqlquerytimeout
command, the SQL statement is not executed and an 6111 error is generated. For details, see "Setting a timeout duration for SQL statements" in the Oracle TimesTen In-Memory Database Java Developer's Guide and "Setting a timeout duration for SQL statements" in the Oracle TimesTen In-Memory Database C Developer's Guide.
Note: TimesTen rollback and query timeout features do not stop IMDB Cache operations that are being processed on Oracle. This includes passthrough statements, flushing, manual loading, manual refreshing, synchronous writethrough, propagating and dynamic loading. |
The following example demonstrates the common use of the ttIsql
built-in transaction management commands.
E:\>ttIsql Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql. Command> connect "DSN=MY_DSN"; Connection successful: DSN=MY_DSN;DataStore=E:\ds\MY_DSN; DRIVER=E:\WINNT\System32\TTdv1122.dll; (Default setting AutoCommit=1) Command> autocommit 0; Command> CREATE TABLE LOOKUP (KEY NUMBER NOT NULL PRIMARY KEY, VALUE CHAR (64)); Command> commit; Command> INSERT INTO LOOKUP VALUES (1, 'ABC'); 1 row inserted. Command> SELECT * FROM LOOKUP; < 1, ABC > 1 row found. Command> rollback; Command> SELECT * FROM LOOKUP; 0 rows found. Command> isolation; isolation = READ_COMMITTED Command> commitdurable; Command> sqlquerytimeout 10; Command> sqlquerytimeout; Query timeout = 10 seconds Command> disconnect; Disconnecting... Command> exit; Done.
Preparing a SQL statement just once and then executing it multiple times is much more efficient for TimesTen applications than re-preparing the statement each time it is to be executed. ttIsql
has a set of built-in commands to work with prepared SQL statements. These commands are summarized below:
prepare
- Prepares a SQL statement. Corresponds to a SQLPrepare
ODBC call.
exec
- Executes a previously prepared statement. Corresponds to a SQLExecute
ODBC call.
execandfetch
- Executes a previously prepared statement and fetches all result rows. Corresponds to a SQLExecute
call followed by one or more calls to SQLFetch
.
fetchall
- Fetches all result rows for a previously executed statement. Corresponds to one or more SQLFetch
calls.
fetchone
- Fetches only one row for a previously executed statement. Corresponds to exactly one SQLFetch
call.
close
- Closes the result set cursor on a previously executed statement that generated a result set. Corresponds to a SQLFreeStmt
call with the SQL_CLOSE
option.
free
- Closes a previously prepared statement. Corresponds to a SQLFreeStmt
call with the SQL_DROP
option.
describe
- Describes the prepared statement including the input parameters and the result columns.
The ttIsql
utility prepared statement commands also handle SQL statement parameter markers. When parameter markers are included in a prepared SQL statement, ttIsql
will automatically prompt for the value of each parameter in the statement at execution time.
The example below uses the prepared statement commands of the ttIsql
utility to prepare an INSERT
statement into a table containing a NUMBER
and a CHAR
column. The statement is prepared and then executed twice with different values for each of the statement's two parameters. The ttIsql
utility timing
command is used to display the elapsed time required to executed the primary ODBC function call associated with each command.
Command> connect "DSN=MY_DSN"; Connection successful: DSN=MY_DSN;DataStore=E:\ds\MY_DSN;DRIVER= E:\WINNT\System32\TTdv1122.dll; (Default setting AutoCommit=1) Command> timing 1; Command> create table t1 (key number not null primary key, value char(20)); Execution time (SQLExecute) = 0.007247 seconds. Command> prepare insert into t1 values (:f, :g); Execution time (SQLPrepare) = 0.000603 seconds. Command> exec; Type '?' for help on entering parameter values. Type '*' to end prompting and abort the command. Type '-' to leave the parameter unbound. Type '/' to leave the remaining parameters unbound and execute the command. Enter Parameter 1 'F' (NUMBER) > 1; Enter Parameter 2 'G' (CHAR) > 'abc'; 1 row inserted. Execution time (SQLExecute) = 0.000454 seconds. Command> exec; Type '?' for help on entering parameter values. Type '*' to end prompting and abort the command. Type '-' to leave the parameter unbound. Type '/' to leave the remaining parameters unbound and execute the help command. Enter Parameter 1 'F' (NUMBER) > 2; Enter Parameter 2 'G' (CHAR) > 'def'; 1 row inserted. Execution time (SQLExecute) = 0.000300 seconds. Command> free; Command> select * from t1; < 1, abc > < 2, def > 2 rows found. Execution time (SQLExecute + Fetch Loop) = 0.000226 seconds. Command> disconnect; Disconnecting... Execution time (SQLDisconnect) = 2.911396 seconds. Command>
In the example above, the prepare
command is immediately followed by the SQL statement to prepare. Whenever a SQL statement is prepared in ttIsql
, a unique command ID is assigned to the prepared statement. The ttIsql
utility uses this ID to keep track of multiple prepared statements. A maximum of 256 prepared statements can exist in a ttIsql
session simultaneously. When the free
command is executed, the command ID is automatically disassociated from the prepared SQL statement.
To see the command IDs generated by ttIsql
when using the prepared statement commands, set the verbosity level to 4 using the verbosity
command before preparing the statement, or use the describe *
command to list all prepared statements with their IDs.
Command IDs can be referenced explicitly when using ttIsql
's prepared statement commands. For a complete description of the syntax of ttIsql
's prepared statement commands see the "ttIsql" section in the Oracle TimesTen In-Memory Database Reference or type help
at the ttIsql
command prompt.
The example below prepares and executes a SELECT
statement with a predicate containing one NUMBER
parameter. The fetchone
command is used to fetch the result row generated by the statement. The showplan
command is used to display the execution plan used by the TimesTen query optimizer when the statement is executed. In addition, the verbosity level is set to 4 so that the command ID used by ttIsql
to keep track of the prepared statement is displayed.
Command> connect "DSN=MY_DSN"; Connection successful: DSN=MY_DSN;DataStore=E:\ds\MY_DSN; DRIVER=E:\WINNT\Sys tem32\TTdv1122.dll; (Default setting AutoCommit=1) The command succeeded. Command> CREATE TABLE T1 (KEY NUMBER NOT NULL PRIMARY KEY, VALUE CHAR (64)); The command succeeded. Command> INSERT INTO T1 VALUES (1, 'abc'); 1 row inserted. The command succeeded. Command> autocommit 0; The command succeeded. Command> showplan 1; The command succeeded. Command> verbosity 4; The command succeeded. Command> prepare SELECT * FROM T1 WHERE KEY=?; Assigning new prepared command id = 0. Query Optimizer Plan: STEP: 1 LEVEL: 1 OPERATION: RowLkHashScan TBLNAME: T1 IXNAME: T1 PRED: T1.KEY = qmark_1 OTHERPRED: <NULL> The command succeeded. Command> exec; Executing prepared command id = 0. Type '?;' for help on entering parameter values. Type '*;' to abort the parameter entry process. Enter Parameter 1 (NUMBER) >1; The command succeeded. Command> fetchone; Fetching prepared command id = 0. < 1, abc > 1 row found. The command succeeded. Command> close; Closing prepared command id = 0. The command succeeded. Command> free; Freeing prepared command id = 0. The command succeeded. Command> commit; The command succeeded. Command> disconnect; Disconnecting... The command succeeded. Command>
Note: For information about usingttIsql with PL/SQL host variables, see "Introduction to PL/SQL in the TimesTen Database" in Oracle TimesTen In-Memory Database PL/SQL Developer's Guide. |
The following sections describe how to declare, set and use bind variables in ttIsql:
You can declare and set variables and arrays in ttIsql that can be referenced in a SQL statement, SQL script, or PL/SQL block. The variables declared using the variable
and setvariable
command must be one of the following data types: NUMBER
, CHAR
, NCHAR
, VARCHAR2
, NVARCHAR2
, CLOB
, NCLOB
, BLOB
, or REFCURSOR
. However, when binding arrays, Timesten supports only binding arrays of the NUMBER
, CHAR
, NCHAR
, VARCHAR2
, or NVARCHAR2
data types.
Note: All variables that are declared exist for the life of the ttIsql session. However, if you declare a new variable with the same name, the new variable replaces the old variable. |
The following examples declare bind variables with the variable
or var
command for a number, character string, and an array. Each is assigned to a value either when declared or by using the setvariable
or setvar
command.
Note: For details on the syntax for these commands, see "ttIsql" in the Oracle TimesTen In-Memory Database Reference. |
Command> VARIABLE house_number NUMBER := 268; Command> PRINT house_number; HOUSE_NUMBER : 268 Command> VARIABLE street_name VARCHAR2(15); Command> SETVARIABLE street_name := 'Oracle Parkway'; Command> VARIABLE occupants[5] VARCHAR2(15); Command> SETVARIABLE occupants[1] := 'Pat'; Command> SETVARIABLE occupants[2] := 'Terry'; Command> PRINT occupants; OCCUPANTS : ARRAY [ 5 ] (Current Size 2) OCCUPANTS[1] : Pat OCCUPANTS[2] : Terry
The following is an example of binding multiple values in an array using square brackets to delineate the values and commas to separate each value for the array:
Command> VARIABLE occupants[5] VARCHAR2(15) := ['Pat', 'Terry']; Command> PRINT occupants; OCCUPANTS : ARRAY [ 5 ] (Current Size 2) OCCUPANTS[1] : Pat OCCUPANTS[2] : Terry
When using array binds, PL/SQL enables you to bind each variable to a PL/SQL variable with the following declaration, where TypeName
is any unique identifier for the PL/SQL data type and DataType
can be specified as CHAR
, NCHAR
, VARCHAR2
, or NVARCHAR2
.
TYPETypeName
IS TABLE OFDataType
(<precision>) INDEX BY BINARY_INTEGER;
If the variable is declared as array of NUMBER
, you can bind it to a PL/SQL variable of the following data types: NUMBER
, INTEGER
, FLOAT
, or DOUBLE PRECISION
. To do so, use the appropriate declaration:
TYPETypeName
IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; TYPETypeName
IS TABLE OF INTEGER INDEX BY BINARY_INTEGER; TYPETypeName
IS TABLE OF FLOAT INDEX BY BINARY_INTEGER; TYPETypeName
IS TABLE OF DOUBLE PRECISION INDEX BY BINARY_INTEGER;
The following example declares the occupants
VARCHAR2
array, which is then declared and used within a PL/SQL block:
Command> VARIABLE occupants[5] VARCHAR2(15); Command> SETVARIABLE occupants[1] := 'Pat'; Command> SETVARIABLE occupants[2] := 'Terry'; Command> DECLARE > TYPE occuname IS TABLE OF VARCHAR2(15) INDEX BY BINARY_INTEGER; > x occuname; > BEGIN > x := :occupants; > FOR LROW IN x.FIRST..x.LAST LOOP > x(LROW) := x(LROW) || ' Doe'; > END LOOP; > :occupants := x; > END; > / PL/SQL procedure successfully completed. Command> PRINT occupants; OCCUPANTS : ARRAY [ 5 ] (Current Size 2) OCCUPANTS[1] : Pat Doe OCCUPANTS[2] : Terry Doe
When you set autovariables
on in ttIsql, TimesTen creates an automatic bind variable named after each column in the last fetched row. An automatic bind variable can be used in the same manner of any bind variable.
The following example selects all rows from the employees
table. Since all columns are retrieved, automatic variables are created and named for each column. The bind variable contains the last value retrieved for each column.
Command> SET AUTOVARIABLES ON; Command> SELECT * FROM employees; ... < 204, Hermann, Baer, HBAER, 515.123.8888, 1994-06-07 00:00:00, PR_REP, 10000, <NULL>, 101, 70 > < 205, Shelley, Higgins, SHIGGINS, 515.123.8080, 1994-06-07 00:00:00, AC_MGR, 12000, <NULL>, 101, 110 > < 206, William, Gietz, WGIETZ, 515.123.8181, 1994-06-07 00:00:00, AC_ACCOUNT, 8300, <NULL>, 205, 110 > Command> PRINT; EMPLOYEE_ID : 206 FIRST_NAME : William LAST_NAME : Gietz EMAIL : WGIETZ PHONE_NUMBER : 515.123.8181 HIRE_DATE : 1994-06-07 00:00:00 JOB_ID : AC_ACCOUNT SALARY : 8300 COMMISSION_PCT : <NULL> MANAGER_ID : 205 DEPARTMENT_ID : 110
If you provide an alias for a column name, the automatic bind variable name uses the alias, rather than the column name.
Command> SET AUTOVARIABLES ON; Command> SELECT employee_id ID, First_name SURNAME, last_name LASTNAME FROM employees; ID, SURNAME, LASTNAME ... < 204, Hermann, Baer > < 205, Shelley, Higgins > < 206, William, Gietz > 107 rows found. Command> PRINT; ID : 206 SURNAME : William LASTNAME : Gietz
For any query that fetches data without a known named column, set columnlabels
on
to show the column names. The following example shows that the columns returns from ttConfiguration
built-in procedure are paramname
and paramvalue
.
Command> SET AUTOVARIABLES ON; Command> SET COLUMNLABELS ON; Command> call TTCONFIGURATION('PLSQL'); PARAMNAME, PARAMVALUE < PLSQL, 1 > 1 row found. Command> IF :paramvalue = 1 THEN "e:PLSQL is enabled"; PLSQL is enabled Command> IF NOT :paramvalue = 1 THEN "e:PLSQL is not enabled";
You can also use the describe
command to show the column names. The following example uses the describe command to display the column names for the ttConfiguration
built-in procedure.
Command> DESCRIBE TTCONFIGURATION; Procedure TTCONFIGURATION: Parameters: PARAMNAME TT_VARCHAR (30) Columns: PARAMNAME TT_VARCHAR (30) NOT NULL PARAMVALUE TT_VARCHAR (1024) 1 procedure found.
You can create and execute PL/SQL blocks from the ttIsql
command line.
Set serveroutput
on to display results generated fro €ÿm the PL/SQL block:
Command> set serveroutput on
Create an anonymous block that puts a text line in the output buffer. Note that the block must be terminated with a slash (/).
Command> BEGIN > DBMS_OUTPUT.put_line( > 'Welcome!'); > END; > / Welcome! PL/SQL procedure successfully completed. Command>
See the Oracle TimesTen In-Memory Database PL/SQL Developer's Guide for more examples.
You can pass data back to applications from PL/SQL by using OUT
parameters. This example returns information about how full a TimesTen database is.
Create the tt_space_info
PL/SQL procedure and use SQL to provide values for the permpct
, permmaxpct
, temppct
, and tempmaxpct
parameters.
Command> CREATE OR REPLACE PROCEDURE tt_space_info > (permpct OUT PLS_INTEGER, > permmaxpct OUT PLS_INTEGER, > temppct OUT PLS_INTEGER, > tempmaxpct OUT PLS_INTEGER) AS > monitor sys.monitor%ROWTYPE; > BEGIN > SELECT * INTO monitor FROM sys.monitor; > permpct := monitor.perm_in_use_size * 100 / monitor.perm_allocated_size; > permmaxpct := monitor.perm_in_use_high_water * 100 / monitor.perm_allocated_size; > temppct := monitor.temp_in_use_size * 100 / monitor.temp_allocated_size; > tempmaxpct := monitor.temp_in_use_high_water * 100 / monitor.temp_allocated_size; > END; >/ Procedure created.
Declare the variables and call tt_space_info
. The parameter values are passed back to ttIsql
so they can be printed:
Command> VARIABLE permpct NUMBER Command> VARIABLE permpctmax NUMBER Command> VARIABLE temppct NUMBER Command> VARIABLE temppctmax NUMBER Command> BEGIN > tt_space_info(:permpct, :permpctmax, :temppct, :temppctmax); > END; >/ PL/SQL procedure successfully completed. Command> PRINT permpct; PERMPCT : 4 Command> PRINT permpctmax; PERMPCTMAX : 4 Command> PRINT temppct; TEMPPCT : 11 Command> PRINT temppctmax; TEMPPCTMAX : 11
You can also pass back a statement handle that can be executed by a PL/SQL statement with an OUT
refcursor parameter. The PL/SQL statement can choose the query associated with the cursor. The following example opens a refcursor, which randomly chooses between ascending or descending order.
Command> VARIABLE ref REFCURSOR; Command> BEGIN > IF (mod(dbms_random.random(), 2) = 0) THEN > open :ref for select object_name from SYS.ALL_OBJECTS order by 1 asc; > ELSE > open :ref for select object_name from SYS.ALL_OBJECTS order by 1 desc; > end if; > END; > / PL/SQL procedure successfully completed.
To fetch the result set from the refcursor, use the PRINT
command:
Command> PRINT ref REF : < ACCESS$ > < ALL_ARGUMENTS > < ALL_COL_PRIVS > < ALL_DEPENDENCIES > ... 143 rows found.
Or if the result set was ordered in descending order, the following would print:
Command> PRINT ref REF : < XLASUBSCRIPTIONS > < WARNING_SETTINGS$ > < VIEWS > ... 143 rows found.
The IF-THEN-ELSE
command construct enables you to implement conditional branching logic in a ttIsql session. The IF
command tests a condition and decides whether to execute commands within the THEN
clause or the optional ELSE
clause. The commands executed can be SQL statements, SQL scripts, PL/SQL blocks, or TimesTen utilities.
Note: For details on the syntax of theIF-THEN-ELSE construct, see the "ttIsql" section in the Oracle TimesTen In-Memory Database Reference. |
The following example creates and tests a bind variable to see if PL/SQL is enabled. It uses the autovariables
command to create the bind variable from the result of the call to ttConfiguration
. The value can be tested within the IF-THEN-ELSE
conditional by testing the paramvalue
variable.
Note: For more details on theautovariables command, see "Automatically creating bind variables for retrieved columns". |
Command> SET AUTOVARIABLES ON; Command> CALL TTCONFIGURATION('PLSQL'); PARAMNAME, PARAMVALUE < PLSQL, 1 > 1 row found. Command> IF :paramvalue = 1 THEN "e:PLSQL is enabled" > ELSE "e:PLSQL is not enabled"; PLSQL is enabled
The following example checks to see that the employees
table exists. If it does not, it executes the SQL script that creates the employees
table; otherwise, a message is printed out.
Command> IF 0 = "SELECT COUNT(*) FROM SYS.TABLES > WHERE TBLNAME LIKE 'employees';" > THEN "e:EMPLOYEES table already exists" > ELSE "@HR_CRE_TT.SQL;"; EMPLOYEES table already exists
There may be a situation where you want to load the results of a SQL query from a back-end Oracle database into a single table on TimesTen without creating a cache grid, cache group, and cache table to contain the results. TimesTen provides the tools that will execute a user-provided SELECT
statement on Oracle and load the result set into a table on TimesTen.
The following are the major steps that are performed to accomplish this task:
Create a table with the correct columns and data types on TimesTen.
Provide a SELECT
statement that will be executed on Oracle to generate the desired result set.
Load the result set into the table on TimesTen.
TimesTen provides two methods to accomplish these tasks:
The ttIsql
utility provides the createandloadfromoraquery
command that, once provided the TimesTen table name and the SELECT
statement, will automatically create the TimesTen table, execute the SELECT
statement on Oracle, and load the result set into the TimesTen table. This command is described fully in "Use ttIsql to create a table and load SQL query results".
The ttTableSchemaFromOraQueryGet
built-in procedure evaluates the user-provided SELECT
statement to generate a CREATE TABLE
statement that can be executed to create a table on TimesTen, which would be appropriate to receive the result set from the SELECT
statement. The ttLoadFromOracle
built-in procedure executes the SELECT
statement on Oracle and loads the result set into the TimesTen table. These built-in procedures are described fully in "Use TimesTen built-in procedures to recommend a table and load SQL query results".
Both methods require the following:
Both the TimesTen and Oracle databases involved must be configured with the same national database character set.
When you connect to the TimesTen database, the connection must contain the same connection attributes that are required when using cache groups, as follows:
The user name, which must be the same on both the TimesTen and Oracle databases
Note: The correct privileges must be granted to these users on each database for the SQL statements that will be executed on their behalf. |
The correct passwords for each user as appropriate in the PWD
and OraclePWD
connection attributes
The OracleServiceName
connection attributes that identifies the Oracle database instance
For either method, the user provides the following:
The table name on the TimesTen database where the results of the SQL query will be loaded. If the owner of the table is not provided, the table is created with the current user as the owner. The table name is not required to be the same name as the table name on the Oracle database against which the SQL statement is executed. This table does not require a primary key. If the table already exists, a warning will be issued and the retrieved rows are appended to the table.
Optionally, the number of parallel threads that you would like to be used in parallel when loading the table with the result set. This defaults to four.
The SQL SELECT
statement that will be executed against the Oracle database to obtain the required rows. The tables specified within this SELECT
statement must be fully qualified, unless the tables are within the schema of the current Oracle user. The query cannot have any parameter bindings.
The SELECT
list should contain either simple column references or column aliases. For example, any expressions in the SELECT
list should be provided with a column alias. You can also use the column alias to avoid duplication of column names in the result table. For example, instead of using SELECT C1+1 FROM T1
, use SELECT C1 + 1 C2 FROM T1
, which would create a column named C2
.
TimesTen evaluates the SELECT
statement and uses the column names, data types, and nullability information to create the table on TimesTen into which the result set will be loaded. The column names and data types (either the same or mapped) are taken from the tables on Oracle involved in the SELECT
statement. However, other Oracle table definition information (such as DEFAULT
values, primary key, foreign key relationships, and so on) are not used when creating the CREATE TABLE
statement for the TimesTen table.
Note: If the evaluation returns any unsupported data types or if the query cannot be executed on Oracle, such as from a syntax error, a warning is logged and a comment is displayed for the unsupported column in the output. However, if the data type is not supported by TimesTen, you can cast the data type directly in theSELECT list to a TimesTen supported data type. |
The load process does not check that the column data types and sizes in the TimesTen table match the data types and sizes of the result set. Instead, the insert is attempted and if the column data types cannot be mapped, an error is returned. If the retrieved Oracle data from the SQL query exceeds the TimesTen column size, the data is truncated without a warning.
The load is automatically committed every 256 rows. If an error is encountered during the load, it will terminate the load, but will not roll back any committed transactions. Any errors returned from the Oracle database are reported in the same manner as when using cache groups.
Because you can use these methods to load into an existing TimesTen table, the following lists the restrictions for this situation:
You cannot load into system tables, dictionary tables, temporary tables, detail tables of views, materialized view tables, materialized view log tables, or tables already in a cache group. In addition, you cannot use a synonym for the table name.
If you load the result set into an existing table that is the referencing table (child table) of a foreign key constraint, the constraint will not be validated. As a result, rows that are missing a parent row may be loaded. Instead, you should verify all foreign keys after the table is loaded.
The following sections provide more details on each individual method:
The ttIsql
utility provides the createandloadfromoraquery
command, which takes a table name, the number of parallel threads, and a SELECT
statement that will be executed on Oracle as input parameters. From these parameters, TimesTen performs the following:
Evaluates the SQL query and creates an appropriate table, if not already created, with the provided table name where the columns are those named in the SQL query with the same (or mapped) data types as those in the Oracle database tables from which the resulting data is retrieved.
Loads the results of the SQL query as executed on the Oracle database into this table. The call returns a single number indicating the number of rows loaded. Any subsequent calls to this command append retrieved rows to the table.
Note: See thecreateandloadfromoraquery command in "ttIsql" in the Oracle TimesTen In-Memory Database Reference for full details on syntax, requirements, restrictions, and required privileges. |
The following ttIsql
example connects providing the DSN, user name, password for the user on TimesTen, and the password for the same user name on the Oracle database. Then, it executes the createandloadfromoraquery
command to evaluate the SELECT
statement. The employees
table is created on TimesTen with the same column names and data types as the columns and data types of the retrieved rows. Then, the table is populated with the result set from Oracle over two parallel threads.
ttisql "DSN=cachedb1_1122;UID=oratt;PWD=timesten;OraclePWD=oracle" Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql connect "DSN=mydb;UID=oratt;PWD=timesten;OraclePWD=oracle"; Connection successful: DSN=mydb;UID=oratt; DataStore=/timesten/install/info/DemoDataStore/mydb;DatabaseCharacterSet=WE8DEC; ConnectionCharacterSet=US7ASCII;DRIVER=/timesten/install/lib/libtten.so; PermSize=40;TempSize=32;TypeMode=0;OracleNetServiceName=inst1; (Default setting AutoCommit=1) Command> createandloadfromoraquery employees 2 SELECT * FROM hr.employees; Mapping query to this table: CREATE TABLE "ORATT"."EMPLOYEES" ( "EMPLOYEE_ID" number(6,0) NOT NULL, "FIRST_NAME" varchar2(20 byte), "LAST_NAME" varchar2(25 byte) NOT NULL, "EMAIL" varchar2(25 byte) NOT NULL, "PHONE_NUMBER" varchar2(20 byte), "HIRE_DATE" date NOT NULL, "JOB_ID" varchar2(10 byte) NOT NULL, "SALARY" number(8,2), "COMMISSION_PCT" number(2,2), "MANAGER_ID" number(6,0), "DEPARTMENT_ID" number(4,0) ) Table employees created 107 rows loaded from oracle.
Execute the DESCRIBE
command to show the new table:
Note: In this example, the table owner is not specified, so it defaults to the current user. In this example, the current user isoratt . |
Command> DESCRIBE employees; Table ORATT.EMPLOYEES: Columns: EMPLOYEE_ID NUMBER (6) NOT NULL FIRST_NAME VARCHAR2 (20) INLINE LAST_NAME VARCHAR2 (25) INLINE NOT NULL EMAIL VARCHAR2 (25) INLINE NOT NULL PHONE_NUMBER VARCHAR2 (20) INLINE HIRE_DATE DATE NOT NULL JOB_ID VARCHAR2 (10) INLINE NOT NULL SALARY NUMBER (8,2) COMMISSION_PCT NUMBER (2,2) MANAGER_ID NUMBER (6) DEPARTMENT_ID NUMBER (4) 1 table found. (primary key columns are indicated with *) Command> SELECT * FROM employees; < 114, Den, Raphaely, DRAPHEAL, 515.127.4561, 2002-12-07 00:00:00, PU_MAN, 11000, <NULL>, 100, 30 > < 115, Alexander, Khoo, AKHOO, 515.127.4562, 2003-05-18 00:00:00, PU_CLERK, 3100, <NULL>, 114, 30 > … < 205, Shelley, Higgins, SHIGGINS, 515.123.8080, 2002-06-07 00:00:00, AC_MGR, 12008, <NULL>, 101, 110 > < 206, William, Gietz, WGIETZ, 515.123.8181, 2002-06-07 00:00:00, AC_ACCOUNT, 8300, <NULL>, 205, 110 > 107 rows found.
The following example uses the createandloadfromoraquery
command to create the oratt.emp
table on TimesTen and populate it in parallel over four threads with data from the hr.employees
table on the Oracle database, where employee_id
is less than 200.
Command> createandloadfromoraquery emp 4 SELECT * FROM hr.employees WHERE employee_id < 200; Mapping query to this table: CREATE TABLE "ORATT"."EMP" ( "EMPLOYEE_ID" number(6,0) NOT NULL, "FIRST_NAME" varchar2(20 byte), "LAST_NAME" varchar2(25 byte) NOT NULL, "EMAIL" varchar2(25 byte) NOT NULL, "PHONE_NUMBER" varchar2(20 byte), "HIRE_DATE" date NOT NULL, "JOB_ID" varchar2(10 byte) NOT NULL, "SALARY" number(8,2), "COMMISSION_PCT" number(2,2), "MANAGER_ID" number(6,0), "DEPARTMENT_ID" number(4,0) ) Table emp created 100 rows loaded from oracle.
Then, the following createandloadfromoraquery
retrieves all employees whose id is > 200 and the result set is appended to the existing table in TimesTen. A warning tells you that the table already exists and that 6 rows were added to it.
Command> createandloadfromoraquery emp 4 SELECT * FROM hr.employees WHERE employee_id > 200; Warning 2207: Table ORATT.EMP already exists 6 rows loaded from oracle.
While the createAndLoadFromOraQuery
command automatically performs all of the tasks for creating the TimesTen table and loading the result set from Oracle into it, the following two built-in procedures separate the same functionality into the following two steps:
The ttTableSchemaFromOraQueryGet
built-in procedure evaluates the SQL query and generates the CREATE TABLE
SQL statement that you can choose to execute. In order to execute this statement, the user should have all required privileges to execute the query on Oracle. This enables you to view the table structure without execution. However, it does require you to execute the recommended CREATE TABLE
statement yourself.
The ttLoadFromOracle
built-in procedure executes the SQL query on the back-end Oracle database and then loads the result set into the TimesTen table. It requires the TimesTen table name where the results will be loaded, the Oracle SQL SELECT
statement to obtain the required rows, and the number of parallel threads that you would like to be used in parallel when loading the table with this result set.
The call returns a single number indicating the number of rows loaded. Any subsequent calls append the retrieved rows to the table.
Note: See "ttTableSchemaFromOraQueryGet" and "ttLoadFromOracle" in the Oracle TimesTen In-Memory Database Reference for full details on syntax, requirements, restrictions, and required privileges. |
The following example connects providing the DSN, user name, password for the user on TimesTen, the password for a user with the same name on the Oracle database, and the OracleNetServiceName
for the Oracle database instance. Then, it executes the ttTableSchemaFromOraQueryGet
built-in procedure to evaluate the SELECT
statement and return a recommended CREATE TABLE
statement for the employees
table. Finally, the example executes the ttLoadFromOracle
built-in procedure to load the employees
table with the result set from Oracle. The load is performed in parallel over four threads, which is the default.
Note: Ifautocommit is set to off, then the user must either commit or rollback manually after loading the table. |
$ ttisql "DSN=mydb;uid=oratt;pwd=timesten; OraclePwd=oracle;OracleNetServiceName=inst1" Copyright (c) 1996-2011, Oracle. All rights reserved. Type ? or "help" for help, type "exit" to quit ttIsql. connect "DSN=mydb;uid=oratt;pwd=timesten; OraclePwd=oracle;OracleNetServiceName=inst1"; Connection successful: DSN=mydb;UID=oratt; DataStore=/timesten/install/info/DemoDataStore/mydb; DatabaseCharacterSet=WE8DEC;ConnectionCharacterSet=US7ASCII; DRIVER=/timesten/install/lib/libtten.so;PermSize=40;TempSize=32; TypeMode=0;OracleNetServiceName=inst1; (Default setting AutoCommit=1) Command> call ttTableSchemaFromOraQueryGet('hr','employees', 'SELECT * FROM hr.employees'); < CREATE TABLE "HR"."EMPLOYEES" ( "EMPLOYEE_ID" number(6,0) NOT NULL, "FIRST_NAME" varchar2(20 byte), "LAST_NAME" varchar2(25 byte) NOT NULL, "EMAIL" varchar2(25 byte) NOT NULL, "PHONE_NUMBER" varchar2(20 byte), "HIRE_DATE" date NOT NULL, "JOB_ID" varchar2(10 byte) NOT NULL, "SALARY" number(8,2), "COMMISSION_PCT" number(2,2), "MANAGER_ID" number(6,0), "DEPARTMENT_ID" number(4,0) ) > 1 row found. Command> CALL ttLoadFromOracle ('HR','EMPLOYEES','SELECT * FROM HR.EMPLOYEES'); < 107 > 1 row found. Command> SELECT * FROM hr.employees; < 100, Steven, King, SKING, 515.123.4567, 2003-06-17 00:00:00, AD_PRES, 24000, <NULL>, <NULL>, 90 > < 101, Neena, Kochhar, NKOCHHAR, 515.123.4568, 2005-09-21 00:00:00, AD_VP, 17000, <NULL>, 100, 90 > ... < 205, Shelley, Higgins, SHIGGINS, 515.123.8080, 2002-06-07 00:00:00, AC_MGR, 12008, <NULL>, 101, 110 > < 206, William, Gietz, WGIETZ, 515.123.8181, 2002-06-07 00:00:00, AC_ACCOUNT, 8300, <NULL>, 205, 110 > 107 rows found.
The following sections describe how to view the query optimizer plans, commands in the SQL command cache, or query plans for commands in the SQL command cache:
The built-in showplan
command is used to display the query optimizer plans used by the TimesTen Data Manager for executing queries. In addition, ttIsql
contains built-in query optimizer hint commands for altering the query optimizer plan. By using the showplan
command in conjunction with the ttIsql
commands summarized below, the optimum execution plan can be designed. For detailed information on the TimesTen query optimizer see "The TimesTen Query Optimizer".
optprofile
- Displays the current optimizer hint settings and join order.
trytmphash
- Enables or disables the use of temporary hash indexes.
trytmptable
- Enables or disables the use of an intermediate results table.
trytmprange
- Enables or disables the use of temporary range indexes.
When using the showplan
command and the query optimizer hint commands the autocommit feature must be turned off. Use ttIsql
's autocommit
built-in command to turn autocommit off.
The example below shows how these commands can be used to change the query optimizer execution plan.
Command> CREATE TABLE T1 (A NUMBER); Command> CREATE TABLE T2 (B NUMBER); Command> CREATE TABLE T3 (C NUMBER); Command> Command> INSERT INTO T1 VALUES (3); 1 row inserted. Command> INSERT INTO T2 VALUES (3); 1 row inserted. Command> INSERT INTO T3 VALUES (3); 1 row inserted. Command> INSERT INTO T1 VALUES (4); 1 row inserted. Command> INSERT INTO T2 VALUES (5); 1 row inserted. Command> INSERT INTO T3 VALUES (6); 1 row inserted. Command> Command> autocommit 0; Command> showplan; Command> SELECT * FROM T1, T2, T3 WHERE A=B AND B=C AND A=B; Query Optimizer Plan: STEP: 1 LEVEL: 3 OPERATION: TblLkSerialScan TBLNAME: T1 IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: <NULL> STEP: 2 LEVEL: 3 OPERATION: TblLkSerialScan TBLNAME: T2 IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: T1.A = T2.B AND T1.A = T2.B STEP: 3 LEVEL: 2 OPERATION: NestedLoop TBLNAME: <NULL> IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: <NULL> STEP: 4 LEVEL: 2 OPERATION: TblLkSerialScan TBLNAME: T3 IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: T1.A = T3.C AND T2.B = T3.C STEP: 5 LEVEL: 1 OPERATION: NestedLoop TBLNAME: <NULL> IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: <NULL> < 3, 3, 3 > 1 row found. Command> trytbllocks 0; Command> tryserial 0; Command> SELECT * FROM T1, T2, T3 WHERE A=B AND B=C AND A=B; Query Optimizer Plan: STEP: 1 LEVEL: 3 OPERATION: TmpRangeScan TBLNAME: T1 IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: <NULL> STEP: 2 LEVEL: 3 OPERATION: RowLkSerialScan TBLNAME: T2 IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: T1.A = T2.B AND T1.A = T2.B STEP: 3 LEVEL: 2 OPERATION: NestedLoop TBLNAME: <NULL> IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: <NULL> STEP: 4 LEVEL: 2 OPERATION: RowLkSerialScan TBLNAME: T3 IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: T1.A = T3.C AND T2.B = T3.C STEP: 5 LEVEL: 1 OPERATION: NestedLoop TBLNAME: <NULL> IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: <NULL> < 3, 3, 3 > 1 row found. Command>
In this example a query against three tables is executed and the query optimizer pla÷@¿n is displayed. The first version of the query simply uses the query optimizer's default execution plan. However, in the second version the trytbllocks
and tryserial
ttIsql
built-in hint commands have been used to alter the query optimizer's plan. Instead of using serial scans and nested loop joins the second version of the query uses temporary index scans, serial scans and nested loops.
In this way the showplan
command in conjunction with ttIsql
's built-in query optimizer hint commands can be used to quickly determine which execution plan should be used to meet application requirements.
The following sections describe how to view commands and their explain plans:
The ttIsql
cmdcache
command invokes the ttSqlCmdCacheInfo
built-in procedure to display the contents of the TimesTen SQL Command Cache. See "Displaying commands stored in the SQL Command Cache" for full details on this procedure.
If you execute the cmdcache
command without parameters, the full SQL Command Cache contents are displayed. Identical to the ttSqlCmdCacheInfo
built-in procedure, you can provide a command ID to specify a specific command to be displayed.
In addition, the ttIsql
cmdcache
command can filter the results so that only those commands that match a particular owner or query text are displayed.
The syntax for the cmdcache
command is as follows:
cmdcache [[by {sqlcmdid | querytext | owner}] <query_substring>
If you provide the owner
parameter, the results are filtered by the owner, identified by the <query_substring>
, displayed within each returned command. If you provide the querytext
parameter, the results are filtered so that all queries are displayed that contain the substring provided within the <query_substring>
. If only the <query_substring>
is provided, such as cmdcache
<query_substring>
, the command assumes to filter the query text by the <query_substring>
.
The ttIsql
explain
command displays the query plan for an individual command.
If you provide a command ID from the SQL Command Cache, the explain
command invokes the ttSqlCmdQueryPlan
built-in procedure to display the query plan for an individual command in the TimesTen SQL Command Cache. If you want the explain plan displayed in a formatted method, execute the explain command instead of calling the ttSqlCmdQueryPlan
built-in procedure. Both provide the same information, but the ttSqlCmdQueryPlan
built-in procedure provides the data in a raw data format. See "Viewing query plans associated with commands stored in the SQL Command Cache" for full details on the ttSqlCmdQueryPlan
built-in procedure.
If you provide a SQL statement or the history item number, the explain
command executes the SQL statements necessary to display the explain plan for this particular SQL statement.
The syntax for the explain
command is as follows:
explain [plan for] {[<Connid>.]<ttisqlcmdid> | sqlcmdid <sqlcmdid> | <sqlstmt> | !<historyitem>}
Identical to the ttSqlCmdQueryPlan
built-in procedure, you can provide a command ID to specify a specific command to be displayed. The command ID can be retrieved with the cmdcache
command, as described in "View commands in the SQL Command Cache".
The following example provides an explain plan for command ID 38001456
:
Command> EXPLAIN SQLCMDID 38001456; Query Optimizer Plan: Query Text: select * from all_objects where object_name = 'DBMS_OUTPUT' STEP: 1 LEVEL: 12 OPERATION: TblLkRangeScan TABLENAME: OBJ$ TABLEOWNERNAME: SYS INDEXNAME: USER$.I_OBJ INDEXEDPRED: NONINDEXEDPRED: (RTRIM( NAME )) = DBMS_OUTPUT;NOT( 10 = TYPE#) ; ( FLAGS ^ 128 = 0) ; STEP: 2 LEVEL: 12 OPERATION: RowLkRangeScan TABLENAME: OBJAUTH$ TABLEOWNERNAME: SYS INDEXNAME: OBJAUTH$.I_OBJAUTH1 INDEXEDPRED: ( (GRANTEE#=1 ) OR (GRANTEE#=10 ) ) AND ( (PRIVILEGE#=8 ) ) NONINDEXEDPRED: OBJ# = OBJ#; STEP: 3 LEVEL: 11 OPERATION: NestedLoop(Left OuterJoin) TABLENAME: TABLEOWNERNAME: INDEXNAME: INDEXEDPRED: NONINDEXEDPRED: ... STEP: 21 LEVEL: 1 OPERATION: Project TABLENAME: TABLEOWNERNAME: INDEXNAME: INDEXEDPRED: NONINDEXEDPRED: Command>
In addition, the ttIsql
explain
command can generate an explain plan for any SQL query you provide. For example, the following shows the explain plan for SQL query "SELECT * FROM DUAL;
"
Command> EXPLAIN SELECT * FROM DUAL; Query Optimizer Plan: STEP: 1 LEVEL: 1 OPERATION: RowLkSerialScan TBLNAME: DUAL IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: <NULL>
You can also retrieve explain plans based upon the command history. The following example shows how you explain a previously executed SQL statement using the history command ID:
Command> SELECT * FROM all_objects WHERE object_name = 'DBMS_OUTPUT'; < SYS, DBMS_OUTPUT, <NULL>, 241, <NULL>, PACKAGE, 2009-10-13 10:41:11, 2009-10-13 10:41:11, 2009-10-13:10:41:11, VALID, N, N, N, 1, <NULL> > < PUBLIC, DBMS_OUTPUT, <NULL>, 242, <NULL>, SYNONYM, 2009-10-13 10:41:11, 2009-10-13 10:41:11, 2009-10-13:10:41:11, INVALID, N, N, N, 1, <NULL> > < SYS, DBMS_OUTPUT, <NULL>, 243, <NULL>, PACKAGE BODY, 2009-10-13 10:41:11, 2009-10-13 10:41:11, 2009-10-13:10:41:11, VALID, N, N, N, 2, <NULL> > 3 rows found. Command> HISTORY; 1 connect "DSN=cache"; 2 help cmdcache; 3 cmdcache; 4 explain select * from dual; 5 select * from all_objects where object_name = 'DBMS_OUTPUT'; Command> EXPLAIN !5; Query Optimizer Plan: STEP: 1 LEVEL: 10 OPERATION: TblLkRangeScan TBLNAME: SYS.OBJ$ IXNAME: USER$.I_OBJ INDEXED CONDITION: <NULL> NOT INDEXED: O.FLAGS & 128 = 0 AND CAST(RTRIM (O.NAME) AS VARCHAR2(30 BYTE) INLINE) = 'DBMS_OUTPUT' AND O.TYPE# <> 10 STEP: 2 LEVEL: 10 OPERATION: RowLkRangeScan TBLNAME: SYS.OBJAUTH$ IXNAME: OBJAUTH$.I_OBJAUTH1 INDEXED CONDITION: (OA.GRANTEE# = 1 OR OA.GRANTEE# = 10) AND OA.PRIVILEGE# = 8 NOT INDEXED: OA.OBJ# = O.OBJ# STEP: 3 LEVEL: 9 OPERATION: NestedLoop(Left OuterJoin) TBLNAME: <NULL> IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: <NULL> STEP: 4 LEVEL: 9 OPERATION: TblLkRangeScan TBLNAME: SYS.OBJAUTH$ IXNAME: OBJAUTH$.I_OBJAUTH1 INDEXED CONDITION: (OBJAUTH$.GRANTEE# = 1 OR OBJAUTH$.GRANTEE# = 10) AND (OBJAUTH$.PRIVILEGE# = 2 OR OBJAUTH$.PRIVILEGE# = 3 OR OBJAUTH$.PRIVILEGE# = 4 OR OBJAUTH$.PRIVILEGE# = 5 OR OBJAUTH$.PRIVILEGE# = 8) NOT INDEXED: O.OBJ# = OBJAUTH$.OBJ# ... STEP: 19 LEVEL: 1 OPERATION: NestedLoop(Left OuterJoin) TBLNAME: <NULL> IXNAME: <NULL> INDEXED CONDITION: <NULL> NOT INDEXED: O.OWNER# = 1 OR (O.TYPE# IN (7,8,9) AND (NOT( ISNULLROW (SYS.OBJAUTH$.ROWID)) OR NOT( ISNULLROW (SYS.SYSAUTH$.ROWID)))) OR (O.TYPE# IN (1,2,3,4,5) AND NOT( ISNULLROW (SYS.SYSAUTH$.ROWID))) OR (O.TYPE# = 6 AND NOT( ISNULLROW (SYS.SYSAUTH$.ROWID))) OR (O.TYPE# = 11 AND NOT( ISNULLROW (SYS.SYSAUTH$.ROWID))) OR (O.TYPE# NOT IN (7,8,9,11) AND NOT( ISNULLROW (SYS.OBJAUTH$.ROWID))) OR (O.TYPE# = 28 AND NOT( ISNULLROW (SYS.SYSAUTH$.ROWID))) OR (O.TYPE# = 23 AND NOT( ISNULLROW (SYS.SYSAUTH$.ROWID))) OR O.OWNER# = 10
You can perform the following on ODBC functions within ttIsql:
The ttIsql command attempts to cancel an ongoing ODBC function when the user presses Ctrl-C.
Information on the time required to execute common ODBC function calls can be displayed by using the ttIsql
timing
command. When the timing feature is enabled many built-in ttIsql
commands will report the elapsed execution time associated with the primary ODBC function call corresponding to the ttIsql
command that is executed.
For example, when executing the ttIsql
connect
command several ODBC function calls are executed, however, the primary ODBC function call associated with connect
is SQLDriverConnect
and this is the function call that is timed and reported as shown below.
Command> timing 1; Command> connect "DSN=MY_DSN"; Connection successful: DSN=MY_DSN;DataStore=E:\ds\MY_DSN; DRIVER=E:\WINNT\System32\ TTdv1122.dll; (Default setting AutoCommit=1) Execution time (SQLDriverConnect) = 1.2626 seconds. Command>
In the example above, the SQLDriverConnect
call took about 1.26 seconds to execute.
When using the timing
command to measure queries, the time required to execute the query plus the time required to fetch the query results is measured. To avoid measuring the time to format and print query results to the display, set the verbosity level to 0 before executing the query.
Command> timing 1; Command> verbosity 0; Command> SELECT * FROM T1; Execution time (SQLExecute + FetchLoop) = 0.064210 seconds. Command>
Execute the WHENEVER
SQLERROR
command to prescribe what to do when a SQL error occurs. WHENEVER
SQLERROR
can be used to set up a recovery action for SQL statements, SQL script, or PL/SQL block.
By default, if a SQL error occurs while in ttIsql, the error information is displayed and ttIsql continues so that you can enter a new command. The default setting is WHENEVER SQLERROR CONTINUE NONE
. You can also specify that ttIsql exits each time an error occurs, which may not be the best action for interactive use or when executing a SQL script or a PL/SQL block.
Note: For syntax of theWHENEVER SQLERROR command, see the "ttIsql" section in the Oracle TimesTen In-Memory Database Reference. |
The following example uses EXIT
to return an error code of 255 and executes a COMMIT
statement to save all changes to the current connection before exiting ttIsql. The example retrieves the error code using the C shell echo $status
command.
Command> WHENEVER SQLERROR EXIT 255 COMMIT; Command> SELECT emp_id FROM employee; 2206: Table PAT.EMPLOYEE not found WHENEVER SQLERROR exiting. $ echo $status 255
The following example demonstrates how the WHENEVER
SQLERROR
command can execute ttIsql commands or TimesTen utilities when an error occurs, even if the error is from another TimesTen utility:
Command> WHENEVER SQLERROR EXEC "DSSIZE;CALL TTSQLCMDCACHEINFOGET();"; Command> CALL TTCACHEPOLICYGET; 5010: No OracleNetServiceName specified in DSN The command failed. DSSIZE; PERM_ALLOCATED_SIZE: 32768 PERM_IN_USE_SIZE: 9204 PERM_IN_USE_HIGH_WATER: 9204 TEMP_ALLOCATED_SIZE: 40960 TEMP_IN_USE_SIZE: 7785 TEMP_IN_USE_HIGH_WATER: 7848 CALL TTSQLCMDCACHEINFOGET(); CMDCOUNT, FREEABLECOUNT, SIZE < 10, 7, 41800 > 1 row found.
The following demonstrates the SUPPRESS
command option. It suppresses all error messages and continues to the next command. The example shows that the error messages can be turned back on in the existing connection with another command option, which in this case is the EXIT
command.
Command> WHENEVER SQLERROR SUPPRESS; Command> SELECT *; Command> WHENEVER SQLERROR EXIT; Command> SELECT *; 1001: Syntax error in SQL statement before or at: "", character position: 9 select * ^ WHENEVER SQLERROR exiting.
The following example sets a bind variable called retcode
, the value of which is returned when a SQL error occurs:
Command> VARIABLE retcode NUMBER := 111; Command> WHENEVER SQLERROR EXIT :retcode; Command> INSERT INTO EMPLOYEES VALUES ( > 202, 'Pat', 'Fay', 'PFAY', '603.123.6666', > TO_DATE ('17-AUG-1997', 'DD-MON-YYYY'), > 'MK_REP', 6000, NULL, 201, 20); 907: Unique constraint (EMPLOYEES on PAT.EMPLOYEES) violated at Rowid <BMUFVUAAACOAAAAIiB> WHENEVER SQLERROR exiting. $ echo $status; 111
This section summarizes the new features and functionality of Oracle TimesTen In-Memory Database Release 11.2.2 that are documented in this guide, providing links into the guide for more information.
A new tool, the Index Advisor, can be used to recommend a set of indexes that could improve the performance of a specific SQL workload. For more details, see "Using the Index Advisor to recommend indexes".
New tools have been added that enable you to load the results of a SQL query from a back-end Oracle database into a single table on TimesTen without creating a cache grid, cache group, and cache table to contain the results. TimesTen provides the tools that will execute a user provided SELECT
statement on Oracle and load the result set into a table on TimesTen. For more information, see "Loading Oracle data into a TimesTen table".
You can defragment a TimesTen database with the ttMigrate
utility. For full details, see "Defragmenting TimesTen databases".
To defragment multiple databases with minimal overall service downtime, use a combination of the ttMigrate
and ttRepAdmin -duplicate
utilities to defragment TimesTen databases that are involved in an active standby pair replication scheme. For details, see "Online defragmentation of TimesTen databases".
You can now declare, use, and set bind variables within ttIsql
with the variable
and setvariable
commands. In addition, automatic bind variables can also be created. See "Using, declaring, and setting variables" for more details.
You can cancel an ODBC function with Ctrl-C. See "Canceling ODBC functions" for more details.
Use the WHENEVER SQLERROR
command to control error recovery within ttIsql
. For more details, see "Error recovery with WHENEVER SQLERROR".
Use the IF-THEN-ELSE
command construct to to implement conditional branching logic in a ttIsql
session. See "Conditional control with the IF-THEN-ELSE command construct" for more details.
It is important to verify at frequent intervals that there are no transaction log holds that could result in an excessive accumulation of transaction log files. If too many transaction log files accumulate and fill up available disk space, new transactions in the TimesTen database cannot begin until the transaction log hold is advanced and transaction log files are purged by the next checkpoint operation. See "Monitoring accumulation of transaction log files" for more details.
The LOB data type is now supported. See "SQL string and character functions" for more details.
Range indexes used to be referred to as T-tree indexes. Now all output and commands use range as the identifying terminology. In "Viewing and changing query optimizer plans", the showplan
command now takes tryrange
and trytmprange
as options and the output for the query plan shows range indexes, such as TmpRangeScan
.
There is a new tablesize
command within ttIsql
that shows the actual sizes of tables within the TimesTen database. For full details, see "Using the ttIsql tablesize command".
The TimesTen Access Control provides authentication for each user and authorization for all objects in the database. Authentication is provided with the correct user password. Management of authorization for all objects in the database is provided by granting appropriate privileges to specific users.
The following sections describe the TimesTen authentication and authorization:
For users to access and manipulate data within the database, you must create users and provide appropriate passwords. When you create a user, you should also grant the appropriate privileges for connecting to the database or for access to objects in the database. For more information on granting privileges, see "Providing authorization to objects through privileges".
The following sections describe how to create and manage your users:
There are three types of users in the TimesTen database:
Instance administrator: The instance administrator is the user who installed the TimesTen instance. This user has full privileges for everything within the TimesTen instance. For information on creating this user, see "TimesTen Installation" in the Oracle TimesTen In-Memory Database Installation Guide.
Note: In addition to the instance administrator, there are four system users created during the TimesTen install. These system users are used internally by TimesTen as follows:SYSTEM for internal use, SYS for system objects, GRID for cache grid objects and TTREP for replication objects. |
Internal user: An internal user is created within TimesTen for use within the TimesTen database. An internal user authenticates with a password for a particular database in which it was defined.
TimesTen user names are case-insensitive, of type TT_CHAR
and limited to 30 characters. For details on all user naming conventions, see "Names, Namespace and Parameters" in the Oracle TimesTen In-Memory Database SQL Reference.
You can create an internal user with the CREATE USER
statement, which is described in the CREATE USER
section in the Oracle TimesTen In-Memory Database SQL Reference.
External user: An external user is created within the operating system. External users are assumed to have been authenticated by the operating system at login time, so there is no stored password within the database. One cannot connect as an external user from a different host from which the TimesTen database is installed. On the same host, we use the operating system credentials of the client to enable the client to connect as that particular external user. For example, if an external user logs into the UNIX system, they can connect to the TimesTen database without specifying a password since they already provided it during the login, as long as the external user has been granted the correct privileges. The external user must also be in the TimesTen users group and have the correct permissions granted to it, as described in the Oracle TimesTen In-Memory Database Installation Guide.
You cannot connect with an external user defined on one host to a TimesTen data source on a remote host. External users can only be used to connect to the local TimesTen data source, because the local operating system authenticates the external user. When connecting over a client/server connection, the external user must be defined on the same host the client and server. Thus, in when using an external user, both the client and the server must be on the same host since the operating system provides the authentication of the user.
While the external user is created within the operating system, you still need to identify the user to the database as an external user with the IDENTIFIED EXTERNALLY
clause of the CREATE USER
statement. For details on this SQL statement, see "CREATE USER" in the Oracle TimesTen In-Memory Database SQL Reference.
UNIX external user names are case sensitive. Windows external user names are not. When connecting from UNIX platforms, TimesTen automatically converts the external user name to upper case, rendering it case insensitive.
If you do not want to use cleartext passwords to log into TimesTen, then use the PWDCrypt
attribute to create a hash of the password. The only reason to use this attribute is if the password is used for logging into other entities, such as an Oracle Database. The PWDCrypt
version of the password can always be used to connect to TimesTen, but you cannot convert it back to the original password in order to connect to Oracle.
Note: Both the instance administrator and all external users must be in the TimesTen users group specified during the install. For more details, see "TimesTen Installation" in the Oracle TimesTen In-Memory Database Installation Guide. |
Only the instance administrator or a user with the ADMIN
privilege can create the internal user or identify the external user with the CREATE USER
statement. For security purposes, you can only create or alter the internal user with the CREATE USER
or ALTER USER
statements using a direct connection to the TimesTen database. Thus, executing CREATE USER
or ALTER USER
from a client-server application or through passthrough execution is not allowed. You can use the ALTER USER
statement to change a user from an internal to an external user or from an external to an internal user. The full syntax for the CREATE USER
statement is detailed in the "SQL Statements" chapter in the Oracle TimesTen In-Memory Database SQL Reference.
To create an internal user, provide the user name and password in the CREATE USER
statement. The following example creates the internal user TERRY
with the password "secret"
:
CREATE USER TERRY IDENTIFIED BY "secret"; User created.
To identify an external user, provide the user name in the CREATE USER IDENTIFIED EXTERNALLY
statement. The following example identifies the external user PAT
to the TimesTen database:
CREATE USER PAT IDENTIFIED EXTERNALLY; User created.
To change the external user PAT
to an internal user, perform the following ALTER USER
statement:
ALTER USER PAT IDENTIFIED BY "secret";
To change the internal user PAT
to an external user, perform the following ALTER USER
statement:
ALTER USER PAT IDENTIFIED EXTERNALLY;
You can see what users have been created by executing a SELECT
statement on the following system views:
SYS.ALL_USERS
lists all users of the database that are visible to the current user.
SYS.USER_USERS
describes the current user of the database.
SYS.DBA_USERS
describes all users of the database. To perform a select statement on this view, you must have the appropriate privileges granted.
For example, to see the current user, perform the following:
SELECT * FROM sys.user_users; < PAT, 4, OPEN, <NULL>, <NULL>, USERS, TEMP, 2009-02-25 12:00:17.027100, <NULL>, <NULL> > 1 row found.
For more details on these views, see "System Tables" in the Oracle TimesTen In-Memory Database System Tables and Views Reference.
Only the internal user has a password that can be modified within the database. A user can alter their own password. A user with the ADMIN
privilege can alter the password of any user. These users can change the password with the IDENTIFIED BY
clause of the ALTER USER
statement.
For example, to change the password for internal user TERRY
to "12345"
from its current setting, perform the following:
ALTER USER TERRY IDENTIFIED BY "12345"; User altered.
If granted the appropriate privileges, you can use the DROP USER
statement to drop users created in the database. You cannot drop the user in the following instances:
You cannot drop the instance administrator.
You cannot drop a user unless all objects owned by that user have first been deleted.
You cannot drop a user if the user is currently connected to the database.
The following DROP USER
statement drops the user TERRY
from the database:
Command> drop user terry; User dropped.
The following error occurs if you try to drop the instance administrator:
Command> drop user instadmin; 15103: System-defined users and roles cannot be dropped The command failed.
The following error occurs if user Pat tries to drop user Terry when Pat does not have the required ADMIN
privilege:
Command> drop user terry; 15100: User PAT lacks privilege ADMIN The command failed.
Note: Currently, we do not supportDROP USER CASCADE . |
When multiple users can access database objects, authorization can be controlled to these objects with privileges. Every object has an owner. Privileges control if a user can modify an object owned by another user. Privileges are granted or revoked either by the instance administrator, a user with the ADMIN
privilege or, for privileges to a certain object, by the owner of the object.
The following sections describe authorization to objects through the use of privileges:
Granting or revoking multiple privileges with a single SQL statement
Privileges needed for utilities, built-in procedures and first connection attributes
TimesTen provides user authorization to objects in the database through privileges. Users must be granted privileges for access to database resources or objects. These privileges restrict what operations users may perform on those objects. A user has all privileges on all objects in their own schema, and these privileges cannot be revoked. A user can be granted privileges for objects in other users' schemas.
TimesTen evaluates each user's privileges when the SQL statement is executed. Each SQL statement can be executed by an arbitrary user. For example:
SELECT * from PAT.TABLE1;
If this statement is executed by Pat, then no extra privileges are necessary because Pat owns this object. However, if another user, such as Terry, executes this statement, then Terry must have been granted the SELECT
privilege for PAT.TABLE1
.
Privileges provide the following:
Define what data users, applications, or functions can access or what operations they can perform.
Prevent users from adversely affecting system performance or from consuming excessive system resources. For example, a privilege restricting the creation of indexes is provided not because of an authorization concern, but because it may affect DML performance and occupies space.
Some examples of privileges include the right to perform the following:
Connect to the database and create a session
Create a table
Select rows from a table that is owned by another user
Perform any cache group operation
In addition, a user may need certain privileges in order to perform the following:
Execute certain TimesTen built-in procedures, which are documented in the Oracle TimesTen In-Memory Database Reference.
Execute certain TimesTen command-line utilities, which are documented in the Oracle TimesTen In-Memory Database Reference.
Initiate a connection with first connection attributes, which are documented in the Oracle TimesTen In-Memory Database Reference.
The privilege required for executing each SQL statement is documented in the statement description in the Oracle TimesTen In-Memory Database SQL Reference
There are two levels of privileges:
System privileges: These privileges enable system-wide functionality, such as access to all objects. Granting system privileges can enable a user to perform standard administrator tasks or access to objects in other users' schemas. These privileges extend beyond a single object. Restrict them only to trusted users.
Object privileges: Each type of object has privileges associated with it.
A subset of these privileges are automatically granted to each user upon creation through the PUBLIC role. Privilege hierarchy rules apply to all privileges granted to a user.
Grant privileges to users so that they can accomplish tasks required for their job. We recommend that you are intentional about who you grant privileges, so that they have only the exact privileges that they need to perform necessary operations.
Privileges are checked at prepare time and when the statement is first executed for each SQL statement. Subsequent executions of that statement require further privilege checks only when a revoke operation is executed in the database.
A system privilege enables a user the ability to perform system-level activities across multiple objects in the database. It confers the right to perform a particular operation in the database or to perform an operation on a type of object. For example, the privilege to create or modify an object in another user's schema in the database requires a system privilege to be granted to the user.
Only the instance administrator or a user with the ADMIN
privilege can grant a system privilege to a user. The instance administrator always has full system and object privileges, which cannot be revoked at any time.
Note: The instance administrator can perform all operations. So, any operation that can be performed by a user withADMIN privileges can also be performed by the instance administrator. |
Some of the system privileges include ADMIN
, SELECT ANY TABLE
, CREATE SESSION
and CREATE ANY SEQUENCE
. For more details on granting or revoking system privileges, see "Granting or revoking system privileges".
An object privilege enables a user to perform defined operations on a specific object. Separate object privileges are available for each object type.
Every object owner has access and full privileges to their own objects. A user does not have access to objects owned by other users unless explicitly granted access by the object's owner or by a user with ADMIN
privilege. If the PUBLIC
role has been granted access to a given object, then all database users have access to that object. A user with ADMIN
privileges cannot revoke an owner's privileges on the owner's object.
Object access control requires that a user either be the owner of an object or granted the appropriate object privilege to perform operations on the object. Object privileges are granted or revoked by the instance administrator, a user with the ADMIN
privilege or the user who is the owner of the object.
For more details on granting or revoking object privileges, see "Granting or revoking object privileges".
A role called PUBLIC
is automatically created in each TimesTen database. By default, TimesTen grants specific privileges to this role. Every user created within the TimesTen database are granted each privilege that is granted to the PUBLIC
role. That is, when the instance administrator or a user with the ADMIN
privilege creates a user, the privileges associated with the PUBLIC
role are granted to each of these users. Each subsequent privilege that is granted to the PUBLIC
role is also automatically granted to all users simultaneously. A user with the ADMIN
privilege can add or remove default privileges for all users by granting or revoking privileges from the PUBLIC
role. When the user revokes a privilege from PUBLIC
, it is revoked from each user, except for those users who have this privilege granted to them explicitly.
Note: The only exception to this behavior is that any privileges that were granted toPUBLIC by user SYS cannot be revoked. The privileges that were granted as part of database creation are shown when you execute the following SQL statement:
SELECT * FROM DBA_TAB_PRIVS WHERE GRANTOR = 'SYS' |
In the following example, user Pat is granted the SELECT ANY TABLE
privilege and PUBLIC
is granted the SELECT ANY TABLE
privilege. Then, all system privileges are displayed from the SYS.DBA_SYS_PRIVS
view. For more information on this view, see "Viewing user privileges". Revoking SELECT ANY TABLE
from PUBLIC
does not remove SELECT ANY TABLE
from Pat, which is shown again through the SYS.DBA_SYS_PRIVS
view.
Command> GRANT SELECT ANY TABLE TO PAT; Command> GRANT SELECT ANY TABLE TO PUBLIC; Command> SELECT * FROM SYS.DBA_SYS_PRIVS; < SYS, ADMIN, NO > < PUBLIC, SELECT ANY TABLE, NO > < SYSTEM, ADMIN, NO > < PAT, ADMIN, NO > < PAT, SELECT ANY TABLE, NO > 5 rows found. Command> REVOKE SELECT ANY TABLE FROM PUBLIC; Command> select * from sys.dba_sys_privs; < SYS, ADMIN, NO > < SYSTEM, ADMIN, NO > < PAT, ADMIN, NO > < PAT, SELECT ANY TABLE, NO > 4 rows found.
If you must, you may create a database that grants the ADMIN
privilege to PUBLIC
. This grants the ADMIN
privilege to all users who will then have unrestricted access to all database objects and be able to perform administrative tasks except for tasks that must be performed by the instance administrator. This is never recommended as a long-term approach, since it results in an insecure database. See "TimesTen Upgrades" in the Oracle TimesTen In-Memory Database Installation Guide for full details on when and for what purposes to use this approach.
Note: For a full description of the default privileges assigned to thePUBLIC role, see "The PUBLIC role" in the Oracle TimesTen In-Memory Database SQL Reference. |
The PUBLIC
role also grants access to certain objects, system tables and views. By default, in a newly created TimesTen database, PUBLIC
has SELECT
and EXECUTE
privileges on various system tables and views and PL/SQL functions, procedures and packages. You can see the list of privileges granted to PUBLIC
, and subsequently all users, by querying the SYS.DBA_TAB_PRIVS
view. In the following query, the privilege granted to PUBLIC
is in the fifth column.
Command> DESC SYS.DBA_TAB_PRIVS; View SYS.DBA_TAB_PRIVS: Columns: GRANTEE VARCHAR2 (30) INLINE OWNER VARCHAR2 (30) INLINE TABLE_NAME VARCHAR2 (30) INLINE GRANTOR VARCHAR2 (30) INLINE PRIVILEGE VARCHAR2 (40) INLINE NOT NULL GRANTABLE VARCHAR2 (3) INLINE NOT NULL HIERARCHY VARCHAR2 (3) INLINE NOT NULL 1 view found. Command> SELECT * FROM SYS.DBA_TAB_PRIVS WHERE GRANTEE='PUBLIC'; < PUBLIC, SYS, TABLES, SYS, SELECT, NO, NO > < PUBLIC, SYS, COLUMNS, SYS, SELECT, NO, NO > < PUBLIC, SYS, INDEXES, SYS, SELECT, NO, NO > < PUBLIC, SYS, USER_COL_PRIVS, SYS, SELECT, NO, NO > < PUBLIC, SYS, PUBLIC_DEPENDENCY, SYS, SELECT, NO, NO > < PUBLIC, SYS, USER_OBJECT_SIZE, SYS, SELECT, NO, NO > < PUBLIC, SYS, STANDARD, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, UTL_IDENT, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, TT_DB_VERSION, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, PLITBLM, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, DBMS_OUTPUT, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, DBMS_SQL, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, DBMS_STANDARD, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, DBMS_PREPROCESSOR, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, UTL_RAW, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, DBMS_UTILITY, SYS, EXECUTE, NO, NO > < PUBLIC, SYS, DBMS_RANDOM, SYS, EXECUTE, NO, NO > ... 57 rows found.
There is a hierarchy for all of the privileges. The higher level privileges confer related lower level privileges. For example, the ADMIN
privilege confers all privileges. The SELECT ANY TABLE
privilege confers the SELECT
privilege on any individual table.
Whenever a user needs a privilege for an operation, you can verify if the user already has the privilege if either the user is the owner of the object or has a higher level privilege that confers the necessary privileges for that operation. For example, if the user Pat needs to have the SELECT
privilege for Terry.Table2
, you can check the following:
Is Pat the owner of the object? If so, owners have all object privileges on their objects
Has Pat been granted the SELECT ANY TABLE
privilege? This privilege means Pat would have SELECT ON
any table, view, or materialized view.
Has Pat been granted the ADMIN
privilege, which would mean that Pat can perform any valid SQL operation.
If you grant a privilege that is included in a higher level privilege, no error occurs. However, when you revoke privileges, they must be revoked in the same unit as granted. The following sequence of grant and revoke statements for user PAT
grants the ability to update any table as well as an update privilege on a specific table:
GRANT UPDATE ANY TABLE TO PAT; GRANT UPDATE ON HR.employees TO PAT; REVOKE UPDATE ON HR.employees FROM PAT;
The UPDATE ANY TABLE
privilege grants the ability to update any table in the database. The second grant is specific for UPDATE
privilege to the HR.employees
table. The second grant is unnecessary as the UPDATE ANY TABLE
provides access to all tables, including employees
, but it does not result in an error. You can revoke the second grant, but it will not affect the first grant of the UPDATE ANY TABLE
system privilege. Thus, Pat can still update the HR.employees
table.
You must revoke in the same unit as was granted. The following example gr €ÿants the UPDATE ANY TABLE
system privilege to Pat. A user tries to revoke the ability to update the HR.employees
table from the user. But, the UPDATE ANY TABLE
privilege is a system privilege and the UPDATE
privilege is an object privilege. The execution of the REVOKE
statement for a unit that was not granted fails with an error.
GRANT UPDATE ANY TABLE TO PAT; REVOKE UPDATE ON HR.employees FROM PAT; 15143: REVOKE failed: User PAT does not have object privilege UPDATE on HR.EMPLOYEES The command failed.
The full details of the privilege hierarchy is described in the "Privilege hierarchy" section in the Oracle TimesTen In-Memory Database SQL Reference.
To grant or revoke a system privilege, use the GRANT
or REVOKE
statements. Only the instance administrator or a user with the ADMIN
privilege can grant or revoke system privileges. The GRANT
or REVOKE
syntax for system privileges includes the system privilege and the user who receives that privilege. Both the syntax for the GRANT
and REVOKE
statements and the required privileges for executing each SQL statement are described in the "SQL Statements" chapter in the Oracle TimesTen In-Memory Database SQL Reference.
Note: How to grant and revoke object privileges is described in "Granting or revoking object privileges". |
The most powerful system privilege is ADMIN
. When you grant a user the ADMIN
privilege, you enable this user to perform any operation for any database object.
An individual user can view their own system privileges in the SYS.USER_SYS_PRIVS
system view. A user with the ADMIN
privilege can view all system privileges for all users in the SYS.DBA_SYS_PRIVS
system table. These system views are described in "Viewing user privileges".
The following sections describe some of the system privileges available in TimesTen:
Note: For a full list of all system privileges, see "Privileges" in the Oracle TimesTen In-Memory Database SQL Reference. |
The ADMIN
privilege confers all system and object privileges, which allows these users to perform all administrative tasks and valid database operations. For all objects, a user with the ADMIN
privilege can perform create, alter, drop, select, update, insert, or delete operations. In addition, a user with the ADMIN
privilege can perform replication tasks, checkpointing, backups, migration, user creation and deletion, and so on. Only a user with the ADMIN
privilege can grant or revoke all privileges.
Only a user with the ADMIN
privilege may view all system tables and views by default. Only a user with the ADMIN
privilege can create, alter or drop replication schemas or active standby pairs. The following views and packages can only be accessed by users with the ADMIN
privilege:
Note: For more information on viewing privileges for users from system tables or views, see "Viewing user privileges". |
To grant the ADMIN
privilege to the user TERRY
, execute the following statement:
GRANT ADMIN TO TERRY;
If you have the ADMIN
privilege, then you can grant privileges to other users. For example, a user with the ADMIN
privilege can grant the SELECT
privilege to TERRY
on the departments
table owned by Pat, as follows:
GRANT SELECT ON PAT.departments TO TERRY;
Note: Since Pat is the owner of departments, Pat may also grant theSELECT object privilege to Terry. |
The ALL PRIVILEGES
grants every system privilege to a user. If you want a user to have most of the system privileges, you can grant ALL PRIVILEGES
to a user and then revoke only those system privileges that you do not want them to have. The following example grants all system privileges to user PAT
. Then, revokes the ADMIN
and DROP ANY TABLE
privileges to disallow Pat the ability to perform all administration tasks or to drop any tables.
GRANT ALL PRIVILEGES TO PAT; REVOKE ADMIN, DROP ANY TABLE FROM PAT;
You may also REVOKE ALL PRIVILEGES
that were granted to a user. This removes all system privileges from the user, except what the user inherits from the PUBLIC
role, as demonstrated below for user PAT
:
REVOKE ALL PRIVILEGES FROM PAT;
TimesTen databases are accessed through Data Source Names (DSNs). If a user tries to use a DSN that has connection attributes for which they do not have privileges, such as first connection attributes, they receive an error.
For a complete description of first connection attributes, see "Connection Attributes" in the Oracle TimesTen In-Memory Database Reference.
All users must be granted the CREATE SESSION
system privilege by a user with the ADMIN
privilege in order to connect to the database. The CREATE SESSION
system privilege provides the authorization to connect to the database. The following example grants the CREATE SESSION
privilege to Pat:
GRANT CREATE SESSION TO PAT;
A user with the ADMIN privilege can grant CREATE SESSION
privilege to all users by granting this privilege to the PUBLIC
role. This allows all users to connect to the database.
GRANT CREATE SESSION TO PUBLIC;
In addition to the ADMIN
privilege, there are a few system privileges that confer a superset of abilities. The following provides a brief description of these privileges:
XLA
: XLA readers can have global impact on the system. They create extra log volume, and can cause long log holds if they do not advance their bookmarks. You must have the XLA
system privilege to connect as an XLA reader.
CACHE_MANAGER
: The CACHE_MANAGER
privilege is used for cache group administrator operations. See "Granting or revoking privileges for cache groups" for details.
When you want to grant or revoke privileges for a user, you can grant or revoke privileges for a single object or for that type of object anywhere in the database.
Note: To grant or revoke privileges for a single object, use object privileges, which are described in "Granting or revoking object privileges". |
The system privileges that contain the ANY
keyword enable the user to perform the functions on all objects of the same type in the database. These system privileges are CREATE ANY
object_type, DROP ANY
object_type, ALTER ANY
object_type, SELECT ANY
object_type, UPDATE ANY TABLE
, INSERT ANY TABLE
, DELETE ANY TABLE
, and EXECUTE ANY PROCEDURE
.
Note: For a full description of these privileges, see "Privileges" in the Oracle TimesTen In-Memory Database SQL Reference. For details on the cache group system privileges that contain theANY keyword, see "Granting or revoking privileges for cache groups". |
The following sections provide more details for the CREATE ANY
object_type, DROP ANY
object_type, and ALTER ANY
object_type system privileges:
Dropping a table, view, materialized view, sequence, procedure, function, package or synonym
Altering a table, view, materialized view, sequence, procedure, function or package
To create a table, view, materialized view, sequence, PL/SQL procedure, PL/SQL function, PL/SQL package, or synonym within the user's namespace or another user's namespace, you must have the appropriate CREATE
object_type or CREATE ANY
object_type system privileges.
The following describes the CREATE
and CREATE ANY
system privileges:
The CREATE
object_type privilege grants a user the ability to create that object, but only in the user's own schema. After creation, the user owns this object and thus, automatically has been granted all privileges for that object.
Other privileges are required if a user wants to create cache groups.
The CREATE ANY
object_type privilege grants a user the ability to create any object of that type in the database, even in another user's schema. The object types include table, index, view, materialized view, sequence, synonym and procedure. The CREATE ANY
object_type privileges are CREATE ANY TABLE
, CREATE ANY INDEX
, CREATE ANY VIEW
, CREATE ANY MATERIALIZED VIEW
, CREATE ANY SEQUENCE
, CREATE ANY SYNONYM
and CREATE ANY PROCEDURE
.
The following example grants the privilege to create any table in other users' schemas to user TERRY
:
GRANT CREATE ANY TABLE TO TERRY;
The following example grants the privilege to create a table within the user's own schema:
GRANT CREATE TABLE TO TERRY;
Grant the DROP ANY
object_type system privilege in order for a user to drop an object of object_type that the user does not own. For example, granting Pat this privilege enables Pat to drop the employees
table that is owned by the user HR
. A user always has the right to drop a table they own. The DROP ANY
object_type privilege enables a user to drop any object of the specified type in the database, except for cache groups that require other privileges.
ALTER
ANY PROCEDURE
allows users to alter any procedure, function or package in the database. The ALTER ANY
object_type privilege is necessary to modify the properties of objects that the user does not own. For example, if a procedure is created in the HR
schema named Proc1
and if Pat is granted the ALTER ANY PROCEDURE
privilege, Pat can successfully alter the procedure HR.Proc1
.
To grant or revoke an object privilege, use the GRANT
or REVOKE
statements. The syntax for the object-level GRANT
or REVOKE
statement requires the name of the object on which the grant or revoke is applied. The syntax for the GRANT
and REVOKE
statements is described in the "SQL Statements" chapter in the Oracle TimesTen In-Memory Database SQL Reference.
The following sections describe and provide examples on the object privileges for all object types, except for the cache admin objects. The cache object privileges are described in "Granting or revoking privileges for cache groups".:
Note:
|
Object Privileges needed when creating foreign key with REFERENCES clause
Object privileges for PL/SQL functions, procedures and packages
You can grant all privileges for an object to a user with the ALL
keyword. This essentially grants a user the right to perform any operation on the object.
There are no specific object privileges for DROP
or ALTER
. These operations cannot be granted for individual objects; instead, granting the appropriate system privilege enables a user other the owner of an object to DROP
or ALTER
that object.
For example, GRANT ALL ON employees TO PAT
grants all privileges for the employees
table to user PAT
. It is possible to revoke individual privileges after granting all object privileges. For instance, the following is a valid sequence of operations:
GRANT ALL ON HR.employees TO PAT; REVOKE DELETE ON HR.employees FROM PAT;
You may also REVOKE ALL
object privileges that were granted to a user for the object. This removes all privileges for the object from the user, as demonstrated below for user PAT
:
REVOKE ALL ON HR.employees FROM PAT;
Both the object owner and a user with the ADMIN
privilege can perform the GRANT ALL
and REVOKE ALL
statements.
For a user to perform operations on tables that they do not own, they must be granted the appropriate object privilege for that table. This includes privileges for tables within cache groups. The object privileges for tables include SELECT
, UPDATE
, DELETE
, INSERT
, INDEX
and REFERENCES
.
The following object privileges may be appropriate not only for authorization, but also for performance reasons:
The INDEX
privilege enables the user to create an index on the table. Creating an index consumes additional space and impacts the performance of DML on the table. A specific grant for INDEX is required for a user to create an index.
The REFERENCES
privilege enables the user to create a foreign key dependency on the table. Foreign key dependencies impact the performance of DML operations on the parent. For more details on the REFERENCES
privilege, see "Object Privileges needed when creating foreign key with REFERENCES clause".
The following example grants the SELECT
object privilege for the employees
table in the HR
schema to the user PAT
:
GRANT SELECT ON HR.employees TO PAT;
The next example shows an example of how to grant the UPDATE
privilege on the employees
table owned by the user HR
to the user PAT
:
GRANT UPDATE ON HR.employees TO PAT;
For a user to create a view, that user must be granted the CREATE VIEW
or CREATE ANY VIEW
privilege. For a user to select from a view that they do not own, they need to be granted the SELECT
object privilege for that view. Furthermore, the view itself needs to be valid; that is, the owner of the view must be granted the SELECT
object privilege for all of the objects referenced by the view.
When user PAT
creates a view owned by Pat and that view only references objects owned by Pat, then Pat is only required to be granted the CREATE VIEW
privilege for this operation. If Pat creates a view owned by Terry that references objects owned by Terry, Pat is required to be granted the CREATE ANY VIEW
privilege for this operation. For example:
CREATE VIEW PAT.VIEW1 as select * from PAT.TABLE1;
In this example, if Pat executes this statement, Pat only needs to be granted the CREATE VIEW
privilege.
If user Pat creates a view, and the view references a table owned by Terry, then Pat needs to be granted the CREATE VIEW
privilege and the SELECT
object privilege on all of the objects referenced by the view. The owner of the view, not the view creator, must be granted the SELECT
object privilege on the objects referenced by the view. Therefore, in this example, Pat must be granted the SELECT
object privilege on TABLE2
that is owned by Terry. Once these privileges are granted, Pat can execute the following:
CREATE VIEW PAT.VIEW2 as select * from TERRY.TABLE2;
However, if a third user, Joe, executes this statement, then Joe must be granted the CREATE ANY VIEW
privilege to create the view. Even though Joe is executing the statement, Pat, as the owner of the view, is still required to be granted the SELECT
object privilege in order to perform the select on Terry's table.
TimesTen validates all views referenced at execution time. TimesTen will notify which privileges are not in place in order to perform the given operation.
For example:
CREATE VIEW PAT.VIEW2 as select * from TERRY.TABLE2; CREATE VIEW JOE.VIEW4 as select * from PAT.VIEW2, TERRY.TABLE4;
If Pat is executing these statements, the following privileges must be granted:
CREATE ANY VIEW
privilege so that Pat can create the view in Pat's own schema as well as a view in Joe's schema.
User Joe must be granted the SELECT
object privilege on Terry.Table4
.
User Joe must be granted the SELECT
object privilege on Pat.View2
User Pat must be granted the SELECT
object privilege on Terry.Table2
When validating all references, TimesTen also validates that PAT.VIEW2
is still valid by verifying that Pat has the SELECT
object privilege on TERRY.TABLE2
. When you select from a view, TimesTen validates that the view itself is still valid, as well as any views referenced by that view.
For a user to perform operations on sequences that they do not own, they must be granted the SELECT
object privilege. The SELECT
privilege on a sequence allows the user to perform all operations on a sequence, including NEXTVAL, even though it ultimately updates the sequence.
For example, to grant SELECT
privilege on the employees_seq
sequence in the HR
schema to the user PAT
, issue the following statement:
GRANT SELECT ON HR.employees_seq TO PAT;
Pat can subsequently generate the next value of the sequence with the following statement:
SELECT HR.employees_seq.NEXTVAL FROM DUAL; < 207 > 1 row found.
In order to create a materialized view, a user needs the CREATE MATERIALIZED VIEW
privilege. If the user is creating a materialized view in some other user's schema, the user needs the CREATE ANY MATERIALIZED VIEW
privilege.
The owner of the materialized view needs to have CREATE TABLE
privilege as well as SELECT
privileges on every detail table in that materialized view. However, the owner of the materialized view is automatically granted the SELECT
privilege on the detail tables if previously granted a higher-level system privilege, such as SELECT
ANY TABLE
or ADMIN
.
For a user to select from a materialized view that they do not own, the user needs to be granted the object privileges for materialized views, which include SELECT
, INDEX
and REFERENCES
. For more details on the privileges required, see the appropriate SQL statements in the Oracle TimesTen In-Memory Database SQL Reference.
In order for the materialized view to be valid, the owner of the view must be granted and must keep the SELECT
object privilege for all of the detail tables referenced by the materialized view. If the owner of an existing materialized view loses the SELECT
privilege on any detail table on which the materialized view is based, the materialized view becomes invalid.
The status of the materialized view is provided in the STATUS
column of the SYS.DBA_OBJECTS
, SYS.ALL_OBJECTS
, and SYS.USER_OBJECTS
views. The owner of the materialized view can see the status of its materialized views in the USER_OBJECTS
view. Alternatively, execute the ttIsql describe
command, which appends INVALID
to the materialized view when it becomes invalid.
Note: If the owner of the materialized view was granted with a higher-level system privilege, such asSELECT ANY TABLE or ADMIN , the owner loses the required SELECT privileges on the detail tables if the higher-level system privilege is revoked. At this point, the materialized view becomes invalid. |
Users may still select from an invalid asynchronous materialized view without error. However, users will receive an error when selecting from an invalid synchronous materialized view.
Users that have the privilege to do so can still update the detail tables of the materialized view. However, the invalid materialized view will not reflect these changes. In addition, for asynchronous materialized views, the materialized view log will not be updated if no valid materialized views depend on them.
REFRESH
on an invalid synchronous materialized view fails with an error.
If the owner of the materialized view has been re-granted the privilege that was previously revoked, a REFRESH
on an invalid COMPLETE
asynchronous materialized view succeeds and the asynchronous materialized view is now valid.
In order to fix an invalid materialized view, you must grant the appropriate privileges to the owner of the materialized view and then drop and re-c Yߦreate the materialized view.
The REFERENCES
clause in the CREATE
or ALTER TABLE
statements creates a foreign key dependency from the new child table column (TABLE1.COL1
) on the parent table column (TABLE2.PK
) as shown in the following operation:
ALTER TABLE PAT.TABLE1 ADD CONSTRAINT FK1 FOREIGN KEY (COL1) REFERENCES PAT.TABLE2 (PK);
In this example, the user executing the SQL must have ALTER ANY TABLE
privilege. Since Pat owns both tables, no additional privileges are needed since Pat owns both tables.
However, if the REFERENCES
clause refers to a table not owned by this user, then the REFERENCES
object privilege on the table not owned by the user is required before execution is allowed. For example:
ALTER TABLE PAT.TABLE1 ADD CONSTRAINT FK1 FOREIGN KEY (COL1) REFERENCES TERRY.TABLE2 (PK);
In this example, the user executing this SQL must have ALTER ANY TABLE
privilege. As in the previous example, if the user executing this SQL is Pat, the ALTER ANY TABLE
privilege is not required because a table's owner can always modify its own table. In addition, the user Pat must be granted the REFERENCES
privilege on TERRY.TABLE2
in order for Pat to create a foreign key involving a table owned by Terry.
A user who creates or alters a child table needs the REFERENCES
object privilege on the parent table to create a foreign key dependency. The REFERENCES
privilege implicitly grants SELECT
privileges for a user creating a foreign key on the parent table. However, this implicit grant does not mean that the user has the SELECT
privilege on the parent table, so any SELECT
statements will fail if the only privilege on the parent table is the REFERENCES
privilege.
For a user to perform operations on PL/SQL functions, PL/SQL procedures or PL/SQL packages that they do not own, they must be granted the EXECUTE
object privilege. When you grant a user EXECUTE
privilege on a package, this automatically grants EXECUTE
privilege on its component procedures and functions.
This privilege grants the right to the following:
Execute the procedure or function.
Access any program object declared in the specification of a package.
Compile the object implicitly during a call to a currently invalid or uncompiled function or procedure.
The EXECUTE
privilege does not allow the user to create, drop or alter any procedure, function or package. This requires appropriate system privileges. For example, to explicitly compile using ALTER PROCEDURE
or ALTER FUNCTION
, the user must be granted the ALTER ANY PROCEDURE
system privilege. For details on the system privileges for functions, procedures or packages, see "Enabling users to perform operations on any database object type".
For a user to create or drop private or public synonyms, the user must have the following privileges:
Table 4-1 Privileges for synonyms
Action | Required privilege |
---|---|
Create a private synonym in the user's own schema. |
|
Create a private synonym in another user's schema. |
|
Create a public synonym. |
|
Drop a private synonym in the user's own schema. |
No privilege needed. |
Drop a private synonym in another user's schema. |
|
Drop a public synonym. |
|
In addition, in order to use a synonym, the user must have the appropriate access privileges for the object that the synonym refers to. For example, if you create a synonym for a view, then to select from that view using the synonym, the user would need the SELECT
privilege that is necessary to select from a view.
You can grant multiple object privileges in the same GRANT
or REVOKE
statement for the same database object for one or more users. For example, the following grants Terry the SELECT
and UPDATE
object privileges on the HR.employees
table in the same SQL statement.
GRANT SELECT, UPDATE ON HR.employees TO TERRY;
You can also grant multiple system privileges to one or more users with the same GRANT
or REVOKE
statement. The following example grants multiple system privileges to both Terry and Pat.
GRANT CREATE ANY TABLE, CREATE SESSION TO TERRY, PAT;
You cannot combine system and object privileges in the same GRANT
or REVOKE
statement.
In order for a user to be able to perform activities involving any cache group, the user must have the appropriate cache group privileges. There are system and object privileges for cache groups, where system privileges confer abilities beyond a singular object.
Note: Passthrough does not require any privileges to be granted, since the privilege checking will be performed by the Oracle Database with the user credentials. For details on passthrough, see the Oracle In-Memory Database Cache User's Guide. |
The following sections provide an overview of cache group privileges:
For a full list of all system and object privileges for cache group operations, see "Privileges" in the Oracle TimesTen In-Memory Database SQL Reference.
The cache group system privileges provide a user the ability to affect cache group objects across the database. The CACHE_MANAGER
system privilege is the administrator privilege for cache groups. If a user has been granted the CACHE_MANAGER
privilege, this user may perform any cache group operation. This privilege confers all cache group operation privileges, which are listed in the "Privilege hierarchy" section in the Oracle TimesTen In-Memory Database SQL Reference.
You must have the CACHE_MANAGER
privilege to perform the initial load of a read-only cache group or to change the state of autorefresh on a read-only cache group. The initial load implicitly alters the state of the cache group autorefresh from paused to on.
The following grants the CACHE_MANAGER
privilege to Pat:
GRANT CACHE_MANAGER TO PAT;
The privileges that the TimesTen users require depend on the types of cache group operations that you want to perform.
To create a cache group, a user must be granted either the CREATE CACHE GROUP
or CREATE ANY CACHE GROUP
system privilege. In addition, the user must be granted either the CREATE ANY TABLE
or CREATE TABLE
privilege to create any underlying cache tables, depending on if the table is owned by the user or not.
To drop or alter a cache group that is not owned by the user, the user must be granted the DROP ANY CACHE GROUP
or ALTER ANY CACHE GROUP
privilege as appropriate. In addition, the user must be granted the DROP ANY TABLE
privilege to drop any underlying cache tables, if the tables are not owned by the user.
Note: All cache group privileges are described in detail in the "Setting Up a Caching Infrastructure" chapter in the Oracle In-Memory Database Cache User's Guide. |
For example, the following confers the privilege for a user to alter any cache group in the database:
GRANT ALTER ANY CACHE GROUP TO PAT;
Note: Users with certain privileges must also be created on the Oracle database to own Oracle tables and to store cache grid information. The privileges required for the Oracle cache administration user and the TimesTen cache manager user for each cache operation are listed in the "Setting Up a Caching Infrastructure" chapter in the Oracle In-Memory Database Cache User's Guide. |
Other system privileges for cache group operations are for performing the following on objects not owned by the user:
FLUSH ANY CACHE GROUP
: Enables users to flush any cache group in the database.
LOAD ANY CACHE GROUP
: Enables users to load any cache group in the database.
UNLOAD ANY CACHE GROUP
: Enables users to unload any cache group in the database.
REFRESH ANY CACHE GROUP
: Enables users to refresh any cache group in the database.
The object privileges for cache group operations are granted to a user for performing the operation on a single, defined object. The following are the object privileges for cache group objects:
FLUSH
: Enables the user to flush a cache group owned by another user.
LOAD
: Enables the user to load a cache group owned by another user.
UNLOAD
: Enables the user to unload a cache group owned by another user.
REFRESH
: Enables the user to refresh a cache group owned by another user.
For example, the following example grants Pat the cache group object privilege to perform a FLUSH
on the cache group CACHEGRP
that is owned by Terry:
GRANT FLUSH ON TERRY.CACHEGRP TO PAT;
For details on cache group operations, see the Oracle In-Memory Database Cache User's Guide.
You can view the privileges granted to each user through the following views:
Table 4-2 System privilege views
View name | Description |
---|---|
Returns all of the system privileges granted to the current user. | |
Returns the list of system privileges granted to all users and inherited from the | |
Returns all of the object privileges granted to the current user. | |
Returns the results of both | |
Returns the object privileges granted to all users and inherited from the |
For example, perform the following to see all of the system privileges granted to all users:
Command> SELECT * FROM SYS.DBA_SYS_PRIVS; < SYS, ADMIN, YES > < SYSTEM, ADMIN, YES > < TERRY, ADMIN, YES > < TERRY, CREATE ANY TABLE, NO > < PAT, CACHE_MANAGER, NO > 5 rows found.
Note: For details on these views, see "System Tables" in the Oracle TimesTen In-Memory Database System Tables and Views Reference. |
Many of the utilities and built-in procedures require a certain privilege in order to execute. In addition, in order to modify or connect with certain first connection attributes, certain privileges are required. First connection attributes are set when a database is first loaded, and only the instance administrator can load a database with first connection attribute settings. The required privilege for each is described with the utility, built-in procedure or first connection attribute description in the Oracle TimesTen In-Memory Database Reference.
If you have tables related by foreign key constraints, then the following applies:
If ON DELETE CASCADE
is specified on a foreign-key constraint for a child table, a user can delete rows from the parent table resulting in deletions from the child table without requiring an explicit DELETE
privilege on the child table. However, a user must have the DELETE
privilege on the parent table for this to occur automatically.
When you perform an insert or update on a child table, TimesTen determines if there is a foreign key constraint violation on the parent table resulting from the change to the child table. In this case, a user is required to have the INSERT
or UPDATE
privilege on the child table, but not a SELECT
privilege on the parent table.
A user who creates a child table needs the REFERENCES
object privilege on the parent table to create a foreign key dependency. See "Object Privileges needed when creating foreign key with REFERENCES clause" for more details.
Operations Guide
11g Release 2 (11.2.2)
E21633-05
September 2012
Oracle TimesTen In-Memory Database Operations Guide, 11g Release 2 (11.2.2)
E21633-05
Copyright © 1996, 2012, Oracle and/or its affiliates. All rights reserved.
This software and related documentation are provided under a license agreement containing restrictions on use and disclosure and are protected by intellectual property laws. Except as expressly permitted in your license agreement or allowed by law, you may not use, copy, reproduce, translate, broadcast, modify, license, transmit, distribute, exhibit, perform, publish, or display any part, in any form, or by any means. Reverse engineering, disassembly, or decompilation of this software, unless required by law for interoperability, is prohibited.
The information contained herein is subject to change without notice and is not warranted to be error-free. If you find any errors, please report them to us in writing.
If this is software or related documentation that is delivered to the U.S. Government or anyone licensing it on behalf of the U.S. Government, the following notice is applicable:
U.S. GOVERNMENT RIGHTS Programs, software, databases, and related documentation and technical data delivered to U.S. Government customers are "commercial computer software" or "commercial technical data" pursuant to the applicable Federal Acquisition Regulation and agency-specific supplemental regulations. As such, the use, duplication, disclosure, modification, and adaptation shall be subject to the restrictions and license terms set forth in the applicable Government contract, and, to the extent applicable by the terms of the Government contract, the additional rights set forth in FAR 52.227-19, Commercial Computer Software License (December 2007). Oracle America, Inc., 500 Oracle Parkway, Redwood City, CA 94065.
This software or hardware is developed for general use in a variety of information management applications. It is not developed or intended for use in any inherently dangerous applications, including applications that may create a risk of personal injury. If you use this software or hardware in dangerous applications, then you shall be responsible to take all appropriate fail-safe, backup, redundancy, and other measures to ensure its safe use. Oracle Corporation and its affiliates disclaim any liability for any damages caused by use of this software or hardware in dangerous applications.
Oracle and Java are registered trademarks of Oracle and/or its affiliates. Other names may be trademarks of their respective owners.
Intel and Intel Xeon are trademarks or registered trademarks of Intel Corporation. All SPARC trademarks are used under license and are trademarks or registered trademarks of SPARC International, Inc. AMD, Opteron, the AMD logo, and the AMD Opteron logo are trademarks or registered trademarks of Advanced Micro Devices. UNIX is a registered trademark of The Open Group.
This software or hardware and documentation may provide access to or information on content, products, and services from third parties. Oracle Corporation and its affiliates are not responsible for and expressly disclaim all warranties of any kind with respect to third-party content, products, and services. Oracle Corporation and its affiliates will not be responsible for any loss, costs, or damages incurred due to your access to or use of third-party content, products, or services.
The TimesTen cost-based query optimizer uses information about an application's tables and their available indexes to choose a fast path to the data. Application developers can examine the plan chosen by the optimizer to check that indexes are used appropriately. If necessary, application developers can also modify the optimizer's behavior so that it chooses a different plan.
This chapter includes the following topics:
It is useful to understand when TimesTen performs query optimization, since a single command may be optimized several times.
TimesTen invokes the optimizer whenever a SELECT
, UPDATE
, DELETE
, INSERT SELECT
or CREATE MATERIALIZED VIEW
statement is prepared through an ODBC SQLPrepare
or SQLExecDirect
function or any of the JDBC execute methods. The resulting plan persists until an invalidating event occurs, or the command is dropped by the application.
A command is invalidated under the following circumstances:
A table it uses is dropped
A table it uses is altered
An index on a table it references is dropped
An index is created on a table it references
Statistics are recomputed with the invalidation
option set to 1 in either the ttIsql
statsupdate
command, the ttOptUpdateStats
built-in procedure, or the ttOptEstimateStats
built-in procedures.
Note: For complete details on when to calculate statistics, see "Compute exact or estimated statistics". In addition, see "ttIsql," "ttOptUpdateStats," or "ttOptEstimateStats" in the Oracle TimesTen In-Memory Database Reference. |
An invalid command is usually reprepared automatically just before it is re-executed. This means that the optimizer is invoked again at this time, possibly resulting in a new plan. Thus, a single command may be prepared several times.
Note: When using JDBC, you must manually reprepare commands when a table has been altered. |
A command may have to be prepared manually if, for example, the table that the command referenced was dropped and a new table with the same name was created. When you prepare a statement manually, you should commit the prepare statement so it can be shared. If the command is recompiled because it was invalid, and if recompilation involves DDL on one of the referenced tables, then the prepared statement must be committed to release the command lock.
For example, in ODBC a command joining tables T1
and T2
may undergo the following changes:
Action | Description |
---|---|
SQLPrepare | Command is prepared. |
SQLExecute | Command is executed. |
SQLExecute | Command is re-executed. |
Create Index on T1 | Command is invalidated. |
SQLExecute | Command is reprepared, then executed. |
SQLExecute | Command is re-executed. |
ttOptUpdateStats on T1 | Command is invalidated if the invalidate flag is passed to the ttOptUpdateStats procedure. |
SQLExecute | Command is reprepared, then executed. |
SQLExecute | Command is re-executed. |
SQLFreeStmt | Command is dropped. |
In JDBC, a command joining tables T1
and T2
may undergo the following changes:
Action | Description |
---|---|
Connection.prepareStatement | Command is prepared. |
PreparedStatement.execute | Command is executed. |
PreparedStatement.execute | Command is re-executed. |
Create Index on T1 | Command is invalidated. |
PreparedStatement.execute | Command is reprepared, then executed. |
PreparedStatement.execute | Command is re-executed. |
ttOptUpdateStats on T1 | Command is invalidated if the invalidate flag is passed to the ttOptUpdateStats procedure. |
PreparedStatement.execute | Command is reprepared, then executed. |
PreparedStatement.execute | Command is re-executed. |
PreparedStatement.close | Command is dropped. |
As illustrated, optimization is generally performed at prepare time, but it may also be performed later when indexes are dropped or created, or when statistics are modified. Optimization does not occur if a prepare can use a command in the cache.
If a command was prepared with the genPlan
flag set, it will be recompiled with the same flag set. Thus, the plan is generated even though the plan for another query was found in the SYS.PLAN
table.
If an application specifies hints to modify the optimizer's behavior, these hints persist until the command is deleted. See "Modifying plan generation" for more information. For example, when the ODBC SQLPrepare
function or JDBC Connection.prepareStatement
method is called again on the same handle or when the SQLFreeStmt
function or PreparedStatement.close
method is called. This means that any intermediate reprepare operations that occur because of invalidations will use those same hints.
All commands executed—SQL statements, built-in procedures, and so on—are stored in the SQL Command Cache, which uses temporary memory. The commands are stored up until the limit of the SQL Command Cache is reached, then the new commands are stored after the last used commands are removed. You can retrieve one or more of these commands that are stored in the SQL Command Cache.
Note: This section describes viewing the commands stored in the SQL Command Cache. For details on how to view the query plans associated with these commands, see "Viewing query plans associated with commands stored in the SQL Command Cache". |
The following sections describe how to view commands cached in the SQL Command Cache:
You can view all one or more commands or details of their query plans with the ttSqlCmdCacheInfo
and ttSqlCmdQueryPlan
built-in procedures. Use the query plan information to monitor and troubleshoot your queries.
Viewing commands and query plans can help you perform the following:
Detect updates or deletes that are not using an index scan.
Monitor query plans of executing queries to ensure all plans are optimized.
Detect applications that do not prepare SQL statements or that re-prepare the same statement multiple times.
Discover the percentage of space used in the command cache for performance evaluation.
The commands executed against the TimesTen database are cached in the SQL command cache. The ttSqlCmdCacheInfo
built-in procedure displays a specific or all cached commands in the TimesTen SQL command cache. By default, all commands are displayed; if you specify a command id, then only this command is retrieved for display.
The command data is saved in the following format:
Command identifier, which is used to retrieve a specific command or its associated query plan.
Private connection identifier.
Counter for the number of executions.
Counter for the number of times the user prepares this statement.
Counter for the number of times the user re-prepares this SQL statement.
Freeable status, where if the value is one, then the subdaemon can free the space with the garbage collector. A value of zero determines that the space is not able to be freed.
Total size in bytes allocated for this command in the cache.
User who created the command.
Query text up to 1024 characters.
At the end of the list of all commands, a status is printed of how many commands were in the cache.
The following examples show how to display all or a single command from the SQL Command Cache using the ttSqlCmdCacheInfo
built-in utility:
Example 10-1 Displaying all commands in the SQL Command Cache
This example executes within ttIsql
the ttSqlCmdCacheInfo
built-in procedure without arguments to show all cached commands. The commands are displayed in terse format. To display the information where each column is prepended with the column name, execute vertical on
before executing the ttsqlCmdCacheInfo
procedure.
Command> call ttsqlCmdCacheInfo; < 528079360, 2048, 0, 1, 0, 1, 2168, PAT , select * from t7 where x7 is not null or exists (select 1 from t2,t3 where not 'tuf' like 'abc') > < 527609108, 2048, 0, 1, 0, 1, 2960, PAT , select * from t1 where x1 = (select x2 from t2 where z2 in (1,3) and y1=y2) order by 1, 2, 3 > < 528054656, 2048, 0, 1, 0, 1, 1216, PAT , create table t2(x2 int,y2 int, z2 int) > < 528066648, 2048, 0, 1, 0, 1, 1176, PAT , insert into t2 select * from t1 > < 528013192, 2048, 0, 1, 0, 1, 1848, PAT , select * from t1 where exists (select * from t2 where x1=x2) or y1=1 > < 527582620, 2048, 0, 1, 0, 1, 1240, PAT , insert into t2 select * from t1 > < 527614292, 2048, 0, 1, 0, 1, 2248, PAT , select * from t1 where exists (select x2 from t2 where x1=x2) order by 1, 2, 3 > < 528061248, 2048, 0, 1, 0, 1, 696, PAT , create index i1 on t3(y3) > < 528070368, 2048, 0, 1, 0, 1, 824, PAT , call ttOptSetOrder('t3 t4 t2 t1') > < 528018856, 2048, 0, 1, 0, 1, 984, PAT , insert into t2 select * from t1 > < 527606460, 2048, 0, 1, 0, 1, 2624, PAT , select * from t1 where x1 = (select x2 from t2 where y1=y2) order by 1, 2, 3 > < 528123000, 2048, 0, 1, 0, 1, 3616, PAT , select * from t1 where x1 = 1 or x1 = (select x2 from t2,t3 where z2=t3.x3) > < 528074624, 2048, 0, 1, 0, 1, 856, PAT , call ttOptSetOrder('t4 t2 t3 t1') > < 527973892, 2048, 0, 1, 0, 1, 2872, PAT , select * from t1 where x1 in (select x2 from t2) or x1 in (select x3 from t3) order by 1, 2, 3 > < 527953876, 2048, 0, 1, 0, 1, 3000, PAT , select * from t1 where x1 = (select x2 from t2) order by 1, 2, 3 > < 527603900, 2048, 0, 1, 0, 1, 2440, PAT , select * from t1 where x1 in (select x2 from t2 where y1=y2) order by 1, 2, 3 > < 528093308, 2048, 0, 1, 0, 1, 3608, PAT , select * from t1 where x1 = 1 or x1 = (select x2 from t2,t3 where z2=t3.x3 and t3.z3=1) > < 528060608, 2048, 0, 1, 0, 1, 696, PAT , create index i1 on t2 (y2) >
Example 10-2 Displaying a single SQL command
If you provide a command id as the input for the ttSqlCmdCacheInfo
, the single command is displayed from within the SQL Command Cache. You can discover the command id from executing this built-in procedure without input. The command id is the first column displayed.
The following example displays the command identified by Command ID of 527973892
. It is displayed in terse format; to view with the column headings prepended, execute vertical on
before executing the ttSqlCmdCacheInfo
built-in.
Command> call ttsqlCmdCacheInfo(527973892); < 527973892, 2048, 0, 1, 0, 1, 2872, PAT , select * from t1 where x1 in (select x2 from t2) or x1 in (select x3 from t3) order by 1, 2, 3 > 1 row found.
You can view the query plan for a command in one of two ways: storing the latest query plan into the system PLAN
table or viewing all cached commands and their query plans in the SQL command cache. Both methods are described in the following sections:
The optimizer prepares the query plans. For the last SQL statement to be executed—such as a prepared SELECT
, UPDATE
, DELETE
, INSERT
SELECT
, CREATE TABLE
, CREATE MATERIALIZED VIEW
and so on—you can instruct that the plan be stored in the system PLAN
table:
Instruct TimesTen to generate the plan and store it in the system PLAN
table.
Prepare the statement means calling the ODBC S
QLPrepare
function or JDBC Connection.prepareStatement
method on the statement. TimesTen stores the plan into the PLAN
table.
Read the generated plan within the SYS.PLAN
table.
The stored plan is updated automatically whenever the command is reprepared. Re-preparation occurs automatically if one or more of the following occurs:
A table in the statement is altered.
If indexes are created or dropped.
The application invalidates commands when statistics are updated with the invalidate
option in the ttOptUpdateStats
built-in procedure.
Note: For more information, seettOptUpdateStats in the Oracle TimesTen In-Memory Database Reference. |
For these cases, read the PLAN
table to view how the plan has been modified.
Before you can view the plan in the system PLAN
table, call the built-in ttOptSetFlag
procedure with the GenPlan
flag. This call informs TimesTen that all subsequent calls to the ODBC SQLPrepare
function or JDBC Connection.prepareStatement
method in the transaction should store the resulting plan in the current SYS.PLAN
table.
Note: Make sureAUTOCOMMIT is not set. If it is, the current transaction completes after the processing of the command and prepares in the next transaction are not affected. |
The SYS.PLAN
table only stores one plan, so each call to the ODBC SQLPrepare
function or JDBC Connection.prepareStatement
method overwrites any plan currently stored in the table.
If a command is prepared with the genPlan
flag set, it is recompiled with this flag. Thus, the plan is generated even though the plan for another query was found in the SYS.PLAN
table.
For example, try the query and optimizer hints with the ttIsql
utility. To display optimizer plans, issue the following commands:
autocommit 0; showplan 1;
Once plan generation has been turned on and a command has been prepared, one or more rows in the SYS.PLAN
table store the plan for the command. The number of rows in the table depends on the complexity of the command. Each row has seven columns, as described in "System Tables" in the Oracle TimesTen In-Memory Database System Tables and Views Reference.
Example 10-3 Generating a query plan
This example uses the following query:
SELECT COUNT(*) FROM T1, T2, T3 WHERE T3.B/T1.B > 1 AND T2.B <> 0 AND T1.A = -T2.A AND T2.A = T3.A
The optimizer generates the five SYS.PLAN
rows shown in the following table. Each row is one step in the plan and reflects an operation that is performed during query execution.
Step | Level | Operation | TblNames | IXName | Pred | Other Pred |
---|---|---|---|---|---|---|
1 | 3 | TblLkRangeScan | T1 | IX1 | ||
2 | 3 | TblLkRangeScan | T2 | IX2(D) | T2.B <> 0 | |
3 | 2 | MergeJoin | T1.A = -T2.A | |||
4 | 2 | TblLkRangeScan | T3 | IX3(D) | ||
5 | 1 | MergeJoin | T2.A = T3.A | T3.B / T1.B > 1 |
For details about each column in the SYS.PLAN
table, see "Describing the PLAN table columns".
The SYS.PLAN
table has seven columns.
Indicates the order of operation, which always starts with one. Example 10-3 uses a table lock range scan in the following order:
Table locking range scan of IX1 on table T1
.
Table locking range scan of IX2 on T2
.
Merge join of T1
and T2
and so forth.
Indicates the position of the operation in the join-tree diagram that describes the execution. For Example 10-3, the join tree is as follows:
Indicates the type of operation being executed. For a description of the potential values in this field and the type of table scan each represents, see SYS.PLAN
in "System Tables" in the Oracle TimesTen In-Memory Database System Tables and Views Reference.
Not all operations the optimizer performs are visible to the user. Only operations significant to performance analysis are shown in the SYS.PLAN
table. TblLk
is an optimizer hint that is honored at execution time in Serializable or Read Committed isolation. Table locks are used during a scan only if row locks are disabled during preparation.
Indicates the table that is being scanned. This column is used only when the operation is a scan. In all other cases, this column is NULL
.
Indicates the index that is being used. This column is used only when the operation is an index scan using an existing index—such as a hash or range scan. In all other cases, this column is NULL
. Names of range indexes are followed with "(D)" if the scan is descending—from large to small rather than from small to large.
Indicates the predicate that participates in the operation, if there is one. Predicates are used only with index scan and MergeJoin
operations. The predicate character string is limited to 1,024 characters.
This column may be NULL
—indicating no predicate—for a range scan. The optimizer may choose a range scan over a table scan because, in addition to filtering, it has two useful properties:
Rows are returned in sorted order, on index key.
Rows may be returned faster, especially if the table is sparse.
In Example 10-3, the range scans are used for their sorting capability; none of them evaluates a predicate.
Indicates any other predicate that is applied while the operation is being executed. These predicates do not participate directly in the scan or join but are evaluated on each row returned by the scan or join.
For example, at step two of the plan generated for Example 10-3, a range scan is performed on table T2
. When that scan is performed, the predicate T2.B <> 0
is also evaluated. Similarly, once the final merge-join has been performed, it is then possible to evaluate the predicate T3.B / T1.B > 1
.
Use the query plan information to monitor and troubleshoot your queries.
Note: For more reasons why to use thettSqlCmdQueryPlan built-in procedure, see "Managing performance and troubleshooting commands". |
The ttSqlCmdQueryPlan
built-in procedure displays the query plan of a specific statement or all statements in the command cache. It displays the detailed run-time query plans for the cached SQL queries. By default, all query plans are displayed; if you specify the command id taken from the command output, only the query plan for the specified command is displayed.
Note: If you want to display a query plan for a specific command, you must provide the command identifier, which is displayed with thettSqlCmdCacheInfo built-in procedure. See "Displaying commands stored in the SQL Command Cache" for full details. |
The plan data displayed when you invoke this built-in procedure is as follows:
Command identifier
Query text up to 1024 characters
Step number of the current operation in the run-time query plan
Level number of the current operation in the query plan tree
Operation name of current step
Name of table used
Owner of the table
Name of index used
If used and available, the index predicate
If used and available, the non-indexed predicate
Note: For more information on how to view this information, see "Reading query plan from the PLAN table". The source of the data may be different, but the mapping and understanding of the material is the same as the query plan in the systemPLAN table. |
The ttSqlCmdQueryPlan
built-in process displays the query plan in a raw data format. Alternatively, you can execute the ttIsql
explain
command for a formatted version of this output. For more information, see "Display query plan for statement in SQL Command Cache".
The following examples show how to display all or a single SQL query plan from the SQL Command Cache using the ttSqlCmdQueryPlan
built-in procedure:
Example 10-4 Displaying all SQL query plans
You can display all SQL query plans associated with commands stored in the command cache with the ttSqlCmdQuery
plan built-in procedure within the ttIsql
utility.
The following example shows the output when executing the ttSqlCmdQueryPlan
built-in procedure without arguments, which displays detailed run-time query plans for all valid queries. For invalid queries, there is no query plan; instead, the query text is displayed.
The query plans are displayed in terse format. To view with the column headings prepended, execute vertical on
before executing the ttSqlCmdQueryPlan
built-in procedure.
Note: For complex expressions, there may be some difficulties in printing out the original expressions.
Command> call ttSqlCmdQueryPlan(); < 528079360, select * from t7 where x7 is not null or exists (select 1 from t2,t3 where not 'tuf' like 'abc'), <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 528079360, <NULL>, 0, 2, RowLkSerialScan , T7 , PAT , , , > < 528079360, <NULL>, 1, 3, RowLkRangeScan , T2 , PAT , I2 , , NOT(LIKE( tuf ,abc ,NULL )) > < 528079360, <NULL>, 2, 3, RowLkRangeScan , T3 , PAT , I2 , , > < 528079360, <NULL>, 3, 2, NestedLoop , , , , , > < 528079360, <NULL>, 4, 1, NestedLoop(Left OuterJoin) , , , , , > < 528079360, <NULL>, 5, 0, Filter , , , , , X7 > < 527576540, call ttSqlCmdQueryPlan(527973892), <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 527576540, <NULL>, 0, 0, Procedure Call , , , , , > < 528054656, create table t2(x2 int,y2 int, z2 int), <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 528066648, insert into t2 select * from t1, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 528066648, <NULL>, 0, 0, Insert , T2 , PAT , , , > < 528013192, select * from t1 where exists (select * from t2 where x1=x2) or y1=1, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 528061248, create index i1 on t3(y3), <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 528070368, call ttOptSetOrder('t3 t4 t2 t1'), <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 528070368, <NULL>, 0, 0, Procedure Call , , , , , > < 528018856, insert into t2 select * from t1, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 527573452, call ttsqlCmdCacheInfo(527973892), <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 527573452, <NULL>, 0, 0, Procedure Call , , , , , > < 528123000, select * from t1 where x1 = 1 or x1 = (select x2 from t2,t3 where z2=t3.x3), <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 528123000, <NULL>, 0, 2, RowLkSerialScan , T1 , PAT , , , > < 528123000, <NULL>, 1, 6, RowLkRangeScan , T2 , PAT , I2 , , > < 528123000, <NULL>, 2, 6, RowLkRangeScan , T3 , PAT , I2 , , Z2 = X3; > < 528123000, <NULL>, 3, 5, NestedLoop , , , , , > < 528123000, <NULL>, 4, 4, Materialized View , , , , , > < 528123000, <NULL>, 5, 3, GroupBy , , , , , > < 528123000, <NULL>, 6, 2, Filter , , , , , X1 = colum_name; > < 528123000, <NULL>, 7, 1, NestedLoop(Left OuterJoin) , , , , , > < 528123000, <NULL>, 8, 0, Filter , , , , , X1 = 1; >
Example 10-5 Displaying a single SQL query plan
You can display any query plan associated with a command by providing the command id of the command as the input for the ttSqlCmdQueryPlan
built-in procedure. The single query plan is displayed from within the SQL Command Cache. You can discover the command id from executing this ttSqlCmdCacheInfo
built-in without input. The command id is the first column displayed.
The following example displays the query plan of the command identified by command id of 528078576
. It is displayed in terse format; to view with the column headings prepended, execute vertical on
before executing the ttSqlCmdQueryPlan
built-in procedure.
Note: for complex expressions, there are some difficulties to print original expressions.
Command> call ttSqlCmdQueryPlan( 528078576); < 528078576, select * from t1 where 1=2 or (x1 in (select x2 from t2, t5 where y2 in (select y3 from t3)) and y1 in (select x4 from t4)), <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL>, <NULL> > < 528078576, <NULL>, 0, 4, RowLkSerialScan , T1 , PAT , , , > < 528078576, <NULL>, 1, 7, RowLkRangeScan , T2 , PAT , I2 , , > < 528078576, <NULL>, 2, 7, RowLkRangeScan , T5 , PAT , I2 , , > < 528078576, <NULL>, 3, 6, NestedLoop , , , , , > < 528078576, <NULL>, 4, 6, RowLkRangeScan , T3 , PAT , I1 , ( (Y3=Y2; ) ) , > < 528078576, <NULL>, 5, 5, NestedLoop , , , , , > < 528078576, <NULL>, 6, 4, Filter , , , , , X1 = X2; > < 528078576, <NULL>, 7, 3, NestedLoop(Left OuterJoin) , , , , , > < 528078576, <NULL>, 8, 2, Filter , , , , , > < 528078576, <NULL>, 9, 2, RowLkRangeScan , T4 , PAT , I2 , , Y1 = X4; > < 528078576, <NULL>, 10, 1, NestedLoop(Left OuterJoin) , , , , , > < 528078576, <NULL>, 11, 0, Filter , , , , , > 13 rows found. Command>
If you decide that you want to modify a query plan, you can only modify the query plan that exists in the system PLAN
table as described in "Viewing a query plan from the system PLAN table". Once you do modify the query plan, it does not replace the query plan, but creates a new query plan with your changes.
The following sections describe why you may want to modify execution plans and then how to modify them:
Applications may want to modify an execution plan for two reasons:
The plan is optimally fast but is ill-suited for the application. The optimizer may select the fastest execution path, but this path may not be desirable from the application's point of view. For example, if the optimizer chooses to use certain indexes, these choices may prevent other operations-such as certain update or delete operations-from occurring simultaneously on the indexed tables. In this case, an application can prevent the use of those indexes.
The plan chosen by the optimizer may also consume more memory than is available or than the application wants to allocate. For example, this may happen if the plan stores intermediate results or requires the creation of temporary indexes.
The plan is not optimally performant. The query optimizer chooses the plan that it estimates will execute the fastest based on its knowledge of the tables' contents, available indexes, statistics, and the relative costs of various internal operations. The optimizer often has to make estimates or generalizations when evaluating this information, so there can be instances where it does not choose the fastest plan. In this case, an application can adjust the optimizer's behavior to try to produce a better plan.
Applications can modify an execution plan by providing hints to the optimizer. Hints are specified by calls to one of the TimesTen optimizer built-in procedures and are in effect for all calls to the ODBC SQLPrepare
function or JDBC PreparedStatement objects in the transaction. For more information on how to provide these hints, see "How to modify execution plan generation".
Note: Make sureAUTOCOMMIT is not set. If it is, the current transaction completes after processing the ttOptSetFlag procedure and prepares in the next transaction are not affected. |
If a command is prepared with certain hints in effect, those hints continue to apply if the command is reprepared automatically, even when this happens outside the initial prepare transaction. This can happen when a table is altered, or an index is dropped or created, or when statistics are modified, as described in "When optimization occurs".
If a command is prepared without hints, subsequent hints will not affect the command if it is reprepared automatically. An application must call the ODBC SQLPrepare
function or JDBC Connection.prepareStatement
method a second time so that hints have an effect.
Example 10-6 Tuning a join when using ODBC
When using ODBC, a developer tuning a join on T1
and T2
might go through the steps shown in the following figure.
During execution, the application may then go through the steps shown in the following figure.
Example 10-7 Tuning a join when using JDBC
When using JDBC, a developer tuning a join on T1
and T2
might go through the steps shown in the following figure.
During execution, the application may then go through the steps shown in the following figure.
You can apply hints to change the query optimizer behavior, which modifies the execution plan generation.
To change the query optimizer behavior for a transaction, an application calls one of the following built-in procedures using the ODBC procedure call interface:
ttOptSetOrder
—Enables an application to specify the table join order.
ttOptUseIndex
—Enables an application to specify that an index be used or to disable the use of certain indexes.
ttOptClearStats
, ttOptEstimateStats
, ttOptSetColIntvlStats
, ttOptSetTblStats
, ttOptUpdateStats
—Manipulate statistics that the TimesTen Data Manager maintains on the application's data that are used by the query optimizer to estimate costs of various operations.
Some of these built-in procedures require that the user have privileges to the objects on which the utility executes. For full details on these built-in procedures and any privileges required, see "Built-In Procedures" in the Oracle TimesTen In-Memory Database Reference.
The following examples provide an ODBC and JDBC method on how to use the ttOptSetFlag
built-in procedure:
Note: You can also experiment with optimizer settings using thettIsql utility. The commands that start with try control the optimizer hints. To view your current optimizer hint settings, use the optprofile command. |
Example 10-8 Using ttOptSetFlag in JDBC
This JDBC example illustrates the use of ttOptSetFlag
to prevent the optimizer from choosing a merge join.
import java.sql.*; class Example { public void myMethod() { CallableStatement cStmt; PreparedStatement pStmt; . . . . . try { . . . . . . . // Prevent the optimizer from choosing Merge Join cStmt = con.prepareCall("{ CALL ttOptSetFlag('MergeJoin', 0)}"); cStmt.execute(); // Next prepared query pStmt=con.prepareStatement( "SELECT * FROM Tbl1, Tbl2 WHERE Tbl1.ssn=Tbl2.ssn"); . . . . . . . catch (SQLException ex) { ex.printStackTrace(); } } . . . . . . . }
Example 10-9 Using ttOptSetFlag in ODBC
This ODBC example illustrates the use of ttOptSetFlag
to prevent the optimizer from choosing a merge join.
#include <sql.h> SQLRETURN rc; SQLHSTMT hstmt; fetchStmt; .... rc = SQLExecDirect (hstmt, (SQLCHAR *) "{CALL ttOptSetFlag (MergeJoin, 0)}", SQL_NTS) /* check return value */ ... rc = SQLPrepare (fetchStmt, ...) /* check return value */ ...
ACID transaction semantics
An acronym referring to the four fundamental properties of a transaction: atomicity, consistency, isolation and durability.
atomicity
A property of a transaction whereby either all or none of the operations of a transaction are applied to the database.
backup instance
A set of files containing backup information for a given database, residing at a given backup path. See also "backup path", "full backup" and "incremental backup".
backup point
The time at which a backup begins. See also "backup path", "full backup" and "incremental backup".
bitmap index
Indexes are used to speed up queries on a table. Bitmap indexes are useful when searching and retrieving data from columns with low cardinality. That is, these columns can have only a few unique possible values.
cache instance
A set of rows related through foreign keys. Each cache instance contains exactly one row from the root table of a cache group and zero or more rows from the other tables in the cache group.
client/server
An approach to application design and development in which application processing is divided between components running on an end user's machine, such as the client, and a network server. Generally, user interface elements are implemented in the client component, while the server controls database access.
concurrency
The ability to have multiple transactions access and manipulate the database at the same time.
connection attribute
A character string that defines a connection parameter to be used when connecting to an ODBC data source. Connection attributes have the form name=value, where name is the name of the parameter and value is the parameter value. See also connection string.
connection request
A message sent by an application through an ODBC driver to an ODBC data source to request a connection to that data source.
connection string
A character string that defines the connection parameters to be used when connecting to an ODBC data source. A connection string is expressed as one or more connection attributes separated by semicolons.
consistency
A property of transactions whereby each transaction transforms the database from one consistent state to another.
data source definition
A named collection of connection attributes that defines the connection parameters to be used when connecting to an ODBC data source. See also "data source name".
data source name
A logical name by which an end user or application refers to an ODBC data source definition. Sometimes incorrectly used to mean "data source definition". See also "data source definition", ODBC.INI
file.
data source name, client
A data source name defined on a TimesTen client machine that refers to a Server DSN on a server machine.
data source name, server
A system data source name (system DSN) defined on a server machine. Server Data Source Names become available to all TimesTen clients on a network when the TimesTen Server is running.
data source name, system
A data source name that is accessible by all users of a particular machine.
data source name, user
A data source name that is accessible only by the user who created the data source name.
durability
A property of transactions whereby the effects of a committed transaction survive system failures.
environment variable
A name, value pair maintained by the operating system that can be used to pass configuration parameters to an application.
event
An activity or occurrence that can be tracked by a logging mechanism in an application, service or operating system. See also "logging", "protocol message logging" and "event viewer".
event viewer
On Windows, a utility program used to view the contents of the operating system event log.
full backup
A database backup procedure in which a complete copy of a database is created. Typically, the first backup of a database must be a full backup. See also "incremental backup".
hash index
Indexes are used to speed up queries on a table. Hash indexes are useful for finding rows with an exact match on one or more columns.
host
A computer. Typically used to refer to a computer on a network that provides services to other computers on the network.
host name
A character string name that uniquely identifies a particular computer on a network. Examples: athena
, thames.mycompany.com
. See also "host".
in-line column
A column whose values are physically stored together with the other column values of a row.
incremental backup
A database backup procedure in which an existing backup is augmented with all the transaction log records created since its last full or incremental backup. See also "backup instance" and "full backup".
IP address
A numeric address that uniquely identifies a computer on a network and consists of four numbers separated by dots. Abbreviation for Internet Protocol address. Example: 123.61.129.91
.
isolation
A property of transactions whereby each transaction runs as if it were the only transaction in the system.
listener thread
A thread that runs on the TimesTen Server that receives and processes connection requests from TimesTen Clients.
logging
The process by which an application, service or operating system records specific events that occur during processing.
network address
A host name, or IP address that uniquely identifies a particular computer on a network. Examples: 123.61.129.91
, athena
, thams.mycompany.com
.
ODBC Administrator
A utility program used on Windows to create, configure and delete data source definitions.
ODBC driver
A library that implements the function calls defined in the ODBC API and enables applications to interact with ODBC data sources.
ODBC Driver Manager
A library that acts as an intermediary between an ODBC application and one or more ODBC drivers.
ODBC initialization file (ODBC INI)
The ODBC.INI file contains a list of Data Sources and any properties for each. Each Data Source name must have a driver property defined. This enables the driver to be loaded when a connect call is made.
Open Database Connectivity (ODBC)
A database-independent application programming interface that enables applications to access data stored in heterogeneous relational and non-relational databases. Based on the Call-Level Interface (CLI) specification developed by X/Open's SQL Access Group and first popularized by Microsoft on the Windows platform.
Open database connectivity (ODBC), is a database access protocol that lets you connect to a database and then prepare and run SQL statements against the database. In conjunction with an ODBC driver, an application can access any data source including data stored in spreadsheets, like Excel. Because ODBC is a widely accepted standard API, applications can be written to comply to the ODBC standard. The ODBC driver performs all mappings between the ODBC standard and the particular database the application is accessing. Using a data source-specific driver, an ODBC compliant program can access any data source without any more development effort.
TimesTen provides the ODBC interface so that applications of any type that are ODBC compliant can access TimesTen using the ODBC driver provided by TimesTen.
out-of-line column
A column whose values are physically stored separately from the other column values of a row.
phantom
A row that appears during one read but not during another read within the same transaction, due to the actions of other concurrently executing transactions.
ping
A utility that tests the connection between two computers on a network by sending a message from one computer to the other and measuring how long it takes for the receiving system to confirm that the message was received. Typically packaged with network software.
propagate
When using IMDB Cache to send table or row modifications from an IMDB Cache to an Oracle database. Compare with "replicate".
protocol message logging
The process that the TimesTen Server uses to record each message it receives through the TimesTen network protocol.
range index
Indexes are used to speed up queries on a table. A range index is similar in functionality to a B+-tree index and is best used for retrieving rows with column values within a certain range.
replicate
The sending of table or row modifications from one database to another. Compare with "propagate".
rollback
To undo the actions of a transaction, thereby returning all items modified by the transaction to their original state.
row buffering
A performance enhancement used by the TimesTen Client in which the client receives multiple result rows of an SQL query in each message from the TimesTen Server to reduce network communication.
scalability
The degree to which a system or application can handle increasing demands on system resources without significant performance degradation.
A schema is automatically created for a user upon user creation. A schema is the namespace for a given user, where all objects owned by this user belong and all objects are identified by schema qualified names. For example, user PAT belongs to the PAT schema. In addition, the object EMPLOYEES
owned by PAT
is identified as PAT.EMPLOYEES
.
If a user refers to an object without the schema name, TimesTen first tries to resolve the name to the user's schema. If this object does not exist, TimesTen tries to resolve the name to SYS.EMPLOYEES
.
A user always has all privileges to all objects in their own schema. These privileges can never be revoked.
shorthand name
A logical name used to refer to a particular TimesTen Server. Shorthand names relieve the end user of having to enter a host name and port number to connect to a TimesTen Server.
SMP
Symmetric multi-processing. A hardware configuration in which two or more similar processors are connected via a high-bandwidth link and managed by one operating system, where each processor has equal access to I/O devices.
stack overflow condition
An error condition in which the stack usage of a thread or process exceeds the amount of space allocated for the stack.
stored procedure
An executable object or named entity stored in a database that can be invoked with input and output parameters and which can return result sets similar to those returned by an SQL query.
system account
A special account on Windows used by the operating system and certain operating system services. The TimesTen service and the TimesTen Server run under the system account.
TCP/IP
The communications protocol used by computers on the Internet. Abbreviation for Transport Control Protocol/Internet Protocol.
TCP/IP port number
A number used by TCP/IP that identifies the end point for a connection to a host that supports multiple simultaneous connections.
telnet
A utility program and protocol that enables a user on one computer to open a virtual terminal, log in to a remote host and interact as a terminal user of that host.
thread-safe ODBC driver
An ODBC driver that supports multithreaded servers and clients. The TimesTen data manager driver and the TimesTen Client driver are thread-safe.
timeout error
An error condition indicating that the requested operation did not complete within the given amount of time. See also "timeout interval".
timeout interval
A configuration parameter that specifies the maximum amount of time that an operation should take to complete. See also "timeout error".
TimesTen Client
(1) An ODBC driver that enables end users to access data sources through a TimesTen Server. (2) A computer on which the TimesTen Client software has been installed. Using the TimesTen Client driver, an end user or application can access any data source managed by an available TimesTen Server.
TimesTen Client/Server network protocol
The protocol used by TimesTen Clients and TimesTen Servers to exchange data over a standard TCP/IP network connection.
TimesTen Data Server
(1) An application program that makes TimesTen data sources available to the TimesTen Clients on a network. (2) A computer on which the TimesTen Data Server software is running.
TimesTen Server address
The host name or IP address used during installation of the TimesTen Server to identify the computer on which the software is being installed.
transaction
An operation or set of operations performed against data in a database. The operations defined in a transaction must be completed as a whole; if any part of the transaction fails, the entire transaction fails. See also "ACID transaction semantics".
UCS-4
A fixed-width, 32-bit Unicode character set. Each character occupies 32 bits of storage. The UCS-2 characters are the first 65,536 code points in this standard, so it can be viewed as a 32-bit extension of UCS-2.
UTF-16
An encoding scheme defined by the ISO/IEC 10646 standard in which each Unicode character is represented by either a two-byte integer or a pair of two-byte integers. Characters from European scripts and most Asian scripts are represented in two bytes. Surrogate pairs are represented in four bytes. Surrogate pairs represent characters such as infrequently used Asian characters that were not included in the original range of two-byte characters.
user account
The combination of a user name, password and access permissions that gives an individual user access to an operating system.
User Manager
A Windows utility program used to create user accounts and assign access rights and group membership.
Oracle TimesTen In-Memory Database is a memory-optimized relational database. Deployed in the application tier, Oracle TimesTen In-Memory Database operates on databases that fit entirely in physical memory using standard SQL interfaces. High availability for the in-memory database is provided through real-time transactional replication.
This guide provides:
Background information to help you understand how TimesTen works
Step-by-step instructions and examples that show how to perform the most commonly needed tasks
To work with this guide, you should understand how database systems work and have some knowledge of Structured Query Language (SQL).
TimesTen documentation is available on the product distribution media and on the Oracle Technology Network:
http://www.oracle.com/technetwork/products/timesten/documentation
TimesTen supports multiple platforms. Unless otherwise indicated, the information in this guide applies to all supported platforms. The term Windows refers to all supported Windows platforms. The term UNIX applies to all supported UNIX and Linux platforms. See "Platforms" in Oracle TimesTen In-Memory Database Release Notes for specific platform versions supported by TimesTen.
Note: In TimesTen documentation, the terms "data store" and "database" are equivalent. Both terms refer to the TimesTen database unless otherwise noted. |
This document uses the following text conventions:
Convention | Meaning |
---|---|
boldface | Boldface type indicates graphical user interface elements associated with an action, or terms defined in text. |
italic | Italic type indicates book titles, emphasis, or placeholder variables for which you supply particular values. |
monospace | Monospace type indicates commands within a paragraph, URLs, code in examples, text that appears on the screen, or text that you enter. |
italic monospace | Italic monospace type indicates a variable in a code example that you must replace. For example:
Replace |
[ ] | Square brackets indicate that an item in a command line is optional. |
{ } | Curly braces indicate that you must choose one of the items separated by a vertical bar ( | ) in a command line. |
| | A vertical bar separates alternative arguments. |
. . . | An ellipsis (. . .) after an argument indicates that you may use more than one argument on a single command line. |
% | The percent sign indicates the UNIX shell prompt. |
# | The number (or pound) sign indicates the prompt for the UNIX root user. |
TimesTen documentation uses these variables to identify path, file and user names:
Convention | Meaning |
---|---|
TimesTen_install_dir | The path that represents the directory where the current release of TimesTen is installed. |
TTinstance | The instance name for your specific installation of TimesTen. Each installation of TimesTen must be identified at install time with a unique alphanumeric instance name. This name appears in the install path. |
bits or bb | Two digits, 32 or 64, that represent either the 32-bit or 64-bit version of the operating system. |
release or rr | The first three parts in a release number, with or without dots. The first three parts of a release number represent a major TimesTen release. For example, 1122 or 11.2.2 represents TimesTen 11g Release 2 (11.2.2). |
jdk_version | One or two digits that represent the major version number of the Java Development Kit (JDK) release. For example, 5 represents JDK 5. |
DSN | The data source name. |
For information about Oracle's commitment to accessibility, visit the Oracle Accessibility Program website at http://www.oracle.com/pls/topic/lookup?ctx=acc&id=docacc
.
Access to Oracle Support
Oracle customers have access to electronic support through My Oracle Support. For information, visit http://www.oracle.com/pls/topic/lookup?ctx=acc&id=info
or visit http://www.oracle.com/pls/topic/lookup?ctx=acc&id=trs
if you are hearing impaired.
The Oracle TimesTen Data Manager daemon, which is the Oracle TimesTen Data Manager service on Windows, starts when TimesTen is installed. The daemon operates continually in the background.
The TimesTen daemon performs the following functions:
Manages shared memory access
Coordinates process recovery
Keeps management statistics on what databases exist, which are in use, and which application processes are connected to which databases
Manages RAM policy
Starts replication processes, the TimesTen Server and the cache agent.
Application developers do not interact with the daemon directly. No application code runs in the daemon and application developers do not generally have to be concerned with it. Application programs that access TimesTen databases communicate with the daemon transparently using TimesTen internal routines.
The following sections discuss interaction with the TimesTen daemon on various platforms:
The Oracle TimesTen Data Manager service starts when you install the Oracle TimesTen Data Manager on your Windows system. To manually start and stop the Oracle TimesTen Data Manager service, you can use the ttDaemonAdmin
utility with the -start
or -stop
option, or the Windows Administrative Tools as follows:
Open Administrative Tools:
On Windows 2000 and XP from the Start menu, select Settings, Control Panel, and finally Administrative Tools.
Double-click Services. All currently available services are displayed.
Select TimesTen Data Manager 11.2.2, then click the appropriate button to stop or start the service.
Note: You must have administrative privileges to start and stop the TimesTen service. |
You must be the instance administrator to start and stop the TimesTen daemon.
The instance administrator must manually start and stop the daemon, after each system reboot, unless the setuproot
script has been run. To manually start and stop the TimesTen main daemon, you can use the ttDaemonAdmin
utility with the -start
or -stop
option.
User root
can start the daemon by executing the daemon startup script. The following table shows the location of the daemon startup script by platform.
Platform | Location of daemon startup script |
---|---|
Linux | /etc/init.d/tt_ instance_name |
Solaris | /etc/init.d/tt_ instance_name |
AIX | /etc/init.d/tt_ instance_name |
A TimesTen application consists of a database that has been allocated shared memory, user connections, and possibly replication and cache agents for communication with other TimesTen or Oracle databases.
To shut down a TimesTen application, complete the following tasks:
Disconnect all user connections gracefully.
Shut down all replication and cache agents.
Unload the database from shared memory if it was manually loaded.
Stop the TimesTen daemon.
The ttendaemon.options
file contains TimesTen daemon options. During installation, the installer sets some of these options to correspond to your responses to the installation prompts.
On Windows, the ttendaemon.options
file is located in the directory:
install_dir\srv\info
On UNIX, the ttendaemon.options
file is located in the directory:
install_dir/info/
The features that the ttendaemon.options
file controls are as follows:
The network interfaces on which the daemon listens
The minimum and maximum number of TimesTen subdaemons that can exist for the TimesTen instance
Whether or not the TimesTen Server is started
Whether or not you use shared memory segments for client/server inter-process communication
The number of Server processes that are prespawned on your system
The location and size of support and user logs
Backward compatibility
The maximum number of users for a TimesTen instance
Data access across NFS mounted systems. This is for Linux only.
The TNS_ADMIN
value for the Oracle Database. This option cannot be modified in this file.
Modifying the default database recovery after a fatal error
Use the ttmodinstall
utility to make changes to the ttendaemon.options
file for most commonly changed options. See "ttmodinstall" in Oracle TimesTen In-Memory Database Reference. If you cannot use ttmodinstall
to change a particular option and must modify the ttendaemon.options
file directly, stop the TimesTen daemon before you change the file. Restart the TimesTen daemon after you have finished changing the file. To change TimesTen Server options, it is only necessary to stop the server. It is not necessary to stop the TimesTen daemon.
The rest of this section includes the following topics:
By default, the TimesTen main daemon, all subdaemons and agents listen on a socket for requests, using any available address. All TimesTen utilities and agents use the loopback address to talk to the main daemon, and the main daemon uses the loopback address to talk to agents.
The -listenaddr
entry in a separate line in the ttendaemon.options
file tells the TimesTen daemons to listen on the specific address indicated in the value supplied. The address specified with this option can be either a host name or a numerical IP address.
The -listenaddr
parameter exists for situations where a server has multiple network addresses and multiple network cards. In this case it is possible to limit the network addresses on which the TimesTen daemon is listening to a subset of the server's network addresses. This is done by making entries only for those addresses on which the daemon listens. These possibilities exist:
Given a situation where a server has a "public" network address that is accessible both inside and outside the local network and a "private" address that is accessible only within the local network, adding a -listenaddr
entry containing only the private address blocks all communications to TimesTen coming on the public address.
By specifying only the local host, the TimesTen main daemon can be cut off from all communications coming from outside the server and communicate only with local clients and subdaemons.
There is no relationship between TimesTen replication and the -listenaddr
parameter and there is no requirement for enabling the -listenaddr
parameter when replication is enabled. If replication is going to be used in an environment where -listenaddr
is enabled, then the replication nodes need to know the allowable network addresses to use. However, if no -listenaddr
parameter is enabled replication still works.
To explicitly specify the address on which the daemons should listen on a separate line in the ttendaemon.options
file, enter:
-listenaddr address
For example, if you want to restrict the daemon to listen to just the loopback address, you say either:
-listenaddr 127.0.0.1
or
-listenaddr localhost
This means that only processes on the local machine can communicate with the daemon. Processes from other machines would be excluded, so you would not be able to replicate to or from other machines, or grant client access from other machines.
If you have multiple ethernet cards on different subnets, you can specify -listenaddr
entries to control which machines can connect to the daemon.
You can enter up to four addresses on which to listen by specifying the option and a value on up to four separate lines in the ttendaemon.options
file. In addition to the addresses you specify, TimesTen always listens on the loopback address.
By default, TimesTen uses the IPv4 protocol. To enable the daemon to listen on IPv6, you must enter on a separate line in the ttendaemon.options
file:
-enableIPv6
and
-listenaddr6 address
You can specify an IPv6 address with the -listenaddr6
option to enable IPv6.
Specifying the -enableIPv6
option with one or more -listenaddr
or -listenaddr6
options adds the IPv6 loopback interface to the list.
If you specify the -enableIPv6
option without specifying any addresses with the -listenaddr
or -listenaddr6
options, then the daemon listens on any IPv6 interface as well as any IPv4 interface.
The address specified with this option can be either a host name or a numerical IP address. See "Determining the daemon listening address" for specifics on the -listenaddr
option
If one or more -listenaddr
options are provided, the daemons listen on the specified IPv4 interfaces, with the IPv4 loopback address being added to the list if not specified. If only -enableIPv6
is specified, the daemons listen on both the IPv4 ANY interface and the IPv6 ANY interface.
You can specify both -listenaddr
and -listenaddr6
options. If you specify one or more -listenaddr6
options, the daemons listen on the specified IPv4 or IPv6 interfaces, with both the IPv4 and IPv6 loopback interfaces being added if not specified. If the name resolver returns multiple IPv4 and/or IPv6 addresses for a name, the daemons listen on all of the names.
As the daemon operates, it generates error, warning, and informational messages. These messages may be useful for TimesTen system administration and for debugging applications.
By default, informational messages are stored in the following:
A user error log that contains information you may need to see. Generally, these messages contain information on actions you may need to take.
A support log containing everything in the user error log plus information of use by TimesTen Customer Support.
The following options specify the locations and size of the support and user logs, as well as the number of files to keep stored on your system.
If you have specified the Event Log as the location for your log messages, to view them follow these steps:
Open the Event Viewer window. From the Start menu, select Control Panel, Administrative Tools, and then select Event Viewer.
In the Event Viewer list, choose Applications and Services Logs.
The window displays log messages generated by applications. Any messages with the word "TimesTen" in the "Source" column were generated by the Oracle TimesTen Data Manager service.
To view any TimesTen message, double-click the message summary.
The message window is displayed. You can view additional messages by clicking Next , Previous, up or down arrows, depending on your version of Windows.
Note: You can also view messages using thettDaemonLog utility. |
To specify the syslog
facility used to log TimesTen daemon and subdaemon messages on UNIX, on a separate line of the ttendaemon.options
file add:
-facility name
Possible name values are: auth
, cron
, daemon
, local0-local7
, lpr
, mail
, news
, user
, or uucp
.
To turn off detailed log messages, add a #
before -verbose
in the ttendaemon.options
file.
TimesTen uses subdaemons to perform the following:
Manage databases.
Flush the transaction log buffer to disk.
Perform periodic checkpoints.
Implement the aging policies of various tables.
Find and break deadlocks.
Rollback transactions for abnormally terminated direct-mode applications.
Perform required background processing for the database.
The main TimesTen daemon spawns subdaemons dynamically as they are needed. You can manually specify a range of subdaemons that the daemon may spawn, by specifying a minimum and maximum.
At any point in time, one subdaemon is potentially needed for TimesTen process recovery for each failed application process that is being recovered at that time.
By default, TimesTen spawns a minimum of 4 subdaemons and specifies the default maximum number of subdaemons at 50. However, you can change these settings by assigning new values to the -minsubs
and -maxsubs
options in the ttendaemon.options
file.
By default, TimesTen systems cannot access data across NFS-mounted systems. On Linux x86 64-bit systems, you can access checkpoint and transaction log files on NFS-mounted systems.
To enable data access on NFS-mounted systems, on a separate line of the ttendaemon.options
file, add:
-allowNetworkFiles
Note: TimesTen does not support the storage of trace files or user and support logs across NFS-mounted systems |
This section includes the following topics:
The TimesTen Server is a child process of the TimesTen daemon that operates continually in the background. To modify the TimesTen Server options, you must do the following:
Stop the TimesTen Server.
Modify the options in the ttendaemon.options
file as described in the following sections.
Restart the TimesTen Server.
The -server
portno
entry in a separate line in the ttendaemon.options
file tells the TimesTen daemon to start the TimesTen Server and what port to use. The portno
is the port number on which the server will listen.
If the TimesTen Server is installed, you can enable or disable the TimesTen Server:
To enable the TimesTen Server, remove the comment symbol '#' in front of the -server
portno
entry.
To disable the TimesTen Server, add a comment symbol '#' in front of the -server
portno
entry.
Each TimesTen Client connection requires one server process. By default, a server process is spawned when a client requests a connection.
You can prespawn a pool of reserve server processes, making them immediately available for a client connection, thus improving client/server connection performance.
The -serverpool
number
entry in a separate line in the ttendaemon.options
file on the Server machine tells the TimesTen Server to create number
processes. If this option is not specified, no processes are prespawned and kept in the reserve pool.
When a new connection is requested, if there are no items in the server pool, a new process is spawned, as long as you have not met the operating system limit.
If you request more process than allowed by your operating system, a warning is returned. Regardless of the number of processes requested, an error does not occur unless a client requests a connection when no more are available on the system, even if there are no processes remaining in the reserve pool.
Changes to the TimesTen Server take effect when the Server is restarted.
By default, TimesTen creates only one connection to a Server for each child process. You can set multiple connects to a single TimesTen Server, either by using the Server connection attributes described in the Oracle TimesTen In-Memory Database Reference or by setting the TimesTen daemon options described in this section. These options enable you to set the number of connections to a TimesTen Server, the number of servers for each DSN and the size of each connection to the server.
Changes to TimesTen Server settings do not occur until the TimesTen server is restarted. To restart the Server, use the following command:
ttDaemonAdmin -restartserver
Note: In the case that you have set both the Server connection attributes and these daemon options, the value of the Server connection attributes takes precedence. |
To run a child server process in multithreaded mode so that a single server process can service multiple client connections to a database, add the following line to the ttendaemon.options
file:
-maxConnsPerServer NumberOfClientConnections
The possible values of NumberOfClientConnections
range from 1 to 2047, inclusive. The default value is 1, which indicates that the child server process runs in multi-process mode and, therefore, can service only one client connection.
To specify the desired number of child server processes to be spawned for a particular server DSN, add the following line to the ttendaemon.options
file:
-serversPerDSN NumberOfChildServerProcesses
The possible values of NumberOfChildServerProcesses
range from 1 to 2047, inclusive. The default value is 1.
Client connections to a particular server DSN are evenly distributed in round-robin fashion to the child server processes that are spawned and assigned to the DSN. The number of child server processes assigned to the server DSN is greater than NumberOfChildServerProcesses
if the number of client connections to the DSN is greater than the maximum number of client connections per child server process multiplied by the desired number of child server processes spawned for a server DSN.
To set the size of the child server process thread stack for each client connection, add the following line to the ttendaemon.options
file:
-serverStackSize ThreadStackSize
ThreadStackSize
is specified in KB. The default is 128 KB on 32-bit systems and 256 KB on 64-bit systems. The ThreadStackSize
setting is ignored if the maximum number of client connections per child server process is 1 because the sole client connection will be serviced by the main thread of the child server process.
Note: These changes to the TimesTen Server do not occur until the TimesTen daemon is restarted. |
By default, TimesTen uses TCP/IP communication between applications linked with the TimesTen Client driver and the TimesTen Server.
Where the client application resides on the same machine as the TimesTen Server, you can alternatively use shared memory for the inter-process communication (IPC).
This can be useful for performance purposes or to allow 32-bit client applications to communicate with a 64-bit database on the server. Before using shared memory as IPC verify that you have configured your system correctly. See "Installation prerequisites" in Oracle TimesTen In-Memory Database Installation Guide.
The -serverShmIpc
entry in a separate line in the ttendaemon.options
file tells the TimesTen Server to accept a client connection that intends to use a shared memory segment for IPC.
If this entry is missing, add this line to the ttendaemon.options
file to start the TimesTen Server with shared memory IPC capability when the TimesTen daemon is restarted.
If the entry exists, add the #
symbol before the line in the ttendaemon.options
file to comment it out. The TimesTen Server is no longer started with shared memory IPC capability when the TimesTen daemon starts.
The -serverShmSize
size
entry in a separate line in the ttendaemon.options
file tells the TimesTen Server to create a shared memory segment of the specified size in MB.
If this entry is missing, the TimesTen Server creates a shared memory segment of 64MB.
An appropriate value for the shared memory segment depends on:
The expected number of concurrent client/server connections to all databases that belong to an instance of the TimesTen Server.
The number of concurrent allocated statements within each such connection.
The amount of data being transmitted for a query.
Some guidelines for determining the size of the shared memory segment include:
The maximum size allowed is 1 gigabyte.
TimesTen needs 1 MB of memory for internal use.
Each connection needs a fixed block of 16 KB.
Each statement starts with a block of 16 KB for the IPC. But this size is increased or decreased depending upon the size of the data being transmitted for a query. TimesTen increments the statement buffer size by doubling it and decreases it by halving it.
For example, if the user application anticipates a max of 100 simultaneous shared-memory-enabled client/server connections, and if each connection is anticipated to have a maximum of 50 statements, and the largest query returns 128 KB of data, use this formula to configure the serverShmSize
:
serverShmSize = 1 MB + (100 * 16) KB + (100 * 50 * 128) KB = 1 MB + 2 MB + 625 MB = 628 MB
This is the most memory required for this example. The entire memory segment would be used only if all 100 connections have 50 statements each and each statement has a query that returns 128 KB of data in a row of the result.
In this example, if you configured the serverShmSize
to 128 MB, either a new shared-memory-enabled client/server connection is refused by the TimesTen Server or a query may fail due to lack of resources within the shared memory segment.
Once configured, to change the value of the shared memory segment you must stop the TimesTen Server. Stopping the server detaches all existing client/server connections to any database that is associated with that instance of the TimesTen Server. The steps for modifying the value of the -serverShmSize
option are:
The -noserverlog
entry in a separate line in the ttendaemon.options
file tells the TimesTen daemon to turn off logging of connects and disconnects from the client applications.
If the TimesTen Server is installed, you can enable or disable logging of connect and disconnect messages by:
To enable logging, add a comment symbol '#' before the -noserverlog
entry.
To disable logging, remove the comment symbol '#' before the -noserverlog
entry.