Scrollable ResultSet Pagination Sample
Hi everyone.
This is a full example how to use a %ScrollableResultSet for results pagination using %DynamicQuery:SQL and build a JSON response including page details.
Feel free to use, share, comment or improve it.
Kind Regards
ClassMethod getPersonsPag(iAge As %Integer, sortField As %String = 1, sortOrder As %String = 2, pageSize As %String = 20, pageIndex As %String = 1) As %DynamicObject
{
set out = []
set vFrom = ((pageIndex -1 ) * pageSize)+1
set vTo = vFrom + (pageSize-1)
set sql = "SELECT ID,SSN,LastName,GivenName,SecondaryName, Gender, Age "_
"FROM Sample.Person WHERE Age > ? "_
"Order By "_sortField _" "_ $CASE(sortOrder,1:"ASC",2:"DESC",:"ASC")
Set rs=##class(%ScrollableResultSet).%New("%DynamicQuery:SQL")
set sc = rs.Prepare(sql)
set sc = rs.Execute(iAge) If $$$ISERR(sc) Do DisplayError^%apiOBJ(sc) Quit
if (rs.Count()=0) Quit {"msg" : "No Records Found"}
Do rs.CurrRowSet(vFrom)
if pageSize >= rs.Count() set pageSize = rs.Count()
try{
FOR i=1:1:pageSize{
Do out.%Push({
"index": (i),
"pid": (rs.%Get("ID")),
"ssn" : (rs.%Get("SSN")),
"lastname" : (rs.%Get("LastName")) ,
"givenname": (rs.%Get("GivenName")),
"secondaryname": (rs.%Get("SecondaryName")) ,
"gender": (rs.%Get("Gender")),
"age": (rs.%Get("Age") )
})
Do rs.%Next()
}
}
catch(e){ }
set outJson = []
Do outJson.%Push({
"pageSize":(pageSize),
"pageIndex":(pageIndex),
"fromIndex":(vFrom),
"toIndex":(vFrom+i - 1),
"resultSetTotal":(rs.Count()),
"pageRecords":(i),
"pages":($NORMALIZE((rs.Count()/pageSize),0)),
"resultSet":(out)
})
return outJson
}Comments
Hi Rubén,
Another proposition on IRIS 2021.1+ can be this one with the use of the new window (OVER) function :
ClassMethod getPersonsPagWindow(iAge As %Integer, sortField As %String = 1, sortOrder As %String = 2, pageSize As %String = 20, pageIndex As %String = 1) As %DynamicObject
{
set out = []
set vFrom = ((pageIndex -1 ) * pageSize)+1
set vTo = vFrom + (pageSize-1)
set sql = "SELECT * "_
"FROM ( SELECT persons.* "_
" , ROW_NUMBER() OVER (ORDER By "_sortField_" "_ $CASE(sortOrder,1:"ASC",2:"DESC",:"ASC")_
" ) rn "_
" FROM Sample.Person persons where Age > ? "_
" ) tmp "_
"WHERE rn between "_vFrom_" and "_vTo_" "_
"ORDER By "_sortField_" "_ $CASE(sortOrder,1:"ASC",2:"DESC",:"ASC")
Set rs=##class(%ResultSet).%New("%DynamicQuery:SQL")
set sc = rs.Prepare(sql)
set sc = rs.Execute(iAge) If $$$ISERR(sc) Do DisplayError^%apiOBJ(sc) Quit
while rs.%Next() {
Do out.%Push({
"pid": (rs.%Get("ID")),
"ssn" : (rs.%Get("SSN")),
"lastname" : (rs.%Get("LastName")) ,
"givenname": (rs.%Get("GivenName")),
"secondaryname": (rs.%Get("SecondaryName")) ,
"gender": (rs.%Get("Gender")),
"age": (rs.%Get("Age") )
})
}
set outJson = []
Do outJson.%Push({
"pageSize":(pageSize),
"pageIndex":(pageIndex),
"fromIndex":(vFrom),
"toIndex":(vTo),
"resultSet":(out)
})
return outJson
}
I bench the two solutions on a dataset of 100 000 rows without index with a result of 20 elements on page 1 and here are the results :
"getPersonsPag timed : 1,647 secondes"
"getPersonsPagWindow timed : 0,247 secondes"
I guess that the window function is faster because you don't have to fetch all the data in a global before paging.
That's Really Awesome! Thanks for the information!
The idea of a scrollable result set is to call Save/OpenId - and the result set would continue on a next row automatically. So you don't need to manage to/from indices:
Here's an example
It's also about 3 times faster since the query is only executed once:
do ##class(User.Pagination).Time("Save")
Save took 0,0048 sec
do ##class(User.Pagination).Time("NoSave")
NoSave took 0,0143 secThat's Really Awesome! Thanks for the information!
Addition to the above: Speedup SQL pagination
Forgive if this is a dumb question, but I'm a little new to IRIS SQL. What does the "iAge" variable represent and what does it do in rs.Execute(iAge) ?
it passes the parameter iAge to the sql statement.
the sql statement have one parameter ?, so it will take place here.
Ah, I see, I didn't realize you could pass parameters into a SQL Statement that way. Thank you!