Skip to content
Snippets Groups Projects
Commit 003e81c4 authored by Andy Yates's avatar Andy Yates
Browse files

Making sure that the views are defined with security set to the invoker and not the definer

parent 7700373c
No related branches found
No related tags found
No related merge requests found
......@@ -25,6 +25,30 @@ CREATE TABLE species (
UNIQUE INDEX db_name_idx (db_name)
);
-- The 'species_alias' table
-- Lists all aliases for all species including those no longer active
CREATE TABLE species_alias (
species_alias_id INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, -- surrogate key
species_id INTEGER UNSIGNED NOT NULL, -- FK into species
alias varchar(255) NOT NULL, -- alias
is_current BOOLEAN NOT NULL DEFAULT true, -- if it's still current
-- Columns for the web interface:
created_by INTEGER,
created_at DATETIME,
modified_by INTEGER,
modified_at DATETIME,
PRIMARY KEY (species_alias_id),
UNIQUE INDEX (alias, is_current), -- aliases MUST be unique for
-- the current set. A certain
-- amount of duplication is
-- allowed if an alias moved
-- once
INDEX sa_speciesid_idx (species_id)
);
-- The 'db' table.
-- This table contains all species-specific databases for this release.
......@@ -170,7 +194,7 @@ CREATE TABLE web_data (
-- The 'db_list' view provides the full database names for all databases
-- in the 'db' table that are current.
CREATE VIEW db_list AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW db_list AS
SELECT db_id AS db_id,
CONCAT(
CONCAT_WS('_', db_name, db_type, db_release, db_assembly),
......@@ -183,7 +207,7 @@ WHERE species.is_current = true;
-- /nearly/ exactly what should go into the 'analysis_description'
-- table, apart from the fact that it uses 'analysis.logic_name' rather
-- than 'analysis.analysis_id'.
CREATE VIEW full_analysis_description AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW full_analysis_description AS
SELECT list.full_db_name AS full_db_name,
ad.logic_name AS logic_name,
ad.description AS description,
......@@ -203,7 +227,7 @@ WHERE db.is_current = true
-- The 'logic_name_overview' is a helper view for people trying to
-- make sense of the 'analysis_description', 'analysis_web_data', and
-- 'web_data' tables.
CREATE VIEW logic_name_overview AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW logic_name_overview AS
SELECT
awd.analysis_web_data_id AS analysis_web_data_id,
ad.logic_name AS logic_name,
......@@ -222,7 +246,7 @@ WHERE s.is_current = true
-- The 'unconnected_analyses' view gives back the analyses from
-- 'analysis_description' that are unused in 'analysis_web_data'.
CREATE VIEW unconnected_analyses AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW unconnected_analyses AS
SELECT ad.analysis_description_id AS analysis_description_id,
ad.logic_name AS logic_name
FROM analysis_description ad
......@@ -232,7 +256,7 @@ WHERE awd.species_id IS NULL
-- The 'unused_web_data' view gives back the entries in 'web_data' that
-- are not connected to any analysis in 'analysis_web_data'.
CREATE VIEW unused_web_data AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW unused_web_data AS
SELECT wd.web_data_id
FROM web_data wd
LEFT JOIN analysis_web_data awd USING (web_data_id)
......@@ -243,7 +267,7 @@ WHERE awd.analysis_web_data_id IS NULL;
-- the entries from the corresponding master table that have is_current
-- set to true.
CREATE VIEW attrib_type AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW attrib_type AS
SELECT
attrib_type_id AS attrib_type_id,
code AS code,
......@@ -253,7 +277,7 @@ FROM master_attrib_type
WHERE is_current = true
ORDER BY attrib_type_id;
CREATE VIEW external_db AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW external_db AS
SELECT
external_db_id AS external_db_id,
db_name AS db_name,
......@@ -269,7 +293,7 @@ FROM master_external_db
WHERE is_current = true
ORDER BY external_db_id;
CREATE VIEW misc_set AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW misc_set AS
SELECT
misc_set_id AS misc_set_id,
code AS code,
......@@ -280,7 +304,7 @@ FROM master_misc_set
WHERE is_current = true
ORDER BY misc_set_id;
CREATE VIEW unmapped_reason AS
CREATE DEFINER = CURRENT_USER SQL SECURITY INVOKER VIEW unmapped_reason AS
SELECT
unmapped_reason_id AS unmapped_reason_id,
summary_description AS summary_description,
......
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment