The facilities PostgreSQL provides to access large objects, both in the backend as part of user-defined functions or the front end as part of an application using the interface, are described below. For users familiar with POSTGRES 4.2, PostgreSQL has a new set of functions providing a more coherent interface.
Note: All large object manipulation must take place within an SQL transaction. This requirement is strictly enforced as of PostgreSQL 6.5, though it has been an implicit requirement in previous versions, resulting in misbehavior if ignored.
The PostgreSQL large object interface is modeled after the Unix file-system interface, with analogues of open(2), read(2), write(2), lseek(2), etc. User functions call these routines to retrieve only the data of interest from a large object. For example, if a large object type called mugshot existed that stored photographs of faces, then a function called beard could be declared on mugshot data. beard could look at the lower third of a photograph, and determine the color of the beard that appeared there, if any. The entire large-object value need not be buffered, or even examined, by the beard function. Large objects may be accessed from dynamically-loaded C functions or database client programs that link the library. PostgreSQL provides a set of routines that support opening, reading, writing, closing, and seeking on large objects.
The routine
(lo-creat conn mode)
creates a new large object. mode is a bit mask describing several different attributes of the new object. The symbolic constants listed here are defined in the header file libpq/libpq-fs.h. The access type (read, write, or both) is controlled by or'ing together the bits INV_READ and INV_WRITE. The low-order sixteen bits of the mask have historically been used at Berkeley to designate the storage manager number on which the large object should reside. These bits should always be zero now. The commands below create a large object:
(set! inv-oid (lo-creat conn (bitwise-ior INV-READ INV-WRITE)))
To import an operating system file as a large object, call
(lo-import conn filename)
filename specifies the operating system name of the file to be imported as a large object.
To export a large object into an operating system file, call
(lo-export conn lobj-id filename)
The lobj-id argument specifies the OID of the large object to export and the filename argument specifies the operating system name name of the file.
To open an existing large object, call
(lo-open conn lobj-id mode)
The lobj-id argument specifies the OID of the large object to open. The mode bits control whether the object is opened for reading (INV-READ), writing (INV-WRITE), or both. A large object cannot be opened before it is created. lo-open returns a large object descriptor for later use in lo-read, lo-write, lo-lseek, lo-tell, and lo-close.
The routine
(lo-write conn fd buf len)
writes len bytes from buf to large object fd. The fd argument must have been returned by a previous lo-open. The number of bytes actually written is returned. In the event of an error, the return value is negative.
The routine
(lo-read conn fd buf len)
reads len bytes from large object fd into buf. The fd argument must have been returned by a previous lo-open. The number of bytes actually read is returned. In the event of an error, the return value is negative.
To change the current read or write location on a large object, call
(lo-lseek conn fd offset whence)
This routine moves the current location pointer for the large object described by fd to the new location specified by offset. The valid values for whence are SEEK-SET, SEEK-CUR, and SEEK-END.
A large object may be closed by calling
(lo-close conn fd)
where fd is a large object descriptor returned by lo-open. On success, lo-close returns zero. On error, the return value is negative.
To remove a large object from the database, call
(lo-unlink conn lobj-id)
The lobj-id argument specifies the OID of the large object to remove. In the event of an error, the return value is negative.
There are two built-in registered functions, lo_import and lo_export which are convenient for use in SQL queries. Here is an example of their use
CREATE TABLE image ( name text, raster oid ); INSERT INTO image (name, raster) VALUES ('beautiful image', lo_import('/etc/motd')); SELECT lo_export(image.raster, '/tmp/motd') FROM image WHERE name = 'beautiful image';