• Home
  • Services
    • HR Services
      • HR Advisory Services
      • Contract Staffing
      • HR Outsourcing Services
      • Manpower Supply Services
      • Payroll Processing
      • Permanent Placement
      • Recruitment and Placement Services
      • Recruitment Process Outsourcing
      • Staffing Agency Services
    • DBA Support
      • DBA Consultancy Services
      • PostgreSQL Support
    • Website Maintenance
    • Company Registration Services
    • Virtual Office Space Address
  • Company
    • FAQs
    • About Us
    • Contact
  • Locations
  • Blogs
    • Blog
    • Blog – PostgreSQL Support
    • Blog – PostgreSQL Migration
    • Blog – All DB’s
    • Blog – Linux
  • Courses

    About Courses

    • List Of Courses
    • Become an Instructor
    Greenplum

    Greenplum

    $1,500.00
    Read More
    Have any question?
    (+91)8838953252
    ITsupport@rayafeel.com
    Login
    RayaFeeL
    • Home
    • Services
      • HR Services
        • HR Advisory Services
        • Contract Staffing
        • HR Outsourcing Services
        • Manpower Supply Services
        • Payroll Processing
        • Permanent Placement
        • Recruitment and Placement Services
        • Recruitment Process Outsourcing
        • Staffing Agency Services
      • DBA Support
        • DBA Consultancy Services
        • PostgreSQL Support
      • Website Maintenance
      • Company Registration Services
      • Virtual Office Space Address
    • Company
      • FAQs
      • About Us
      • Contact
    • Locations
    • Blogs
      • Blog
      • Blog – PostgreSQL Support
      • Blog – PostgreSQL Migration
      • Blog – All DB’s
      • Blog – Linux
    • Courses

      About Courses

      • List Of Courses
      • Become an Instructor
      Greenplum

      Greenplum

      $1,500.00
      Read More

      Blog

      • Home
      • Blog
      • Blog
      • Postgres user creation and restrict DDL & database access

      Postgres user creation and restrict DDL & database access

      • Posted by Nijamutheen J
      • Categories Blog
      • Date September 13, 2019
      • Comments 0 comment

      How to create a postgres user ? user should not have any DDL execution permission on postgres database.
      and the user should not connect other database means user need to restrict the other database connectivity

      How to achive this ?

      Note : Db_name is nijam, user and schema name should be nijam.

      Connecting the database where you want to create schema:

      \c nijam

      Creating seperate schema for nijam user:

      create schema nijam;

      creating postgres user :

      CREATE ROLE nijam WITH LOGIN PASSWORD 'Nijam@$%&123';

      Grant connect to the database:

      GRANT CONNECT ON DATABASE nijam TO nijam;
      GRANT USAGE ON schema nijam TO nijam;

      Now you cannot create any objects on non default databases but you can create objects in default databases(postgres,template1) of default schemas (public) .

      NON_default Database:
      ================

      nijam=> \dn
      List of schemas
      Name | Owner
      --------+---------
      nijam | pginsta
      public | pginsta
      (2 rows)

      Default schema of non default database:

      nijam=> show search_path;
      search_path
      -----------------
      "$user", public
      (1 row)
      
      nijam=> create table t1(id int);
      ERROR: permission denied for schema nijam
      LINE 1: create table t1(id int);
      ^

      Non default schema of non default database:

      pginsta=> \c nijam
      You are now connected to database "nijam" as user "nijam".
      nijam=> set search_path=nijam;
      SET
      nijam=> create table t(id int);
      ERROR: permission denied for schema nijam
      LINE 1: create table t(id int);

      Default Database :
      ============

      $ psql -U nijam -d postgres
      psql (10.5)
      Type "help" for help.
      
      postgres=> create schema schema1;
      ERROR: permission denied for database postgres
      postgres=>

      Default schema of Default database:

      postgres=> show search_Path;
      search_path
      -----------------
      "$user", public
      (1 row)
      
      postgres=> create table t1(id int);
      CREATE TABLE
      
      postgres=> drop table t1;
      DROP TABLE

      As super user create a default schema :

      nijam@2ndquadrant.in:/nijam> psql -d postgres
      psql (10.5)
      Type "help" for help.
      
      postgres=# create schema schema1;
      CREATE SCHEMA
      postgres=#
      
      postgres=> \dn
      List of schemas
      Name | Owner
      ---------+---------
      public | pginsta
      schema1 | pginsta
      (2 rows)

      Non default schema of default database:

      nijam@2ndquadrant.in:/nijam> psql -U nijam -d postgres
      psql (10.5)
      Type "help" for help.
      
      postgres=> set search_path=schema1;
      SET
      postgres=> show search_path;
      search_path
      -------------
      schema1
      (1 row)
      
      postgres=> create table t1(id int);
      ERROR: no schema has been selected to create in
      LINE 1: create table t1(id int);

      FOR POSTGRES DB RESTRICTION :
      ==========================

      We have much more control here. If we do not grant access to a specific database we will not be able to connect. So we might grant access to the postgres_db database but not to the postgres database by adding this line to pg_hba.conf:

      host postgres_db nijam 192.168.1.5/32 md5
      nijam@2ndquadrant.in~$ psql -h 192.168.1.5 -p 5444 -U nijam -d postgres_db
      Password for user nijam:
      psql (9.3.10, server 9.4.5.12)
      WARNING: psql major version 9.3, server major version 9.4.
      Some psql features might not work.
      Type "help" for help.
      
      postgres_db=>

      But we are not able to connect to any other database:

      nijam@2ndquadrant.in~$ psql -h 192.168.1.5 -p 5444 -U nijam -d postgres
      psql: FATAL: no pg_hba.conf entry for host "192.168.22.1", user "nijam", database "postgres", SSL off
      
      nijam@2ndquadrant.in~$ psql -h 192.168.22.22 -p 5444 -U nijam -d template1
      psql: FATAL: no pg_hba.conf entry for host "192.168.22.1", user "nijam", database "template1", SSL off

      Granting create and table access privileges to bvms user for bvms schema :

      psql -d bvms -U pginsta
      \c bvms
      Grant CREATE ON SCHEMA bvms to bvms;

      Creating t1 table as bvms user connected with bvms schema :

      psql -U bvms
      set search_path=bvms;
      show search_path;
      drop table t1;
      create table t1(id int);
      
      psql -U bvms
      set search_path=public;
      show search_path;
      drop table t1;
      create table t1(id int);
      
      bvms=> create table t1(id int);
      CREATE TABLE
      bvms=> drop table t1;
      DROP TABLE

      • Share:
      Nijamutheen J
      Nijamutheen J

      Nijamutheen J 7+ years of experience in PostgreSQL, Linux admin , web hosting - apache server , Oracle ,mySQL, Mriadb, vertica DB & Server security administrator

      My updated resume is https://www.tutorialdba.com/p/hi-i-have-4.html

      Previous post

      PostgreSQL SSL Setup
      September 13, 2019

      Next post

      Tools for PostgreSQL
      September 16, 2019

      Leave A Reply

      You must be logged in to post a comment.

      Connect with



      Search

      ADVERTISEMENT

      Latest Posts

      Tips to Choose the Best Serviced Office for Your Business
      24May2022
      What key considerations do you need to keep in mind when choosing a new serviced office to house your business?
      24May2022
      The Benefits of Coworking
      24May2022
      The Long-Term Impact of Coworking
      24May2022
      Are you spending more money than you earn? Outsource with Ease and Move When You’re Ready
      24May2022
      PostgreSQL

      PostgreSQL

      $800.00 $500.00
      Greenplum

      Greenplum

      $1,500.00
      Oracle Database

      Oracle Database

      $350.00
      2ndquadrant.in

      (+91) 8838953252

      ITsupport@rayafeel.com

      Company

      • About Us
      • Our Team

      COURSES

      • List Of Course
      • Become An Instructor

      Support

      • DBA Support
      • Consultancy Services

      Recommend

      • Login
      • Contact Us

      IT Services by rayafeel.com. Powered by Rayafeel Technologies Pvt Ltd.

      • Privacy
      • Terms

      Become An Instructor?

      Join thousand of instructors and earn money hassle free!

      Get Started Now

      Connect with

      Login with Google Login with Twitter Login with Linkedin Login with Windowslive Login with Yahoo

      Login with your site account

      Connect with



      Lost your password?