Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
emerson89
Helper I
Helper I

Power Query M function in Paginate API

Hi,

I created this api paginated below. It works correctly, but in the OFFSET property, I need to stipulate instead of the number of the next page, the next record of the second page, and so on.

 

- My record limit per page is 250

- The field totalItems returned me the total of records, for example: 4500

- I divide the total number of records by the total number of records per page, to get to know how many pages my api has:  pageRange = {0..Number.RoundUp(totalItems / 250)}
- When going to the second page, what happens in the API below, is that the records of the second page are coming repeated, because I should instead use the number 1 (referring to the second page), pass the number 251, and then, when doing the loop again, pass the number 501, until finishing the whole sequence (this parameter in the api is: offset=.

 

My code:

 

 

 

 

let
    ufnCallAPI = (nPage) =>
        let
            query = Web.Contents("https://api.vhsys.com/v2/pedidos?offset=" & Number.ToText(nPage)  &  "&limit=250", 
            [Headers=[#"access-token"="OCKNYbAMaDgLBZBSQPCOGPWOXGSbdO", #"secret-access-token"="XXXXXXXXXXX"]]),
            result = Json.Document(query)
        in
            result,

        tmpResult = ufnCallAPI(1),

        auxTotal1 = Record.ToTable(tmpResult),
        Value = auxTotal1{2}[Value],
        auxTotal2 = Value[total],

        totalItems = auxTotal2 - 1,
        pageRange = {0..Number.RoundUp(totalItems / 250)},
        pages = List.Transform(pageRange, each ufnCallAPI(_)),
        pages2 = Table.FromList(pages, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
        pages3 = Table.ExpandRecordColumn(pages2, "Column1", {"code", "status", "paging", "data"}, {"Column1.code", "Column1.status", "Column1.paging", "Column1.data"}),
        pages4 = Table.ExpandListColumn(pages3, "Column1.data"),
        pages5 = Table.RemoveColumns(pages4,{"Column1.code", "Column1.status", "Column1.paging"}),
        data = Table.ExpandRecordColumn(pages5, "Column1.data", {"id_ped", "id_pedido", "id_cliente", "nome_cliente", "id_local_retirada", "id_local_cobranca", "vendedor_pedido", "vendedor_pedido_id", "listapreco_produtos", "valor_total_produtos", "desconto_pedido", "desconto_pedido_porc", "peso_total_nota", "peso_total_nota_liq", "frete_pedido", "valor_total_nota", "valor_baseICMS", "valor_ICMS", "valor_baseST", "valor_ST", "valor_IPI", "condicao_pagamento_id", "condicao_pagamento", "frete_por_pedido", "transportadora_pedido", "id_transportadora", "data_pedido", "prazo_entrega", "referencia_pedido", "obs_pedido", "obs_interno_pedido", "status_pedido", "contas_pedido", "comissao_pedido", "estoque_pedido", "ordemc_emitido", "data_cad_pedido", "data_mod_pedido", "id_aplicativo", "id_pedido_aplicativo", "lixeira"}, {"id_ped", "id_pedido", "id_cliente", "nome_cliente", "id_local_retirada", "id_local_cobranca", "vendedor_pedido", "vendedor_pedido_id", "listapreco_produtos", "valor_total_produtos", "desconto_pedido", "desconto_pedido_porc", "peso_total_nota", "peso_total_nota_liq", "frete_pedido", "valor_total_nota", "valor_baseICMS", "valor_ICMS", "valor_baseST", "valor_ST", "valor_IPI", "condicao_pagamento_id", "condicao_pagamento", "frete_por_pedido", "transportadora_pedido", "id_transportadora", "data_pedido", "prazo_entrega", "referencia_pedido", "obs_pedido", "obs_interno_pedido", "status_pedido", "contas_pedido", "comissao_pedido", "estoque_pedido", "ordemc_emitido", "data_cad_pedido", "data_mod_pedido", "id_aplicativo", "id_pedido_aplicativo", "lixeira"}),
    #"Tipo Alterado" = Table.TransformColumnTypes(data,{{"id_ped", type text}, {"id_pedido", Int64.Type}, {"nome_cliente", type text}, {"valor_total_produtos", type text}}),
    #"Valor Substituído" = Table.ReplaceValue(#"Tipo Alterado",".",",",Replacer.ReplaceText,{"valor_total_produtos"}),
    #"Tipo Alterado1" = Table.TransformColumnTypes(#"Valor Substituído",{{"valor_total_produtos", Currency.Type}}),
    #"Valor Substituído1" = Table.ReplaceValue(#"Tipo Alterado1",".",",",Replacer.ReplaceValue,{"desconto_pedido", "desconto_pedido_porc", "peso_total_nota", "peso_total_nota_liq", "frete_pedido", "valor_total_nota", "valor_baseICMS", "valor_ICMS", "valor_baseST", "valor_ST", "valor_IPI"}),
    #"Tipo Alterado2" = Table.TransformColumnTypes(#"Valor Substituído1",{{"desconto_pedido", Currency.Type}, {"desconto_pedido_porc", Currency.Type}, {"peso_total_nota", Currency.Type}, {"peso_total_nota_liq", Currency.Type}, {"frete_pedido", Currency.Type}, {"valor_total_nota", type text}, {"valor_baseICMS", Currency.Type}, {"valor_ICMS", Currency.Type}, {"valor_baseST", Currency.Type}, {"valor_ST", Currency.Type}, {"valor_IPI", Currency.Type}, {"prazo_entrega", type text}, {"data_pedido", type date}}),
    #"Colunas Removidas" = Table.RemoveColumns(#"Tipo Alterado2",{"id_aplicativo", "id_pedido_aplicativo", "lixeira"}),
    #"Tipo Alterado3" = Table.TransformColumnTypes(#"Colunas Removidas",{{"valor_total_nota", type text}}),
    #"Valor Substituído2" = Table.ReplaceValue(#"Tipo Alterado3",".",",",Replacer.ReplaceText,{"valor_total_nota"}),
    #"Tipo Alterado4" = Table.TransformColumnTypes(#"Valor Substituído2",{{"valor_total_nota", Currency.Type}})
   
in
#"Tipo Alterado4"

 

 

 

 

I need alter this lines:
pageRange = {0..Number.RoundUp(totalItems / 250)},
pages = List.Transform(pageRange, each ufnCallAPI(_)),

and inclued a FOR/WHILE to modified my API to not pass the number of the next page, but the number of the beginning of the list of the next page (offset)

 

I believe that in this part of the code pageRange = {0..Number.RoundUp (totalItems / 250)}, I need to leave something like:

for (i = 0; i <totalItems, i ++)
{
pageRange = ???
}


Thanks very much!

 

1 ACCEPTED SOLUTION
v-lid-msft
Community Support
Community Support

Hi @emerson89 ,

 

For example the total Items return 600, then the pageRange return{0,1,2,3} , the offset will be 1, 251, 501. please change this step

 

pageRange = {0..Number.RoundUp(totalItems / 250)}
pages = List.Transform(pageRange, each ufnCallAPI(_)),

 

to following:

 

pageRange = {0..Number.RoundUp(totalItems / 250)-1}
pages = List.Transform(pageRange, each ufnCallAPI(_*250+1)),

 


Best regards,

 

 

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

3 REPLIES 3
v-lid-msft
Community Support
Community Support

Hi @emerson89 ,

 

For example the total Items return 600, then the pageRange return{0,1,2,3} , the offset will be 1, 251, 501. please change this step

 

pageRange = {0..Number.RoundUp(totalItems / 250)}
pages = List.Transform(pageRange, each ufnCallAPI(_)),

 

to following:

 

pageRange = {0..Number.RoundUp(totalItems / 250)-1}
pages = List.Transform(pageRange, each ufnCallAPI(_*250+1)),

 


Best regards,

 

 

Community Support Team _ Dong Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Anonymous
Not applicable

Pessoal estou com um probleminha e gostaria da ajuda de vcs se puderem...

 

Preciso de um codigo de api que conecte ao sistema VHSYS e faça a requisição de alguns dados específicos 

 

Meu codigo;

 

let
ufnCallAPI = (nPage) =>
let
query = Web.Contents("https://api.vhsys.com/v2/contas-pagar?offset=" & Number.ToText(nPage) & "&limit=250",
[Headers=[#"access-token"="XXXXXXXXXXXXXXXXXXXX", #"secret-access-token"="XXXXXXXXXXXXXXXXXXXXX"]]),
result = Json.Document(query)
in
result,

tmpResult = ufnCallAPI(1),

auxTotal1 = Record.ToTable(tmpResult),
Value = auxTotal1{2}[Value],
auxTotal2 = Value[total],

totalItems = auxTotal2 - 1,
pageRange = {0..Number.RoundUp(totalItems / 250)-1},

pages = List.Transform(pageRange, each ufnCallAPI(_*250+1)),

pages2 = Table.FromList(pages, Splitter.SplitByNothing(), null, null, ExtraValues.Error),

pages3 = Table.ExpandRecordColumn(pages2, "Column1", {"code", "status", "paging", "data"}, {"Column1.code", "Column1.status", "Column1.paging", "Column1.data"}),

pages4 = Table.ExpandListColumn(pages3, "Column1.data"),

pages5 = Table.RemoveColumns(pages4,{"Column1.code", "Column1.status", "Column1.paging"}),

 

 

preciso que na planilha gerada venha com os campos;

FILIAL

CNPJ FILIAL

EMISSAO

VENCIMENTO

DATA DE LIQUIDACAO

DATA DE CADASTRO

DATA DE ALTERACAO

SITUACAO

DOCUMENTO

FORNECEDOR

CNPJ/CPF

CEP

CIDADE

ESTADO

NOME DA EMPRESA

CONTA BANCARIA

CENTRO DE CUSTO

CATEGORIA

FORMA DE PAGAMENTO

OBSERVACOES.

 

Poderiam me dar uma força?

Hey @v-lid-msft ,

 

Your solution is perfect.

Thank you very much, I tried in several ways and there was no thinking about this excellent solution. Answered what I needed!

 

Best regards,

Emerson

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.