DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports Events Over 2 million developers have joined DZone. Join Today! Thanks for visiting DZone today,
Edit Profile Manage Email Subscriptions Moderation Admin Console How to Post to DZone Article Submission Guidelines
View Profile
Sign Out
Refcards
Trend Reports
Events
Zones
Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
  1. DZone
  2. Data Engineering
  3. Databases
  4. Revealing the Queries Behind Psql's Backslash Commands

Revealing the Queries Behind Psql's Backslash Commands

Psql has a lot of super useful backslash commands, but sometimes it's even more useful to know the queries behind them.

Dustin Marx user avatar by
Dustin Marx
·
Feb. 06, 19 · Tutorial
Like (1)
Save
Tweet
Share
11.16K Views

Join the DZone community and get the full member experience.

Join For Free

PostgreSQL's psql interactive terminal tool provides several useful "backslash list commands" such as \d (lists "relations" such as tables, views, indexes, and sequences), \dt (lists tables), \di (lists indexes), \ds (lists sequences), \dv (lists views), \df (lists functions), \du (lists roles), and \? (displays help/usage details on backslash commands). These commands are concise and much simpler to use than writing the queries against PostgreSQL system catalogs ( pg_class, pg_roles, pg_namespace, pg_trigger, pg_index, etc.) and information_schema that would provide the same types of details.

Although the psql backslash commands are easier to use than their associated queries, there are situations when it is important to know the full query behind a particular command. These situations include needing to perform a slightly different/adapted query from that associated with the pre-built command and needing to perform similar queries in scripts or code that are being used as PostgreSQL clients instead of psql. These situations make it important to be able to determine what queries psql is performing and the psql option -E (or --echo-hidden) allow that.

The PostgreSQL psql documentation states that the psql options -E and --echo-hidden "echo the actual queries generated by \d and other backslash commands." The documentation adds commentary on why this is useful. "You can use this to study psql's internal operations." When psql is started with the -E or --echo-hidden options, it will display the query associated with a backslash command before executing that command. The next screen snapshot illustrates this for the \du command used to show roles.

From use of psql -E and execution of the command \du, we're able to see that the query underling \du is this:

SELECT r.rolname, r.rolsuper, r.rolinherit,
  r.rolcreaterole, r.rolcreatedb, r.rolcanlogin,
  r.rolconnlimit, r.rolvaliduntil,
  ARRAY(SELECT b.rolname
        FROM pg_catalog.pg_auth_members m
        JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid)
        WHERE m.member = r.oid) as memberof
, r.rolreplication
, r.rolbypassrls
FROM pg_catalog.pg_roles r
WHERE r.rolname !~ '^pg_'
ORDER BY 1;

Although the query is not nearly as nice to use as \du, we are now able to adapt this query for a related but different use case and are able to run this query from a PostgreSQL client other than psql.

Database Command (computing)

Published at DZone with permission of Dustin Marx, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Popular on DZone

  • Java Development Trends 2023
  • Using JSON Web Encryption (JWE)
  • Top Five Tools for AI-based Test Automation
  • Why Every Fintech Company Needs DevOps

Comments

Partner Resources

X

ABOUT US

  • About DZone
  • Send feedback
  • Careers
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 600 Park Offices Drive
  • Suite 300
  • Durham, NC 27709
  • support@dzone.com
  • +1 (919) 678-0300

Let's be friends: