flibs/sqlite(n) 1.0 "flibs"

NAME

flibs/sqlite - Interface to SQLite

TABLE OF CONTENTS

    TABLE OF CONTENTS
    SYNOPSIS
    DESCRIPTION
    DATA TYPES
    ROUTINES
    EXAMPLE
    LIMITATIONS
    IMPLEMENTATION NOTES
    COPYRIGHT

SYNOPSIS

type(SQLITE_DATABASE)
type(SQLITE_STATEMENT)
type(SQLITE_COLUMN)
call sqlite3_column_props( column, name, type, length )
call sqlite3_column_query( column, name, type, length, function )
call sqlite3_set_column( column, value )
call sqlite3_get_column( column, value )
call sqlite3_open( filename, db )
call sqlite3_close( db )
err = sqlite3_error( db )
errmsg = sqlite3_errmsg( db )
call sqlite3_do( db, command )
call sqlite3_begin( db )
call sqlite3_commit( db )
call sqlite3_rollback( db )
call sqlite3_create_table( db )
call sqlite3_delete_table( db )
call sqlite3_prepare_select( db, tablename, columns, stmt, extra_clause )
call sqlite3_prepare( db, command, stmt, columns )
call sqlite3_step( stmt, completion )
call sqlite3_reset( stmt )
call sqlite3_finalize( stmt )
call sqlite3_next_row( stmt, columns, finished )
call sqlite3_insert( db, tablename, columns )
call sqlite3_get_table( db, commmand, result, errmsg )
call sqlite3_query_table( db, tablename, columns )

DESCRIPTION

The sqlite module provides a Fortran interface to the SQLite database management system (SQLite 3 to be more precise). The interface has been implemented in such a way, that you can use a high-level interface for common tasks, such as inserting data into a database and querying the contents, as well as lower-level functionality, accessible via SQL statements, for instance.

To this end the module defines a set of routines and functions as well as several derived types to hide the low-level details.

In its current form, it does not provide a full Fortran API to all the functionality offered by SQLite, but it should be quite useable.

Note: When in doubt, consult the SQLite documentation at http://www.sqlite.org - most routines merely prepare SQL statements or are a simple interface to the original C functions.

DATA TYPES

The following derived types are defined:

type(SQLITE_DATABASE)
Variables of this type are used to hold the connection to the database or databases. They are created by the subroutine sqlite3_open

The contents are valid until the database is closed (via sqlite3_close).

type(SQLITE_STATEMENT)
Variables of this type hold prepared statements, the common method for database management systems to efficiently execute SQL statements.

type(SQLITE_COLUMN)
To provide easy communication with the database, SQLITE_COLUMN can hold values of different types. This means you can use a single routine and variable to transfer strings, integers or reals to and from the database.
The first two derived types are "opaque", that is they are used only to communicate between the application and the database library and there is information of interest to be gotten from them.

The third type is rather crucial to the working of the implementation: By setting the properties of an SQLITE_COLUMN variable you put data into the database or you can retrieve data from the database. See the example below for how this works.

There are a number of routines that are meant to make this easier:

call sqlite3_column_props( column, name, type, length )
Set the properties of a column

type(SQLITE_COLUMN) column
The variable that holds the information on the column

character(len=*) filename
Name of the column in the table to which it belongs or will belong

integer type
Type of the column: one of SQLITE_INT, SQLITE_REAL, SQLITE_DOUBLE or SQLITE_CHAR

integer, optional length
Length of a character-valued column (defaults to 20 characters)


call sqlite3_column_query( column, name, type, length, function )
Set the properties of a column when constructing a SELECT query. The "function" argument, if present, is a string representing an SQL function like count or max.

type(SQLITE_COLUMN) column
The variable that holds the information on the column

character(len=*) filename
Name of the column in the table to which it belongs or will belong

integer type
Type of the column: one of SQLITE_INT, SQLITE_REAL, SQLITE_DOUBLE or SQLITE_CHAR

integer, optional length
Length of a character-valued column (defaults to 20 characters)

character(len=*), optional function
Name of the SQL function to perform on the values.


call sqlite3_set_column( column, value )
Set the value of a column

type(SQLITE_COLUMN) column
The variable that holds the information on the column

any type value
The new value for the column. The type of the value that is passed can be integer, real, double precision real or character string.

Note: currently there is no conversion from the type of value that is stored to the type of the actual variable that is passed to the routine. If you ask for an integer and the column holds a real, then the result is undefined. Check the type with the value of the flag "type_set". (This is one of the things that should be improved)


call sqlite3_get_column( column, value )
Get the value of a column

type(SQLITE_COLUMN) column
The variable that holds the information on the column

any type value
The value stored in the column. The type of the value that is passed can be integer, real, double precision real or character string.


ROUTINES

The sqlite module currently provides the following functions:

call sqlite3_open( filename, db )
Open a database file and store the connection for later use.

character(len=*) filename
The name of the database file (it may also be ":mem" to get a memory-based database instead of a file on disk)

type(SQLITE_DATABASE) db
Variable to identify the database connection


call sqlite3_close( db )
Close the database connection. Simply an interface to the corresponding C function.

type(SQLITE_DATABASE) db
Variable identifying the database connection


err = sqlite3_error( db )
Retrieve whether the previous command resulted in an error or not. Returns true if so, otherwise false.

type(SQLITE_DATABASE) db
Variable identifying the database connection


errmsg = sqlite3_errmsg( db )
Retrieve the last error message as a string of at most 80 characters.

type(SQLITE_DATABASE) db
Variable identifying the database connection


call sqlite3_do( db, command )
Run a single SQL command

type(SQLITE_DATABASE) db
Variable identifying the database connection

character(len=*) command
String holding a complete SQL command


call sqlite3_begin( db )
Start a transaction. When the corresponding routine sqlite3_commit is called, all changes will be made permanent. Use a transaction to gather lots of changes to the database - this is much faster than an automatic commission after each change.

type(SQLITE_DATABASE) db
Variable identifying the database connection


call sqlite3_commit( db )
Commit the changes made since the start of a transaction. This makes the changes permanent.

type(SQLITE_DATABASE) db
Variable identifying the database connection


call sqlite3_rollback( db )
Undo the changes made since the start a transaction. The database will be restored to the state it was in before the transaction was started.

type(SQLITE_DATABASE) db
Variable identifying the database connection


call sqlite3_create_table( db )
Create a new table, based on the properties of the columns. Convenience routine that constructs an SQL statement to do the actual job.

type(SQLITE_DATABASE) db
Variable identifying the database connection

character(len=*) tablename
Name of the table to be created

type(SQLITE_COLUMN), dimension(:) columns
An array of the properties of the columns in the tables (name, type, ...)

character(len=*), optional primary
Name of the column that acts as the primary key (this gets the "unique" constraint)


call sqlite3_delete_table( db )
Delete an existing table by name. Convenience routine that constructs an SQL statement to do the actual job.

type(SQLITE_DATABASE) db
Variable identifying the database connection

character(len=*) tablename
Name of the table to be deleted


call sqlite3_prepare_select( db, tablename, columns, stmt, extra_clause )
Prepare a SELECT query. Convenience routine that creates the SQL query and "compiles" (prepares) it for later actual execution.

type(SQLITE_DATABASE) db
Variable identifying the database connection

character(len=*) tablename
Name of the table to be queried

type(SQLITE_COLUMN), dimension(:) columns
An array of the properties of the columns to be returned

type(SQLITE_STATEMENT) stmt
A derived type used as a handle to the prepared statement

character(len=*), optional extra_clause
A string holding an extra clause, such as "SORT BY" or "GROUP BY"


call sqlite3_prepare( db, command, stmt, columns )
Prepare a general SQL statement for later actual execution. The statement can be any SQL statement.

type(SQLITE_DATABASE) db
Variable identifying the database connection

character(len=*) command
The SQL statement to be prepared

type(SQLITE_STATEMENT) stmt
A derived type used as a handle to the prepared statement

type(SQLITE_COLUMN), dimension(:), pointer columns
An array of the properties of the columns that will be returned by the statement. The routine returns an allocated array. You must deallocate it yourself, when it is no longer needed.


call sqlite3_step( stmt, completion )
Run the prepared SQL statement for one step. The code in completion will tell whether it was successful or not. Simply an interface to the equivalent C routine.

type(SQLITE_STATEMENT) stmt
A derived type used as a handle to the prepared statement

integer completion
One of the values SQLITE_DONE (success), SQLITE_MISUSE or SQLITE_ERROR


call sqlite3_reset( stmt )
Reset the prepared statement so that it can be used again.

type(SQLITE_STATEMENT) stmt
A derived type used as a handle to the prepared statement


call sqlite3_finalize( stmt )
Free all resources associated with the prepared statement.

type(SQLITE_STATEMENT) stmt
A derived type used as a handle to the prepared statement


call sqlite3_next_row( stmt, columns, finished )
Retrieve the next row of a SELECT query. If the argument "finished" is set to true, the previous row was the last one.

type(SQLITE_STATEMENT) stmt
A derived type used as a handle to the prepared statement

logical finished
Set to true if the last row was retrieved.


call sqlite3_insert( db, tablename, columns )
Insert a complete new row into the table.

type(SQLITE_DATABASE) db
Variable identifying the database connection

character(len=*) tablename
Name of the table into which the row must be inserted

type(SQLITE_COLUMN), dimension(:) columns
An array of values for all columns


call sqlite3_get_table( db, commmand, result, errmsg )
Get the result of a query in a single two-dimensional array

type(SQLITE_DATABASE) db
Variable identifying the database connection

character(len=*) command
The SQL command (query) to executed

character(len=*), dimension(:,:), pointer result
A two-dimensional array that will be filled with the results of the SQl command. When done, you will have to deallocate it.

character(len=*) errmsg
If there is an error, then "result" will not be allocated, and "errmsg" will contain the information about the error that occurred.


call sqlite3_query_table( db, tablename, columns )
Query the structure of the table

type(SQLITE_DATABASE) db
Variable identifying the database connection

character(len=*) tablename
Name of the table to be inspected

type(SQLITE_COLUMN), dimension(:), pointer columns
An array with the properties of all columns. Deallocate it when you are done.


EXAMPLE

To illustrate the usage of the library, here is a small example:

The first part of the program simply defines the table:

 
   allocate( column(4) )
   call sqlite3_column_props( column(1), name(1), SQLITE_CHAR, 10 )
   call sqlite3_column_props( column(2), name(2), SQLITE_CHAR, 10 )
   call sqlite3_column_props( column(3), name(3), SQLITE_REAL )
   call sqlite3_column_props( column(4), name(4), SQLITE_REAL )
   call sqlite3_create_table( db, 'measurements', column )

The second part reads the data file and stores the data in a new row:

 
   call sqlite3_begin( db )
   do
      read( lun, *, iostat=ierr ) station, date, salin, temp

      if ( ierr .ne. 0 ) exit

      call sqlite3_set_column( column(1), station )
      call sqlite3_set_column( column(2), date    )
      call sqlite3_set_column( column(3), salin   )
      call sqlite3_set_column( column(4), temp    )
      call sqlite3_insert( db, 'measurements', column )

   enddo

   close( lun )

   call sqlite3_commit( db )

Note that it uses a transaction (via calls to sqlite3_begin and sqlite3_commit pair), so that all the inserts can be done in one go. Inserting with autocommit is much slower, as the database file needs to be flushed very time.

The last part retrieves the data by constructing an SQL query that will actually look like:

 
    select station, avg(salinity), avg(temperature) from measurements
        grouped by station order by station;

The routine sqlite3_prepare_select takes care of the actual construction of the above SQL query:

 
   deallocate( column )
   allocate( column(3) )
   call sqlite3_column_query( column(1), 'station', SQLITE_CHAR )
   call sqlite3_column_query( column(2), name(3), SQLITE_REAL, function='avg' )
   call sqlite3_column_query( column(3), name(4), SQLITE_REAL, function='avg' )
   call sqlite3_prepare_select( db, 'measurements', column, stmt, &
      'group by station order by station' )

   write( *, '(3a20)' ) 'Station', 'Mean salinity', 'Mean temperature'
   do
      call sqlite3_next_row( stmt, column, finished )

      if ( finished ) exit

      call sqlite3_get_column( column(1), station )
      call sqlite3_get_column( column(2), salin   )
      call sqlite3_get_column( column(3), temp    )

      write( *, '(a20,2f20.3)' ) station, salin, temp
   enddo

The full program looks like this (see also the tests/examples directory of the Flibs project):

 
! csvtable.f90 --
!    Program to read a simple CSV file and put it into a
!    SQLite database, just to demonstrate how the Fortran
!    interface works.
!
!    To keep it simple:
!    - The first line contains the names of the four columns
!    - All lines after that contain the name of the station
!      the date and the two values.
!
!    $Id: fsqlite.man,v 1.2 2007/04/16 20:00:18 arjenmarkus Exp $
!
program csvtable
   use sqlite

   implicit none

   type(SQLITE_DATABASE)                      :: db
   type(SQLITE_STATEMENT)                     :: stmt
   type(SQLITE_COLUMN), dimension(:), pointer :: column

   integer                                    :: lun = 10
   integer                                    :: i
   integer                                    :: ierr
   character(len=40), dimension(4)            :: name
   real                                       :: salin
   real                                       :: temp
   character(len=40)                          :: station
   character(len=40)                          :: date
   logical                                    :: finished

   !
   ! Read the CSV file and feed the data into the database
   !
   open( lun, file = 'somedata.csv' )
   read( lun, * ) name

   call sqlite3_open( 'somedata.db', db )

   allocate( column(4) )
   call sqlite3_column_props( column(1), name(1), SQLITE_CHAR, 10 )
   call sqlite3_column_props( column(2), name(2), SQLITE_CHAR, 10 )
   call sqlite3_column_props( column(3), name(3), SQLITE_REAL )
   call sqlite3_column_props( column(4), name(4), SQLITE_REAL )
   call sqlite3_create_table( db, 'measurements', column )

   !
   ! Insert the values into the table. For better performance,
   ! make sure (via begin/commit) that the changes are committed
   ! only once.
   !
   call sqlite3_begin( db )
   do
      read( lun, *, iostat=ierr ) station, date, salin, temp

      if ( ierr .ne. 0 ) exit

      call sqlite3_set_column( column(1), station )
      call sqlite3_set_column( column(2), date    )
      call sqlite3_set_column( column(3), salin   )
      call sqlite3_set_column( column(4), temp    )
      call sqlite3_insert( db, 'measurements', column )

   enddo

   close( lun )

   call sqlite3_commit( db )

   !
   ! We want a simple report, the mean of salinity and temperature
   ! sorted by the station
   !
   deallocate( column )
   allocate( column(3) )
   call sqlite3_column_query( column(1), 'station', SQLITE_CHAR )
   call sqlite3_column_query( column(2), name(3), SQLITE_REAL, function='avg' )
   call sqlite3_column_query( column(3), name(4), SQLITE_REAL, function='avg' )
   call sqlite3_prepare_select( db, 'measurements', column, stmt, &
      'group by station order by station' )

   write( *, '(3a20)' ) 'Station', 'Mean salinity', 'Mean temperature'
   do
      call sqlite3_next_row( stmt, column, finished )

      if ( finished ) exit

      call sqlite3_get_column( column(1), station )
      call sqlite3_get_column( column(2), salin   )
      call sqlite3_get_column( column(3), temp    )

      write( *, '(a20,2f20.3)' ) station, salin, temp
   enddo

   call sqlite3_close( db )
end program

LIMITATIONS

The module is not complete yet:

IMPLEMENTATION NOTES

While the module is fairly straightforward Fortran 95 code, building a library out of it may not be straightforward due to the intricacies of C-Fortran interfacing.

This section aims to give a few guidelines:

COPYRIGHT

Copyright © 2005 Arjen Markus <arjenmarkus@sourceforge.net>