mirror of https://github.com/postgres/postgres
Orphaning that occurs with JDBC & ODBC. Contents: contrib/lo/Makefile contrib/lo/README contrib/lo/lo.c contrib/lo/lo.sql.in These are just test stuff - not essential contrib/lo/test.sql contrib/lo/drop.sql Peter MountREL6_4
parent
d6e0ee6bcb
commit
7784312f99
@ -0,0 +1,39 @@ |
||||
#
|
||||
# PostgreSQL lo type
|
||||
#
|
||||
# Makefile pinched from the ip-mac contrib package
|
||||
#
|
||||
# $Id: Makefile,v 1.1 1998/06/16 07:07:11 momjian Exp $
|
||||
|
||||
SRCDIR= ../../src
|
||||
|
||||
include $(SRCDIR)/Makefile.global |
||||
|
||||
CONTRIBDIR=$(LIBDIR)/modules
|
||||
|
||||
CFLAGS+= $(CFLAGS_SL) -I$(SRCDIR)/include
|
||||
|
||||
ifdef REFINT_VERBOSE |
||||
CFLAGS+= -DREFINT_VERBOSE
|
||||
endif |
||||
|
||||
TARGETS= lo$(DLSUFFIX) lo.sql
|
||||
|
||||
CLEANFILES+= $(TARGETS)
|
||||
|
||||
all:: $(TARGETS) |
||||
|
||||
install:: all $(CONTRIBDIR) |
||||
for f in *$(DLSUFFIX); do $(INSTALL) -c $$f $(CONTRIBDIR)/$$f; done
|
||||
|
||||
$(CONTRIBDIR): |
||||
mkdir -p $(CONTRIBDIR)
|
||||
|
||||
%.sql: %.sql.in |
||||
rm -f $@; \
|
||||
C=`pwd`; \
|
||||
sed -e "s:_OBJWD_:$(CONTRIBDIR):g" \
|
||||
-e "s:_DLSUFFIX_:$(DLSUFFIX):g" < $< > $@
|
||||
|
||||
clean: |
||||
rm -f $(TARGETS) *.o
|
||||
@ -0,0 +1,71 @@ |
||||
PostgreSQL type extension for managing Large Objects |
||||
---------------------------------------------------- |
||||
|
||||
$Id: README,v 1.1 1998/06/16 07:07:11 momjian Exp $ |
||||
|
||||
Overview |
||||
|
||||
One of the problems with the JDBC driver (and this affects the ODBC driver |
||||
also), is that the specification assumes that references to BLOBS (Binary |
||||
Large OBjectS) are stored within a table, and if that entry is changed, the |
||||
associated BLOB is deleted from the database. |
||||
|
||||
As PostgreSQL stands, this doesn't occur. It allocates an OID for each object, |
||||
and it is up to the application to store, and ultimately delete the objects. |
||||
|
||||
Now this is fine for new postgresql specific applications, but existing ones |
||||
using JDBC or ODBC wont delete the objects, arising to orphaning - objects |
||||
that are not referenced by anything, and simply occupy disk space. |
||||
|
||||
The Fix |
||||
|
||||
I've fixed this by creating a new data type 'lo', some support functions, and |
||||
a Trigger which handles the orphaning problem. |
||||
|
||||
The 'lo' type was created because we needed to differenciate between normal |
||||
Oid's and Large Objects. Currently the JDBC driver handles this dilema easily, |
||||
but (after talking to Byron), the ODBC driver needed a unique type. They had created an 'lo' type, but not the solution to orphaning. |
||||
|
||||
Install |
||||
|
||||
Ok, first build the shared library, and install. Typing 'make install' in the |
||||
contrib/lo directory should do it. |
||||
|
||||
Then, as the postgres super user, run the lo.sql script. This will install the |
||||
type, and define the support functions. |
||||
|
||||
How to Use |
||||
|
||||
The easiest way is by an example: |
||||
|
||||
> create table image (title text,raster lo); |
||||
> create trigger t_image before update or delete on image for each row execute procedure lo_manage(raster); |
||||
|
||||
Here, a trigger is created for each column that contains a lo type. |
||||
|
||||
Issues |
||||
|
||||
* dropping a table will still orphan any objects it contains, as the trigger |
||||
is not actioned. |
||||
|
||||
For now, precede the 'drop table' with 'delete from {table}'. However, this |
||||
could be fixed by having 'drop table' perform an additional |
||||
|
||||
'select lo_unlink({colname}::oid) from {tablename}' |
||||
|
||||
for each column, before actually dropping the table. |
||||
|
||||
* Some frontends may create their own tables, and will not create the |
||||
associated trigger(s). Also, users may not remember (or know) to create |
||||
the triggers. |
||||
|
||||
This can be solved, but would involve changes to the parser. |
||||
|
||||
As the ODBC driver needs a permanent lo type (& JDBC could be optimised to |
||||
use it if it's Oid is fixed), and as the above issues can only be fixed by |
||||
some internal changes, I feel it should become a permanent built-in type. |
||||
|
||||
I'm releasing this into contrib, just to get it out, and tested. |
||||
|
||||
Peter Mount <peter@retep.org.uk> June 13 1998 |
||||
|
||||
@ -0,0 +1,21 @@ |
||||
-- |
||||
-- This removes the type (and a test table) |
||||
-- It's used just for development |
||||
-- |
||||
|
||||
-- remove our test table |
||||
drop table a; |
||||
|
||||
-- now drop any sql based functions associated with the lo type |
||||
drop function oid(lo); |
||||
|
||||
-- now drop the type |
||||
drop type lo; |
||||
|
||||
-- as the type is gone, remove the C based functions |
||||
drop function lo_in(opaque); |
||||
drop function lo_out(opaque); |
||||
drop function lo(oid); |
||||
drop function lo_manage(); |
||||
|
||||
-- the lo stuff is now removed from the system |
||||
@ -0,0 +1,213 @@ |
||||
/*
|
||||
* PostgreSQL type definitions for managed LargeObjects. |
||||
* |
||||
* $Id: lo.c,v 1.1 1998/06/16 07:07:11 momjian Exp $ |
||||
* |
||||
*/ |
||||
|
||||
#include <stdio.h> |
||||
|
||||
#include <postgres.h> |
||||
#include <utils/palloc.h> |
||||
|
||||
/* Required for largeobjects */ |
||||
#include <libpq/libpq-fs.h> |
||||
#include <libpq/be-fsstubs.h> |
||||
|
||||
/* Required for SPI */ |
||||
#include <executor/spi.h> |
||||
|
||||
/* Required for triggers */ |
||||
#include <commands/trigger.h> |
||||
|
||||
/* required for tolower() */ |
||||
|
||||
/*
|
||||
* This is the internal storage format for managed large objects |
||||
* |
||||
*/ |
||||
|
||||
typedef Oid Blob; |
||||
|
||||
/*
|
||||
* Various forward declarations: |
||||
*/ |
||||
|
||||
Blob *lo_in(char *str); /* Create from String */ |
||||
char *lo_out(Blob * addr); /* Output oid as String */ |
||||
Oid lo_oid(Blob * addr); /* Return oid as an oid */ |
||||
Blob *lo(Oid oid); /* Return Blob based on oid */ |
||||
HeapTuple lo_manage(void); /* Trigger handler */ |
||||
|
||||
/*
|
||||
* This creates a large object, and set's its OID to the value in the |
||||
* supplied string. |
||||
* |
||||
* If the string is empty, then a new LargeObject is created, and its oid |
||||
* is placed in the resulting lo. |
||||
*/ |
||||
Blob * |
||||
lo_in(char *str) |
||||
{ |
||||
Blob *result; |
||||
Oid oid; |
||||
int count; |
||||
|
||||
if (strlen(str) > 0) |
||||
{ |
||||
|
||||
count = sscanf(str, "%d", &oid); |
||||
|
||||
if (count < 1) |
||||
{ |
||||
elog(ERROR, "lo_in: error in parsing \"%s\"", str); |
||||
return (NULL); |
||||
} |
||||
|
||||
if(oid < 0) |
||||
{ |
||||
elog(ERROR, "lo_in: illegal oid \"%s\"", str); |
||||
return (NULL); |
||||
} |
||||
} |
||||
else |
||||
{ |
||||
/*
|
||||
* There is no Oid passed, so create a new one |
||||
*/ |
||||
oid = lo_creat(INV_READ|INV_WRITE); |
||||
if(oid == InvalidOid) |
||||
{ |
||||
elog(ERROR,"lo_in: InvalidOid returned from lo_creat"); |
||||
return (NULL); |
||||
} |
||||
} |
||||
|
||||
result = (Blob *) palloc(sizeof(Blob)); |
||||
|
||||
*result = oid; |
||||
|
||||
return (result); |
||||
} |
||||
|
||||
/*
|
||||
* This simply outputs the Oid of the Blob as a string. |
||||
*/ |
||||
char * |
||||
lo_out(Blob * addr) |
||||
{ |
||||
char *result; |
||||
|
||||
if (addr == NULL) |
||||
return (NULL); |
||||
|
||||
result = (char *) palloc(32); |
||||
sprintf(result,"%d",*addr); |
||||
return (result); |
||||
} |
||||
|
||||
/*
|
||||
* This function converts Blob to oid. |
||||
* |
||||
* eg: select lo_export(raster::oid,'/path/file') from table; |
||||
*
|
||||
*/ |
||||
Oid |
||||
lo_oid(Blob * addr) |
||||
{ |
||||
if(addr == NULL) |
||||
return InvalidOid; |
||||
return (Oid)(*addr); |
||||
} |
||||
|
||||
/*
|
||||
* This function is used so we can convert oid's to lo's |
||||
* |
||||
* ie: insert into table values(lo_import('/path/file')::lo); |
||||
* |
||||
*/ |
||||
Blob * |
||||
lo(Oid oid) |
||||
{ |
||||
Blob *result = (Blob *) palloc(sizeof(Blob)); |
||||
*result = oid; |
||||
return (result); |
||||
} |
||||
|
||||
/*
|
||||
* This handles the trigger that protects us from orphaned large objects |
||||
*/ |
||||
HeapTuple |
||||
lo_manage(void) |
||||
{ |
||||
int attnum; /* attribute number to monitor */ |
||||
char **args; /* Args containing attr name */ |
||||
TupleDesc tupdesc; /* Tuple Descriptor */ |
||||
HeapTuple rettuple; /* Tuple to be returned */ |
||||
bool isdelete; /* are we deleting? */ |
||||
HeapTuple newtuple=NULL; /* The new value for tuple */ |
||||
HeapTuple trigtuple; /* The original value of tuple */ |
||||
|
||||
if (!CurrentTriggerData) |
||||
elog(ERROR, "lo: triggers are not initialized"); |
||||
|
||||
/*
|
||||
* Fetch some values from CurrentTriggerData |
||||
*/ |
||||
newtuple = CurrentTriggerData->tg_newtuple; |
||||
trigtuple = CurrentTriggerData->tg_trigtuple; |
||||
tupdesc = CurrentTriggerData->tg_relation->rd_att; |
||||
args = CurrentTriggerData->tg_trigger->tgargs; |
||||
|
||||
/* tuple to return to Executor */ |
||||
if (TRIGGER_FIRED_BY_UPDATE(CurrentTriggerData->tg_event)) |
||||
rettuple = newtuple; |
||||
else |
||||
rettuple = trigtuple; |
||||
|
||||
/* Are we deleting the row? */ |
||||
isdelete = TRIGGER_FIRED_BY_DELETE(CurrentTriggerData->tg_event); |
||||
|
||||
/* Were done with it */ |
||||
CurrentTriggerData = NULL; |
||||
|
||||
/* Get the column were interested in */ |
||||
attnum = SPI_fnumber(tupdesc,args[0]); |
||||
|
||||
/*
|
||||
* Handle updates |
||||
* |
||||
* Here, if the value of the monitored attribute changes, then the |
||||
* large object associated with the original value is unlinked. |
||||
*/ |
||||
if(newtuple!=NULL) { |
||||
char *orig = SPI_getvalue(trigtuple,tupdesc,attnum); |
||||
char *newv = SPI_getvalue(newtuple,tupdesc,attnum); |
||||
|
||||
if((orig != newv && (orig==NULL || newv==NULL)) || (orig!=NULL && newv!=NULL && strcmp(orig,newv))) |
||||
lo_unlink(atoi(orig)); |
||||
|
||||
if(newv) |
||||
pfree(newv); |
||||
if(orig) |
||||
pfree(orig); |
||||
} |
||||
|
||||
/*
|
||||
* Handle deleting of rows |
||||
* |
||||
* Here, we unlink the large object associated with the managed attribute |
||||
* |
||||
*/ |
||||
if(isdelete) { |
||||
char *orig = SPI_getvalue(trigtuple,tupdesc,attnum); |
||||
|
||||
if(orig != NULL) { |
||||
lo_unlink(atoi(orig)); |
||||
|
||||
pfree(orig); |
||||
} |
||||
} |
||||
|
||||
return (rettuple); |
||||
} |
||||
@ -0,0 +1,59 @@ |
||||
-- |
||||
-- PostgreSQL code for LargeObjects |
||||
-- |
||||
-- $Id: lo.sql.in,v 1.1 1998/06/16 07:07:11 momjian Exp $ |
||||
-- |
||||
|
||||
load '_OBJWD_/lo_DLSUFFIX_'; |
||||
|
||||
-- |
||||
-- Create the data type |
||||
-- |
||||
|
||||
-- used by the lo type, it takes an oid and returns an lo object |
||||
create function lo_in(opaque) |
||||
returns opaque |
||||
as '_OBJWD_/lo_DLSUFFIX_' |
||||
language 'c'; |
||||
|
||||
-- used by the lo type, it returns the oid of the object |
||||
create function lo_out(opaque) |
||||
returns opaque |
||||
as '_OBJWD_/lo_DLSUFFIX_' |
||||
language 'c'; |
||||
|
||||
-- finally the type itself |
||||
create type lo ( |
||||
internallength = 4, |
||||
externallength = variable, |
||||
input = lo_in, |
||||
output = lo_out |
||||
); |
||||
|
||||
-- this returns the oid associated with a lo object |
||||
create function lo_oid(lo) |
||||
returns oid |
||||
as '_OBJWD_/lo_DLSUFFIX_' |
||||
language 'c'; |
||||
|
||||
-- this allows us to convert an oid to a managed lo object |
||||
-- ie: insert into test values (lo_import('/fullpath/file')::lo); |
||||
create function lo(oid) |
||||
returns lo |
||||
as '_OBJWD_/lo_DLSUFFIX_' |
||||
language 'c'; |
||||
|
||||
-- This is used in triggers |
||||
create function lo_manage() |
||||
returns opaque |
||||
as '_OBJWD_/lo_DLSUFFIX_' |
||||
language 'c'; |
||||
|
||||
-- This allows us to map lo to oid |
||||
-- |
||||
-- eg: |
||||
-- create table a (image lo); |
||||
-- select image::oid from a; |
||||
-- |
||||
create function oid(lo) returns oid as 'select lo_oid($1)' language 'sql'; |
||||
|
||||
@ -0,0 +1,57 @@ |
||||
-- |
||||
-- This runs some common tests against the type |
||||
-- |
||||
-- It's used just for development |
||||
-- |
||||
|
||||
-- ignore any errors here - simply drop the table if it already exists |
||||
drop table a; |
||||
|
||||
-- create the test table |
||||
create table a (fname name,image lo); |
||||
|
||||
-- insert a null object |
||||
insert into a values ('null'); |
||||
|
||||
-- insert an empty large object |
||||
insert into a values ('empty',''); |
||||
|
||||
-- insert a large object based on a file |
||||
insert into a values ('/etc/group',lo_import('/etc/group')::lo); |
||||
|
||||
-- now select the table |
||||
select * from a; |
||||
|
||||
-- this select also returns an oid based on the lo column |
||||
select *,image::oid from a; |
||||
|
||||
-- now test the trigger |
||||
create trigger t_a before update or delete on a for each row execute procedure lo_manage(image); |
||||
|
||||
-- insert |
||||
insert into a values ('aa',''); |
||||
select * from a where fname like 'aa%'; |
||||
|
||||
-- update |
||||
update a set image=lo_import('/etc/group')::lo where fname='aa'; |
||||
select * from a where fname like 'aa%'; |
||||
|
||||
-- update the 'empty' row which should be null |
||||
update a set image=lo_import('/etc/hosts')::lo where fname='empty'; |
||||
select * from a where fname like 'empty%'; |
||||
update a set image=null where fname='empty'; |
||||
select * from a where fname like 'empty%'; |
||||
|
||||
-- delete the entry |
||||
delete from a where fname='aa'; |
||||
select * from a where fname like 'aa%'; |
||||
|
||||
-- This deletes the table contents. Note, if you comment this out, and |
||||
-- expect the drop table to remove the objects, think again. The trigger |
||||
-- doesn't get thrown by drop table. |
||||
delete from a; |
||||
|
||||
-- finally drop the table |
||||
drop table a; |
||||
|
||||
-- end of tests |
||||
Loading…
Reference in new issue