Skip to content

Commit

Permalink
Merge pull request #576 from jberkus/master
Browse files Browse the repository at this point in the history
9.0 SQL database changes.
  • Loading branch information
jberkus committed May 9, 2012
2 parents 8b9c61f + a18f268 commit 3541570
Show file tree
Hide file tree
Showing 9 changed files with 385 additions and 3 deletions.
96 changes: 96 additions & 0 deletions docs/databaseadminfunctions.rst
Original file line number Diff line number Diff line change
Expand Up @@ -391,6 +391,48 @@ it allows you to rerun the script multiple times without erroring out.
However, be aware that it only checks for the existance of the table, not
its definition, so if you modify the table definition you'll need to
manually drop and recreate it.

add_column_if_not_exists
------------------------

Purpose: allow idempotent addition of new columns to existing tables.

Called by: upgrade scripts

::

add_column_if_not_exists (
tablename text,
columnname text,
datatype text,
nonnull boolean default false,
defaultval text default '',
constrainttext text default ''
) returns boolean
SELECT add_column_if_not_exists (
'product_version_builds','repository','citext' );
tablename
name of the existing table to which to add the column
columname
name of the new column to add
datatype
data type of the new column to add
nonnull
is the column NOT NULL? defaults to false. must have a default
parameter if notnull.
defaultval
default value for the column. this will cause the table to
be rewritten if set; beware of using on large tables.
constrainttext
any constraint, including foreign keys, to be added to the
column, written as a table constraint. will cause the whole
table to be checked; beware of adding to large tables.

Note: just checks if the table & column exist, and does nothing if they do.
does not check if data type, constraints and defaults match.


Other Administrative Functions
==============================
Expand Down Expand Up @@ -418,6 +460,60 @@ Called By: on demand by Firefox or Camino teams.
Notes: if this leads to more than 4 currently featured versions, the oldest
featured vesion will be "bumped".

add_new_release
---------------

Purpose: allows admin users to manually add a release to the
releases_raw table.

Called By: admin interface

::

add_new_release (
product citext,
version citext,
release_channel citext,
build_id numeric,
platform citext,
beta_number integer default NULL,
repository text default 'release',
update_products boolean default false
) returns BOOLEAN
SELECT add_new_release('Camino','5.0','release',201206271111,'osx');
SELECT add_new_release('Camino','6.0','beta',201206271198,'osx',2,
'camino-beta',true);
Notes: validates the contents of the required fields. If update_products=true, will run the update_products hourly job to process the new release into product_versions etc.

edit_featured_versions
----------------------

Purpose: let admin users change the featured versions for a specific product.

Called By: admin interface

::

edit_featured_versions (
product citext,
featured_versions LIST of text
) returns BOOLEAN
SELECT edit_featured_versions ( 'Firefox', '15.0a1','14.0a2','13.0b2','12.0' );
SELECT edit_featured_versions ( 'SeaMonkey', '2.9.' );
Notes: completely replaces the list of currently featured versions. Will check that versions featured have not expired. Does not validate product names or version numbers, though.












Expand Down
31 changes: 31 additions & 0 deletions docs/databasemiscfunctions.rst
Original file line number Diff line number Diff line change
Expand Up @@ -70,7 +70,38 @@ Takes a product name and a list of version_strings, and returns an array (list)
SELECT * FROM reports_clean WHERE date_processed BETWEEN '2012-03-21' AND '2012-03-38'
WHERE product_version_id = ANY ( $list );
Internal Functions
==================

These functions are designed to be called by other functions, so are sparsely documented.

nonzero_string
--------------

::

nonzero_string (
TEXT or CITEXT
) returns boolean
Returns FALSE if the string consists of '', only spaces, or NULL. True otherwise.

validate_lookup
---------------

::

validate_lookup (
ltable TEXT, -- lookup table name
lcol TEXT, -- lookup column name
lval TEXT, -- value to look up
lmessage TEXT -- name of the entity in error messages
) returns boolean
Returns TRUE if the value is present in the named lookup table. Raises a custom ERROR if it's not present.






Expand Down
28 changes: 28 additions & 0 deletions sql/roles.sql
Original file line number Diff line number Diff line change
Expand Up @@ -38,3 +38,31 @@ END LOOP;

END;$d$;

-- analyst role, for read-only connections by analytics users
ALTER ROLE analyst CONNECTION LIMIT 10;
ALTER ROLE analyst SET statement_timeout TO '15min';
ALTER ROLE analyst SET work_mem TO '128MB';
ALTER ROLE analyst SET temp_buffers TO '128MB';

-- breakpad group and RW and RO users
-- these are our main users
ALTER ROLE breakpad WITH NOLOGIN;
GRANT breakpad TO breakpad_ro GRANTED BY postgres;
GRANT breakpad TO breakpad_rw GRANTED BY postgres;

-- breakpad_metrics user for nightly batch updates from metrics
GRANT breakpad TO breakpad_metrics GRANTED BY postgres;

-- monitor and processor roles for data processing
GRANT breakpad_rw TO processor GRANTED BY postgres;
GRANT breakpad_rw TO monitor GRANTED BY postgres;
GRANT processor TO monitor GRANTED BY postgres;

-- monitoring group and separate users for ganglia and nagios
ALTER ROLE monitoring WITH NOLOGIN;
GRANT monitoring TO ganglia GRANTED BY postgres;
GRANT monitoring TO nagiosdaemon GRANTED BY postgres;

-- replicator role for replication
ALTER ROLE replicator WITH SUPERUSER;

7 changes: 6 additions & 1 deletion sql/upgrade/9.0/README.rst
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,12 @@
This batch makes the following database changes:

bug #748194
Restrict product_version_builds to primary repositories.
Restrict product_version_builds to primary repositories.

bug #752074
Add new functions for adding a manual release to releases_raw,
and changing the featured versions.

...

The above changes should take only a few minutes to deploy.
Expand Down
66 changes: 66 additions & 0 deletions sql/upgrade/9.0/add_release.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,66 @@
\set ON_ERROR_STOP 1

CREATE OR REPLACE FUNCTION add_new_release (
product citext,
version citext,
release_channel citext,
build_id numeric,
platform citext,
beta_number integer default NULL,
repository text default 'release',
update_products boolean default false
)
RETURNS boolean
LANGUAGE plpgsql
AS $f$
BEGIN
-- adds a new release to the releases_raw table
-- to be picked up by update_products later
-- does some light format validation

-- check for NULLs, blanks
IF NOT ( nonzero_string(product) AND nonzero_string(version)
AND nonzero_string(release_channel) and nonzero_string(platform)
AND build_id IS NOT NULL ) THEN
RAISE EXCEPTION 'product, version, release_channel, platform and build ID are all required';
END IF;

--validations
-- validate product
SELECT validate_lookup('products','product_name',product,'product');
--validate channel
SELECT validate_lookup('release_channels','release_channel',release_channel,'release channel');
--validate build
IF NOT ( build_date(build_id) BETWEEN '2005-01-01'
AND (current_date + '1 month') ) THEN
RAISE EXCEPTION 'invalid buildid';
END IF;

--add row
--duplicate check will occur in the EXECEPTION section
INSERT INTO releases_raw (
product_name, version, platform, build_id,
build_type, beta_number, repository )
VALUES ( product, version, platform, build_id,
release_channel, beta_number, repository );

--call update_products, if desired
IF update_products THEN
SELECT update_product_versions();
END IF;

--return
RETURN TRUE;

--exception clause, mainly catches duplicate rows.
EXCEPTION
WHEN UNIQUE_VIOLATION THEN
RAISE EXCEPTION 'the release you have entered is already present in he database';
END;$f$;







40 changes: 40 additions & 0 deletions sql/upgrade/9.0/feature_versions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,40 @@
\set ON_ERROR_STOP 1

CREATE OR REPLACE FUNCTION edit_featured_versions (
product citext,
VARIADIC featured_versions text
)
RETURNS boolean
LANGUAGE plpgsql
AS $f$
-- this function allows admins to change the featured versions
-- for a particular product
BEGIN

--check required parameters
IF NOT ( nonzero_string(product) AND nonzero_string(featured_versions[1]) ) THEN
RAISE EXCEPTION 'a product name and at least one version are required';
END IF;

--check that all versions are not expired
SELECT 1 FROM product_verstions
WHERE product_name = product
AND version_string = ANY ( featured_versions )
AND sunset_date < current_date;
IF FOUND THEN
RAISE EXCEPTION 'one or more of the versions you have selected is already expired';
END IF;

--Remove disfeatured versions
UPDATE product_versions SET featured_version = false
WHERE featured_version
AND NOT ( version_string = ANY( featured_versions ) );

--feature new versions
UPDATE product_versions SET featured_version = true
WHERE version_string = ANY ( featured_versions )
AND NOT featured_version;

RETURN TRUE;

END;$f$;
Loading

0 comments on commit 3541570

Please sign in to comment.