Copyright 2002-2005 Bob Preston and Fred Toussi. Permission is granted to distribute this document without any alteration under the terms of the HSQLDB license. Additional permission is granted to the HSQLDB Development Group to distribute this document with or without alterations under the terms of the HSQLDB license.
$Date: 2007/08/28 13:19:09 $
Table of Contents
Text Table support for HSQLDB was originally developed by Bob Preston independently from the Project. Subsequently Bob joined the Project and incorporated this feature into version 1.7.0, with a number of enhancements, especially the use of conventional SQL commands for specifying the files used for Text Tables.
In a nutshell, Text Tables are CSV or other delimited files treated as SQL tables. Any ordinary CSV or other delimited file can be used. The full range of SQL queries can be performed on these files, including SELECT, INSERT, UPDATE and DELETE. Indexes and unique constraints can be set up, and foreign key constraints can be used to enforce referential integrity between Text Tables themselves or with conventional tables.
HSQLDB with Text Table support is the only comprehensive solution that employs the power of SQL and the universal reach of JDBC to handle data stored in text files and will have wide-ranging use way beyond the currently established Java realm of HSQLDB.
Goals of the Implementation
We aimed to finalise the DDL for Text Tables so that future releases of HSQLDB use the same DDL scripts.
We aimed to support Text Tables as GLOBAL TEMPORARY or GLOBAL BASE tables in the SQL domain.
Text Tables are defined similarly to conventional tables with the added TEXT keyword:
CREATE TEXT TABLE <tablename> (<column definition> [<constraint definition>])
In addition, a SET command specifies the file and the separator character that the Text table uses:
SET TABLE <tablename> SOURCE <quoted_filename_and_options> [DESC]
Text Tables cannot be created in memory-only databases (databases that have no script file).
A Text table without a file assigned to it is READ ONLY and EMPTY.
A Temporary Text table has the scope and the lifetime of the SQL session (a JDBC Connection).
Reassigning a Text Table definition to a new file has implications in the following areas:
The user is required to be an administrator.
Existing transactions are committed at this point.
Constraints, including foreign keys referencing this table, are kept intact. It is the responsibility of the administrator to ensure their integrity.
From version 1.7.2 the new source file is scanned and indexes are built when it is assigned to the table. At this point any violation of NOT NULL, UNIQUE or PRIMARY KEY constrainst are caught and the assignment is aborted. However, foreign key constraints are not checked at the time of assignment or reassignment of the source file.
This has changed since 1.7.2 to support both null values and empty strings.
Empty fields are treated as NULL. These are fields where there is nothing or just spaces between the separators.
Quoted empty strings are treated as empty strings.
The default field separator is a comma (,). A different field separator can be specified within the SET TABLE SOURCE statement. For example, to change the field separator for the table mytable to a vertical bar, place the following in the SET TABLE SOURCE statement, for example:
SET TABLE mytable SOURCE "myfile;fs=|"
Since HSQLDB treats CHAR's, VARCHARs, and LONGVARCHARs the same, the ability to assign different separators to the latter two is provided. When a different separator is assigned to a VARCHAR or LONGVARCHAR field, it will terminate any CSV field of that type. For example, if the first field is CHAR, and the second field LONGVARCHAR, and the separator fs has been defined as the pipe (|) and vs as the period (.) then the data in the CSV file for a row will look like:
First field data|Second field data.Third field data
The following example shows how to change the default separator to the pipe (|), VARCHAR separator to the period (.) and the LONGVARCHAR separator to the tilde (~). Place the following within the SET TABLE SOURCE statement, for example:
SET TABLE mytable SOURCE "myfile;fs=|;vs=.;lvs=~"
HSQLDB also recognises the following special indicators for separators:
special indicators for separators
semicolon
qoute
space character
apostrophe
newline - Used as an end anchor (like $ in regular expressions)
carriage return
tab
backslash
a Unicode character specified in hexadecimal
Furthermore, HSQLDB provides csv file support with three additional boolean options: ignore_first, quoted and all_quoted. The ignore_first option (default false) tells HSQLDB to ignore the first line in a file. This option is used when the first line of the file contains column headings. The all_quoted option (default false) tells the program that it should use quotes around all character fields when writing to the source file. The quoted option (default true) uses quotes only when necessary to distinguish a field that contains the separator character. It can be set to false to prevent the use of quoting altogether and treat quote characters as normal characters. These options may be specified within the SET TABLE SOURCE statement:
SET TABLE mytable SOURCE "myfile;ignore_first=true;all_quoted=true"
When the default options all_quoted= false and quoted=true are in force, fields that are written to a line of the csv file will be quoted only if they contain the separator or the quote character. The quote character is doubled when used inside a string. When all_quoted=false and quoted=false the quote character is not doubled. With this option, it is not possible to insert any string containing the separator into the table, as it would become impossible to distinguish from a separator. While reading an existing data source file, the program treats each individual field separately. It determines that a field is quoted only if the first character is the quote character. It interprets the rest of the field on this basis.
The character encoding for the source file is ASCII by default. To support UNICODE or source files preprared with different encodings this can be changed to UTF-8 or any other encoding. The default is encoding=ASCII and the option encoding=UTF-8 or other supported encodings can be used.
Finally, HSQLDB provides the ability to read a text file from the bottom up and making them READ ONLY, by placing the keyword "DESC" at the end of the SET TABLE SOURCE statement:
SET TABLE mytable SOURCE "myfile" DESC
This feature provides functionality similar to the Unix tail command, by re-reading the file each time a select is executed. Using this feature sets the table to read-only mode. Afterwards, it will no longer be possible to change the read-only status with SET TABLE <tablename> READONLY TRUE.
Text table source files are cached in memory. The maximum number of rows of data that are in memory at any time is controlled by the textdb.cache_scale property. The default value for textdb.cache_scale is 10 and can be changed by setting the property in the .properties file for the database. The number of rows in memory is calculated as 3*(2**scale), which translates to 3072 rows for the default textdb.cache_scale setting (10). The property can also be set for individual text tables:
SET TABLE mytable SOURCE "myfile;ignore_first=true;all_quoted=true;cache_scale=12"
The following describes behaviour present in 1.8.0.8 and later.
Text tables may be disconnected from their underlying data source, i.e. the text file.
You can explicitly disconnect a text table from its file by issuing the following statement:
SET TABLE mytable SOURCE OFF
Subsequently, mytable will be empty and read-only. However, the data source description will be preserved, and the table can be re-connected to it with
SET TABLE mytable SOURCE ON
When a database is opened, if the source file for an existing text table is missing the table remains disconnected from its data source, but the source sescription is preserved. This allows the missing source file to be added to the directory and the table re-connected to it with the above command.
Text File Issues
File locations are restricted to below the directory that contains the database, unless the textdb.allow_full_path property is set true in the database properties file.
Blank lines are allowed anywhere in the text file, and are ignored.
The file location for a text table created with
SELECT <select list> INTO TEXT <tablename> FROM
is the directory that contains the database and the file name is based on the table name. The table name is converted into the file name by replacing all the non-alphanumeric characters with the underscore character, conversion into lowercase, and adding the ".csv" suffix.
It is possible to define a primay key or identity column for text tables.
When a table source file is used with the ignore_first=true option, the first, ignored line is replaced with a blank line after a SHUTDOWN COMPACT.
An existing table source file may include CHARACTER fields that do not begin with the quote character but contain instances of the quote character. These fields are read as literal strings. Alternatively, if any field begins with the quote character, then it is interpreted as a quoted string that should end with the quote character and any instances of the quote character within the string is doubled. When any field containing the quote character or the separator is written out to the source file by the program, the field is enclosed in quote character and any instance of the quote character inside the field is doubled.
Inserts or updates of CHARACTER type field values are allowed with strings that contains the linefeed or the carriage return character. This feature is disabled when both quoted and all_quoted properties are false.
ALTER TABLE commands that add or drop columns are not supported with non-empty text tables.
Complete list of supported global properties in *.properties files
textdb.fs
textdb.lvs
textdb.quoted
textdb.all_quoted
textdb.ignore_first
textdb.encoding
textdb.cache_scale
textdb.allow_full_path
The directory src/org/hsqldb/sample in your HSQLDB distibution contains a file named load_binding_lu.sql. This is a working SQL file which imports a pipe-delimited text file from the database's file directory into an existing normal table. You can edit a copy of this file and use it directly with SqlTool, or you can use the SQL therein as a model (using any SQL client at all).