--- /dev/null
+BEGIN;
+
+CREATE OR REPLACE FUNCTION evergreen.find_matching_fields (re TEXT, f_re TEXT) RETURNS TABLE (find_matching_fields TEXT) LANGUAGE PLPGSQL AS $F$
+DECLARE
+ S TEXT;
+ T TEXT;
+ F TEXT;
+ P TEXT;
+BEGIN
+
+ FOR S,T,F IN SELECT table_schema, table_name, column_name FROM information_schema.columns WHERE column_name LIKE f_re LOOP
+ -- RETURN QUERY EXECUTE $$ select 'Checking table $$ || S || '.' || T || $$...'::text$$;
+ SELECT column_name INTO P FROM information_schema.key_column_usage WHERE table_schema = S AND table_name = T AND constraint_name like '%_pkey';
+ IF P IS NOT NULL THEN
+ RETURN QUERY EXECUTE $$ select '!!! Field $$ || F || $$ on $$ || S || '.' || T || $$ with $$ || P || $$ = ' || $$ || P || $$ || ': ' || $$ || F || $$ from $$ || S || '.' || T || $$ where $$ || F || $$ ~ '$$ || re || $$' $$;
+ ELSE
+ RETURN QUERY EXECUTE $$ select '!!! Field $$ || F || $$ on $$ || S || '.' || T || $$: ' || $$ || F || $$ from $$ || S || '.' || T || $$ where $$ || F || $$ ~ '$$ || re || $$' $$;
+ END IF;
+ END LOOP;
+
+END;
+$F$;
+
+CREATE OR REPLACE FUNCTION evergreen.find_matching_xpath (re TEXT) RETURNS TABLE (find_matching_xpath TEXT) LANGUAGE SQL AS $F$
+ SELECT evergreen.find_matching_fields(re,'%xpath%');
+$F$;
+
+CREATE OR REPLACE FUNCTION evergreen.find_content_mode_xpath () RETURNS TABLE (find_content_mode_xpath TEXT) LANGUAGE SQL AS $F$
+ SELECT evergreen.find_matching_xpath('(?:^\(?|\|)[.*]');
+$F$;
+
+COMMENT ON FUNCTION evergreen.find_content_mode_xpath () IS $$
+/**
+
+This function will look at all fields in an Evergreen database with
+"xpath" in their name and identify those that use an idiom valid
+in CONTENT mode, used internally in XSLT, but which is invalid in
+DOCUMENT mode, the mode used in SQL/XML. These are typically
+expressions that begin with "." or "*", which assumes there is no
+difference between the root node and the document node. Any such
+XPath expressions will need to be adjusted, often simply by adding
+"//" before "*", or replacing "./" with "//".
+
+**/
+$$;
+
+CREATE OR REPLACE FUNCTION evergreen.find_simple_xpath () RETURNS TABLE (find_content_mode_xpath TEXT) LANGUAGE SQL AS $F$
+ SELECT evergreen.find_matching_xpath('(^|//)[^/]*\*\[\s*(?!local-name)[^/]+@[^/]+$');
+$F$;
+
+COMMENT ON FUNCTION evergreen.find_simple_xpath () IS $$
+/**
+
+This function will look at all fields in an Evergreen database with
+"xpath" in their name and identify those that seemt to be overly
+simple, which can lead to duplicated content. It looks for expressions
+that have just one node level, start with an "all nodes" test, use at
+least one attribute test, and do not use the local-name() function as
+the first node test.
+
+This heuristic is far from perfect, but should identify cases where
+more specificity would be beneficial.
+
+**/
+$$;
+
+COMMIT;
+
+SELECT evergreen.find_content_mode_xpath();
+SELECT evergreen.find_simple_xpath();
+