--- /dev/null
+PROPER ROLE PERMISSIONS
+SEE extensions: Open-ILS/src/sql/Pg/create_database_extensions.sql
+pg>
+ \c 'user=postgres dbname=test'
+ create role duh;
+ REASSIGN OWNED BY stest TO duh;
+ DROP OWNED BY stest;
+ drop role stest;
+ \c postgres
+ REASSIGN OWNED BY stest TO duh;
+ DROP OWNED BY stest;
+ drop role stest;
+ drop role duh;
+ \du
+
+ \c postgres;
+ drop database test;
+ create user stest nosuperuser login;
+ grant all on schema public to stest;
+ \password stest
+
+ CREATE DATABASE test TEMPLATE template0 ENCODING 'UNICODE' LC_COLLATE 'C' LC_CTYPE 'C';
+ \c test
+ CREATE LANGUAGE plperlu;
+ CREATE EXTENSION xml2;
+ CREATE EXTENSION hstore;
+ CREATE EXTENSION intarray;
+ CREATE EXTENSION pgcrypto;
+ CREATE EXTENSION unaccent;
+
+ GRANT CONNECT ON DATABASE test TO stest;
+ GRANT ALL ON schema public to stest;
+ ALTER USER stest set default_transaction_read_only = on;
+ select * FROM pg_roles WHERE rolname = 'stest';
+ rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolreplication | rolconnlimit | rolpassword | rolvaliduntil | rolbypassrls | rolconfig | oid
+ ---------+----------+------------+---------------+-------------+-------------+----------------+--------------+-------------+---------------+--------------+------------------------------------+----------
+ stest | t | t | f | f | t | f | -1 | ******** | | f | {default_transaction_read_only=on} | 34156734
+
+
+# cd ~opensrf/repos/Evergreen
+# perl Open-ILS/src/support-scripts/eg_db_config \
+ --service all --create-schema \
+ --user nc --password blabla --hostname 127.0.0.1 --port 5432 \
+ --database test --admin-user admin --admin-pass demo123 \
+ --load-all-sample
+
+pg>
+ \c 'user=postgres dbname=test'
+ \c 'user=postgres dbname=nc'
+ DO $do$
+ DECLARE
+ sch text;
+ tbl text;
+ BEGIN
+ FOR sch IN SELECT nspname FROM pg_namespace where nspname != 'information_schema' and nspname !~* 'pg_' order by 1
+ LOOP
+ EXECUTE format($$ GRANT ALL ON SCHEMA %I TO stest $$, sch);
+ FOR tbl IN SELECT tablename FROM pg_tables WHERE schemaname = sch order by 1 LOOP
+ RAISE NOTICE 'ENABLE RLS FOR TABLE %.%', sch, tbl;
+ EXECUTE format($$ GRANT ALL ON TABLE %I.%I TO stest $$, sch, tbl);
+ EXECUTE format($$ ALTER TABLE %I.%I ENABLE ROW LEVEL SECURITY $$, sch, tbl);
+ END LOOP;
+ EXECUTE format($$ GRANT SELECT ON ALL SEQUENCES IN SCHEMA %I TO stest $$, sch);
+ EXECUTE format($$ ALTER DEFAULT PRIVILEGES IN SCHEMA %I GRANT ALL ON TABLES TO stest $$, sch);
+ END LOOP;
+ END;
+ $do$;
+
+pg>
+ set role postgres;
+
+ CREATE POLICY rls_acorun ON actor.org_unit TO stest USING (true);
+ --DROP POLICY rls_acorun ON actor.org_unit;
+ \dp actor.org_unit
+
+ CREATE POLICY rls_pegrtr ON permission.grp_tree TO stest USING (true);
+ --DROP POLICY rls_pegrtr ON permission.grp_tree;
+ \dp permission.grp_tree
+
+ CREATE POLICY rls_ascolo ON asset.copy_location TO stest USING (deleted = 'f');
+ --DROP POLICY rls_ascolo ON asset.copy_location;
+ \dp asset.copy_location
+
+ CREATE POLICY rls_acus ON actor.usr TO stest USING (deleted = 'f' and (id = 1 or id < 300 or (id % 3 = 0 and profile in (select id from permission.grp_descendants(3))) or (id % 2000 = 0 and profile in (select id from permission.grp_descendants(2))))); --keep admin and staff accounts too.
+ --DROP POLICY rls_acus ON actor.usr;
+ \dp actor.usr
+
+ CREATE POLICY rls_bireen ON biblio.record_entry TO stest USING ((((id < 200 or id % 17 = 0) and deleted = 'f') or (id < 10 and id > -10 and deleted = 't')) and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_bireen ON biblio.record_entry;
+ \dp biblio.record_entry
+
+ CREATE POLICY rls_bimopa ON biblio.monograph_part TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_bimopa ON biblio.monograph_part;
+ \dp biblio.monograph_part
+
+ CREATE POLICY rls_bipety ON biblio.peer_type TO stest USING (true);
+ --DROP POLICY rls_bipety ON biblio.peer_type;
+ \dp biblio.peer_type
+
+ CREATE POLICY rls_bipebicoma ON biblio.peer_bib_copy_map TO stest USING (peer_record in(select id from biblio.record_entry) and peer_type in(select id from biblio.peer_type));
+ --DROP POLICY rls_bipebicoma ON biblio.peer_bib_copy_map;
+ \dp biblio.peer_bib_copy_map
+
+ CREATE POLICY rls_bireno ON biblio.record_note TO stest USING (creator in(select id from actor.usr) and editor in(select id from actor.usr) and record in(select id from biblio.record_entry));
+ --DROP POLICY rls_bireno ON biblio.record_note;
+ \dp biblio.record_note
+
+ CREATE POLICY rls_ascanu ON asset.call_number TO stest USING (((deleted = 't' and creator = 1 and id < 100) or (deleted = 'f')) and record in(select id from biblio.record_entry) and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_ascanu ON asset.call_number;
+ \dp asset.call_number;
+
+ CREATE POLICY rls_asco ON asset.copy TO stest USING (((deleted = 't' and id % 60 = 0) or (deleted = 'f')) and call_number in(select id from asset.call_number) and location in(select id from asset.copy_location) and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_asco ON asset.copy;
+ \dp asset.copy
+
+ CREATE POLICY rls_ascoal ON asset.copy_alert TO stest USING (copy in(select id from asset.copy) and ack_staff in(select id from actor.usr) and create_staff in(select id from actor.usr));
+ --DROP POLICY rls_ascoal ON asset.copy_alert;
+ \dp asset.copy_alert
+
+ CREATE POLICY rls_ascono ON asset.copy_note TO stest USING ((id < 10 or id % 8 = 0) and extract(year from create_date) >= extract(year from now())-1 and owning_copy in(select id from asset.copy) and creator in(select id from actor.usr));
+ --DROP POLICY rls_ascono ON asset.copy_note;
+ \dp asset.copy_note
+
+ CREATE POLICY rls_ascopama ON asset.copy_part_map TO stest USING (part in(select id from biblio.monograph_part) and target_copy in(select id from asset.copy));
+ --DROP POLICY rls_ascopama ON asset.copy_part_map;
+ \dp asset.copy_part_map
+
+ CREATE POLICY rls_ascote ON asset.copy_template TO stest USING (creator in(select id from actor.usr) and editor in(select id from actor.usr) and location in(select id from asset.copy_location));
+ --DROP POLICY rls_ascote ON asset.copy_template;
+ \dp asset.copy_template
+
+ CREATE POLICY rls_ascoviatca ON asset.copy_vis_attr_cache TO stest USING (record in(select id from biblio.record_entry) and target_copy in(select id from asset.copy));
+ --DROP POLICY rls_ascoviatca ON asset.copy_vis_attr_cache;
+ \dp asset.copy_vis_attr_cache
+
+ CREATE POLICY rls_acci ON action.circulation TO stest USING ((xact_finish is null or xact_finish > (select 'now'::date-'3 months'::interval)) and usr in(select id from actor.usr) and copy_location in(select id from asset.copy_location) and target_copy in(select id from asset.copy));
+ --DROP POLICY rls_acci ON action.circulation;
+ \dp action.circulation
+
+ CREATE POLICY rls_accare ON acq.cancel_reason TO stest USING (true);
+ --DROP POLICY rls_accare ON acq.cancel_reason;
+ \dp acq.cancel_reason
+
+ CREATE POLICY rls_accuty ON acq.currency_type TO stest USING (true);
+ --DROP POLICY rls_accuty ON acq.currency_type;
+ \dp acq.currency_type
+
+ CREATE POLICY rls_acedat ON acq.edi_attr TO stest USING (true);
+ --DROP POLICY rls_acedat ON acq.edi_attr;
+ \dp acq.edi_attr
+
+ CREATE POLICY rls_acedatse ON acq.edi_attr_set TO stest USING (true);
+ --DROP POLICY rls_acedatse ON acq.edi_attr_set;
+ \dp acq.edi_attr_set
+
+ CREATE POLICY rls_acedatsema ON acq.edi_attr_set_map TO stest USING (true);
+ --DROP POLICY rls_acedatsema ON acq.edi_attr_set_map;
+ \dp acq.edi_attr_set_map
+
+ CREATE POLICY rls_acexra ON acq.exchange_rate TO stest USING (true);
+ --DROP POLICY rls_acexra ON acq.exchange_rate;;
+ \dp acq.exchange_rate
+
+ CREATE POLICY rls_acfica ON acq.fiscal_calendar TO stest USING (true);
+ --DROP POLICY rls_acfica ON acq.fiscal_calendar;
+ \dp acq.fiscal_calendar
+
+ CREATE POLICY rls_acfu ON acq.fund TO stest USING (year = date_part('year'::text, now()));
+ --DROP POLICY rls_acfu ON acq.fund;
+ \dp acq.fund
+
+ CREATE POLICY rls_acfual ON acq.fund_allocation TO stest USING ((id < 10 or id % 2 = 0) and extract(year from create_time) >= extract(year from now())-1 and fund in(select id from acq.fund) and allocator in(select id from actor.usr));
+ --DROP POLICY rls_acfual ON acq.fund_allocation;
+ \dp acq.fund_allocation
+
+ CREATE POLICY rls_acfude ON acq.fund_debit TO stest USING ((id < 10 or id % 1000 = 0) and extract(year from create_time) >= extract(year from now())-1 and fund in(select id from acq.fund));
+ --DROP POLICY rls_acfude ON acq.fund_debit;
+ \dp acq.fund_debit
+
+ CREATE POLICY rls_acfuso ON acq.funding_source TO stest USING (true);
+ --DROP POLICY rls_acfuso ON acq.funding_source;
+ \dp acq.funding_source;
+
+ CREATE POLICY rls_achore ON action.hold_request TO stest USING (id % 2 = 0 and requestor in(select id from actor.usr) and usr in(select id from actor.usr));
+ --DROP POLICY rls_achore ON action.hold_request;
+ \dp action.hold_request
+
+ CREATE POLICY rls_achorecaca ON action.hold_request_cancel_cause TO stest USING (true);
+ --DROP POLICY rls_achorecaca ON action.hold_request_cancel_cause;
+ \dp action.hold_request_cancel_cause
+
+ CREATE POLICY rls_achoreno ON action.hold_request_note TO stest USING (hold in(select id from action.hold_request));
+ --DROP POLICY rls_achoreno ON action.hold_request_note;
+ \dp action.hold_request_note
+
+ CREATE POLICY rls_acsu ON action.survey TO stest USING (true);
+ --DROP POLICY rls_acsu ON action.survey;
+ \dp action.survey
+
+ CREATE POLICY rls_acsuan ON action.survey_answer TO stest USING (true);
+ --DROP POLICY rls_acsuan ON action.survey_answer;
+ \dp action.survey_answer
+
+ CREATE POLICY rls_acsuqu ON action.survey_question TO stest USING (true);
+ --DROP POLICY rls_acsuqu ON action.survey_question;
+ \dp action.survey_question
+
+ CREATE POLICY rls_acsure ON action.survey_response TO stest USING (true);
+ --DROP POLICY rls_acsure ON action.survey_response;
+ \dp action.survey_response
+
+ CREATE POLICY rls_actrcl ON action_trigger.cleanup TO stest USING (true);
+ --DROP POLICY rls_actrcl ON action_trigger.cleanup;
+ \dp action_trigger.cleanup
+
+ CREATE POLICY rls_actrco ON action_trigger.collector TO stest USING (true);
+ --DROP POLICY rls_actrco ON action_trigger.collector;
+ \dp action_trigger.collector
+
+ CREATE POLICY rls_actren ON action_trigger.environment TO stest USING (id % 6 = 0);
+ --DROP POLICY rls_actren ON action_trigger.environment;
+ \dp action_trigger.environment
+
+ CREATE POLICY rls_actrevde ON action_trigger.event_definition TO stest USING (true);
+ --DROP POLICY rls_actrevde ON action_trigger.event_definition
+ \dp action_trigger.event_definition
+
+ CREATE POLICY rls_actrevpa ON action_trigger.event_params TO stest USING (true);
+ --DROP POLICY rls_actrevpa ON action_trigger.event_params
+ \dp action_trigger.event_params
+
+ CREATE POLICY rls_actrho ON action_trigger.hook TO stest USING (true);
+ --DROP POLICY rls_actrho ON action_trigger.hook
+ \dp action_trigger.hook
+
+ CREATE POLICY rls_actrre ON action_trigger.reactor TO stest USING (true);
+ --DROP POLICY rls_actrre ON action_trigger.reactor;
+ \dp action_trigger.reactor
+
+ CREATE POLICY rls_actrva ON action_trigger.validator TO stest USING (true);
+ --DROP POLICY rls_actrva ON action_trigger.validator;
+ \dp action_trigger.validator
+
+ CREATE POLICY rls_acca ON actor.card TO stest USING (usr in(select id from actor.usr));
+ --DROP POLICY rls_acca ON actor.card;
+ \dp actor.card
+
+ CREATE POLICY rls_achoofop ON actor.hours_of_operation TO stest USING (true);
+ --DROP POLICY rls_achoofop ON actor.hours_of_operation;
+ \dp actor.hours_of_operation
+
+ CREATE POLICY rls_acorad ON actor.org_address TO stest USING (true);
+ --DROP POLICY rls_acorad ON actor.org_address;
+ \dp actor.org_address
+
+ CREATE POLICY rls_acorunpr ON actor.org_unit_proximity TO stest USING ((id < 20 and id % 2 = 0) or (id > 19 and id % 100 = 0));
+ --DROP POLICY rls_acorunpr ON actor.org_unit_proximity;
+ \dp actor.org_unit_proximity
+
+ CREATE POLICY rls_acorunse ON actor.org_unit_setting TO stest USING ((id < 20 and id % 2 = 0) or (id > 19 and id % 10 = 0));
+ --DROP POLICY rls_acorunse ON actor.org_unit_setting;
+ \dp actor.org_unit_setting
+
+ CREATE POLICY rls_acorunty ON actor.org_unit_type TO stest USING (true);
+ --DROP POLICY rls_acorunty ON actor.org_unit_type;
+ \dp actor.org_unit_type
+
+ CREATE POLICY rls_acpa ON actor.passwd TO stest USING (usr in(select id from actor.usr));
+ --DROP POLICY rls_acpa ON actor.passwd;
+ \dp actor.passwd
+
+ CREATE POLICY rls_acpaty ON actor.passwd_type TO stest USING (true);
+ --DROP POLICY rls_acpaty ON actor.passwd_type;
+ \dp actor.passwd_type
+
+ CREATE POLICY rls_acsefigr ON actor.search_filter_group TO stest USING (true);
+ --DROP POLICY rls_acsefigr ON actor.search_filter_group;
+ \dp actor.search_filter_group
+
+ CREATE POLICY rls_acsefigren ON actor.search_filter_group_entry TO stest USING (true);
+ --DROP POLICY rls_acsefigren ON actor.search_filter_group_entry;
+ \dp actor.search_filter_group_entry
+
+ CREATE POLICY rls_acsequ ON actor.search_query TO stest USING (true);
+ --DROP POLICY rls_acsequ ON actor.search_query;
+ \dp actor.search_query
+
+ CREATE POLICY rls_acstca ON actor.stat_cat TO stest USING (true);
+ --DROP POLICY rls_acstca ON actor.stat_cat;
+ \dp actor.stat_cat
+
+ CREATE POLICY rls_acstcaen ON actor.stat_cat_entry TO stest USING (id % 20 = 0);
+ --DROP POLICY rls_acstcaen ON actor.stat_cat_entry;
+ \dp actor.stat_cat_entry
+
+ CREATE POLICY rls_acstcaenusma ON actor.stat_cat_entry_usr_map TO stest USING (id % 20 = 0 and target_usr in(select id from actor.usr));
+ --DROP POLICY rls_acstcaenusma ON actor.stat_cat_entry_usr_map;
+ \dp actor.stat_cat_entry_usr_map
+
+ CREATE POLICY rls_acto ON actor.toolbar TO stest USING (true);
+ --DROP POLICY rls_acto ON actor.toolbar;
+ \dp actor.toolbar
+
+ CREATE POLICY rls_acusac ON actor.usr_activity TO stest USING (id < 21);
+ --DROP POLICY rls_acusac ON actor.usr_activity;
+ \dp actor.usr_activity
+
+ CREATE POLICY rls_acusad ON actor.usr_address TO stest USING (usr in(select id from actor.usr));
+ --DROP POLICY rls_acusad ON actor.usr_address;
+ \dp actor.usr_address
+
+ CREATE POLICY rls_acusme ON actor.usr_message TO stest USING (id % 20 = 0 and usr in(select id from actor.usr));
+ --DROP POLICY rls_acusme ON actor.usr_message;
+ \dp actor.usr_message
+
+ CREATE POLICY rls_acusno ON actor.usr_note TO stest USING (usr in(select id from actor.usr));
+ --DROP POLICY rls_acusno ON actor.usr_note;
+ \dp actor.usr_note
+
+ CREATE POLICY rls_acusse ON actor.usr_setting TO stest USING (usr in(select id from actor.usr));
+ --DROP POLICY rls_acusse ON actor.usr_setting;
+ \dp actor.usr_setting
+
+ CREATE POLICY rls_acusstpe ON actor.usr_standing_penalty TO stest USING (staff in(select id from actor.usr) and usr in(select id from actor.usr));
+ --DROP POLICY rls_acusstpe ON actor.usr_standing_penalty;
+ \dp actor.usr_standing_penalty
+
+ CREATE POLICY rls_acwo ON actor.workstation TO stest USING (id % 200 = 0);
+ --DROP POLICY rls_acwo ON actor.workstation;
+ \dp actor.workstation
+
+ CREATE POLICY rls_ascanucl ON asset.call_number_class TO stest USING (true);
+ --DROP POLICY rls_ascanucl ON asset.call_number_class;
+ \dp asset.call_number_class
+
+ CREATE POLICY rls_ascanupr ON asset.call_number_prefix TO stest USING (true);
+ --DROP POLICY rls_ascanupr ON asset.call_number_prefix;
+ \dp asset.call_number_prefix
+
+ CREATE POLICY rls_ascanusu ON asset.call_number_suffix TO stest USING (true);
+ --DROP POLICY rls_ascanusu ON asset.call_number_suffix;
+ \dp asset.call_number_suffix
+
+ CREATE POLICY rls_ascologr ON asset.copy_location_group TO stest USING (true);
+ --DROP POLICY rls_ascologr ON asset.copy_location_group;
+ \dp asset.copy_location_group
+
+ CREATE POLICY rls_ascologrma ON asset.copy_location_group_map TO stest USING (location in(select id from asset.copy_location));
+ --DROP POLICY rls_ascologrma ON asset.copy_location_group_map;
+ \dp asset.copy_location_group_map
+
+ CREATE POLICY rls_ascoloor ON asset.copy_location_order TO stest USING (location in(select id from asset.copy_location));
+ --DROP POLICY rls_ascoloor ON asset.copy_location_order;
+ \dp asset.copy_location_order
+
+ CREATE POLICY rls_ascota ON asset.copy_tag TO stest USING (true);
+ --DROP POLICY rls_ascota ON asset.copy_tag;
+ \dp asset.copy_tag
+
+ CREATE POLICY rls_ascotacoma ON asset.copy_tag_copy_map TO stest USING (copy in(select id from asset.copy));
+ --DROP POLICY rls_ascotacoma ON asset.copy_tag_copy_map;
+ \dp asset.copy_tag_copy_map
+
+ CREATE POLICY rls_asopvico ON asset.opac_visible_copies TO stest USING (copy_id in(select id from asset.copy) and record in(select id from biblio.record_entry));
+ --DROP POLICY rls_asopvico ON asset.opac_visible_copies;
+ \dp asset.opac_visible_copies
+
+ CREATE POLICY rls_asstca ON asset.stat_cat TO stest USING (true);
+ --DROP POLICY rls_asstca ON asset.stat_cat;
+ \dp asset.stat_cat
+
+ CREATE POLICY rls_asstcaen ON asset.stat_cat_entry TO stest USING (true);
+ --DROP POLICY rls_asstcaen ON asset.stat_cat_entry;
+ \dp asset.stat_cat_entry
+
+ CREATE POLICY rls_asstcaencoma ON asset.stat_cat_entry_copy_map TO stest USING (id % 100 = 0 and owning_copy in(select id from asset.copy));
+ --DROP POLICY rls_asstcaencoma ON asset.stat_cat_entry_copy_map;
+ \dp asset.stat_cat_entry_copy_map
+
+ CREATE POLICY rls_asur ON asset.uri TO stest USING (id < 20 or id % 1000 = 0);
+ --DROP POLICY rls_asur ON asset.uri;
+ \dp asset.uri
+
+ CREATE POLICY rls_asurcanuma ON asset.uri_call_number_map TO stest USING (call_number in(select id from asset.call_number) and uri in(select id from asset.uri));
+ --DROP POLICY rls_asurcanuma ON asset.uri_call_number_map;
+ \dp asset.uri_call_number_map
+
+ CREATE POLICY rls_auacorunhi ON auditor.actor_org_unit_history TO stest USING (audit_id < 20 or audit_id % 100 = 0);
+ --DROP POLICY rls_auacorunhi ON auditor.actor_org_unit_history;
+ \dp auditor.actor_org_unit_history
+
+ CREATE POLICY rls_auacushi ON auditor.actor_usr_history TO stest USING (id in(select id from actor.usr) and (audit_id < 200 or audit_id % 100 = 0));
+ --DROP POLICY rls_auacushi ON auditor.actor_usr_history;
+ \dp auditor.actor_usr_history
+
+ CREATE POLICY rls_auascanuhi ON auditor.asset_call_number_history TO stest USING ((audit_id < 200 or audit_id % 100 = 0) and id in(select id from asset.call_number) and record in(select id from biblio.record_entry) and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_auascanuhi ON auditor.asset_call_number_history;
+ \dp auditor.asset_call_number_history
+
+ CREATE POLICY rls_auascohi ON auditor.asset_copy_history TO stest USING ((audit_id < 200 or audit_id % 5000 = 0) and id in(select id from asset.copy) and call_number in(select id from asset.call_number) and location in (select id from asset.copy_location) and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_auascohi ON auditor.asset_copy_history;
+ \dp auditor.asset_copy_history
+
+ CREATE POLICY rls_aubireenhi ON auditor.biblio_record_entry_history TO stest USING ((audit_id < 200 or audit_id % 5000 = 0) and id in(select id from biblio.record_entry) and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_aubireenhi ON auditor.biblio_record_entry_history;
+ \dp auditor.biblio_record_entry_history
+
+ CREATE POLICY rls_seun ON serial.unit TO stest USING ((id < 200 or id % 5 = 0) and call_number in(select id from asset.call_number) and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_seun ON serial.unit;
+ \dp serial.unit
+
+ CREATE POLICY rls_auseunhi ON auditor.serial_unit_history TO stest USING ((audit_id < 200 or audit_id % 5000 = 0) and id in(select id from serial.unit) and call_number in(select id from asset.call_number) and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_auseunhi ON auditor.serial_unit_history;
+ \dp auditor.serial_unit_history
+
+ CREATE POLICY rls_aucose ON authority.control_set TO stest USING (true);
+ --DROP POLICY rls_aucose ON authority.control_set;
+ \dp authority.control_set
+
+ CREATE POLICY rls_auhefi ON authority.heading_field TO stest USING (true);
+ --DROP POLICY rls_auhefi ON authority.heading_field;
+ \dp authority.heading_field
+
+ CREATE POLICY rls_auhefinoma ON authority.heading_field_norm_map TO stest USING (true);
+ --DROP POLICY rls_auhefinoma ON authority.heading_field_norm_map;
+ \dp authority.heading_field_norm_map
+
+ CREATE POLICY rls_aucoseaufi ON authority.control_set_authority_field TO stest USING (true);
+ --DROP POLICY rls_aucoseaufi ON authority.control_set_authority_field;
+ \dp authority.control_set_authority_field
+
+ CREATE POLICY rls_aubrax ON authority.browse_axis TO stest USING (true);
+ --DROP POLICY rls_aubrax ON authority.browse_axis;
+ \dp authority.browse_axis
+
+ CREATE POLICY rls_aubraxaufima ON authority.browse_axis_authority_field_map TO stest USING (true);
+ --DROP POLICY rls_aubraxaufima ON authority.browse_axis_authority_field_map;
+ \dp authority.browse_axis_authority_field_map
+
+ CREATE POLICY rls_aucosebifi ON authority.control_set_bib_field TO stest USING (true);
+ --DROP POLICY rls_aucosebifi ON authority.control_set_bib_field;
+ \dp authority.control_set_bib_field
+
+ CREATE POLICY rls_aucosebifimefima ON authority.control_set_bib_field_metabib_field_map TO stest USING (true);
+ --DROP POLICY rls_aucosebifimefima ON authority.control_set_bib_field_metabib_field_map;
+ \dp authority.control_set_bib_field_metabib_field_map
+
+ CREATE POLICY rls_aureen ON authority.record_entry TO stest USING ((id < 200 or id % 17 = 0) and deleted = 'f' and creator in(select id from actor.usr) and editor in(select id from actor.usr));
+ --DROP POLICY rls_aureen ON authority.record_entry;
+ \dp authority.record_entry
+
+ CREATE POLICY rls_aureno ON authority.record_note TO stest USING (record in(select id from authority.record_entry));
+ --DROP POLICY rls_aureno ON authority.record_note;
+ \dp authority.record_note
+
+ CREATE POLICY rls_auli ON authority.authority_linking TO stest USING (source in(select id from authority.record_entry) and target in(select id from authority.record_entry));
+ --DROP POLICY rls_auli ON authority.authority_linking;
+ \dp authority.authority_linking
+
+ CREATE POLICY rls_aubili ON authority.bib_linking TO stest USING (authority in(select id from authority.record_entry) and bib in(select id from biblio.record_entry));
+ --DROP POLICY rls_aubili ON authority.bib_linking;
+ \dp authority.bib_linking
+
+ CREATE POLICY rls_aurede ON authority.rec_descriptor TO stest USING (record in(select id from authority.record_entry));
+ --DROP POLICY rls_aurede ON authority.rec_descriptor;
+ \dp authority.rec_descriptor
+
+ CREATE POLICY rls_vaauqu ON vandelay.authority_queue TO stest USING (true);
+ --DROP POLICY rls_vaauqu ON vandelay.authority_queue;
+ \dp vandelay.authority_queue
+
+ CREATE POLICY rls_vaimer ON vandelay.import_error TO stest USING (true);
+ --DROP POLICY rls_vaimer ON vandelay.import_error;
+ \dp vandelay.import_error
+
+ CREATE POLICY rls_vaquaure ON vandelay.queued_authority_record TO stest USING (import_error in(select code from vandelay.import_error) and imported_as in(select id from authority.record_entry) and queue in(select id from vandelay.authority_queue));
+ --DROP POLICY rls_vaquaure ON vandelay.queued_authority_record
+ \dp vandelay.queued_authority_record
+
+ CREATE POLICY rls_vaaumu ON vandelay.authority_match TO stest USING (eg_record in(select id from authority.record_entry) and queued_record in(select id from vandelay.queued_authority_record));
+ --DROP POLICY rls_vaauma ON vandelay.authority_match;
+ \dp vandelay.authority_match
+
+ CREATE POLICY rls_mebren ON metabib.browse_entry TO stest USING (true);
+ --DROP POLICY rls_mebren ON metabib.browse_entry;
+ \dp metabib.browse_entry
+
+ CREATE POLICY rls_mebrendema ON metabib.browse_entry_def_map TO stest USING (authority in(select id from authority.record_entry) and entry in(select id from metabib.browse_entry) and source in(select id from biblio.record_entry));
+ --DROP POLICY rls_mebrendema ON metabib.browse_entry_def_map;
+ \dp metabib.browse_entry_def_map
+
+ CREATE POLICY rls_ausihe ON authority.simple_heading TO stest USING (atag in(select id from authority.control_set_authority_field) and record in(select id from authority.record_entry));
+ --DROP POLICY rls_ausihe ON authority.simple_heading;
+ \dp authority.simple_heading
+
+ CREATE POLICY rls_mebrensihema ON metabib.browse_entry_simple_heading_map TO stest USING (entry in(select id from metabib.browse_entry) and simple_heading in(select id from authority.simple_heading));
+ --DROP POLICY rls_mebrensihema ON metabib.browse_entry_simple_heading_map;
+ \dp metabib.browse_entry_simple_heading_map
+
+ CREATE POLICY rls_aufure ON authority.full_rec TO stest USING (record in(select id from authority.record_entry where id = record));
+ --DROP POLICY rls_aufure ON authority.full_rec;
+ \dp authority.full_rec
+
+ CREATE POLICY rls_auth ON authority.thesaurus TO stest USING (control_set in(select id from authority.control_set));
+ --DROP POLICY rls_auth ON authority.thesaurus;
+ \dp authority.thesaurus
+
+ CREATE POLICY rls_borety ON booking.resource_type TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_borety ON booking.resource_type;
+ \dp booking.resource_type
+
+
+
+ RAISE NOTICE 'ADD RLS POLICY FOR TABLE %.%', sch, tbl;
+ pg>
+ \c 'user=postgres dbname=test'
+ \c 'user=postgres dbname=nc'
+ DO $do$
+ DECLARE
+ sch text;
+ tbl text;
+ BEGIN
+ FOR sch IN SELECT nspname FROM pg_namespace where nspname = 'config'
+ LOOP
+ FOR tbl IN SELECT tablename FROM pg_tables WHERE schemaname = sch order by 1 LOOP
+ RAISE NOTICE 'ADD RLS POLICY FOR TABLE %.%', sch, tbl;
+ EXECUTE format($$ CREATE POLICY rls_%I ON %I.%I TO stest USING (true) $$, tbl, sch, tbl);
+ END LOOP;
+ END LOOP;
+ END;
+ $do$;
+
+ DROP POLICY rls_circ_limit_set_copy_loc_map ON config.circ_limit_set_copy_loc_map;
+ CREATE POLICY rls_cocilisecoloma ON config.circ_limit_set_copy_loc_map TO stest USING (copy_loc in(select id from asset.copy_location));
+ \dp config.circ_limit_set_copy_loc_map
+
+ DROP POLICY rls_circ_matrix_matchpoint ON config.circ_matrix_matchpoint;
+ CREATE POLICY rls_cocimama ON config.circ_matrix_matchpoint TO stest USING (copy_location in(select id from asset.copy_location));
+ \dp config.circ_matrix_matchpoint
+
+ DROP POLICY rls_circ_matrix_limit_set_map ON config.circ_matrix_limit_set_map;
+ CREATE POLICY rls_cocimalisema ON config.circ_matrix_limit_set_map TO stest USING (matchpoint in(select id from config.circ_matrix_matchpoint));
+ \dp config.circ_matrix_limit_set_map
+
+ DROP POLICY rls_filter_dialog_filter_set ON config.filter_dialog_filter_set;
+ CREATE POLICY rls_cofidifise ON config.filter_dialog_filter_set TO stest USING (creator in(select id from actor.usr));
+ \dp config.filter_dialog_filter_set
+
+ CREATE POLICY rls_cobireenbuty ON container.biblio_record_entry_bucket_type TO stest USING (true);
+ --DROP POLICY rls_cobireenbuty ON container.biblio_record_entry_bucket_type;
+ \dp container.biblio_record_entry_bucket_type
+
+ CREATE POLICY rls_cobireenbu ON container.biblio_record_entry_bucket TO stest USING (id % 25 = 0 and btype in(select code from container.biblio_record_entry_bucket_type) and owner in(select id from actor.usr));
+ --DROP POLICY rls_cobireenbu ON container.biblio_record_entry_bucket;
+ \dp container.biblio_record_entry_bucket
+
+ CREATE POLICY rls_cobireenbuit ON container.biblio_record_entry_bucket_item TO stest USING (bucket in(select id from container.biblio_record_entry_bucket) and target_biblio_record_entry in(select id from biblio.record_entry));
+ --DROP POLICY rls_cobireenbuit ON container.biblio_record_entry_bucket_item;
+ \dp container.biblio_record_entry_bucket_item
+
+ CREATE POLICY rls_cobireenbuitno ON container.biblio_record_entry_bucket_item_note TO stest USING (item in(select id from container.biblio_record_entry_bucket_item));
+ --DROP POLICY rls_cobireenbuitno ON container.biblio_record_entry_bucket_item_note;
+ \dp container.biblio_record_entry_bucket_item_note
+
+ CREATE POLICY rls_cobireenbuno ON container.biblio_record_entry_bucket_note TO stest USING (bucket in(select id from container.biblio_record_entry_bucket));
+ --DROP POLICY rls_cobireenbuno ON container.biblio_record_entry_bucket_note;
+ \dp container.biblio_record_entry_bucket_note
+
+ CREATE POLICY rls_cocanubuty ON container.call_number_bucket_type TO stest USING (true);
+ --DROP POLICY rls_cocanubuty ON container.call_number_bucket_type;
+ \dp container.call_number_bucket_type
+
+ CREATE POLICY rls_cocanubu ON container.call_number_bucket TO stest USING (btype in(select code from container.call_number_bucket_type) and owner in(select id from actor.usr));
+ --DROP POLICY rls_cocanubu ON container.call_number_bucket;
+ \dp container.call_number_bucket
+
+ CREATE POLICY rls_cocanubuit ON container.call_number_bucket_item TO stest USING (bucket in(select id from container.call_number_bucket) and target_call_number in(select id from asset.call_number));
+ --DROP POLICY rls_cocanubuit ON container.call_number_bucket_item;
+ \dp container.call_number_bucket_item
+
+ CREATE POLICY rls_cocanubuitno ON container.call_number_bucket_item_note TO stest USING (item in(select id from container.call_number_bucket_item));
+ --DROP POLICY rls_cocanubuitno ON container.call_number_bucket_item_note;
+ \dp container.call_number_bucket_item_note
+
+ CREATE POLICY rls_cocanubuno ON container.call_number_bucket_note TO stest USING (bucket in(select id from container.call_number_bucket));
+ --DROP POLICY rls_cocanubuno ON container.call_number_bucket_note;
+ \dp container.call_number_bucket_note
+
+ CREATE POLICY rls_cocobuty ON container.copy_bucket_type TO stest USING (true);
+ --DROP POLICY rls_cocobuty ON container.copy_bucket_type;
+ \dp container.copy_bucket_type
+
+ CREATE POLICY rls_cocobu ON container.copy_bucket TO stest USING (id % 600 = 0 and btype in(select code from container.copy_bucket_type) and owner in(select id from actor.usr));
+ --DROP POLICY rls_cocobu ON container.copy_bucket;
+ \dp container.copy_bucket
+
+ CREATE POLICY rls_cocobuit ON container.copy_bucket_item TO stest USING (bucket in(select id from container.copy_bucket));
+ --DROP POLICY rls_cocobuit ON container.copy_bucket_item;
+ \dp container.copy_bucket_item
+
+ CREATE POLICY rls_cocobuitno ON container.copy_bucket_item_note TO stest USING (item in(select id from container.copy_bucket_item));
+ --DROP POLICY rls_cocobuitno ON container.copy_bucket_item_note;
+ \dp container.copy_bucket_item_note
+
+ CREATE POLICY rls_cocobuno ON container.copy_bucket_note TO stest USING (bucket in(select id from container.copy_bucket));
+ --DROP POLICY rls_cocobuno ON container.copy_bucket_note;
+ \dp container.copy_bucket_note
+
+ CREATE POLICY rls_cousbuty ON container.user_bucket_type TO stest USING (true);
+ --DROP POLICY rls_cousbuty ON container.user_bucket_type;
+ \dp container.user_bucket_type
+
+ CREATE POLICY rls_cousbu ON container.user_bucket TO stest USING (id % 25 = 0 and btype in(select code from container.user_bucket_type) and owner in(select id from actor.usr));
+ --DROP POLICY rls_cousbu ON container.user_bucket;
+ \dp container.user_bucket
+
+ CREATE POLICY rls_cousbuit ON container.user_bucket_item TO stest USING (bucket in(select id from container.user_bucket) and target_user in(select id from actor.usr));
+ --DROP POLICY rls_cousbuit ON container.user_bucket_item;
+ \dp container.user_bucket_item
+
+ CREATE POLICY rls_cousbuitno ON container.user_bucket_item_note TO stest USING (item in(select id from container.user_bucket_item));
+ --DROP POLICY rls_cousbuitno ON container.user_bucket_item_note;
+ \dp container.user_bucket_item_note
+
+ CREATE POLICY rls_cousbuno ON container.user_bucket_note TO stest USING (bucket in(select id from container.user_bucket));
+ --DROP POLICY rls_cousbuno ON container.user_bucket_note;
+ \dp container.user_bucket_note
+
+ CREATE POLICY rls_meaufien ON metabib.author_field_entry TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_meaufien ON metabib.author_field_entry;
+ \dp metabib.author_field_entry
+
+ CREATE POLICY rls_mecoaufien ON metabib.combined_author_field_entry TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_mecoaufien ON metabib.combined_author_field_entry;
+ \dp metabib.combined_author_field_entry
+
+ CREATE POLICY rls_mecoidfien ON metabib.combined_identifier_field_entry TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_mecoidfien ON metabib.combined_identifier_field_entry;
+ \dp metabib.combined_identifier_field_entry
+
+ CREATE POLICY rls_mecokefien ON metabib.combined_keyword_field_entry TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_mecokefien ON metabib.combined_keyword_field_entry;
+ \dp metabib.combined_keyword_field_entry
+
+ CREATE POLICY rls_mecosefien ON metabib.combined_series_field_entry TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_mecosefien ON metabib.combined_series_field_entry;
+ \dp metabib.combined_series_field_entry
+
+ CREATE POLICY rls_mecosufien ON metabib.combined_subject_field_entry TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_mecosufien ON metabib.combined_subject_field_entry;
+ \dp metabib.combined_subject_field_entry
+
+ CREATE POLICY rls_mecotifien ON metabib.combined_title_field_entry TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_mecotifien ON metabib.combined_title_field_entry;
+ \dp metabib.combined_title_field_entry
+
+ CREATE POLICY rls_medien ON metabib.display_entry TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_medien ON metabib.display_entry;
+ \dp metabib.display_entry
+
+ CREATE POLICY rls_mefaen ON metabib.facet_entry TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_mefaen ON metabib.facet_entry;
+ \dp metabib.facet_entry
+
+ CREATE POLICY rls_meidfien ON metabib.identifier_field_entry TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_meidfien ON metabib.identifier_field_entry;
+ \dp metabib.identifier_field_entry
+
+ CREATE POLICY rls_mekefien ON metabib.keyword_field_entry TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_mekefien ON metabib.keyword_field_entry;
+ \dp metabib.keyword_field_entry
+
+ CREATE POLICY rls_meme ON metabib.metarecord TO stest USING (master_record in(select id from biblio.record_entry));
+ --DROP POLICY rls_meme ON metabib.metarecord;
+ \dp metabib.metarecord
+
+ CREATE POLICY rls_memesoma ON metabib.metarecord_source_map TO stest USING (metarecord in(select id from metabib.metarecord) and source in(select id from biblio.record_entry));
+ --DROP POLICY rls_memesoma ON metabib.metarecord_source_map;
+ \dp metabib.metarecord_source_map
+
+ CREATE POLICY rls_merefure ON metabib.real_full_rec TO stest USING (record in(select id from biblio.record_entry));
+ --DROP POLICY rls_merefure ON metabib.real_full_rec;
+ \dp metabib.real_full_rec
+
+ CREATE POLICY rls_mereatveli ON metabib.record_attr_vector_list TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_mereatveli ON metabib.record_attr_vector_list;
+ \dp metabib.record_attr_vector_list
+
+ CREATE POLICY rls_mereso ON metabib.record_sorter TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_mereso ON metabib.record_sorter;
+ \dp metabib.record_sorter
+
+ CREATE POLICY rls_mereso ON metabib.record_sorter TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_mereso ON metabib.record_sorter;
+ \dp metabib.record_sorter
+
+ CREATE POLICY rls_mesefien ON metabib.series_field_entry TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_mesefien ON metabib.series_field_entry;
+ \dp metabib.series_field_entry
+
+ CREATE POLICY rls_mesufien ON metabib.subject_field_entry TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_mesufien ON metabib.subject_field_entry;
+ \dp metabib.subject_field_entry
+
+ CREATE POLICY rls_metifien ON metabib.title_field_entry TO stest USING (source in(select id from biblio.record_entry));
+ --DROP POLICY rls_metifien ON metabib.title_field_entry;
+ \dp metabib.title_field_entry
+
+ CREATE POLICY rls_meunreatva ON metabib.uncontrolled_record_attr_value TO stest USING (true);
+ --DROP POLICY rls_meunreatva ON metabib.uncontrolled_record_attr_value;
+ \dp metabib.uncontrolled_record_attr_value
+
+ CREATE POLICY rls_mobi ON money.billing TO stest USING ((id < 100) or (id % 40000 = 0 and extract(year from create_date) >= extract(year from now())-1));
+ --DROP POLICY rls_mobi ON money.billing;
+ \dp money.billing
+
+ CREATE POLICY rls_moacad ON money.account_adjustment TO stest USING (billing in(select id from money.billing));
+ --DROP POLICY rls_moacad ON money.account_adjustment
+ \dp money.account_adjustment
+
+ CREATE POLICY rls_mobixa ON money.billable_xact TO stest USING (usr in(select id from actor.usr));
+ --DROP POLICY rls_mobixa ON money.billable_xact;
+ \dp money.billable_xact
+
+ CREATE POLICY rls_mocotr ON money.collections_tracker TO stest USING (usr in(select id from actor.usr) and collector in(select id from actor.usr));
+ --DROP POLICY rls_mocotr ON money.collections_tracker
+ \dp money.collections_tracker
+
+ CREATE POLICY rls_mogr ON money.grocery TO stest USING (usr in(select id from actor.usr));
+ --DROP POLICY rls_mogr ON money.grocery;
+ \dp money.grocery
+
+ CREATE POLICY rls_momabixasu ON money.materialized_billable_xact_summary TO stest USING (usr in(select id from actor.usr));
+ --DROP POLICY rls_momabixasu ON money.materialized_billable_xact_summary;
+ \dp money.materialized_billable_xact_summary
+
+ CREATE POLICY rls_mopa ON money.payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mopa ON money.payment;
+ \dp money.payment
+
+ CREATE POLICY rls_mobnpa ON money.bnm_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mobnpa ON money.bnm_payment;
+ \dp money.bnm_payment
+
+ CREATE POLICY rls_mowopa ON money.work_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mowopa ON money.work_payment;
+ \dp money.work_payment
+
+ CREATE POLICY rls_mobndepa ON money.bnm_desk_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary) and cash_drawer in(select id from actor.workstation));
+ --DROP POLICY rls_mobndepa ON money.bnm_desk_payment;
+ \dp money.bnm_desk_payment
+
+ CREATE POLICY rls_mocapa ON money.cash_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mocapa ON money.cash_payment;
+ \dp money.cash_payment
+
+ CREATE POLICY rls_mochpa ON money.check_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mochpa ON money.check_payment;
+ \dp money.check_payment
+
+ CREATE POLICY rls_mocrcapa ON money.credit_card_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mocrcapa ON money.credit_card_payment;
+ \dp money.credit_card_payment
+
+ CREATE POLICY rls_mocrpa ON money.credit_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mocrpa ON money.credit_payment;
+ \dp money.credit_payment
+
+ CREATE POLICY rls_mofopa ON money.forgive_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mofopa ON money.forgive_payment;
+ \dp money.forgive_payment
+
+ CREATE POLICY rls_mogopa ON money.goods_payment TO stest USING (xact in(select id from money.materialized_billable_xact_summary));
+ --DROP POLICY rls_mogopa ON money.goods_payment;
+ \dp money.goods_payment
+
+ >>
+
+ >>>> resume adding below policies to nc database <<<
+
+==
+LIST POLICIES:
+ select schemaname,tablename,policyname from pg_catalog.pg_policies order by 1,2,3;
+
+LIST TABLES WITHOUT POLICIES:
+ select * from (select schemaname,tablename from pg_catalog.pg_policies) as a right join (select schemaname,tablename from pg_catalog.pg_tables) as b
+ on a.schemaname = b.schemaname
+ and a.tablename = b.tablename and a.schemaname is null and a.tablename is null;
+
+EVERGREEN DISK SPACE PER SCHEMA:
+https://galencharlton.com/blog/2010/05/database-server-disk-space-usage-in-evergreen/
+ select schemaname,
+ pg_size_pretty(sum(
+ pg_total_relation_size(schemaname || '.' || tablename)
+ )::bigint) AS used
+ from pg_tables
+ group by schemaname
+ order by
+ sum(pg_total_relation_size(schemaname || '.' || tablename))::bigint desc;
+
+ >> "So, what’s my rule of thumb for estimating total disk space needed for an Evergreen database server? 200K per bibliographic record that you expect to have in your database three years from now".
+==
+
+DB SIZE BEFORE:
+SELECT pg_size_pretty( pg_database_size('dbname') );
+
+ pg_size_pretty
+----------------
+ 466 GB
+(1 row)
+
+
+SCHEMA BEFORE:
+ schemaname | used
+--------------------+---------
+ metabib | 204 GB
+ auditor | 73 GB
+ action | 49 GB
+ money | 42 GB
+ asset | 21 GB
+ action_trigger | 18 GB
+ actor | 18 GB
+ biblio | 11 GB
+ authority | 11 GB
+ acq | 6790 MB
+ m_coo | 3015 MB
+ reporter | 2981 MB
+ auth_load | 1266 MB
+ m_hal | 1198 MB
+ vandelay | 1080 MB
+ m_mad | 712 MB
+ seekdestroy | 354 MB
+ extend_reporter | 300 MB
+ m_sh | 289 MB
+ mymig | 284 MB
+ serial | 208 MB
+ container | 124 MB
+ m_madd | 85 MB
+ pg_catalog | 61 MB
+ m_polk | 45 MB
+ m_vance | 41 MB
+ m_circ_time | 21 MB
+ config | 7680 kB
+ staging | 4448 kB
+ offline | 2496 kB
+ edelweiss | 1856 kB
+ permission | 1840 kB
+ esi | 1656 kB
+ evergreen | 1648 kB
+ molib2go | 1232 kB
+ booking | 600 kB
+ query | 560 kB
+ information_schema | 344 kB
+ url_verify | 288 kB
+ rating | 192 kB
+ search | 80 kB
+ unapi | 64 kB
+(42 rows)
+
+
+
+DUMP AND RESTORE
+sudo su -
+# pg_dump --enable-row-security -U stest -h 127.0.0.1 -d nc > /mnt/evergreen/tmp/eg_subsetted.sql
+# su - postgres
+# createdb -T template0 -E UTF8 -U postgres -h 127.0.0.1 subsetted
+# psql -U postgres -h 127.0.0.1 -f /mnt/evergreen/tmp/eg_subsetted.sql subsetted
+
+
+DB SIZE AFTER:
+SELECT pg_size_pretty( pg_database_size('dbname') );
+
+ pg_size_pretty
+----------------
+ 7855 MB
+(1 row)
+
+
+SCHEMA AFTER:
+ select schemaname,
+ pg_size_pretty(sum(
+ pg_total_relation_size(schemaname || '.' || tablename)
+ )::bigint) AS used
+ from pg_tables
+ group by schemaname
+ order by
+ sum(pg_total_relation_size(schemaname || '.' || tablename))::bigint desc;
+
+ schemaname | used
+--------------------+------------
+ metabib | 6947 MB
+ authority | 391 MB
+ asset | 217 MB
+ biblio | 214 MB
+ pg_catalog | 33 MB
+ money | 18 MB
+ actor | 6280 kB
+ config | 5560 kB
+ action | 4568 kB
+ m_vance | 2328 kB
+ m_polk | 2152 kB
+ acq | 2024 kB
+ auditor | 1520 kB
+ action_trigger | 1368 kB
+ m_hal | 1288 kB
+ m_coo | 864 kB
+ m_mad | 832 kB
+ vandelay | 752 kB
+ m_madd | 736 kB
+ m_sh | 712 kB
+ container | 616 kB
+ serial | 616 kB
+ information_schema | 344 kB
+ edelweiss | 272 kB
+ reporter | 272 kB
+ query | 256 kB
+ permission | 224 kB
+ booking | 160 kB
+ evergreen | 136 kB
+ seekdestroy | 96 kB
+ staging | 96 kB
+ url_verify | 88 kB
+ rating | 80 kB
+ offline | 80 kB
+ auth_load | 32 kB
+ molib2go | 32 kB
+ search | 24 kB
+ unapi | 16 kB
+ mymig | 16 kB
+ m_circ_time | 16 kB
+ extend_reporter | 8192 bytes
+ esi | 0 bytes
+(42 rows)
\ No newline at end of file