diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml
index 82fba48d5f..360cb48f70 100644
--- a/doc/src/sgml/func.sgml
+++ b/doc/src/sgml/func.sgml
@@ -17625,6 +17625,11 @@ $.* ? (@ like_regex "^\\d+$")
         command.
       
        
+
+SELECT nextval('myseq'::regclass);
+
+      
+       
         This function requires USAGE
         or UPDATE privilege on the sequence.
        
@@ -17657,11 +17662,11 @@ $.* ? (@ like_regex "^\\d+$")
         Furthermore, the value reported by currval is not
         changed in this case.  For example,
 
-SELECT setval('myseq', 42);           Next nextval will return 43
-SELECT setval('myseq', 42, true);     Same as above
-SELECT setval('myseq', 42, false);    Next nextval will return 42
+SELECT setval('myseq', 42);           -- The next nextval('myseq') will return 43
+SELECT setval('myseq', 42, true);     -- Same as above
+SELECT setval('myseq', 42, false);    -- The next nextval('myseq') will return 42
 
-        The result returned by setval is just the value of its
+        The result returned by setval is the value of its
         second argument.
        
        
@@ -17669,7 +17674,6 @@ SELECT setval('myseq', 42, false);    Next nextval
       
-
       
        
         
@@ -17686,6 +17690,9 @@ SELECT setval('myseq', 42, false);    Next nextvalnextval since
         the current session did.
+
+SELECT currval('myseq'::regclass);
+
        
        
         This function requires USAGE
@@ -17707,19 +17714,75 @@ SELECT setval('myseq', 42, false);    Next nextvalcurrval, except that instead
         of taking the sequence name as an argument it refers to whichever
         sequence nextval was most recently applied to
-        in the current session. It is an error to call
-        lastval if nextval
-        has not yet been called in the current session.
+        in the current session. (An error is reported if nextval has
+        never been called in this session.) 
+ 
+SELECT lastval();
+
        
        
         This function requires USAGE
         or SELECT privilege on the last used sequence.
        
       
+      
+       
+      
+      
      
     
    
+  Example
+
+CREATE SCHEMA play;                            -- Create a play schema
+SET search_path = play;                        -- Make sure we create this in the play schema
+
+CREATE SEQUENCE test_seq;
+
+SELECT nextval('test_seq'::regclass);          -- 1
+SELECT currval('test_seq');                    -- 1
+SELECT lastval();                              -- 1
 
+-- If you want to see this sequence in psql
+\ds test_seq
+-- If you want to see all sequences in psql
+\ds
+
+-- Using the DEFAULT value you can assign this SEQUENCE to be used when the field is not assigned a value
+CREATE TABLE t1 (id bigint NOT NULL DEFAULT nextval('test_seq'), other_data text); -- links column/sequence
+
+INSERT INTO t1 (other_data) VALUES ('Some Data');  -- Assigns the next ID automatically
+INSERT INTO t1 (other_data) VALUES ('Some Data')
+  RETURNING id;                                    -- Assigns the next ID, and returns it to you!
+
+INSERT INTO t1 (id, other_data) VALUES (NULL, 'Some Data');
+-- Oops, you forced the ID to NULL: error violates not-null constraint
+
+INSERT INTO t1 (id, other_data) VALUES (nextval('test_seq'), 'Some Data')
+  RETURNING id;                                    -- Redundant, but useful in some ETL
+
+-- If you create a table with the GENERATED syntax, a sequence is generated behind the scenes
+
+CREATE TABLE t2 ( id bigint PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY, other_data text);
+
+-- An implicit sequence named t2_id_seq is created
+
+INSERT INTO t2 (other_data) values ('data') RETURNING id;   -- 1
+SELECT currval('t2_id_seq'::regclass);                      -- 1
+
+SELECT setval('t2_id_seq', 10);
+INSERT INTO t2 (other_data) values (1234)  RETURNING id;    -- 11
+  
+SELECT lastval();                                           -- 11
+
+-- Finally, how can you determine the sequence name used for a GENERATED SEQUENCE?
+SELECT pg_get_serial_sequence('t2', 'id');
+
+-- And therefore you can use it with the functions in this section, without knowing it's name
+SELECT currval(pg_get_serial_sequence('t2', 'id')); 
+
+
+  
   
    
     To avoid blocking concurrent transactions that obtain numbers from