1 -- SQL file for AWL tables
3 -- Table for holding the schema version so we can be more structured in future
4 CREATE TABLE awl_db_revision (
10 applied_on TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp
13 CREATE or REPLACE FUNCTION check_db_revision( INT, INT, INT ) RETURNS BOOLEAN AS '
20 SELECT COUNT(*) INTO matching FROM awl_db_revision
21 WHERE schema_major = major AND schema_minor = minor AND schema_patch = patch;
23 RAISE EXCEPTION ''Database has not been upgraded to %.%.%'', major, minor, patch;
26 SELECT COUNT(*) INTO matching FROM awl_db_revision
27 WHERE (schema_major = major AND schema_minor = minor AND schema_patch > patch)
28 OR (schema_major = major AND schema_minor > minor)
29 OR (schema_major > major)
32 RAISE EXCEPTION ''Database revisions after %.%.% have already been applied.'', major, minor, patch;
39 -- The schema_id should always be incremented. The major / minor / patch level should
40 -- be incremented as seems appropriate...
41 CREATE or REPLACE FUNCTION new_db_revision( INT, INT, INT, TEXT ) RETURNS BOOLEAN AS '
49 SELECT MAX(schema_id) + 1 INTO new_id FROM awl_db_revision;
50 IF NOT FOUND OR new_id IS NULL THEN
53 INSERT INTO awl_db_revision (schema_id, schema_major, schema_minor, schema_patch, schema_name)
54 VALUES( new_id, major, minor, patch, blurb );
58 SELECT new_db_revision(1,1,0, 'Dawn' );