Create tables acq.fiscal_calendar and acq.fiscal_year.
authorscottmk <scottmk@dcc99617-32d9-48b4-a31d-7c20da2025e4>
Thu, 27 Aug 2009 12:51:09 +0000 (12:51 +0000)
committerscottmk <scottmk@dcc99617-32d9-48b4-a31d-7c20da2025e4>
Thu, 27 Aug 2009 12:51:09 +0000 (12:51 +0000)
Create function acq.find_bad_fy to perform sanity checks
on acq.fiscal_year.

To add to an existing database:

CREATE TABLE acq.fiscal_calendar (
id              SERIAL         PRIMARY KEY,
name            TEXT           NOT NULL
);

CREATE TABLE acq.fiscal_year (
id              SERIAL         PRIMARY KEY,
calendar        INT            NOT NULL
                               REFERENCES acq.fiscal_calendar
                               ON DELETE CASCADE
                               DEFERRABLE INITIALLY DEFERRED,
year            INT            NOT NULL,
year_begin      TIMESTAMPTZ    NOT NULL,
year_end        TIMESTAMPTZ    NOT NULL,
CONSTRAINT acq_fy_logical_key  UNIQUE ( calendar, year ),
    CONSTRAINT acq_fy_physical_key UNIQUE ( calendar, year_begin )
);

CREATE OR REPLACE FUNCTION acq.find_bad_fy()
/*
Examine the acq.fiscal_year table, comparing successive years.
Report any inconsistencies, i.e. years that overlap or have
gaps between them.
*/
RETURNS SETOF RECORD AS $$
DECLARE
first_row  BOOLEAN;
curr_year  RECORD;
prev_year  RECORD;
return_rec RECORD;
BEGIN
first_row := true;
FOR curr_year in
SELECT
id,
calendar,
year,
year_begin,
year_end
FROM
acq.fiscal_year
ORDER BY
calendar,
year_begin
LOOP
--
IF first_row THEN
first_row := FALSE;
ELSIF curr_year.calendar    = prev_year.calendar THEN
IF curr_year.year_begin > prev_year.year_end THEN
-- This ugly kludge works around the fact that older
-- versions of PostgreSQL don't support RETURN QUERY SELECT
FOR return_rec IN SELECT
prev_year.id,
prev_year.year,
'Gap between fiscal years'::TEXT
LOOP
RETURN NEXT return_rec;
END LOOP;
ELSIF curr_year.year_begin < prev_year.year_end THEN
FOR return_rec IN SELECT
prev_year.id,
prev_year.year,
'Overlapping fiscal years'::TEXT
LOOP
RETURN NEXT return_rec;
END LOOP;
ELSIF curr_year.year < prev_year.year THEN
FOR return_rec IN SELECT
prev_year.id,
prev_year.year,
'Fiscal years out of order'::TEXT
LOOP
RETURN NEXT return_rec;
END LOOP;
END IF;
END IF;
--
prev_year := curr_year;
END LOOP;
--
RETURN;
END;
$$ LANGUAGE plpgsql;

git-svn-id: svn://svn.open-ils.org/ILS/trunk@13931 dcc99617-32d9-48b4-a31d-7c20da2025e4

Open-ILS/examples/fm_IDL.xml
Open-ILS/src/sql/Pg/200.schema.acq.sql

index c230ee0..4a3ffd7 100644 (file)
@@ -3961,6 +3961,54 @@ Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA  02110-1301, USA
         </permacrud>
        </class>
 
+       <class id="acqfc" controller="open-ils.cstore" oils_obj:fieldmapper="acq::fiscal_calendar" oils_persist:tablename="acq.fiscal_calendar" reporter:label="Fiscal Calendar">
+               <fields oils_persist:primary="id" oils_persist:sequence="acq.fiscal_calendar_id_seq">
+                       <field reporter:label="Fiscal Calendar ID" name="id" reporter:datatype="id" reporter:selector='id'/>
+                       <field reporter:label="Fiscal Calendar Name" name="name" reporter:datatype="text"/>
+                       <field reporter:label="Years" name="years" oils_persist:virtual="true" reporter:datatype="link"/>
+               </fields>
+               <links>
+            <link field="years" reltype="has_many" map="" key="calendar" class="acqfy"/>
+               </links>
+               <!--
+                       For now, we don't have pcrud as one of the controllers, so the permacrud section is moot.
+                       But here's what it should look like if we ever do use pcrud.
+               -->
+               <permacrud xmlns="http://open-ils.org/spec/opensrf/IDL/permacrud/v1">
+                       <actions>
+                               <create permission="ADMIN_ACQ_FISCAL_YEAR" global_required="true"/>
+                               <retrieve permission="ADMIN_ACQ_FISCAL_YEAR" global_required="true"/>
+                               <update permission="ADMIN_ACQ_FISCAL_YEAR" global_required="true"/>
+                               <delete permission="ADMIN_ACQ_FISCAL_YEAR" global_required="true"/>
+                       </actions>
+               </permacrud>
+       </class>
+
+       <class id="acqfy" controller="open-ils.cstore" oils_obj:fieldmapper="acq::fiscal_year" oils_persist:tablename="acq.fiscal_year" reporter:label="Fiscal Year">
+               <fields oils_persist:primary="id" oils_persist:sequence="acq.fiscal_year_id_seq">
+                       <field reporter:label="Fiscal Year ID" name="id" reporter:datatype="id" reporter:selector='id'/>
+                       <field reporter:label="Calendar" name="calendar" reporter:datatype="link"/>
+                       <field reporter:label="Fiscal Year" name="year" reporter:datatype="int"/>
+                       <field reporter:label="Year Begin" name="year_begin" reporter:datatype="timestamp"/>
+                       <field reporter:label="Year End" name="year_end" reporter:datatype="timestamp"/>
+               </fields>
+               <links>
+                       <link field="calendar" reltype="has_a" key="id" map="" class="acqfc"/>
+               </links>
+               <!--
+                       For now, we don't have pcrud as one of the controllers, so the permacrud section is moot.
+                       But here's what it should look like if we ever do use pcrud.
+               -->
+               <permacrud xmlns="http://open-ils.org/spec/opensrf/IDL/permacrud/v1">
+                       <actions>
+                               <create permission="ADMIN_ACQ_FISCAL_YEAR" global_required="true"/>
+                               <retrieve permission="ADMIN_ACQ_FISCAL_YEAR" global_required="true"/>
+                               <update permission="ADMIN_ACQ_FISCAL_YEAR" global_required="true"/>
+                               <delete permission="ADMIN_ACQ_FISCAL_YEAR" global_required="true"/>
+                       </actions>
+               </permacrud>
+       </class>
+
        <class id="acqfs" controller="open-ils.cstore open-ils.reporter-store open-ils.pcrud" oils_obj:fieldmapper="acq::funding_source" oils_persist:tablename="acq.funding_source" reporter:label="Funding Source">
                <fields oils_persist:primary="id" oils_persist:sequence="acq.funding_source_id_seq">
                        <field reporter:label="Funding Source ID" name="id" reporter:datatype="id" reporter:selector='code'/>
index 131347d..80c20cf 100644 (file)
@@ -413,6 +413,24 @@ CREATE TABLE acq.fund_tag_map (
        CONSTRAINT acqftm_fund_once_per_tag UNIQUE( fund, tag )
 );
 
+CREATE TABLE acq.fiscal_calendar (
+       id              SERIAL         PRIMARY KEY,
+       name            TEXT           NOT NULL
+);
+
+CREATE TABLE acq.fiscal_year (
+       id              SERIAL         PRIMARY KEY,
+       calendar        INT            NOT NULL
+                                      REFERENCES acq.fiscal_calendar
+                                      ON DELETE CASCADE
+                                      DEFERRABLE INITIALLY DEFERRED,
+       year            INT            NOT NULL,
+       year_begin      TIMESTAMPTZ    NOT NULL,
+       year_end        TIMESTAMPTZ    NOT NULL,
+       CONSTRAINT acq_fy_logical_key  UNIQUE ( calendar, year ),
+    CONSTRAINT acq_fy_physical_key UNIQUE ( calendar, year_begin )
+);
+
 -- Functions
 
 CREATE TYPE acq.flat_lineitem_holding_subfield AS (lineitem int, holding int, subfield text, data text);
@@ -599,6 +617,73 @@ CREATE OR REPLACE FUNCTION acq.exchange_ratio ( TEXT, TEXT, NUMERIC ) RETURNS NU
     SELECT $3 * acq.exchange_ratio($1, $2);
 $$ LANGUAGE SQL;
 
+CREATE OR REPLACE FUNCTION acq.find_bad_fy()
+/*
+       Examine the acq.fiscal_year table, comparing successive years.
+       Report any inconsistencies, i.e. years that overlap, have gaps
+    between them, or are out of sequence.
+*/
+RETURNS SETOF RECORD AS $$
+DECLARE
+       first_row  BOOLEAN;
+       curr_year  RECORD;
+       prev_year  RECORD;
+       return_rec RECORD;
+BEGIN
+       first_row := true;
+       FOR curr_year in
+               SELECT
+                       id,
+                       calendar,
+                       year,
+                       year_begin,
+                       year_end
+               FROM
+                       acq.fiscal_year
+               ORDER BY
+                       calendar,
+                       year_begin
+       LOOP
+               --
+               IF first_row THEN
+                       first_row := FALSE;
+               ELSIF curr_year.calendar    = prev_year.calendar THEN
+                       IF curr_year.year_begin > prev_year.year_end THEN
+                               -- This ugly kludge works around the fact that older
+                               -- versions of PostgreSQL don't support RETURN QUERY SELECT
+                               FOR return_rec IN SELECT
+                                       prev_year.id,
+                                       prev_year.year,
+                                       'Gap between fiscal years'::TEXT
+                               LOOP
+                                       RETURN NEXT return_rec;
+                               END LOOP;
+                       ELSIF curr_year.year_begin < prev_year.year_end THEN
+                               FOR return_rec IN SELECT
+                                       prev_year.id,
+                                       prev_year.year,
+                                       'Overlapping fiscal years'::TEXT
+                               LOOP
+                                       RETURN NEXT return_rec;
+                               END LOOP;
+                       ELSIF curr_year.year < prev_year.year THEN
+                               FOR return_rec IN SELECT
+                                       prev_year.id,
+                                       prev_year.year,
+                                       'Fiscal years out of order'::TEXT
+                               LOOP
+                                       RETURN NEXT return_rec;
+                               END LOOP;
+                       END IF;
+               END IF;
+               --
+               prev_year := curr_year;
+       END LOOP;
+       --
+       RETURN;
+END;
+$$ LANGUAGE plpgsql;
+
 CREATE OR REPLACE VIEW acq.funding_source_credit_total AS
     SELECT  funding_source,
             SUM(amount) AS amount